Creating Query Plan Stability in Oracle Relational Databases with Cost-based Optimizers

What Query Plan Stability?

Query Plan Stability ensures predictable and appreciable database performance no matter how much data is being stored in the buffer cache or on disk.   It ensures that all queries are performing according to business requirements and processes are running in a timely manner during the all business hours.

The information presented in this document applies to object relational databases with a cost-base optimizer. The principal audience for this documentation are database administrators, database programmers and customer support analyst.

Whenever confronted with a poorly performing application.  The following typically occurs during troubleshooting

  1. Ask stakeholder when and at what frequency statistical collection is performed.  If stakeholder has not computed statistics recently or has never computed statistics, they must compute statistics before proceeding.
  2. Ask customers if there has been a recent change in data. If this has occurred, get as much detail on the changes
    1. When and where the changes made
    2. The quantity of changes.

During execution of processes  plan instability can occur due to the following factors:

  1. Lack of adherence to cardinality and primary and foreign key relationships.
  2. Lack of proper statistics.
  3. Misuse of predicates in query and plan binding.
  4. Flush of “good” plans from the shared pool (plan cache).

One of the best tools for ensuring plan stability in Oracle is the cost-based optimizer explain plan, which helps determine how costly it is to execute a plan based on its cost in CPU.

Query identifies in Oracle (SQL_ID) are indexes with alphanumeric characters (e.g. 3mx8whn1c5jbb). 

When reviewing query execution performance, it’s always best to create a query plan:

SQL>EXPLAIN PLAN FOR 
select XML_LOADID, XML_RECORDTEXT FROM OLAPSYS.XML_LOAD_RECORDS WHERE XML_RECORDID=2;

SQL>  select * from TABLE(DBMS_XPLAN.DISPLAY);

Explain plans show how the query is performing in the cost-based optimizer once parsed. It provides valuable information of where the highest cost are in your query. Query tuning is essential for maintaining performance in a cost-based optimizer.

If plan instability occurs in an Oracle database, there are several options in addition to the list in the preceding sections to correct the issue.   

  1.  Query performs very poorly or performs full table scans on very high cardinal and big table objects.
  2. Make sure that statistical collection script has been executed.  Make certain that statistics are up to date.   See appendix for script to check statistics.
  3. If Statistics are up to date.  Attempt to generate a plan analysis (SQL profile) of the current plan.  Note:  Oracle Diagnostic Pack and Automated Database Diagnostic Manager (ADDM) needs to be installed.  The profile can be generated via the OEM GUI or using scripts.

Command Line SQL Tuning and SQL Profiling.

The following steps allow an administrator to create SQL profile tuning sets as well as export out those profiles from a source database and import it into a new database.  This allows administrator to create and test better plans in test systems and then load them safely into production systems and enable/disable them when needed.

Run query to find currently in memory that has high execution time.

SET HEADING ON
SET PAGESIZE 20000
SET LINESIZE 2000
COL text FOR A50
COL ctext FOR A50


select vs.last_load_time, ao.OWNER, parsing_schema_name, first_load_time , ao.OBJECT_NAME, vs.program_line#, executions exe, vs.sqltype, vs.sql_id, vs.rows_processed rows_processed, concurrency_wait_time, elapsed_time/1000000 elapsed_secs, elapsed_time/1000000/(case when executions = 0 then 1 else executions end) elap_per_exec_secs, vs.sql_fulltext text, vs.sql_text ctext
from v$sql vs, all_objects ao
where vs.PROGRAM_ID = ao.OBJECT_ID and parsing_schema_name not in ('SYS','SYSTEM') and parsing_schema_name in ('<SCHEMA_OWNER>')
and owner not in ('SYS','SYSTEM','DBSNMP','SYSMAN','MDSYS')
order by vs.last_load_time desc , vs.parsing_schema_name, vs.first_load_time desc , program_id, vs.program_line#;

Execute v$sqlarea query to find plan and hash values that identify that query.


select address, hash_value, plan_hash_value from v$sqlarea where sql_id in ('2zd224kurqsr9');

ADDRESS          HASH_VALUE PLAN_HASH_VALUE
---------------- ---------- ---------------
00000003ACC32290 3419553494      1111780545

