High Version Count Issues:
Metadata is all the information which enables a statement to run. For instance, in the example I have given EMP is owned by scott and therefore has an OBJECT_ID which points to the EMP table owned by this user. When the user SCOTT logged in, optimizer parameters are initialised in that session for use by the statement, so this too is used by the optimizer and is therefore metadata. There are other examples of Metadata which will be mentioned further in this document.
Let's say this session logs out and back in again now. It then runs the same command again (as the same user). This time we already have the SQL in the shared pool (but we don't know this yet). What we do is hash the statement and then search for that hash value in the shared pool. If we find it, we can then search through the children to determine if any of them are usable by us (ie the metadata is the same). If it is, then we can share that SQL statement
I would still have one version of that SQL in the shared pool because the metadata enabled me to share the statement with the already existent child. The fundamentals are that the parent is not shared, it is the children which determine shareability.
Now - another user 'TEST' has it's own version of EMP. If that user was to now run the select statement above then what would happen is :-
1. The statement is hashed - it is hashed to the value 4085390015
2. The SQL will be found in the shared pool as it already exists
3. The children are scanned (at this point we have one child)
4. Because the OBJECT_ID of the EMP table owned by TEST is different the OBJECT_ID owned by scott we have a 'mismatch'
(Essentially, what happens here is that we have a linked list of children which we move through in turn, comparing the metadata of the current SQL with that of all the children. If there were 100 children then we would scan each of them (looking for a possible mismatch and moving on) until we found one we could share. If we cannot share any (ie. have exhausted the list of children) then we need to create a new child)
5. We therefore have to create a new child - we now have 1 PARENT and 2 CHILDREN.
To find the reasons for mismatches see the following section: What do the reasons given in v$SQL_SHARED_CURSOR mean?
If you are unable to use that script then you can select the same information from the base views as illustrated in the examples below.
Lets use the example above and take a look at what SQL we can use to see this in the shared pool.
SCOTT runs select count(*) from emp
I can now run the following to see the PARENT statement and it's hash value and address
To see the CHILDREN (I expect to see 1 at this point) :-
We can see we have a single child (ADDRESS 0000000386BC2D08).
The mismatch information (U S O O S L etc) is all N because this is the first child. Now, if I log in as another user and run the same select (select count(*) from emp) and look again I will get the following output:-
Running the Script:
Generate reports for all cursors with more than 100 versions using SQL_ID (10g and up):
In 10g (10.2.0.5) and 11g using the example query above this looks like:
The "fl2=0300" entry indicates that this is and Unsafe literal and the bind was generated by replacement :
The 0x200 entry being the important flag for determination of literal 'safety'.
For additional details on this topic see:
A cursor is the instance of query/dml in the library cache.
A hash key to locate the cursor in the library cache is calculated based on the text of the statement.
But if the text is the only criteria used to identify the cursor in the library cache what happens if the cursor is not compatible with the conditions that execute them ?
For example, how can the same cursor be used when the same query is executed by 2 users with different privileges or with different language or even different objects?
It creates a version of the cursor with those unique conditions that make it possible to execute.
A version of a cursor is also known as child cursor. So if there is a child, is there a parent ?
Yes, the parent cursor is the root where all those child cursors are linked.
In order for a session to find the correct version to execute, it attempts to match the query text in the library cache using the hash key generated by the text to the parent cursor and once found it scans the list of versions (or children) one by one to match which has the correct set of conditions and if it does not find one then it creates a new version and adds it to the list.
For example, lets say I have 3 schemas, A, B ,C and a table T in schema A and a public synonym for T.
Lets say further that A grants access on T to B.
What happens if I run the query : "SELECT * FROM T" from each schema ?
if the query is ran by A, "T" points to the schema object "A"."T" and the query runs ok. A version is created that indicates that a session connected with schema "A" can access "A"."T".
if the query is ran by B, "T" points to public synonym "T" and that points to "A"."T" and because A granted access on T to B then the query runs ok. A version is created that indicates that a session connected with schema "B" can access "A"."T".
if the query us ran by C, "T" points to public synonym "T" and that points to "A"."T" and but because A has not granted access on T to C then the query fails and no version is created.
If now, "A" grants access on "T" to "C" and runs the query again, then "T" is resolved again to to public synonym "T" and that points to "A"."T" and since it now has privileges the query runs ok and a version is created that indicates that a session connected with schema "C" can access "A"."T".
If now, "A" revokes access on "T" to "B", then the version associated with schema "B" is invalidated, to let any session that has a pointer to that child cursor that it is no longer valid.
If the query is ran by "A" but on a client that has German NLS settings and all the previous ones were done in English then a new version is created for German NLS settings.
I can easily continue the examples as there are over 50 different reasons why a child needs to be created.
These are tracked in V$SQL_SHARED_CURSOR.
There are reasons related to Binds, privileges, languages, parallel execution, optimization, and more,
and reasons are added, removed or change in meaning with each version.
Even if in theory there could be 50+ combinations of reasons and each reason may have "n" number of variables that can make it non share-able to anyone but who has those same conditions , the number of versions usually remains low. The norm is that most cursors will have less than 100 versions but there are times when hundreds or thousands of versions are made and their management cause significant performance degradation in the system.
As each reason is related to different features in the database there is not one way to debug a high version count situation.
For example, in order to diagnose when the reason for not sharing is language, it might be necessary to know what languanges are involved.
If the reason is binds, it might be necessary to know how many, what datatype, and what size are the binds.
and so on.
For a more in depth explanation see : Troubleshooting: High Version Count Issues [ID 296377.1]
After working several of these high version count cases I came to identify some common diagnostics , their presentation and their interpretation so I made a diagnostic tool to collect them.
Roudtrips between support and the customer have always been annoying and riddled with mistakes and omitions so the tool has the objective to collect as much relevant information as possible to only the reasons identified.
The tool is VERSION_RPT and can be found in : High SQL Version Counts - Script to determine reason(s) [ID:438755.1]
The tool adapts to the number of reasons in each version so it works from 9.2 to 11gR2 and I expect to work too on 12c once released.
The tool can be used to diagnose one or many cursors, including pseudocursors, using SQL_ID or HASH_VALUE.
The output of the report shows a summary of the reasons and information about the factors that each reason may take into consideration to decide to share or not, like Optimizer parameters when the reason is OPTIMIZER_MISMATCH.
These reasons are searchable in MOS. Searching for the phrase :
"Cursor not shared due to USER_BIND_PEEK_MISMATCH"
Can found BugTag Notes like Bug 8981059 - High Version Count (due to USER_BIND_PEEK_MISMATCH) with bind peeking [ID 8981059.8]
To collect data for a group of SQLs it can be done
SELECT b.*FROM v$sqlarea a ,TABLE(version_rpt(a.sql_id)) bWHERE loaded_versions >=100;
Here is an example of its use for one cursor:
===============
============================================================SQL> set pages 2000 lines 180SQL> SELECT * FROM TABLE(version_rpt('8swypbbr0m372'));Version Count Report Version 3.2.1 -- Today's Date 02-may-12 11:50RDBMS Version :11.2.0.3.0 Host: XXXXXXXXXXXXXXXXXXXX Instance 1 : XXXXXXXXXX==================================================================Addr: 00000003D8B6A570 Hash_Value: 3993603298 SQL_ID 8swypbbr0m372Sharable_Mem: 208913 bytes Parses: 477Stmt:0 select order#,columns,types from access$ where d_obj#=:11Versions Summary----------------OPTIMIZER_MISMATCH :10BIND_MISMATCH :1LANGUAGE_MISMATCH :1OPTIMIZER_MODE_MISMATCH :3PX_MISMATCH :2Total Versions:10~Plan Hash Value Summary-----------------------Plan Hash Value Count=============== =====872636971 110 1~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~Details for OPTIMIZER_MISMATCH :1 versions with is_recur_flags = 1672 versions with is_recur_flags = 1619 versions with _pga_max_size = 614400 KB7 versions with optimizer_mode = choose3 versions with is_recur_flags = 357 versions with hash_area_size = 104857601 versions with optimizer_mode = rule2 versions with advanced_queuing_internal_cursor = 12 versions with is_recur_flags = 1631 versions with parallel_execution_enabled = false1 versions with _pga_max_size = 204800 KB10 versions with _optimizer_order_by_elimination_enabled = false2 versions with is_recur_flags = 391 versions with hash_area_size = 20000001 versions with sort_area_size = 10000008 versions with _db_file_optimizer_read_count = 12810 versions with _optimizer_cost_based_transformation = on1 versions with parallel_threads_per_cpu = 41 versions with parallel_max_degree = 161 versions with _parallel_syspls_obey_force = false~~~~~~~~~~~~~~~~~~~~~~~~~~~Details for BIND_MISMATCH :Consolidated details for :BIND_MISMATCH,USER_BIND_PEEK_MISMATCH,BIND_UACS_DIFF andBIND_EQUIV_FAILURE (Mislabled as ROW_LEVEL_SEC_MISMATCH BY bug 6964441 in 11gR1)from v$sql_bind_captureCOUNT(*) POSITION MIN(MAX_LENGTH) MAX(MAX_LENGTH) DATATYPE (PRECISION,SCALE)======== ======== =============== =============== ======== ================11 1 22 22 2 (,)SUM(DECODE(column,Y, 1, 0) FROM V$SQLIS_OBSOLETE IS_BIND_SENSITIVE IS_BIND_AWARE IS_SHAREABLE=========== ================= ============= ============0 0 0 9~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~Details for LANGUAGE_MISMATCH :No details available~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~Details for OPTIMIZER_MODE_MISMATCH :1 versions with RULE9 versions with CHOOSE2 versions with ALL_ROWS~~~~~~~~~~~~~~~~~~~~~~~~~Details for PX_MISMATCH :No details available####To further debug Ask Oracle Support for the appropiate level LLL.alter session set events 'immediate trace name cursortrace address 3993603298, level LLL';To turn it off do use address 1, level 2147483648
TROUBLESHOOTING STEPS
What is a 'High' Version Count?
There is no definitive definition of what a 'High' number of versions for a particular cursor is, different systems may be able to deal with different ranges of versions, However, AWR reports start reporting versions over 20 for a particular cursor and so that is as good an indicator of a potential problem as any.
Once you start getting into the hundreds or thousands range, then these are definitely 'High' counts and the causes should be examined and the numbers reduced so as to encourage the SQL to be shared. It is important to understand that sometimes high version counts are expected and not a result of any defect.
Once you start getting into the hundreds or thousands range, then these are definitely 'High' counts and the causes should be examined and the numbers reduced so as to encourage the SQL to be shared. It is important to understand that sometimes high version counts are expected and not a result of any defect.
What is shared SQL ?
The first thing to remember is that all SQL is implicitly sharable. When a SQL statement is entered, the RDBMS will create a hash value for text of the statement and that hash value then helps the RDBMS to easily find SQL already in the shared pool. It is not in the scope of this article to discuss this in any great detail, so let's just assume entering a series of text results in a hash value being created.
For instance :- 'select count(*) from emp' hashes to the value 4085390015
We now create a parent cursor for this sql and a single child. It does not matter that a SQL statement may never be shared - when it is first parsed a parent and a single child are created. The easy way to think of this is that the PARENT cursor is a representation of the hash value and the child cursor(s) represent the metadata for that SQL
For instance :- 'select count(*) from emp' hashes to the value 4085390015
We now create a parent cursor for this sql and a single child. It does not matter that a SQL statement may never be shared - when it is first parsed a parent and a single child are created. The easy way to think of this is that the PARENT cursor is a representation of the hash value and the child cursor(s) represent the metadata for that SQL
What is 'SQL Metadata'?
Metadata is all the information which enables a statement to run. For instance, in the example I have given EMP is owned by scott and therefore has an OBJECT_ID which points to the EMP table owned by this user. When the user SCOTT logged in, optimizer parameters are initialised in that session for use by the statement, so this too is used by the optimizer and is therefore metadata. There are other examples of Metadata which will be mentioned further in this document.
Let's say this session logs out and back in again now. It then runs the same command again (as the same user). This time we already have the SQL in the shared pool (but we don't know this yet). What we do is hash the statement and then search for that hash value in the shared pool. If we find it, we can then search through the children to determine if any of them are usable by us (ie the metadata is the same). If it is, then we can share that SQL statement
I would still have one version of that SQL in the shared pool because the metadata enabled me to share the statement with the already existent child. The fundamentals are that the parent is not shared, it is the children which determine shareability.
Now - another user 'TEST' has it's own version of EMP. If that user was to now run the select statement above then what would happen is :-
1. The statement is hashed - it is hashed to the value 4085390015
2. The SQL will be found in the shared pool as it already exists
3. The children are scanned (at this point we have one child)
4. Because the OBJECT_ID of the EMP table owned by TEST is different the OBJECT_ID owned by scott we have a 'mismatch'
(Essentially, what happens here is that we have a linked list of children which we move through in turn, comparing the metadata of the current SQL with that of all the children. If there were 100 children then we would scan each of them (looking for a possible mismatch and moving on) until we found one we could share. If we cannot share any (ie. have exhausted the list of children) then we need to create a new child)
5. We therefore have to create a new child - we now have 1 PARENT and 2 CHILDREN.
Why should I be concerned about 'High' Versions?
Unnecessary non-sharing of SQL, and the resultant versions of SQL, is a primary cause of library cache contention. Contention reduces the performance of your database and, in extreme cases, can cause it to appear to 'hang'. When you have unnecessary versions of a cursor, each time that cursor is executed, the parse engine has to search through the list of versions to see which is the cursor that you want. This wastes CPU cycles that you could be using on something else.
How do I see the versions and why they are not shared ?
The easiest way to get version information in a clear format is to use the script in the following article:
Document 438755.1 High SQL Version Counts - Script to determine reason(s)
To find the reasons for mismatches see the following section: What do the reasons given in v$SQL_SHARED_CURSOR mean?
If you are unable to use that script then you can select the same information from the base views as illustrated in the examples below.
Lets use the example above and take a look at what SQL we can use to see this in the shared pool.
SCOTT runs select count(*) from emp
I can now run the following to see the PARENT statement and it's hash value and address
select sql_text, hash_value,address from v$sqlarea where sql_text like 'select count(*) from emp%';
SQL_TEXT HASH_VALUE ADDRESS
------------------------ ------------ ----------------
select count(*) from emp 4085390015 0000000386BC2E58
SQL_TEXT HASH_VALUE ADDRESS
------------------------ ------------ ----------------
select count(*) from emp 4085390015 0000000386BC2E58
To see the CHILDREN (I expect to see 1 at this point) :-
- Version 9.2.X.X and below : select * from v$sql_shared_cursor where kglhdpar = '0000000386BC2E58'
- Version 10.0.X.X and above:select * from v$sql_shared_cursor where address = '0000000386BC2E58'
Output:
ADDRESS KGLHDPAR U S O O S L S E B P I S T A B D L T R I I R L I O S M U T N F
---------------- ---------------- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
0000000386BC2D08 0000000386BC2E58 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N
We can see we have a single child (ADDRESS 0000000386BC2D08).
The mismatch information (U S O O S L etc) is all N because this is the first child. Now, if I log in as another user and run the same select (select count(*) from emp) and look again I will get the following output:-
ADDRESS KGLHDPAR U S O O S L S E B P I S T A B D L T R I I R L I O S M U T N F
---------------- ---------------- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
0000000386BC2D08 0000000386BC2E58 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N
0000000386A91AA0 0000000386BC2E58 N N N N N N N N N N N N N Y N N N Y N N N N N N N N N N N N N
We can now see the 2nd child ( 0000000386A91AA0) and also the reasons why it could not be shared with the first (The 'Y's denote a mismatch). The reasons are:
(1) AUTH_CHECK_MISMATCH and
(2) TRANSLATION_MISMATCH
This is because the objects under my new user do not map to those of SCOTT (the current child). A mismatch occurs because I cannot access SCOTTs objects and translation fails since we have different object_ids for the objects in each of our schemas.
(1) AUTH_CHECK_MISMATCH and
(2) TRANSLATION_MISMATCH
This is because the objects under my new user do not map to those of SCOTT (the current child). A mismatch occurs because I cannot access SCOTTs objects and translation fails since we have different object_ids for the objects in each of our schemas.
What do the reasons given in v$SQL_SHARED_CURSOR mean?
Below are the list of reasons as well as some worked examples (Those denoted by ** are the ones most often seen) :-
UNBOUND_CURSOR
The existing child cursor was not fully built (in other words, it was not optimized)SQL_TYPE_MISMATCH
The SQL type does not match the existing child cursor
**OPTIMIZER_MISMATCH
The optimizer environment does not match the existing child cursor (The optimizer mode has changed and therefore the existing child cannot be re-used).
For example:select count(*) from emp; ->> 1 PARENT, 1 CHILD
alter session set optimizer_mode=ALL_ROWS
select count(*) from emp; ->> 1 PARENT, 2 CHILDRENNote: The behavior applies with the setting of trace events. for example, if I turned on tracing with 10046 than I would get an OPTIMIZER_MISMATCH and another child cursorOUTLINE_MISMATCH
The outlines do not match the existing child cursor. For example, if a user had created stored outlines previously for this command and they were stored in separate categories (say "OUTLINES1" and "OUTLINES2"), if they then executed the following:alter session set use_stored_outlines = OUTLINES1;
select count(*) from emp;
alter session set use_stored_oulines= OUTLINES2;
select count(*) from emp;
The second execution of the select from emp would create another child since the outline used is different than the first run. This child would be marked as an OUTLINE_MISMATCH.STATS_ROW_MISMATCH
The existing statistics do not match the existing child cursor. Check that 10046/sql_trace is not set on all sessions as this can cause this.LITERAL_MISMATCH
Non-data literal values do not match the existing child cursorSEC_DEPTH_MISMATCH
Security level does not match the existing child cursorEXPLAIN_PLAN_CURSOR
The child cursor is an explain plan cursor and should not be shared. Explain plan statements will generate a new child by default - the mismatch will be this.BUFFERED_DML_MISMATCH
Buffered DML does not match the existing child cursorPDML_ENV_MISMATCH
PDML environment does not match the existing child cursorINST_DRTLD_MISMATCH
Insert direct load does not match the existing child cursorSLAVE_QC_MISMATCH
The existing child cursor is a slave cursor and the new one was issued by the coordinator (or, the existing child cursor was issued by the coordinator and the new one is a slave cursor).TYPECHECK_MISMATCH
The existing child cursor is not fully optimizedAUTH_CHECK_MISMATCH
Authorization/translation check failed for the existing child cursor
The user does not have permission to access the object in any previous version of the cursor. A typical example would be where each user has it's own copy of a table**BIND_MISMATCH
The bind metadata does not match the existing child cursor. For example, in the following, the definition of the bind variable 'a' has changed between the 2 statements:variable a varchar2(100);
select count(*) from emp where ename = :a ->> 1 PARENT, 1 CHILD
variable a varchar2(400);
select count(*) from emp where ename = :a ->> 1 PARENT, 2 CHILDRENDESCRIBE_MISMATCH
The type-check heap is not present during the describe for the child cursorLANGUAGE_MISMATCH
The language handle does not match the existing child cursorTRANSLATION_MISMATCH
The base objects of the existing child cursor do not match.
The definition of the object does not match any current version. Usually this is indicative of the same issue as "AUTH_CHECK_MISMATCH" where the object is different.ROW_LEVEL_SEC_MISMATCH
The row level security policies do not matchINSUFF_PRIVS
Insufficient privileges on objects referenced by the existing child cursorINSUFF_PRIVS_REM
Insufficient privileges on remote objects referenced by the existing child cursorREMOTE_TRANS_MISMATCH
The remote base objects of the existing child cursor do not match. For example:
USER1:select count(*) from table@remote_dbUSER2:select count(*) from table@remote_dbAlthough the SQL is identical, the dblink pointed to by remote_db may be a private dblink which resolves to a different object altogetherLOGMINER_SESSION_MISMATCH
INCOMP_LTRL_MISMATCH
OVERLAP_TIME_MISMATCH
Error_on_overlap_time mismatchSQL_REDIRECT_MISMATCH
SQL redirection mismatchMV_QUERY_GEN_MISMATCH
Materialized view query generationUSER_BIND_PEEK_MISMATCH
User bind peeking mismatchTYPCHK_DEP_MISMATCH
Cursor has type-check dependenciesNO_TRIGGER_MISMATCH
No trigger mismatchFLASHBACK_CURSOR
No cursor sharing for flashbackANYDATA_TRANSFORMATION
Anydata transformation changeINCOMPLETE_CURSOR
Incomplete cursor. When bind length is upgradeable (i.e. we found a child cursor that matches everything else except that the bind length is not long enough), we mark the old cursor is not usable and build a new one. This means the version can be ignored.TOP_LEVEL_RPI_CURSOR
Top level/rpi cursor. In a Parallel Query invocation this is expected behaviour (we purposely do not share)DIFFERENT_LONG_LENGTH
Different long lengthLOGICAL_STANDBY_APPLY
Logical standby apply mismatchDIFF_CALL_DURN
Different call durationBIND_UACS_DIFF
Bind uacs mismatchPLSQL_CMP_SWITCHS_DIFF
PL/SQL compiler switches mismatchCURSOR_PARTS_MISMATCH
Cursor "parts executed" mismatchSTB_OBJECT_MISMATCH
STB object different (now exists). For explanation of STB_OBJECT_MISMATCH, please read following blog:https://blogs.oracle.com/optimizer/entry/my_cursor_wasn_t_sharedROW_SHIP_MISMATCH
Row shipping capability mismatchPQ_SLAVE_MISMATCH
PQ slave mismatch If you encounter this reason code and you are using parallel execution (PX), then check you really want to be using it. This mismatch can be caused by running lots of small SQL statements which do not really need PX. Also, if you are on versions prior to 11g you may be hitting Bug:4367986TOP_LEVEL_DDL_MISMATCH
Top-level DDL cursorMULTI_PX_MISMATCH
Multi-px and slave-compiled cursorBIND_PEEKED_PQ_MISMATCH
Bind-peeked PQ cursorMV_REWRITE_MISMATCH
MV rewrite cursorROLL_INVALID_MISMATCH
Rolling invalidation window exceeded. This is caused by the rolling invalidation capability in DBMS_STATS. The child cannot be shared as it's invalidation window is exceeded. See:Document 557661.1 Rolling Cursor Invalidations with DBMS_STATS in Oracle10gOPTIMIZER_MODE_MISMATCH
Optimizer mode mismatchPX_MISMATCH
Parallel query execution mismatch. Refer to the following for known issues where this reason is shown:Document 1629107.1 Common Bugs Associated with PX_MISMATCHMV_STALEOBJ_MISMATCH
Materialixed View stale object mismatchFLASHBACK_TABLE_MISMATCH
Flashback table mismatchLITREP_COMP_MISMATCH
Literal replacement compilation mismatch
New in 11g :
HASH_MATCH_FAILED
Hash mismatch. Set to "Y" if sharing fails due to a hash mismatch, such as the case with mismatched histogram data or a range predicate marked as unsafe by literal replacement (See Bug 3461251)
New in 11.2:
PURGED_CURSOR
Cursor marked for purging. The cursor has been marked for purging with dbms_shared_pool.purge
BIND_LENGTH_UPGRADEABLE
Bind length upgradeable and could not be shared because a bind variable size was smaller than the new value being inserted (marked as BIND_MISMATCH in earlier versions).
USE_FEEDBACK_STATS
Cardinality feedback. Cardinality feedback is being used and therefore a new plan could be formed for the current execution.
BIND_EQUIV_FAILURE
The bind value's selectivity does not match that used to optimize the existing child cursor. When adaptive cursor sharing is used and the cursor is bind aware, then if the selectivity is outside of the current ranges and a new plan is desirable then a new child is raised with this as the reason code for non-sharing of the previous plan. For an example, see Document 836256.1. After each execution in the example, run:select sql_id, address, child_address, child_number, BIND_EQUIV_FAILURE from v$sql_shared_cursor where sql_id='19sxt3v07nzm4';... once the cursor is marked as bind aware and a second plan is seen then the following will be the resultant output:SQL_ID ADDRESS CHILD_ADDRESS CHILD_NUMBER BAs can be seen, the new version is created due to BIND_EQUIV_FAILURE
------------- ---------------- ---------------- ------------ -
19sxt3v07nzm4 000000007A1C0DE0 000000007A1BF980 0 N
19sxt3v07nzm4 000000007A1C0DE0 000000007A10DDB0 1 Y
There is no longer ROW_LEVEL_SEC_MISMATCH in 11.2.
Version_rpt script:
The script version_rpt can also be run to produce a summary report of the v$sql_shared_cursor view with additional diagnostic information. The script can be found in:
Document 438755.1 High SQL Version Counts - Script to determine reason(s)
Running the Script:
Generate reports for all cursors with more than 100 versions using SQL_ID (10g and up):
select b.* from v$sqlarea a ,table(version_rpt(a.sql_id)) b where loaded_versions >=100;
Generate reports for all cursors with more than 100 versions using HASH_VALUE:
select b.* from v$sqlarea a ,table(version_rpt(null,a.hash_value)) b where loaded_versions>=100;
Generate the report for cursor with sql_id cyzznbykb509s:
select * from table(version_rpt('cyzznbykb509s'));
What further tracing is available.
In 10G it is possible to use CURSORTRACE to aid the investigation of why cursors are not being shared. This event should only be used under the guidance of support and the resultant trace file is undocumented. To get the trace for a particular SQL statement you first of all need to get the hash_value (See the above select from v$sqlarea). You then set the trace on using:-
alter system set events 'immediate trace name cursortrace level 577, address hash_value';
(levels 578-580 can be used for high level tracing (577=level 1, 578=level 2, 580=level 3)
This will write a trace file to user_dump_dest each time we try to reuse the cursor.
To turn off tracing use:-
To turn off tracing use:-
alter system set events
'immediate trace name cursortrace level 2147483648, address 1';
'immediate trace name cursortrace level 2147483648, address 1';
Please note: Bug 5555371 exists in 10.2 (fixed in 10.2.0.4) where cursor trace cannot fully be turned off and single line entries will still be made to the trace file as a result. The w/a is to restart the instance. How invasive this BUG is depends on the executions of the cursor (and the size of the resultant trace file additions)
In 11.2 there is also cursordump:
alter system set events 'immediate trace name cursordump level 16'
(please ensure system , not session, is used as the level meaning changes)
This dumps some additional information such as expanding on the parameters for 'optimizer_mismatch' issues.
In later versions of the RDBMS there are also enhancements which dump more information as to the actual reason a child cursor could not share (ie the parameter differences). This information can be found in the REASON column of v$sql_shared_cursor and is in XML format. See Bug 16770590 for example.
Are there any times when a high version count is expected even though BINDS are being used?
Consider the following where cursor_sharing=SIMILAR
select /* TEST */ * from emp where sal > 100;
select /* TEST */ * from emp where sal > 101;
select /* TEST */ * from emp where sal > 102;
select /* TEST */ * from emp where sal > 103;
select /* TEST */ * from emp where sal > 104;
SELECT sql_text,version_count,address
FROM V$SQLAREA
WHERE sql_text like 'select /* TEST */%';
SELECT * FROM V$SQL_SHARED_CURSOR WHERE kglhdpar = '&my_addr';
select /* TEST */ * from emp where sal > 101;
select /* TEST */ * from emp where sal > 102;
select /* TEST */ * from emp where sal > 103;
select /* TEST */ * from emp where sal > 104;
SELECT sql_text,version_count,address
FROM V$SQLAREA
WHERE sql_text like 'select /* TEST */%';
SELECT * FROM V$SQL_SHARED_CURSOR WHERE kglhdpar = '&my_addr';
You will see several versions , each with no obvious reason for not being shared
Explanation:
One of the cursor sharing criteria when literal replacement is enabled with cursor_sharing as similar is that bind value should match initial bind value if the execution plan is going to change depending on the value of the literal. The reason for this is we _might_ get a sub optimal plan if we use the same cursor. This would typically happen when depending on the value of the literal optimizer is going to chose a different plan. Thus in this test case we have a predicate with > , if this was a equality we would always share the same child cursor. If application developers are ready to live with a sub-optimal plan and save on memory , then they need to set the parameter to force.
"The difference between SIMILAR and FORCE is that SIMILAR forces similar statements to share the SQL area without deteriorating execution plans.
Setting CURSOR_SHARING to FORCE forces similar statements to share the SQL area potentially deteriorating execution plans."
It is also possible to tell from 10046 trace (level 4/12 - BINDS) if a bind is considered to be unsafe
The flag oacfl2 in 9i and fl2 in 10g will show if a variable is unsafe.
"The difference between SIMILAR and FORCE is that SIMILAR forces similar statements to share the SQL area without deteriorating execution plans.
Setting CURSOR_SHARING to FORCE forces similar statements to share the SQL area potentially deteriorating execution plans."
It is also possible to tell from 10046 trace (level 4/12 - BINDS) if a bind is considered to be unsafe
The flag oacfl2 in 9i and fl2 in 10g will show if a variable is unsafe.
BINDS #2:
bind 0: dty=2 mxl=22(04) mal=00 scl=00 pre=00 oacflg=10 oacfl2=500 size=24
offset=0
bfp=1036d6408 bln=22 avl=04 flg=09
value=16064
bind 1: dty=2 mxl=22(04) mal=00 scl=00 pre=00 oacflg=10 oacfl2=500 size=24
offset=0
bfp=1036d4340 bln=22 avl=04 flg=09
bind 0: dty=2 mxl=22(04) mal=00 scl=00 pre=00 oacflg=10 oacfl2=500 size=24
offset=0
bfp=1036d6408 bln=22 avl=04 flg=09
value=16064
bind 1: dty=2 mxl=22(04) mal=00 scl=00 pre=00 oacflg=10 oacfl2=500 size=24
offset=0
bfp=1036d4340 bln=22 avl=04 flg=09
In 10g (10.2.0.5) and 11g using the example query above this looks like:
alter session set cursor_sharing=force;
alter session set events '10046 trace name context forever,level 12';
select /* TEST */ * from emp where sal > :"SYS_B_0"
END OF STMT
..
BINDS #3071441600:
Bind#0
oacdty=02 mxl=22(03) mxlc=00 mal=00 scl=00 pre=00
oacflg=10 fl2=0300 frm=00 csi=00 siz=24 off=0
kxsbbbfp=295c96f0 bln=22 avl=03 flg=09
value=103
alter session set events '10046 trace name context forever,level 12';
select /* TEST */ * from emp where sal > :"SYS_B_0"
END OF STMT
..
BINDS #3071441600:
Bind#0
oacdty=02 mxl=22(03) mxlc=00 mal=00 scl=00 pre=00
oacflg=10 fl2=0300 frm=00 csi=00 siz=24 off=0
kxsbbbfp=295c96f0 bln=22 avl=03 flg=09
value=103
The "fl2=0300" entry indicates that this is and Unsafe literal and the bind was generated by replacement :
#define UACFBLTR 0x00000100 /* Bind was generated by LiTeRal replacement */
#define UACFUNSL 0x00000200 /* UNSafe Literal */
#define UACFUNSL 0x00000200 /* UNSafe Literal */
The 0x200 entry being the important flag for determination of literal 'safety'.
For additional details on this topic see:
Document 377847.1 Unsafe Literals or Peeked Bind Variables
Document 261020.1 High Version Count with CURSOR_SHARING = SIMILAR or FORCE
Document 261020.1 High Version Count with CURSOR_SHARING = SIMILAR or FORCE
Enhancement to obsolete parent cursors if Version Count exceeds a threshold
In 11gr2, an issue of Child cursors growing very long was introduced. An enhancement request was filed to address this issue Bug 10187168. When the child cursors grow beyond certain count be it 20 or 100, it obsoletes the parent cursors. In order to activate this enhancement bug set following:
1. If 11.2.0.3 and above, set the following parameters:
"_cursor_obsolete_threshold" to 100 (this is the number of child cursor after which we obsolete it)
2. If 11.2.0.2.2, then set:
"_cursor_features_enabled" to 1026
event 106001 with value 100 (as the parameter _cursor_obsolete_threshold is not present)
event 106001 with value 100 (as the parameter _cursor_obsolete_threshold is not present)
To show obsoleted cursor, run following query:
select count(*) as version_count, sql_id
from v$sql
where is_obsolete = 'N'
group by sql_id
having count(*) > 125;
from v$sql
where is_obsolete = 'N'
group by sql_id
having count(*) > 125;
For more information, please read the following article regarding the enhancement involved:
Document 10187168.8 Enhancement to obsolete parent cursors if Version Count exceeds a threshold
High Version Count with Adaptive Cursor Sharing
With introduction of adaptive cursor sharing in 11g, there may be increased version count due to more child cursors. The adaptive cursor sharing is meant to adapt execution plans, depending on the selectivity of the bind variable. For more information on adaptive cursor sharing, please review following note:
Document 740052.1 Adaptive Cursor Sharing Overview
Some known issues with Adaptive Cursor Sharing Overview:
Document 7213010.8 Bug 7213010 - Adaptive cursor sharing generates lots of child cursors
Document 8491399.8 Bug 8491399 - Adaptive Cursor Sharing does not match the correct cursor version for queries using CHAR datatype
Document 8491399.8 Bug 8491399 - Adaptive Cursor Sharing does not match the correct cursor version for queries using CHAR datatype
Known Issues
A list of known issues can be found in:
Document 120655.1 VIEW: "V$SQL_SHARED_CURSOR" Reference Note
Troubleshooting Other Issues
For guidance troubleshooting other performance issues take a look at:
Document 1377446.1 Troubleshooting Performance Issues
Comments
Post a Comment
Oracle DBA Information