v$sql_shared_cursor LANGUAGE_MISMATCH

Child Cursors Related with LANGUAGE_MISMATCH

I generally use Stew Ashton’s below query to summarize reasons why cursors are not shared. 

SQL> SELECT reason_not_shared, COUNT (*) cursors, COUNT (DISTINCT sql_id) sql_ids
FROM v$sql_shared_cursor
UNPIVOT (val
FOR reason_not_shared
IN (UNBOUND_CURSOR,
SQL_TYPE_MISMATCH,
OPTIMIZER_MISMATCH,
OUTLINE_MISMATCH,
STATS_ROW_MISMATCH,
LITERAL_MISMATCH,
FORCE_HARD_PARSE,
EXPLAIN_PLAN_CURSOR,
BUFFERED_DML_MISMATCH,
PDML_ENV_MISMATCH,
INST_DRTLD_MISMATCH,
SLAVE_QC_MISMATCH,
TYPECHECK_MISMATCH,
AUTH_CHECK_MISMATCH,
BIND_MISMATCH,
DESCRIBE_MISMATCH,
LANGUAGE_MISMATCH,
TRANSLATION_MISMATCH,
BIND_EQUIV_FAILURE,
INSUFF_PRIVS,
INSUFF_PRIVS_REM,
REMOTE_TRANS_MISMATCH,
LOGMINER_SESSION_MISMATCH,
INCOMP_LTRL_MISMATCH,
OVERLAP_TIME_MISMATCH,
EDITION_MISMATCH,
MV_QUERY_GEN_MISMATCH,
USER_BIND_PEEK_MISMATCH,
TYPCHK_DEP_MISMATCH,
NO_TRIGGER_MISMATCH,
FLASHBACK_CURSOR,
ANYDATA_TRANSFORMATION,
PDDL_ENV_MISMATCH,
TOP_LEVEL_RPI_CURSOR,
DIFFERENT_LONG_LENGTH,
LOGICAL_STANDBY_APPLY,
DIFF_CALL_DURN,
BIND_UACS_DIFF,
PLSQL_CMP_SWITCHS_DIFF,
CURSOR_PARTS_MISMATCH,
STB_OBJECT_MISMATCH,
CROSSEDITION_TRIGGER_MISMATCH,
PQ_SLAVE_MISMATCH,
TOP_LEVEL_DDL_MISMATCH,
MULTI_PX_MISMATCH,
BIND_PEEKED_PQ_MISMATCH,
MV_REWRITE_MISMATCH,
ROLL_INVALID_MISMATCH,
OPTIMIZER_MODE_MISMATCH,
PX_MISMATCH,
MV_STALEOBJ_MISMATCH,
FLASHBACK_TABLE_MISMATCH,
LITREP_COMP_MISMATCH,
PLSQL_DEBUG,
LOAD_OPTIMIZER_STATS,
ACL_MISMATCH,
FLASHBACK_ARCHIVE_MISMATCH,
LOCK_USER_SCHEMA_FAILED,
REMOTE_MAPPING_MISMATCH,
LOAD_RUNTIME_HEAP_FAILED,
HASH_MATCH_FAILED,
PURGED_CURSOR,
BIND_LENGTH_UPGRADEABLE,
USE_FEEDBACK_STATS))
WHERE val = 'Y'
GROUP BY reason_not_shared
ORDER BY 2 DESC, 3, 1;

In one of our production database, the amount of child cursor count related with “LANGUAGE_MISMATCH” attracted my attention and i tried to make clear the reason behind.

According to the Database Hang With ‘cursor: mutex X’ Contention Due To High Version Count Under LANGUAGE_MISMATCH (Doc ID 2542447.1), Whenever there are different NLS settings got changed in different combinations in every execution, it creates new child and version count increases with LANGUAGE_MISMATCH.

Exactly the same queries and PL/SQL packages are called from different applications. Different applications connect to database with different database users, but execute some common sql statements. Also These applications are deployed to different servers with different operating systems and client environments.

Some example child cursor reasons are as below.

