Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Cursor Sharing| Soft Parsing
Possibly burying myself deeper: Parsing is done at the open call. If a cursor needs to be
re-opened, Oracle will check for permissions whether cursors are cached or not.
Some experiments. First just using bind variables in the statement.
SQL> alter session set session_cached_cursors = 10;
Session altered.
SQL> VARIABLE V_EMPNO NUMBER
BEGIN
:V_EMPNO := 7934;
END;
/
SQL> select ename from scott.emp where empno = :v_empno;
ENAME
SQL> BEGIN
2 :V_EMPNO := 7782;
3 END;
4 /
PL/SQL procedure successfully completed.
SQL> select ename from scott.emp where empno = :v_empno;
ENAME
and the above statement is rerun
SQL> /
select ename from scott.emp where empno = :v_empno
*
SQL> variable my_select refcursor;
SQL> BEGIN
2 OPEN :my_select FOR SELECT ename from s
3 END;
4 /
PL/SQL procedure successfully completed.
SQL> print my_select
ENAME
If "scott" revokes permisssions at this point.
SQL> BEGIN
2 OPEN :my_select FOR SELECT ename from scott.emp;
3 END;
4 /
OPEN :my_select FOR SELECT ename from scott.emp;
*ERROR at line 2:
ORA-06550: line 2, column 45: PLS-00904: insufficient privilege to access object SCOTT.EMP ORA-06550: line 2, column 21:
SQL> BEGIN
2 OPEN :my_select FOR SELECT ename from scott.emp;
3 END;
4 /
PL/SQL procedure successfully completed.
and now revokes them here.
The print statement will still work
SQL> print my_sele
ENAME
BEGIN
OPEN :my_select FOR SELECT ename from scott.emp
where empno = :v_empno;
END;
How does one display the information, change the value of :v_empno, and display the infromation again without re-opening the cursor.
In the distant past when I was writing a lot of Pro*C I'd get the occaisional fetch out of sequence error when I would change the value of a bind variable and try to fetch without first opening the cursor. Doesn't one have to re-opne to rebind.
N.B. mail sent in haste -- late for an appointment.
Ian MacGregor
Stanford Linear Accelerator Center
ian_at_SLAC.Stanford.edu
-----Original Message-----
Sent: Thursday, July 25, 2002 12:38 AM
To: Multiple recipients of list ORACLE-L
On Wednesday 24 July 2002 22:08, MacGregor, Ian A. wrote:
> 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.
No, code that uses bind variables need only parse SQL statements once if session_cached_cursors is set. Further executions of the same SQL don't require a hard or soft parse.
Jared
> 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.
>
>
> >
>
>
>
>
>
>
>
>
>
>
>
>
>> To REMOVE yourself from this mailing list, send an E-Mail message
> Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051
> San Diego, California -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Jared Still INET: jkstill_at_cybcon.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). -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: MacGregor, Ian A. INET: ian_at_SLAC.Stanford.EDU 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 - 11:59:11 CDT
![]() |
![]() |