Text Matching Might Not Be Enough
Beyond matching the text of a cursor, there are several other factors influencing cursor reuse—for example, optimizer statistics and Globalization Support (previously National Language Support, or NLS) setting mismatches. In such cases, it’s not enough to simply match ASCII values.
Let’s look at the example of setting the optimizer mode in this example.
SQL>ALTER SESSION SET optimizer_mode = FIRST_ROWS;Session altered. SQL>SELECT COUNT(*)2FROM orders;COUNT(*) ---------- 10000 SQL>ALTER SESSION SET optimizer_mode = ALL_ROWS;Session altered. SQL>SELECT COUNT(*)2FROM orders;COUNT(*) ---------- 10000
Astute DBAs know that two cursors will be created in this case: even though the text matched, the optimizer mode used was different, so Oracle built a different execution plan for each cursor. Here’s what’s in the shared pool.
SQL>SELECT sql_id,2sql_text,3parse_calls,4executions5FROM v$sql6WHERE INSTR(UPPER(sql_text),'ORDERS') > 07AND INSTR(UPPER(sql_text),'SQL_TEXT') = 08AND command_type = 3;SQL_ID SQL_TEXT PARSE_CALLS EXECUTIONS ------------- --------------------- ----------- ---------- d8ksp6aaxa26d SELECT COUNT(*) FRO 1 1 M orders d8ksp6aaxa26d SELECT COUNT(*) FRO 1 1 M orders
Tip
Starting with Oracle Database 10g Release 1, the column SQL_ID is used to uniquely identify a cursor in views such as V$SQL and V$OPEN_CURSOR. Earlier releases use a combination of the HASH_VALUE and ADDRESS columns for this purpose.
Oracle obviously ...