<ChildNode><ChildNumber>14</ChildNumber><ID>44</ID><reason>NLS Settings(2)</reason><size>2×568</size><NLS_DATE_FORMAT>’DD/MM/RRRR’->’DD.MM.YYYY'</NLS_DATE_FORMAT></ChildNode> 

<ChildNode><ChildNumber>15</ChildNumber><ID>44</ID><reason>NLS Settings(2)</reason><size>2×568</size><NLS_DATE_FORMAT>’DD.MM.YYYY’->’DD/MM/RRRR'</NLS_DATE_FORMAT></ChildNode> 

<ChildNode><ChildNumber>16</ChildNumber><ID>44</ID><reason>NLS Settings(2)</reason><size>2×568</size><NLS_LANGUAGE>’TURKISH’->’AMERICAN'</NLS_LANGUAGE><NLS_TERRITORY>’TURKEY’->’AMERICA'</NLS_TERRITORY><NLS_CURRENCY>’TL’->’$'</NLS_CURRENCY><NLS_ISO_CURRENCY>’TURKEY’->’AMERICA'</NLS_ISO_CURRENCY><NLS_NUMERIC_CHARACTERS>’,.’->’.,'</NLS_NUMERIC_CHARACTERS><NLS_DATE_FORMAT>’DD/MM/RRRR’->’DD-MON-RR'</NLS_DATE_FORMAT><NLS_DATE_LANGUAGE>’TURKISH’->’AMERICAN'</NLS_DATE_LANGUAGE><NLS_SORT>’TURKISH’->’BINARY'</NLS_SORT><NLS_TIME_FORMAT>’HH24:MI:SSXFF’->’HH.MI.SSXFF AM'</NLS_TIME_FORMAT><NLS_TIMESTAMP_FORMAT>’DD/MM/RRRR HH24:MI:SSXFF’->’DD-MON-RR HH.MI.SSXFF AM'</NLS_TIMESTAMP_FORMAT><NLS_TIME_TZ_FORMAT>’HH24:MI:SSXFF TZR’->’HH.MI.SSXFF AM TZR'</NLS_TIME_TZ_FORMAT><NLS_TIMESTAMP_TZ_FORMAT>’DD/MM/RRRR HH24:MI:SSXFF TZR’->’DD-MON-RR HH.MI.SSXFF AM TZR'</NLS_TIMESTAMP_TZ_FORMAT><NLS_DUAL_CURRENCY>’YTL’->’$'</NLS_DUAL_CURRENCY></ChildNode> 

First I checked all login triggers,  for some users there were “ALTER SESSION SET NLS_DATE_FORMAT” commands. They were added deliberately to prevent  some queries (without appropriated date format casting) from failing. I created login triggers like below to detect all NLS_SETTINGS for applications.

SQL> CREATE TABLE SYSTEM.t_client_nls_temp
(
parameter VARCHAR2 (100),
value VARCHAR2 (100)
);
SQL> CREATE or replace TRIGGER SYSTEM.trg_client_HR_nls
AFTER LOGON
ON HR.SCHEMA
DECLARE
p_param VARCHAR2 (100);
p_value VARCHAR2 (100);
BEGIN
FOR rec IN (SELECT parameter, VALUE FROM nls_session_parameters)
LOOP
SELECT parameter, VALUE
INTO p_param, p_value
FROM nls_session_parameters
WHERE parameter = rec.parameter;
INSERT INTO SYSTEM.t_client_nls_temp
VALUES (p_param, p_value);
COMMIT;
END LOOP;
END;

The most common format i detected was as below. 

PARAMETER VALUE

NLS_LANGUAGE TURKISH

NLS_TERRITORY TURKEY

NLS_CURRENCY ?

NLS_ISO_CURRENCY TURKEY

NLS_NUMERIC_CHARACTERS ,.

NLS_CALENDAR         GREGORIAN

NLS_DATE_FORMAT DD/MM/RRRR

NLS_DATE_LANGUAGE TURKISH

NLS_SORT         TURKISH

NLS_TIME_FORMAT HH24:MI:SSXFF

NLS_TIMESTAMP_FORMAT DD/MM/RRRR HH24:MI:SSXFF

NLS_TIME_TZ_FORMAT HH24:MI:SSXFF TZR