Prior to doing a purge of a PLAN_HASH from the shared_pool, it’s important to collect information about the bad plan.   You can do this by executing an DBMS_XPLAN outline on the Plans.  To preserve the plan prior to flushing if from the shared_pool, read section on Loading Plan from Cache to Baseline and return here to continue.

SQL> EXPLAIN PLAN FOR select XML_LOADID, XML_RECORDTEXT FROM OLAPSYS.XML_LOAD_RECORDS WHERE XML_RECORDID=2;

Explained.

SQL> select * from TABLE(DBMS_XPLAN.DISPLAY);

If plan exists in memory, but has a bad hash plan number, create tuning task and SQL set for the query.

Execute tuning task command to see if ADDM will generate a better plan (Do not purge from memory if using this step).

var stmt_task VARCHAR2(64);

SET SERVEROUTPUT ON LINESIZE 200 PAGESIZE 20000 LONG 9999

EXEC :stmt_task := DBMS_SQLTUNE.CREATE_TUNING_TASK(sql_id => '2zd224kurqsr9', task_name => 'sga_tuning_task_1');
	
SELECT DBMS_SQLTUNE.REPORT_TUNING_TASK('sga_tuning_task_1', 'TEXT', 'TYPICAL', 'FINDINGS') FROM DUAL;

 If no results are returned, then ADDM will not be able to tune.

SQL> SELECT DBMS_SQLTUNE.REPORT_TUNING_TASK('sga_tuning_task_1', 'TEXT', 'TYPICAL', 'FINDINGS') FROM DUAL;
ERROR:
ORA-13631: The most recent execution of task sga_tuning_task_1 contains no results.
ORA-06512: at "SYS.PRVT_ADVISOR", line 5739
ORA-06512: at "SYS.DBMS_SQLTUNE", line 1045
ORA-06512: at line 1

If no results are returned skip following query and go to step 6.  Always make sure not to purge SGA if you use these steps.

DECLARE
    
    sqlprofile_name VARCHAR2(30);

BEGIN
	 
    sqlprofile_name := DBMS_SQLTUNE.ACCEPT_SQL_PROFILE ( 
    task_name    => 'sga_tuning_task_1'
,   name         => 'sql_profile_1'
,   force_match  => true 
);
END;
/

Create a SQL Tuning Set from AWR.

