Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: OPEN_CURSORS !
Hi based on my few understanding a cursor is a query, not what you get from
it.
I hope not to bore you but here is something I investigate about this parameter sometime ago and will be in my next paper, I need to check once again.
Anything wrong someone could find tellme please
1 open_cursors parameter
6.1 What it’s for? 6.1.1 Precompilers Programs 6.1.2 Heterogeneous Services 6.1.3 Relation with session_cached_cursors 6.2 Syntax 6.3 Evaluating the accuracy of the value 6.3.1 V$OPEN_CURSOR 6.3.2 Stat: opened cursors current 6.4 Examples 6.4.1 Closing Cursors 1.1 What it’s for?
To take advantage of the additional memory available for shared SQL areas,
you may also need to increase the number of cursors permitted per session.
You can increase this limit by increasing the value of the initialization
parameter OPEN_CURSORS.
Be careful where you place a recursive call. If you place it inside a cursor
FOR loop or between OPEN and CLOSE statements, another cursor is opened at
each call. As a result, your program might exceed the limit set by the
Oracle initialization parameter OPEN_CURSORS.
1.1.1 Precompilers Programs
When writing precompiler programs, increasing the number of cursors using
MAX_OPEN_CURSORS can often reduce the frequency of parsing and improve
performance.
Oracle allocates an additional cache entry if it cannot find one to reuse.
For example, if MAXOPENCURSORS=8 and all eight entries are active, a ninth
is created. If necessary, Oracle keeps allocating additional cache entries
until it runs out of memory or reaches the limit set by OPEN_CURSORS. This
dynamic allocation adds to processing overhead.
MAXOPENCURSORS specifies the initial size of the cursor cache. If a new
cursor is needed and there are no free cache entries, the server tries to
reuse an entry. Its success depends on the values of HOLD_CURSOR and
RELEASE_CURSOR and, for explicit cursors, on the status of the cursor itself
If the value of MAXOPENCURSORS is less than the number of cache entries
actually needed, the server uses the first cache entry marked as reusable.
For example, suppose an INSERT statement's cache entry E(1) is marked as
reusable, and the number of cache entries already equals MAXOPENCURSORS. If
the program executes a new statement, cache entry E(1) and its private SQL
area might be reassigned to the new statement. To reexecute the INSERT
statement, the server would have to reparse it and reassign another cache
entry.
Thus, specifying a low value for MAXOPENCURSORS saves memory but causes
potentially expensive dynamic allocations and deallocations of new cache
entries. Specifying a high value for MAXOPENCURSORS assures speedy execution
but uses more memory.
A system-wide limit of cursors for each session is set by the initialization
parameter named OPEN_CURSORS found in the parameter file (such as INIT.ORA).
1.1.2 Heterogeneous Services
HS_OPEN_CURSORS FOR Heterogeneous Services, defines the maximum number of
cursors that can be open on one connection to a non-Oracle system instance.
1.1.3 Relation with session_cached_cursors
None relation.
session_cached_cursors -- how many cached CLOSED cursors you can have.
open_cursor -- how many concurrently opened cursors you can have.
ops$tkyte_at_ORA920> show parameter _cursors
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
------------------------------ ----------opened cursors cumulative 26
ops$tkyte_at_ORA920> declare
2 type rc is ref cursor;
3
4 l_cursor rc;
5 begin
6 for i in 1 .. 100
7 loop
8 for j in 1 .. 5
9 loop
10 open l_cursor for 'select * from dual xx' || i;
11 close l_cursor;
12 end loop;
13 end loop;
14 end;
15 /
PL/SQL procedure successfully completed.
ops$tkyte_at_ORA920> ops$tkyte_at_ORA920> @mystat cursor ops$tkyte_at_ORA920> select a.name, b.value2 from v$statname a, v$mystat b
------------------------------ ----------opened cursors cumulative 529
1.4 Examples 1.4.1 Closing Cursors 1.4.1.1 Closing ref cursor explicitly
ops$tkyte_at_ORA817DEV.US.ORACLE.COM>
ops$tkyte_at_ORA817DEV.US.ORACLE.COM> create or replace function foo return
types.rc
2 as
3 l_cursor types.rc;
4 begin
5 open l_cursor for select * from dual;
6 return l_cursor;
7 end;
8 /
Function created.
ops$tkyte_at_ORA817DEV.US.ORACLE.COM>
ops$tkyte_at_ORA817DEV.US.ORACLE.COM> create or replace procedure bar
2 as
3 l_cursor types.rc;
4 l_rec dual%rowtype;
5 begin
6 l_cursor := foo;
7 loop
8 fetch l_cursor into l_rec;
9 exit when l_cursor%notfound;
10 dbms_output.put_line( l_rec.dummy );
11 end loop;
12 close l_cursor;
13 end;
14 /
Procedure created.
ops$tkyte_at_ORA817DEV.US.ORACLE.COM>
ops$tkyte_at_ORA817DEV.US.ORACLE.COM> exec bar
X
PL/SQL procedure successfully completed.
1.4.1.3 Closing cursor in Java
Cursors will remain there until you run out of slots in your OPEN CURSOR
array --
at which point they are flushed if not currently being used (plsql lets them
"go
away" if and when the server needs that slot)
They do not count against you, they are there for performance. It is an
EXCELLENT reason why most java programs entire suite of SQL should consist
of
nothing more then begin .... end; -- never any actual DML of its own. More
manageable, more flexible.
You can test this out yourself by using this:
create or replace package demo_pkg
as
type refcur is ref cursor;
procedure get_cur( x in out refcur );
end;
/
create or replace package body demo_pkg
as
g_first_time boolean default true;
procedure get_cur( x in out refcur )
is
l_user varchar2(1000);
begin
open x for select USER from dual THIS_IS_A_JAVA_CURSOR;
if ( g_first_time )
then
select user
into l_user
from dual THIS_IS_PLSQL where rownum = 1;
select user
into l_user
from dual THIS_TOO_IS_PLSQL where rownum = 1;
g_first_time := false;
end if;
end;
end;
/
that plsql only needs the cursors for a bit -- we don't need them everytime. .
Now I modified the java to be:
public static void main (String args [])
throws SQLException, ClassNotFoundException
{
String query =
"begin demo_pkg.get_cur( :1 ); end;";
DriverManager.registerDriver
(new oracle.jdbc.driver.OracleDriver());
Connection conn=
DriverManager.getConnection
("jdbc:oracle:oci8:@ora817dev",
"scott", "tiger");
showOpenCnt( conn, "Before Anything" );
CallableStatement cstmt = conn.prepareCall(query); cstmt.registerOutParameter(1,OracleTypes.CURSOR);
for( int j = 0; j < 100; j++ )
{
cstmt.execute();
showOpenCnt( conn, j + ") After prepare and execute" );
ResultSet rset = (ResultSet)cstmt.getObject(1);
for(int i = 0; rset.next(); i++ );
}
cstmt.close();
showOpenCnt( conn, "After CallableStatement closes" );
}
I don't close the result sets - we just let them leak all over the place. I have open_cursors set to 50 and run:
> !java
java curvar
SID***8 SELECT VALUE FROM NLS_INSTANCE_PARAMETERS WHERE PARAMETER =' SID***8 select a.value, b.name from v$mystat a, v$statname b where a SID***8 ALTER SESSION SET NLS_TERRITORY = 'AMERICA' SID***8 ALTER SESSION SET NLS_LANGUAGE = 'AMERICAN' SID***8 select sid, sql_text from v$open_cursor where sid = (select SID***8 ALTER SESSION SET NLS_LANGUAGE= 'AMERICAN' NLS_TERRITORY= 'A ----------------------- ====================================
SID***8 SELECT VALUE FROM NLS_INSTANCE_PARAMETERS WHERE PARAMETER =' SID***8 select a.value, b.name from v$mystat a, v$statname b where a SID***8 SELECT USER FROM DUAL THIS_IS_PLSQL WHERE ROWNUM = 1 SID***8 begin demo_pkg.get_cur( :1 ); end; SID***8 ALTER SESSION SET NLS_TERRITORY = 'AMERICA' SID***8 ALTER SESSION SET NLS_LANGUAGE = 'AMERICAN' SID***8 select sid, sql_text from v$open_cursor where sid = (select SID***8 ALTER SESSION SET NLS_LANGUAGE= 'AMERICAN' NLS_TERRITORY= 'A SID***8 SELECT USER FROM DUAL THIS_TOO_IS_PLSQL WHERE ROWNUM = 1 SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR ----------------------- ====================================
6 opened cursors current
SID***8 SELECT VALUE FROM NLS_INSTANCE_PARAMETERS WHERE PARAMETER =' SID***8 select a.value, b.name from v$mystat a, v$statname b where a SID***8 SELECT USER FROM DUAL THIS_IS_PLSQL WHERE ROWNUM = 1 SID***8 begin demo_pkg.get_cur( :1 ); end; SID***8 ALTER SESSION SET NLS_TERRITORY = 'AMERICA' SID***8 ALTER SESSION SET NLS_LANGUAGE = 'AMERICAN' SID***8 select sid, sql_text from v$open_cursor where sid = (select SID***8 ALTER SESSION SET NLS_LANGUAGE= 'AMERICAN' NLS_TERRITORY= 'A SID***8 SELECT USER FROM DUAL THIS_TOO_IS_PLSQL WHERE ROWNUM = 1 SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR -----------------------
note that after each iteration I got more and more "this is a java cursor". The plsql guys stayed in there.... UNTIL:
SID***8 select a.value, b.name from v$mystat a, v$statname b where a SID***8 SELECT USER FROM DUAL THIS_IS_PLSQL WHERE ROWNUM = 1 SID***8 begin demo_pkg.get_cur( :1 ); end; SID***8 select sid, sql_text from v$open_cursor where sid = (select SID***8 ALTER SESSION SET NLS_LANGUAGE= 'AMERICAN' NLS_TERRITORY= 'A SID***8 SELECT USER FROM DUAL THIS_TOO_IS_PLSQL WHERE ROWNUM = 1 SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR<lots of those chopped out>
SID***8 select a.value, b.name from v$mystat a, v$statname b where a SID***8 begin demo_pkg.get_cur( :1 ); end; SID***8 select sid, sql_text from v$open_cursor where sid = (select SID***8 ALTER SESSION SET NLS_LANGUAGE= 'AMERICAN' NLS_TERRITORY= 'A SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR<lots chopped NOTE: PLSQL cursors *gone*> SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR
SID***8 select a.value, b.name from v$mystat a, v$statname b where a SID***8 begin demo_pkg.get_cur( :1 ); end; SID***8 select sid, sql_text from v$open_cursor where sid = (select SID***8 ALTER SESSION SET NLS_LANGUAGE= 'AMERICAN' NLS_TERRITORY= 'A SID***8 SELECT USER FROM DUAL THIS_IS_A_JAVA_CURSOR..
java.sql.SQLException: ORA-01000: maximum open cursors exceeded
at java.lang.Throwable.<init>(Compiled Code) at java.lang.Exception.<init>(Compiled Code) at java.sql.SQLException.<init>(Compiled Code) at oracle.jdbc.dbaccess.DBError.throwSqlException(Compiled Code) at oracle.jdbc.oci8.OCIDBAccess.check_error(Compiled Code) at oracle.jdbc.oci8.OCIDBAccess.parseExecuteDescribe(Compiled Code)at oracle.jdbc.driver.OracleStatement.doExecuteQuery(Compiled Code) at oracle.jdbc.driver.OracleStatement.doExecuteWithTimeout(Compiled Code)
at oracle.jdbc.driver.OracleStatement.executeQuery(Compiled Code) at curvar.showOpenCnt(Compiled Code) at curvar.main(Compiled Code) ----------------------------------------------------------------Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html -----------------------------------------------------------------Received on Wed Jul 14 2004 - 16:16:54 CDT