NLS_TIMESTAMP_TZ_FORMAT DD/MM/RRRR HH24:MI:SSXFF TZR

NLS_DUAL_CURRENCY TL

NLS_COMP         BINARY

NLS_LENGTH_SEMANTICS BYTE

NLS_NCHAR_CONV_EXCP FALSE

Most of NLS_SETTINGS are derived from NLS_LANGUAGE and NLS_TERRITORY parameters. More information is available on blog post NLS defaults for LANGUAGE and TERRITORY by Franck Pachot. Also Oracle Official Documentation (NLS_LANG FAQ) is a must read document.

Also i found that some queries called from PL/SQL packages within scheduler_jobs are also generates child cursors with LANGUAGE_MISMATCH reason. This is derived from the fact that client environment session NLS_SETTINGS are different from the applications. Whenever a scheduler job is created, its NLS_SETTINGS are set according to the client’s nls_session_parameters. You can use dbms_metadata.get_ddl function to detect them like below.

SQL> select dbms_metadata.get_ddl ('PROCOBJ',job_name,owner) from dba_scheduler_jobs where owner='HR' and job_name='JOB_HR_SENDMAIL'

We changed NLS_ENV settings  of all scheduler jobs which are not owned by Oracle Internal Users and made them same with the common format. We used the command below.

SQL> SELECT owner,
job_name,
'begin
sys.dbms_scheduler.set_attribute('''
|| owner
|| '.'
|| job_name
|| ''',''NLS_ENV'',''NLS_LANGUAGE=''''TURKISH'''' NLS_TERRITORY=''''TURKEY'''' NLS_CURRENCY=''''?''''
NLS_ISO_CURRENCY=''''TURKEY'''' NLS_NUMERIC_CHARACTERS='''',.'''' NLS_CALENDAR=''''GREGORIAN''''
NLS_DATE_FORMAT=''''DD/MM/RRRR'''' NLS_DATE_LANGUAGE=''''TURKISH'''' NLS_SORT=''''TURKISH''''
NLS_TIME_FORMAT=''''HH24:MI:SSXFF'''' NLS_TIMESTAMP_FORMAT=''''DD/MM/RRRR HH24:MI:SSXFF''''
NLS_TIME_TZ_FORMAT=''''HH24:MI:SSXFF TZR'''' NLS_TIMESTAMP_TZ_FORMAT=''''DD/MM/RRRR HH24:MI:SSXFF TZR''''
NLS_DUAL_CURRENCY=''''TL'''' NLS_COMP=''''BINARY'''' NLS_LENGTH_SEMANTICS=''''BYTE''''
NLS_NCHAR_CONV_EXCP=''''FALSE'''''');
end;' AS sql_command
FROM dba_scheduler_jobs
WHERE owner IN (SELECT username FROM dba_users WHERE oracle_maintained = 'N')
ORDER BY 1, 2 ;
BEGIN
sys.DBMS_SCHEDULER.set_attribute (
'HR.JOB_HR_SENDMAIL',
'NLS_ENV',
'NLS_LANGUAGE=''TURKISH'' NLS_TERRITORY=''TURKEY'' NLS_CURRENCY=''?'' NLS_ISO_CURRENCY=''TURKEY''
NLS_NUMERIC_CHARACTERS='',.'' NLS_CALENDAR=''GREGORIAN'' NLS_DATE_FORMAT=''DD/MM/RRRR''
NLS_DATE_LANGUAGE=''TURKISH'' NLS_SORT=''TURKISH'' NLS_TIME_FORMAT=''HH24:MI:SSXFF''
NLS_TIMESTAMP_FORMAT=''DD/MM/RRRR HH24:MI:SSXFF'' NLS_TIME_TZ_FORMAT=''HH24:MI:SSXFF TZR''
NLS_TIMESTAMP_TZ_FORMAT=''DD/MM/RRRR HH24:MI:SSXFF TZR'' NLS_DUAL_CURRENCY=''TL''
NLS_COMP=''BINARY'' NLS_LENGTH_SEMANTICS=''BYTE'' NLS_NCHAR_CONV_EXCP=''FALSE''');
END;

Hope it helps.


Discover More from Osman DİNÇ


Comments

Leave your comment