Find the begin and end span for the SQL_ID and plan hash that you need from AWR (This is if the plan has been purged from the pool and exists in AWR repository.

SET LINESIZE 2000 PAGESIZE 20000
SET LONG 99999
     select
        SNAP_ID,
        TO_CHAR(begin_interval_time,'DD-MON-YYYY HH24') begin_interval_time,
        TO_CHAR(end_interval_time,'DD-MON-YYYY HH24') end_interval_time,
        SQL_ID,
        round((round((avg(ELAPSED_TIME_DELTA)/1000000),2)/(case when avg(EXECUTIONS_DELTA)=0 then 1 else avg(EXECUTIONS_DELTA) end)),2) as ELAPSED_TIME_SECS,
        round((round((avg(CPU_TIME_DELTA)/1000000),2)/(case when avg(EXECUTIONS_DELTA)=0 then 1 else avg(EXECUTIONS_DELTA) end)),2) as CPU_TIME_SECS,
        round((avg(BUFFER_GETS_DELTA)/(case when avg(EXECUTIONS_DELTA)=0 then 1 else avg(EXECUTIONS_DELTA) end)),2) as GETS_PER_EXEC
     from
        dba_hist_snapshot natural join dba_hist_sqlstat natural join dba_hist_sqltext
     where
      (elapsed_time_delta > 0 or elapsed_time_delta is not null)
      and SQL_ID = 'bbuc9hr5x4gqq'
     group by
        SNAP_ID,
        TO_CHAR(begin_interval_time,'DD-MON-YYYY HH24'),
        TO_CHAR(end_interval_time,'DD-MON-YYYY HH24'),
        SQL_ID
     order by
        snap_id asc
/

Create a SQL set.

Begin 
  DBMS_SQLTUNE.CREATE_SQLSET (sqlset_name => '2zd224kurqsr9_TUNING_SET_1');
END;
/

 Load SQL Tuning Set.

DECLARE
   Cur sys_refcursor;
 BEGIN
    OPEN cur FOR
     SELECT VALUE(P) FROM TABLE(dbms_sqltune.select_workload_repository(begin_snap=>13645, end_snap=>13649, Basic_filter=>'sql_id=''2zd224kurqsr9''', attribute_list => 'ALL' )
) p;
DBMS_SQLTUNE.LOAD_SQLSET(sqlset_name=> '2zd224kurqsr9_TUNING_SET_1', populate_cursor=> cur);
CLOSE cur;
End;
/

 Verify tuning set is correct.

SELECT * FROM TABLE(DBMS_SQLTUNE.SELECT_SQLSET(sqlset_name => '2zd224kurqsr9_TUNING_SET_1'));

 create the sql set staging table (Cannot be created in the SYS or SYSTEM schema).

execute DBMS_SQLTUNE.CREATE_STGTAB_SQLSET(table_name =>'TUNING_SET_1_STGTAB');

Pack the tuning set into the staging table.

execute DBMS_SQLTUNE.PACK_STGTAB_SQLSET(sqlset_name => 'bbuc9hr5x4gqq_TUNING_SET_1',staging_table_name => 'TUNING_SET_1_STGTAB', staging_schema_owner=>'<SCHEMA_OWNER_SOURCE>');

Check the count of the table to make sure it’s been populated.

SQL> select count(*) from <SCHEMA_OWNER_SOURCE>.TUNING_SET_1_STGTAB;

  COUNT(*)
----------
         3

Export out the staging table.

[oracle]$ expdp system/******* DUMPFILE=TUNIING_SET_1.DMP DIRECTORY=BACKUPS TABLES='<SCHEMA_OWNER_SOURCE>.TUNING_SET_1_STGTAB'

Export: Release 11.2.0.4.0 - Production on Fri Mar 9 04:10:34 2018

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
Starting "SYSTEM"."SYS_EXPORT_TABLE_01":  system/******** DUMPFILE=TUNIING_SET_1.DMP DIRECTORY=BACKUPS TABLES=<SCHEMA_OWNER_SOURCE>.TUNING_SET_1_STGTAB
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 9.562 MB
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
. . exported "<SCHEMA_OWNER_SOURCE>"."TUNING_SET_1_STGTAB"             54.01 KB       3 rows
Master table "SYSTEM"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SYSTEM.SYS_EXPORT_TABLE_01 is:
  /data/backups/TUNIING_SET_1.DMP
Job "SYSTEM"."SYS_EXPORT_TABLE_01" successfully completed at Fri Mar 9 04:11:10 2018 elapsed 0 00:00:32


******** impdp staging table into target database  ******

Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
Master table "SYSTEM"."SYS_IMPORT_FULL_01" successfully loaded/unloaded
Starting "SYSTEM"."SYS_IMPORT_FULL_01":  system/******** DUMPFILE=TUNIING_SET_1.DMP REMAP_SCHEMA=<schema_owner_source>:<schema_owner> DIRECTORY=BACKUPS
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
. . imported "<SCHEMA_OWNER>"."TUNING_SET_1_STGTAB"                54.01 KB       3 rows
Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
Job "SYSTEM"."SYS_IMPORT_FULL_01" successfully completed at Fri Mar 9 04:29:52 2018 elapsed 0 00:00:41

Purge the plan from the shared pool on source database.

exec sys.dbms_shared_pool.purge('00000003ACC32290,3419553494','C');

*** OR ***

set pagesize 20000
select 'exec sys.dbms_shared_pool.purge(''' || address || ',' ||  hash_value   || ''',''C'');' from v$sqlarea where sql_text like '%TASKTEMPLATEPARAMETERVALUE X  where (1=1)%'
/

'EXECSYS.DBMS_SHARED_POOL.PURGE('''||ADDRESS||','||HASH_VALUE||''',''C'');'
--------------------------------------------------------------------------------
exec sys.dbms_shared_pool.purge('00000003ACC32290,3419553494','C');
exec sys.dbms_shared_pool.purge('0000000127D41C68,3957004154','C');
exec sys.dbms_shared_pool.purge('00000001A851BB70,525044174','C');
exec sys.dbms_shared_pool.purge('000000016C757A98,4128744307','C');
exec sys.dbms_shared_pool.purge('000000025115E2A8,4132567071','C');

Installing new plan on target database.

Unpack the SQL set in the target database.


NAME
--------------------------------------------------------------------------------
CREATED             STATEMENT_COUNT
------------------- ---------------
bbuc9hr5x4gqq_TUNING_SET_1
2018-03-09 04:33:59               

Load plan into SQL Plan Management (SPM).

set serveroutput on
declare
my_integer pls_integer;
begin
my_integer := dbms_spm.load_plans_from_sqlset (
sqlset_name => '2zd224kurqsr9_TUNING_SET_1',
sqlset_owner => 'SYS',
fixed => 'YES',
enabled => 'YES'
);
DBMS_OUTPUT.PUT_line(my_integer);
end;
/

Gather stats on objects used by tuning set.

begin
dbms_stats.gather_table_stats( 
ownname=> '<schema_owner>', 
tabname=> 'TASKTEMPLATEPARAMETERVALUE', 
estimate_percent=> null, 
cascade=> TRUE, 
degree=> null, 
no_invalidate=> DBMS_STATS.AUTO_INVALIDATE, 
granularity=> 'AUTO', 
method_opt=> 'FOR ALL COLUMNS SIZE AUTO');
end;

Load known STS for baseline.

DECLARE
my_plans pls_integer;
BEGIN
  my_plans := DBMS_SPM.LOAD_PLANS_FROM_SQLSET(
     sqlset_name => '2zd224kurqsr9_TUNING_SET_1',
     basic_filter => 'plan_hash_value = '1111780545');
END;
/

List out baseline.

SELECT * FROM dba_sql_plan_baselines;

Please make sure that the plan we would like optimizer to use is fixed enabled.

DECLARE
My_plan pls_integer;
BEGIN
	my_plans := DBMS_SPM.ALTER_SQL_PLAN_BASELINE (
 sql_handle =><sql_handle>, plan_name => <plan_name>, attribute_name => <attribute_name>, ‘ENABLED’, attribute_value =>’YES’);
END;
/

For the plan that was manually loaded, check to make sure it has been accepted.

select sql_handle, plan_name, enabled, accepted,fixed,origin from dba_sql_plan_baselines where signature=<signature>;

Load old plan(s) from cache into baseline to preserve it.

Query the pool.

Select sql_id, exact_matching_signature, force_matching_signature from v$sql where sql_text like ‘%<sql_text%’;

Create baseline from plan.

SET SERVEROUTPUT ON

declare
my_int pls_integer;
begin
my_int := DBMS_SPM.load_plans_from_cursor_cache(sql_id => '2zd224kurqsr9’, plan_hash_value => 1111780545, fixed => 'NO', enabled => 'NO');
DBMS_OUTPUT.PUT_line(my_int);
end;
/

List baseline to make sure it has been loaded.

SELECT * FROM dba_sql_plan_baselines where signature=<exact matching signature query>;

Make sure to load current plan from cursor cache into baseline and disable with the following command.  Also make certain that the baseline is not accepted.

DECLARE
My_plan pls_integer;
BEGIN
	my_plans := DBMS_SPM.ALTER_SQL_PLAN_BASELINE (
 sql_handle =><sql_handle>, plan_name => <plan_name>, attribute_name => <attribute_name>, ‘ENABLED’, attribute_value =>’NO’);
END;

Purge the SQL from cursor Cache, so that the optimizer will pick the new plan from baseline.

select 'DBMS_SHARED_POOL.PURGE ('''||ADDRESS||', '||HASH_VALUE||''', ''C'');' from V$SQLAREA where SQL_ID = '2zd224kurqsr9';

exec DBMS_SHARED_POOL.PURGE ('000000051A0961B0, 1111780545', 'C');

Confirmation and rollback procedures

You can roll back the changes by enabling the previous plans within SQL Profile Manager and running the application to reload planes into the pool.

DECLARE
My_plan pls_integer;
BEGIN
	my_plans := DBMS_SPM.ALTER_SQL_PLAN_BASELINE (
 sql_handle =><sql_handle>, plan_name => <plan_name>, attribute_name => ‘ENABLED’, 
attribute_value =>’YES’);
END;
/

Check to make sure old plan is enabled and accepted.

select sql_handle, plan_name, enabled, accepted,fixed,origin from dba_sql_plan_baselines where signature=<signature>;
Derek Moore
Derek Moore