Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Cursor Sharing| Soft Parsing
Interesting. Sometimes you've got to test things and not just believe what
you read.
> now if I revoke the permissions on the table.
Hmmm... if you modify a table all the associated shared SQL area is
invalidated. I wonder if something like that is going on when you alter user
privileges? Maybe the cached cursor is nolonger available?
Sometimes trying to figure out what Oracle is doing is like smashing sub-atomic particles together at the speed of light. You deduce the way it was put together by the way it broke into pieces. Kind of crude but what else can you do without the source code of the creator?
Steve Orr
-----Original Message-----
Sent: Thursday, July 25, 2002 3:58 PM
To: Multiple recipients of list ORACLE-L
Importance: High
I checked the Tom Kyte site. A soft parse comprises two operations. One
is a simple syntax check;
e.g. "select from dual;" would fail this soft parse as it is missing a
column list or a literal.
The other portion of a soft parse what he calls a semantics check is
checking to see if the tables and columns exist, that the person has the
proper permissions, that there are no ambiguities.
select deptno from emp, dept
where emp.deptno = dept.deptno
/
would fail this type of parse. My Kyte's definition of a soft parse jibes nicely with the one I used earlier. I didn't include the syntactical error portion as the statements in question are all valid SQL. However it is just as important. Semantic and syntactical checks are done; i.e.., a soft parse is done before the cache is checked.
Quoting from the article
"The next step in the parse operation is to see if the statement we are
currently
parsing has already in fact been processed by some other session. If it has
?
we may be in luck here, we can skip the next two steps in the process, that
of
optimization and row source generation. If we can skip these next two steps
in
the process, we have done what is known as a Soft Parse.
While writing this it has suddenly dawned on me what Suhen was talking about when said cursor_sharing = 'FORCE' avoids a hard parse at the cost of a soft.
If this is set
select * from emp where ename = 'KING';
will be soft parsed.
It will be changed to
select * from emp where ename = :bind_variable;
This statement will undergo soft parsing again.
If the statement can be found in cache; then no hard parsing is needed. The generation of the second SQL statement replacing the literal with a bind variables increases the likelihood of not having to hard parse.
1 select a.name, b.value
2 from v$sysstat a, v$sesstat b
3 where a.statistic# = b.statistic#
4 and a.statistic# = 191
5* and b.sid = 8
SQL> /
NAME VALUE ---------------------------------------------------------------- --------- session cursor cache hits 10 ----------------------------------------------------------------------------
1* select ename from scott.emp where empno = :v_empno SQL> / ENAME
NAME VALUE ---------------------------------------------------------------- --------- session cursor cache hits 11
now if I revoke the permissions on the table.
SQL> /
select ename from scott.emp where empno = :v_empno
*
ORA-01031: insufficient privileges ---------------------------------------------------------------------------- ---------------
The article posted by Tom Kyte, does not state that session_cached_cursors avoids soft parses. It says they make finding the cursor less expensive. Particularly the expense of latching the shared pool and the library cache.
He runs a query 1000 times. Once without it being cached and again with it being cached and finds
NAME RUN1 RUN2 DIFF ---------------------------------------- ---------- ---------- ---------- LATCH.shared pool 2142 1097 -1045 LATCH.library cache 17361 2388 -14973 ============================================================================ ==================
The lesser latch count is for the query using session_cached cursors. Session_Cached_Cursors do save on resources and are important to scalability. But I have yet to see something which proves they stop soft parsing.
I saw Steve' Orr's contribution
"An entry is created
for the session's cursor cache and future cursor CLOSEs are ignored. Once in
the session cursor cache the SQL statement does not need to be reparsed.
This gives a significant performance boost!
Giving credit where due: The above was "inspired" from pages 277-280 in "Scaling Oracle8i" by James Morle."
I have posted material which refutes the above.
Again how does one avoid the soft parsing?
-----Original Message-----
Sent: Wednesday, July 24, 2002 11:43 PM
To: Multiple recipients of list ORACLE-L
Ian,
When coding you should parse once and execute the query many times rather than
loop
parse
bind
execute
close
end;
It can be seen that a parse operation is done on each iteration through the loop. You may have avoided hard parsing but the program is still soft parsing. It has to check the shared pool for the query executed each time.
When coding u should rather
parse
loop
bind
execute
end;
close;
So you would be parsing once and executing the query several times. Therefore reduction on latch contention which makes your application more scalable and hence better performance.
Check out
http://asktom.oracle.com/pls/ask/f?p=4950:8:1092060::NO::F4950_P8_DISPLAYID,
F4950_P8_CRITERIA:2588723819082,%7Bsoft%7D%20and%20%7Bparsing%7D
Also see Bjorn's paper on bind variables
Cheers
Suhen
> Please define soft parsing. Oracle needs to check that the user
> submitting a SQL statement has permissions to run it. It has to do this
> every time a statement is run, bind variables or not. I thought the
> processing of the statement to check permissions to be soft parsing. But,
> perhaps I'm misinformed.
>
> When "cursor-sharing" converts a statement to use bind variables it
would
> save on hard parsing, if a match were found the pool; also, it could
lessen
> the number of statements present in the pool.
>
>
> >
>
>
>
>
>
>
>
>
>
>
>
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Suhen Pather INET: Suhen.Pather_at_strandbags.com.au -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Orr, Steve INET: sorr_at_rightnow.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).Received on Thu Jul 25 2002 - 18:43:18 CDT
![]() |
![]() |