Mohamed Houri’s Oracle Notes

August 21, 2015

Cardinality Feedback: a practical case

Filed under: Oracle — hourim @ 5:36 pm

Here it is an interesting case of cardinality feedback collected from an 11.2.0.3 running system. A simple query against a single table has a perfect first execution response time with, according to the human eyes, a quite acceptable difference between Oracle cardinality estimates and actual rows as shown below:

SELECT 
   tr_id
FROM 
    t1 t1
WHERE 
     t1.t1_col_name= 'GroupID'
AND  t1.t1_col_value= '6276931'
AND EXISTS(SELECT 
               1 
            FROM  
                t1 t2
            WHERE t1.tr_id   = t2.tr_id
            AND   t2.t1_col_name= 'TrRangeOrder'
            AND   t2.t1_col_value= 'TrOrderPlace'
           );

SQL_ID  8b3tv5uh8ckfb, child number 0
-------------------------------------

Plan hash value: 1066392926
--------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name                    | Starts | E-Rows | A-Rows |   A-Time   |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                         |      1 |        |      1 |00:00:00.14 |
|   1 |  NESTED LOOPS SEMI           |                         |      1 |      1 |      1 |00:00:00.14 |
|   2 |   TABLE ACCESS BY INDEX ROWID| T1                      |      1 |      1 |      6 |00:00:00.07 |
|*  3 |    INDEX RANGE SCAN          | IDX_T1_NAME_VALUE       |      1 |      1 |      6 |00:00:00.03 |
|*  4 |   TABLE ACCESS BY INDEX ROWID| T1                      |      6 |      1 |      1 |00:00:00.07 |
|*  5 |    INDEX UNIQUE SCAN         | T1_PK                   |      6 |      1 |      6 |00:00:00.07 |
--------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."T1_COL_NAME"='GroupID' AND "T1"."T1_COL_VALUE"='6276931')
   4 - filter("T2"."T1_COL_VALUE"='TrOrderPlace')
   5 - access("T1"."TR_ID"="T2"."TR_ID" AND 
               "T2"."T1_COL_NAME"='TrRangeOrder')

And here it is the second dramatic execution plan and response time due, this time, to cardinality feedback optimisation:


SQL_ID  8b3tv5uh8ckfb, child number 1
-------------------------------------
Plan hash value: 3786385867
----------------------------------------------------------------------------------------------------------
| Id  | Operation                      | Name                    | Starts | E-Rows | A-Rows |   A-Time   |
----------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT               |                         |      1 |        |      1 |00:10:40.14 |
|   1 |  NESTED LOOPS                  |                         |      1 |        |      1 |00:10:40.14 |
|   2 |   NESTED LOOPS                 |                         |      1 |      1 |    787K|00:09:31.00 |
|   3 |    SORT UNIQUE                 |                         |      1 |      1 |    787K|00:02:44.83 |
|   4 |     TABLE ACCESS BY INDEX ROWID| T1                      |      1 |      1 |    787K|00:02:41.58 |
|*  5 |      INDEX RANGE SCAN          | IDX_T1_NAME_VALUE       |      1 |      1 |    787K|00:00:36.46 |
|*  6 |    INDEX UNIQUE SCAN           | T1_PK                   |    787K|      1 |    787K|00:06:45.25 |
|*  7 |   TABLE ACCESS BY INDEX ROWID  | T1                      |    787K|      1 |      1 |00:05:00.24 |
----------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   5 - access("T2"."T1_COL_NAME"='TrRangeOrder' AND "T2"."T1_COL_VALUE"='TrOrderPlace')
   6 - access("T1"."TR_ID"="T2"."TR_ID" AND "T1"."T1_COL_NAME"='GroupID')
   7 - filter("T1"."T1_COL_VALUE"='6276931')

Note
-----
   - cardinality feedback used for this statement

There is no real noticeable difference between actual and estimated rows in the first run of the query (E-Rows =1 versus A-Rows = 6) which implies a new re-optimisation. But Oracle did it and marked the child cursor n°0 candidate for a cardinality feedback:

SQL> select
       sql_id
      ,child_number
      ,use_feedback_stats
    from
      v$sql_shared_cursor
    where
      sql_id = '8b3tv5uh8ckfb';

SQL_ID        CHILD_NUMBER U
------------- ------------ -
8b3tv5uh8ckfb            0 Y

The bad news however with this Oracle decision is that we went from a quasi-instantaneous response time to a catastrophic 10 min. In the first plan the always suspicious estimated ‘’1’’ cardinality is not significantly far from actual rows (6), so why then Oracle has decided to re-optimize the first cursor? It might be “possible” that when Oracle rounds up its cardinality estimation to 1 for a cursor that has been previously monitored for cardinality feedback, it flags somewhere that this cursor is subject to a re-optimization during its next execution whatever the actual rows will be (close to 1 or not)?

Fortunately, this second execution has also been marked for re-optimisation:

SQL> select
       sql_id
      ,child_number
      ,use_feedback_stats
    from
      v$sql_shared_cursor
    where
      sql_id = '8b3tv5uh8ckfb';

SQL_ID        CHILD_NUMBER U
------------- ------------ -
8b3tv5uh8ckfb            0 Y
8b3tv5uh8ckfb            1 Y

And the third execution of the query produces the following interesting execution plan

SQL_ID  8b3tv5uh8ckfb, child number 2
-------------------------------------

Plan hash value: 1066392926
--------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name                    | Starts | E-Rows | A-Rows |   A-Time   |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                         |      1 |        |      1 |00:00:00.01 |
|   1 |  NESTED LOOPS SEMI           |                         |      1 |      1 |      1 |00:00:00.01 |
|   2 |   TABLE ACCESS BY INDEX ROWID| T1                      |      1 |      6 |      6 |00:00:00.01 |
|*  3 |    INDEX RANGE SCAN          | IDX_T1_NAME_VALUE       |      1 |      6 |      6 |00:00:00.01 |
|*  4 |   TABLE ACCESS BY INDEX ROWID| T1                      |      6 |      1 |      1 |00:00:00.01 |
|*  5 |    INDEX UNIQUE SCAN         | T1_PK                   |      6 |      1 |      6 |00:00:00.01 |
--------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."T1_COL_NAME"='GroupID' AND "T1"."T1_COL_VALUE"='6276931')
   4 - filter("T2"."T1_COL_VALUE"='TrOrderPlace')
   5 - access("T1"."TR_ID"="T2"."TR_ID" AND
              "T2"."T1_COL_NAME"='TrRangeOrder')

Note
-----
   - cardinality feedback used for this statement   

Oracle is back to its first execution plan. The new estimations coincide perfectly with the actuals so that Oracle decided to stop monitoring this cursor with cardinality feedback as shown below:

SQL> select
       sql_id
      ,child_number
      ,use_feedback_stats
    from
      v$sql_shared_cursor
    where
      sql_id = '8b3tv5uh8ckfb';

SQL_ID        CHILD_NUMBER U
------------- ------------ -
8b3tv5uh8ckfb            0 Y
8b3tv5uh8ckfb            1 Y
8b3tv5uh8ckfb            2 N

Several questions come to my mind at this stage of the investigation:

  1.  What are the circumstances for which Oracle marks a cursor for cardinality feedback optimisation?
  2. How Oracle decides that E-Rows are significantly different from A-Rows and henceforth a cursor re-optimization will be done? In other words is E-Rows =1 significantly different from A-Rows =6? Or does that suspicious cardinality 1 participate in Oracle decision to re-optimize a cursor monitored with cardinality feedback?

Let’s try to answer the first question. There is only one unique table involved in this query with two conjunctive predicates. The two predicate columns have the following statistics

SQL> select
        column_name
       ,num_distinct
       ,density
       ,histogram
     from 
	    all_tab_col_statistics
     where
        table_name = 'T1'
     and
       column_name in ('T1_COL_NAME','T1_COL_VALUE');

COLUMN_NAME     NUM_DISTINCT    DENSITY HISTOGRAM
--------------- ------------ ---------- ---------------
T1_COL_NAME           103     4,9781E-09 FREQUENCY
T1_COL_VALUE      14833664   ,000993049  HEIGHT BALANCED

The presence of histograms, particularly the HEIGHT BALANCED, on these two columns participates strongly in the Oracle decision to monitor the cursor for cardinality feedback. In order to be sure of it I decided to get rid of histograms from both columns and re-query again:

SQL> select
        column_name
       ,num_distinct
       ,density
       ,histogram
     from 
	    all_tab_col_statistics
     where
        table_name = 'T1'
     and
       column_name in ('T1_COL_NAME','T1_COL_VALUE');

COLUMN_NAME     NUM_DISTINCT    DENSITY HISTOGRAM
--------------- ------------ ---------- ---------
T1_COL_NAME           103    ,009708738 NONE
T1_COL_VALUE      15477760   6,4609E-08 NONE

The new cursor is not anymore monitored with the cardinality feedback as shown below:

SQL_ID  fakc7vfbu1mam, child number 0
-------------------------------------

Plan hash value: 739349168
--------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name                    | Starts | E-Rows | A-Rows |   A-Time   |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                         |      1 |        |      1 |00:02:00.68 |
|*  1 |  HASH JOIN SEMI              |                         |      1 |      6 |      1 |00:02:00.68 |
|   2 |   TABLE ACCESS BY INDEX ROWID| T1                      |      1 |      6 |      6 |00:00:00.01 |
|*  3 |    INDEX RANGE SCAN          | IDX_T1_NAME_VALUE       |      1 |      6 |      6 |00:00:00.01 |
|   4 |   TABLE ACCESS BY INDEX ROWID| T1                      |      1 |      6 |    787K|00:02:00.14 |
|*  5 |    INDEX RANGE SCAN          | IDX_T1_NAME_VALUE       |      1 |      6 |    787K|00:00:12.36 |
--------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."TR_ID"="T2"."TR_ID")
   3 - access("T1"."T1_COL_NAME"='GroupID' AND "T1"."T1_COL_VALUE"='6276931')
   5 - access("T2"."T1_COL_NAME"='TrRangeOrder' AND "T2"."T1_COL_VALUE"='TrOrderPlace')

   SQL> select
         sql_id
        ,child_number
        ,use_feedback_stats
    from
       v$sql_shared_cursor
    where
        sql_id = 'fakc7vfbu1mam';

SQL_ID        CHILD_NUMBER U
------------- ------------ -
fakc7vfbu1mam            0 N --> cursor not re-optimisable 

Without histograms on the two columns Oracle has not monitored the query for cardinality feedback. Unfortunately getting rid of histogram was not an option accepted by the client nor changing this packaged query to force the optimizer not unnesting the EXISTS subquery with its parent query as far as the later is always generating a couple of rows that will not hurt performance when filtered with the EXIST subquery. Attaching a SQL Profile has also been discarded because several copies of the same query are found in the packaged application which would have necessitated a couple of extra SQL Profiles.

The last option that remains at my hands was to collect extended statistics so that Oracle will be able to get accurate estimations and henceforth will stop using cardinality feedback

SQL> SELECT
       dbms_stats.create_extended_stats
       (ownname   => user
       ,tabname   => 'T1'
       ,extension => '(T1_COL_NAME,T1_COL_VALUE)'
      )
  FROM dual;

DBMS_STATS.CREATE_EXTENDED_STATS(
---------------------------------
SYS_STUE3EBVNLB6M1SYS3A07$LD52

SQL> begin
      dbms_stats.gather_table_stats
            (user
           ,'T1'
           ,method_opt    => 'for columns SYS_STUE3EBVNLB6M1SYS3A07$LD52 size skewonly'
           ,cascade       => true
           ,no_invalidate => false
            );
    end;
    /

SQL> select
       column_name
      ,num_distinct
      ,density
      ,histogram
    from all_tab_col_statistics
    where
        table_name = 'T1'
    and column_name in ('T1_COL_NAME','T1_COL_VALUE', 'SYS_STUE3EBVNLB6M1SYS3A07$LD52');

COLUMN_NAME                    NUM_DISTINCT    DENSITY HISTOGRAM
------------------------------ ------------ ---------- ---------------
SYS_STUE3EBVNLB6M1SYS3A07$LD52     18057216 ,000778816 HEIGHT BALANCED
T1_COL_NAME                          103    4,9781E-09 FREQUENCY
T1_COL_VALUE                     14833664   ,000993049 HEIGHT BALANCED


SQL_ID  dn6p58b9b6348, child number 0
-------------------------------------
Plan hash value: 1066392926
--------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name                    | Starts | E-Rows | A-Rows |   A-Time   |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                         |      1 |        |      1 |00:00:00.01 |
|   1 |  NESTED LOOPS SEMI           |                         |      1 |      3 |      1 |00:00:00.01 |
|   2 |   TABLE ACCESS BY INDEX ROWID| T1                      |      1 |      3 |      6 |00:00:00.01 |
|*  3 |    INDEX RANGE SCAN          | IDX_T1_NAME_VALUE       |      1 |      3 |      6 |00:00:00.01 |
|*  4 |   TABLE ACCESS BY INDEX ROWID| T1                      |      6 |    832K|      1 |00:00:00.01 |
|*  5 |    INDEX UNIQUE SCAN         | T1_PK                   |      6 |      1 |      6 |00:00:00.01 |
--------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."T1_COL_NAME"='GroupID' AND "T1"."T1_COL_VALUE"='6276931')
   4 - filter("T2"."T1_COL_VALUE"='TrOrderPlace')
   5 - access("T1"."TR_ID"="T2"."TR_ID" AND
              "T2"."T1_COL_NAME"='TrRangeOrder')

SQL> select
       sql_id
      ,child_number
      ,use_feedback_stats
    from
      v$sql_shared_cursor
    where
      sql_id = 'dn6p58b9b6348';
   
SQL_ID        CHILD_NUMBER U
------------- ------------ -
dn6p58b9b6348            0 N

This time, for E-Rows = 3 and A-Rows =6, Oracle decided that there is no significant difference between cardinality estimates and the actual rows so that the cursor is not anymore subject to cardinality feedback optimization.

You might have pointed out that I have forced the Extended Statistics column to have histogram. Otherwise the cardinality feedback will kicks off. In fact I have conducted several experiments to see when the cardinality feedback occurs and when not depending on the existence or the absence of the column group extension, its type of statistics and the statistics that have been gathered on the underlying two columns predicates:
cardinality feedback

 

August 12, 2015

Adaptive Cursor Sharing triggering mechanism

Filed under: cursor sharing — hourim @ 10:08 pm

Inspired by Dominic Brooks’ last post on SQL Plan Management choices, I decided to do the same work about my thoughts on Adaptive and Extended Cursor Sharing triggering mechanism:

ACS triggering diagramOnce a cursor is bind aware and subject to an eventual plan optimization at each execution keep a careful eye on the number of cursors the Extended Cursor Sharing Layer are going to produce

August 5, 2015

Flash back causing library cache: mutex X

Filed under: Oracle — hourim @ 5:28 pm

Recently one of our applications suffered from a severe performance issue. It is an application running on a database(11.2.0.4.0) used to validate a pre-production release. This performance issue has delayed the campaign test and the validation process for more than 3 days. The ASH data taken during the altered performance period shows this:

SQL> select event, count(1)
    from gv$active_session_history
    where sample_time between to_date('15072015 16:00:00', 'ddmmyyyy hh24:mi:ss')
                      and     to_date('15072015 16:30:00', 'ddmmyyyy hh24:mi:ss')
    group by event
    order by 2 desc;

EVENT                                COUNT(1)
----------------------------------- ----------
library cache: mutex X                    3928
kksfbc child completion                    655
cursor: pin S wait on X                    580
PX Deq: Slave Session Stats                278
                                           136
db file sequential read                    112
cursor: pin S                               35
null event                                  26
latch: shared pool                          15
cursor: mutex S                             13
library cache lock                          11
read by other session                       10
log file parallel write                      5
PX Deq: Signal ACK EXT                       3
os thread startup                            3
log file sync                                2
latch free                                   1
db file parallel write                       1
SQL*Net more data from client                1
enq: PS - contention                         1
cursor: mutex X                              1
direct path read                             1
control file sequential read                 1
CSS operation: action                        1

As you can notice the dominant wait event is:

EVENT                          COUNT(1)
------------------------------ -------
library cache: mutex X         3928

A library cache: mutex X wait event represents a concurrency wait event that is a part of 6 mutexes wait events

	CURSOR : pin S
	CURSOR : pin X
	CURSOR : pin S wait on X
	CURSOR : mutex S
	CURSOR : mutex X
	Library cache : mutex X

Mutexes are similar to locks except that they lock object in shared memory rather than rows in tables and indexes. Whenever a session wants to read or write into the library cache shared memory it needs to pin that object (cursor generally) and acquire a mutex on it. If another session wants simultaneously to read the same piece of memory it will try to acquire a mutex on it. This session might then wait on one of those library or cursor mutex wait event since another session has already preceded it and has still not released the latch (the mutex).

So, extended to my actual case what has been exaggerated so that a library cache: mutex X has made the database unusable?

SQL> select
       sql_id
      ,session_id
      ,in_parse
      ,in_sql_execution
    from
      gv$active_session_history
    where sample_time between to_date('15072015 16:00:00', 'ddmmyyyy hh24:mi:ss')
                      and     to_date('15072015 16:30:00', 'ddmmyyyy hh24:mi:ss')
    and event = 'library cache: mutex X'
    order by sql_id; 

SQL_ID        SQL_CHILD_NUMBER SESSION_ID IN_PARSE   IN_SQL_EXECUTION
------------- ---------------- ---------- ---------- ----------------
20f2kut7fg4g0               -1          8 Y          N
20f2kut7fg4g0               -1         20 Y          N
20f2kut7fg4g0                1         24 N          Y
20f2kut7fg4g0               -1         40 Y          N
20f2kut7fg4g0               -1         60 Y          N
20f2kut7fg4g0               -1         88 Y          N
20f2kut7fg4g0                1         89 N          Y
20f2kut7fg4g0                1         92 N          Y
20f2kut7fg4g0               -1        105 Y          N
20f2kut7fg4g0               -1        106 Y          N
20f2kut7fg4g0                1        109 N          Y
20f2kut7fg4g0               -1        124 Y          N
20f2kut7fg4g0               -1        128 Y          N
20f2kut7fg4g0               -1        143 Y          N
20f2kut7fg4g0               -1        157 Y          N
20f2kut7fg4g0                1        159 N          Y
20f2kut7fg4g0               -1        160 Y          N
20f2kut7fg4g0               -1        161 Y          N
20f2kut7fg4g0                1        172 N          Y
20f2kut7fg4g0                1        178 N          Y
20f2kut7fg4g0               -1        191 Y          N
20f2kut7fg4g0               -1        192 Y          N
20f2kut7fg4g0               -1        194 Y          N
20f2kut7fg4g0                1        209 N          Y
20f2kut7fg4g0               -1        223 Y          N
20f2kut7fg4g0                1        229 N          Y
20f2kut7fg4g0               -1        241 Y          N
20f2kut7fg4g0               -1        246 Y          N
20f2kut7fg4g0               -1        258 Y          N
20f2kut7fg4g0                1        259 N          Y
20f2kut7fg4g0                1        280 N          Y
20f2kut7fg4g0                1        294 N          Y
20f2kut7fg4g0               -1        309 Y          N
20f2kut7fg4g0               -1        310 Y          N
20f2kut7fg4g0               -1        328 Y          N
20f2kut7fg4g0                1        348 N          Y
20f2kut7fg4g0               -1        382 Y          N
20f2kut7fg4g0               -1        413 Y          N
20f2kut7fg4g0               -1        415 Y          N
20f2kut7fg4g0                1        428 N          Y
20f2kut7fg4g0               -1        449 Y          N
20f2kut7fg4g0               -1        450 Y          N
20f2kut7fg4g0               -1        462 Y          N
20f2kut7fg4g0                1        467 N          Y
20f2kut7fg4g0               -1        480 Y          N
20f2kut7fg4g0               -1        484 Y          N
20f2kut7fg4g0                1        516 N          Y
20f2kut7fg4g0               -1        533 Y          N
20f2kut7fg4g0                1        535 N          Y
20f2kut7fg4g0               -1        546 Y          N
20f2kut7fg4g0               -1        565 Y          N
20f2kut7fg4g0                1        568 N          Y
20f2kut7fg4g0               -1        584 Y          N
20f2kut7fg4g0               -1        585 Y          N
20f2kut7fg4g0               -1        601 Y          N
20f2kut7fg4g0               -1        602 Y          N
20f2kut7fg4g0               -1        615 Y          N
20f2kut7fg4g0               -1        619 Y          N
20f2kut7fg4g0               -1        635 Y          N
20f2kut7fg4g0               -1        652 Y          N
20f2kut7fg4g0               -1        667 Y          N
20f2kut7fg4g0               -1        668 Y          N
20f2kut7fg4g0               -1        687 Y          N
20f2kut7fg4g0               -1        705 Y          N
20f2kut7fg4g0               -1        717 Y          N
20f2kut7fg4g0               -1        721 Y          N
20f2kut7fg4g0               -1        733 Y          N
20f2kut7fg4g0               -1        735 Y          N
20f2kut7fg4g0               -1        753 Y          N
20f2kut7fg4g0               -1        754 Y          N
20f2kut7fg4g0                1        770 N          Y
20f2kut7fg4g0               -1        773 Y          N
20f2kut7fg4g0               -1        785 Y          N
20f2kut7fg4g0               -1        786 Y          N
20f2kut7fg4g0               -1        804 Y          N

75 rows selected.

I have limited the output to just one sql_id (20f2kut7fg4g0) in order to keep the explanation clear and simple.

What does represent this particular sql_id which is executed by 75 different sessions that are sometimes in parse and sometimes in execution?

SQL> with got_my_sql_id
    as ( select sql_id, count(1)
    from gv$active_session_history
    where sample_time between to_date('16072015 09:30:00', 'ddmmyyyy hh24:mi:ss')
                      and     to_date('16072015 10:30:00', 'ddmmyyyy hh24:mi:ss')
    and event  = 'library cache: mutex X'
    group by sql_id)
    select distinct sql_id, sql_text
    from v$sql b
   where exists (select null
                 from got_my_sql_id a
                 where a.sql_id = b.sql_id)
   order by sql_id; 

SQL_ID        SQL_TEXT
------------ ----------------------------------------------------------------------
20f2kut7fg4g0 /* Flashback Table */ INSERT /*+ PARALLEL(S, DEFAULT) PARALLEL(T,
                 DEFAULT) */ INTO "DEV_ZXX"."CLOSED_DAY" SELECT
              /*+ USE_NL(S) ORDERED PARALLEL(S, DEFAULT) PARALLEL(T, DEFAULT) */
              S.* FROM SYS_TEMP_FBT T , "DEV_ZXX"."CLOSED_DAY"
              as of SCN :1 S WHERE T.rid = S.
              rowid and T.action = 'I' and T.object# = :2

The above piece of SQL code is generated by Oracle behind the scene when flashing backward a content of a given table. And this is exactly what this client was doing. At the end of their pre-production test campaign they flash back a certain number of tables to the data they have at the beginning of the test. And since the generated code uses parallel run with default degree it has produce such a kind of monitored execution plan


Parallel Execution Details (DOP=96 , Servers Allocated=96) 

SQL Plan Monitoring Details (Plan Hash Value=4258977226)
===============================================================================
| Id |        Operation        |      Name       |  Rows   | Execs |   Rows   |
|    |                         |                 | (Estim) |       | (Actual) |
===============================================================================
|  0 | INSERT STATEMENT        |                 |         |     1 |          |
|  1 |   LOAD AS SELECT        |                 |         |     1 |          |
|  2 |    PX COORDINATOR       |                 |         |    82 |          |
|  3 |     PX SEND QC (RANDOM) | :TQ10000        |     322 |    81 |          |
|  4 |      PX BLOCK ITERATOR  |                 |     322 |    81 |          |
|  5 |       TABLE ACCESS FULL | TABLE_RULE_SUP  |     322 |     4 |          |
===============================================================================

For every flashed back table Oracle started 96 parallel servers (96 sessions) in order to do a simple insert statement causing the observed library cache mutex X wait event. The DOP 96 is the maximum DOP which represents in fact the default DOP determined by the following simplified formula:

DOP = PARALLEL_THREADS_PER_CPU x CPU_COUNT
DOP = 2 x 48 = 96
SQL> show parameter parallel

NAME                               TYPE        VALUE
---------------------------------- ----------- ----------
fast_start_parallel_rollback       string      LOW
parallel_adaptive_multi_user       boolean     TRUE
parallel_automatic_tuning          boolean     FALSE
parallel_degree_limit              string      CPU
parallel_degree_policy             string      MANUAL
parallel_execution_message_size    integer     16384
parallel_force_local               boolean     FALSE
parallel_instance_group            string
parallel_io_cap_enabled            boolean     FALSE
parallel_max_servers               integer     100
parallel_min_percent               integer     0
parallel_min_servers               integer     0
parallel_min_time_threshold        string      AUTO
parallel_server                    boolean     FALSE
parallel_server_instances          integer     1
parallel_servers_target            integer     100
_parallel_syspls_obey_force        boolean     TRUE
parallel_threads_per_cpu           integer     2
recovery_parallelism               integer     0
SQL> show parameter cpu

NAME                           TYPE        VALUE
------------------------------ ----------- -----
cpu_count                       integer     48
parallel_threads_per_cpu        integer     2
resource_manager_cpu_allocation integer     48

Having no possibility to hint the internal flash back Oracle code so that it will not execute in parallel, all what I have been left with is to pre-empt Oracle from starting a huge number of parallel process by limiting the parallel_max_servers parameter to 8 and, and as such, the maximum DOP will be limited to 8 whatever the cpu_count is.

Once this done I observed the following new situation for one flashed back sql_id (a5u912v53t11t)


Global Information
------------------------------
 Status              :  DONE
 Instance ID         :  1
 Session             :  XXXXX (172:40851)
 SQL ID              :  a5u912v53t11t
 SQL Execution ID    :  16777236
 Execution Started   :  07/16/2015 11:21:55
 First Refresh Time  :  07/16/2015 11:21:55
 Last Refresh Time   :  07/16/2015 11:21:55
 Duration            :  .011388s
 Module/Action       :  JDBC Thin Client/-
 Service             :  SYS$USERS
 Program             :  JDBC Thin Client
 DOP Downgrade       :  92%                       

Global Stats
=======================================================
| Elapsed |   Cpu   | Concurrency |  Other   | Buffer |
| Time(s) | Time(s) |  Waits(s)   | Waits(s) |  Gets  |
=======================================================
|    0.05 |    0.00 |        0.04 |     0.00 |     19 |
=======================================================

Parallel Execution Details (DOP=8 , Servers Requested=96 , Servers Allocated=8)
==============================================================================
|      Name      | Type  | Server# | Elapsed |   Cpu   | Concurrency |Buffer |
|                |       |         | Time(s) | Time(s) |  Waits(s)   | Gets  |
==============================================================================
| PX Coordinator | QC    |         |    0.00 |    0.00 |             |     4 |
| p000           | Set 1 |       1 |    0.01 |         |        0.01 |     3 |
| p001           | Set 1 |       2 |    0.01 |         |        0.01 |     3 |
| p002           | Set 1 |       3 |    0.00 |         |        0.00 |     3 |
| p003           | Set 1 |       4 |    0.00 |         |        0.00 |     3 |
| p004           | Set 1 |       5 |    0.00 |    0.00 |        0.00 |     3 |
| p005           | Set 1 |       6 |    0.01 |         |        0.01 |       |
| p006           | Set 1 |       7 |    0.00 |         |        0.00 |       |
| p007           | Set 1 |       8 |    0.01 |         |        0.01 |       |
==============================================================================

SQL Plan Monitoring Details (Plan Hash Value=96405358)
============================================================
| Id |        Operation        |   Name   |  Rows   | Cost |
|    |                         |          | (Estim) |      |
============================================================
|  0 | INSERT STATEMENT        |          |         |      |
|  1 |   LOAD AS SELECT        |          |         |      |
|  2 |    PX COORDINATOR       |          |         |      |
|  3 |     PX SEND QC (RANDOM) | :TQ10000 |     409 |    2 |
|  4 |      PX BLOCK ITERATOR  |          |     409 |    2 |
|  5 |       TABLE ACCESS FULL | TABLE_CLS|     409 |    2 |
============================================================

Notice how Oracle has serviced the insert statement with 8 parallel servers instead of the requested 96 servers. This is a clear demonstration of how to bound the default DOP

Parallel Execution Details (DOP=8, Servers Requested=96, Servers Allocated=8)

Unfortunately, despite this implicit parallel run limitation, the application was still suffering from the same library cache symptoms (less than before thought) as shown below:

SQL> select event, count(1)
    from gv$active_session_history
    where sample_time between to_date('16072015 10:57:00', 'ddmmyyyy hh24:mi:ss')
                      and     to_date('16072015 11:30:00', 'ddmmyyyy hh24:mi:ss')
    group by event
    order by 2 desc;

EVENT                                  COUNT(1)
------------------------------------ ----------
library cache: mutex X                      518
                                            382
db file sequential read                     269
read by other session                        42
kksfbc child completion                      37
null event                                   31
log file parallel write                      18
cursor: pin S wait on X                      12
latch: shared pool                            7
cursor: pin S                                 7
log file sync                                 5
latch free                                    5
enq: RO - fast object reuse                   3
SQL*Net more data from client                 2
db file parallel write                        2
enq: CR - block range reuse ckpt              1
os thread startup                             1
SQL> select sql_id, session_id,in_parse, in_sql_execution
    from gv$active_session_history
    where sample_time between to_date('16072015 10:57:00', 'ddmmyyyy hh24:mi:ss'
                      and     to_date('16072015 11:30:00', 'ddmmyyyy hh24:mi:ss'
    and event = 'library cache: mutex X'
    order by sql_id;

SQL_ID        SESSION_ID IN_PARSE IN_SQL_EXEC
------------- ---------- -------- -----------
a5u912v53t11t        516 Y 	 N
a5u912v53t11t        494 Y 	 N
a5u912v53t11t        343 Y 	 N
a5u912v53t11t        482 Y 	 N

Finally we agreed with the client to disable parallelism (by setting the parallel_max_servers parameter value to 1) so that the flash back treatment will go serially:

SQL> show parameter parallel_max_servers

NAME                           TYPE        VALUE
------------------------------ ----------- -----
parallel_max_servers           integer     1

Once this has been done the test campaign finally started to perform very quickly with the following picture from ASH:

SQL> select event, count(1)
    from gv$active_session_history
    where sample_time between to_date('16072015 14:15:00', 'ddmmyyyy hh24:mi:ss')
                      and     to_date('16072015 15:30:00', 'ddmmyyyy hh24:mi:ss')
    group by event
    order by 2 desc;

EVENT                                  COUNT(1)
------------------------------------- ----------
                                             966
db file sequential read                      375
db file scattered read                        49
log file parallel write                       46
log file sync                                 22
db file parallel write                        13
null event                                     8
local write wait                               7
SQL*Net more data from client                  5
os thread startup                              3
reliable message                               3
enq: PS - contention                           3
enq: RO - fast object reuse                    3
cursor: pin S wait on X                        1
direct path read                               1
Disk file operations I/O                       1
enq: CR - block range reuse ckpt               1
enq: TX - row lock contention                  1

The flashed back treatment ceases completely from being run in parallel and the campaign test started again to perform quickly.

This is not an invitation to go with drastic and brutal workaround to reduce the effect of many sessions waked up due to a very high degree of parallelism itself due to the default maximum DOP. It represents a demonstration on

  • how a high degree of parallelism can affect the locking in the library cache
  • how the parallel_max_servers parameter can bound the DOP of your query

August 4, 2015

Degree of Parallelism is 16 because of table property

Filed under: Oracle — hourim @ 10:11 am

I have been pleasantly surprised by the following Note at the bottom of an execution plan coming from a 12.1.0.2.0 Oracle instance


SQL> select * from v$version;

BANNER                                                                               CON_ID
-------------------------------------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production              0
PL/SQL Release 12.1.0.2.0 - Production                                                    0
CORE    12.1.0.2.0      Production                                                        0
TNS for Linux: Version 12.1.0.2.0 - Production                                            0
NLSRTL Version 12.1.0.2.0 - Production                                                    0


SQL> create table t_par as select rownum n1, trunc((rownum -1/3)) n2, mod(rownum, 5) n3
    from dual
    connect by level<=1e6;
  
SQL> create index t_part_idx on t_par(n1);

Index created.
 
SQL> alter table t_par parallel 16;

Table altered.  

SQL> select count(1) from t_par where n1> 1;

  COUNT(1)
----------
    999999

SQL> select * from table(dbms_xplan.display_cursor);
----------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name     | Rows  | Bytes | Cost (%CPU)| Time     |    TQ  |IN-OUT| PQ Distrib |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |          |       |       |    48 (100)|          |        |      |            |
|   1 |  SORT AGGREGATE        |          |     1 |     5 |            |          |        |      |            |
|   2 |   PX COORDINATOR       |          |       |       |            |          |        |      |            |
|   3 |    PX SEND QC (RANDOM) | :TQ10000 |     1 |     5 |            |          |  Q1,00 | P->S | QC (RAND)  |
|   4 |     SORT AGGREGATE     |          |     1 |     5 |            |          |  Q1,00 | PCWP |            |
|   5 |      PX BLOCK ITERATOR |          |   999K|  4882K|    48   (3)| 00:00:01 |  Q1,00 | PCWC |            |
|*  6 |       TABLE ACCESS FULL| T_PAR    |   999K|  4882K|    48   (3)| 00:00:01 |  Q1,00 | PCWP |            |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   6 - access(:Z>=:Z AND :Z<=:Z)
       filter("N1">1)

Note
-----
   - Degree of Parallelism is 16 because of table property

As you can point it out, thanks to the above Note, we can immediately guess that the Optimizer decided to run the query in parallel because the T_PAR table has been decorated with a DOP of 16

SQL> select table_name,degree
  2  from user_tables
  3  where table_name = 'T_PAR';

TABLE_NAME    DEGREE
------------ -------
T_PAR        16 

A nice 12c add.

A couple of month ago a query running on 11.2.0.3 which used to run very quickly suddenly started deviating dangerously from its habitual execution time. The end user told me that they didn’t changed anything and he asked to investigate the root cause of this performance degradation. The corresponding SQL real time monitoring looks like:

Global Stats
======================================================================================
| Elapsed |   Cpu   |    IO    | Concurrency | Buffer | Read | Read  | Write | Write |
| Time(s) | Time(s) | Waits(s) |  Waits(s)   |  Gets  | Reqs | Bytes | Reqs  | Bytes |
======================================================================================
|     799 |     443 |      356 |        0.01 |     3M | 398K |  11GB |  122K |  24GB |
======================================================================================

Parallel Execution Details (DOP=4 , Servers Allocated=8)
SQL Plan Monitoring Details (Plan Hash Value=637438362)
========================================================================================================================
| Id    |                 Operation                  |       Name        |  Rows   |Execs |   Rows   | Temp | Activity |
|       |                                            |                   | (Estim) |      | (Actual) |      |   (%)    |
========================================================================================================================
|     0 | SELECT STATEMENT                           |                   |         |    9 |        0 |      |     0.13 |
|     1 |   PX COORDINATOR                           |                   |         |    9 |          |      |          |
|     2 |    PX SEND QC (RANDOM)                     | :TQ10003          |     19M |    4 |          |      |          |
|     3 |     HASH JOIN RIGHT SEMI                   |                   |     19M |    4 |        0 |      |          |
|     4 |      PX RECEIVE                            |                   |      3M |    4 |     1853 |      |          |
|     5 |       PX SEND HASH                         | :TQ10002          |      3M |    4 |     1853 |      |          |
|     6 |        VIEW                                | VW_NSO_1          |      3M |    4 |     1853 |      |          |
|     7 |         FILTER                             |                   |         |    4 |     1853 |      |          |
|     8 |          NESTED LOOPS                      |                   |      3M |    4 |     1853 |      |          |
|     9 |           BUFFER SORT                      |                   |         |    4 |       38 |      |          |
|    10 |            PX RECEIVE                      |                   |         |    4 |       38 |      |          |
|    11 |             PX SEND ROUND-ROBIN            | :TQ10000          |         |    1 |       38 |      |          |
|    12 |              HASH JOIN                     |                   |   69556 |    1 |       38 |      |          |
|    13 |               INLIST ITERATOR              |                   |         |    1 |     6258 |      |          |
|    14 |                TABLE ACCESS BY INDEX ROWID | TAB_001X          |   69556 |  840 |     6258 |      |          |
|    15 |                 INDEX RANGE SCAN           | IDX_TAB_001X25    |   69556 |  840 |     6258 |      |          |
|    16 |               INDEX FAST FULL SCAN         | PK_TAB_00X13      |     18M |    1 |      19M |      |     0.27 |
|    17 |           INDEX RANGE SCAN                 | PK_IDX_MAIN_TAB   |      36 |   38 |     1853 |      |          |
| -> 18 |      BUFFER SORT                           |                   |         |    4 |        0 |  26G |    34.18 |
| -> 19 |       PX RECEIVE                           |                   |    648M |    4 |     566M |      |     4.14 |
| -> 20 |        PX SEND HASH                        | :TQ10001          |    648M |    1 |     566M |      |    13.89 |
| -> 21 |         TABLE ACCESS FULL                  | MAIN_TABLE_001    |    648M |    1 |     566M |      |    47.40 |
========================================================================================================================

The BUFFER SORT operation at line 18 was killing the performance of this query as far as it was buffering 566M of rows.

Looking back to the previous execution plans shows that they were serial plans!!! What makes this new plan running in parallel? I was practically sure from where this was coming. I know that this application rebuilds indexes from time to time. And I know that very often, they use parallel rebuild to accelerate the operation. But I know also that very often, DBA forget to set back the indexes at their default value at the end of the index rebuild process. Indeed the primary index PK_IDX_MAIN_TAB was at a DOP of 4 while it shouldn’t. Putting back this index to degree 1 sets back the corresponding execution plan to the serial execution plan the underlying query used to follow in the past:

Global Stats
=================================================
| Elapsed |   Cpu   |  Other   | Fetch | Buffer |
| Time(s) | Time(s) | Waits(s) | Calls |  Gets  |
=================================================
|      43 |      43 |     0.02 |    11 |     4M |
=================================================

SQL Plan Monitoring Details (Plan Hash Value=1734192894)
============================================================================================
| Id |              Operation              |       Name        |  Rows   |Execs |   Rows   |
|    |                                     |                   | (Estim) |      | (Actual) |
============================================================================================
|  0 | SELECT STATEMENT                    |                   |         |    1 |      108 |
|  1 |   HASH JOIN RIGHT SEMI              |                   |     19M |    1 |      108 |
|  2 |    VIEW                             | VW_NSO_1          |    701K |    1 |      108 |
|  3 |     FILTER                          |                   |         |    1 |      108 |
|  4 |      NESTED LOOPS                   |                   |    701K |    1 |      108 |
|  5 |       HASH JOIN                     |                   |   19387 |    1 |        3 |
|  6 |        INLIST ITERATOR              |                   |         |    1 |        3 |
|  7 |         TABLE ACCESS BY INDEX ROWID | TAB_001X          |   19387 |  168 |        3 |
|  8 |          INDEX RANGE SCAN           | IDX_TAB_001X25    |   19387 |  168 |        3 |
|  9 |        INDEX FAST FULL SCAN         | PK_TAB_00X13      |     18M |    1 |      19M |
| 10 |       INDEX RANGE SCAN              | PK_IDX_MAIN_TAB   |      36 |    3 |      108 |
| 11 |    TABLE ACCESS FULL                | MAIN_TABLE_001    |    648M |    1 |     677M |
============================================================================================ 

In this context of rebuild indexes left at a DOP > 1 and this nicely 12c added Note about the reason for which Oracle has decided to use parallel run, I was curious to know if the 12c Note will show the same information if the parallel plan was due to an index having a DOP > 1

SQL> alter table t_par noparallel;

SQL> alter index T_PART_IDX parallel 16;

SQL> select count(1) from t_par where n1> 1;

  COUNT(1)
----------
    999999

SQL> select * from table(dbms_xplan.display_cursor);

SQL_ID  4s7n5z52gun33, child number 0
-------------------------------------
---------------------------------------------------------------------------------------------------------------------
| Id  | Operation                 | Name       | Rows  | Bytes | Cost (%CPU)| Time     |    TQ  |IN-OUT| PQ Distrib |
---------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT          |            |       |       |   610 (100)|          |        |      |            |
|   1 |  SORT AGGREGATE           |            |     1 |     5 |            |          |        |      |            |
|   2 |   PX COORDINATOR          |            |       |       |            |          |        |      |            |
|   3 |    PX SEND QC (RANDOM)    | :TQ10000   |     1 |     5 |            |          |  Q1,00 | P->S | QC (RAND)  |
|   4 |     SORT AGGREGATE        |            |     1 |     5 |            |          |  Q1,00 | PCWP |            |
|   5 |      PX BLOCK ITERATOR    |            |   999K|  4882K|   610   (1)| 00:00:01 |  Q1,00 | PCWC |            |
|*  6 |       INDEX FAST FULL SCAN| T_PART_IDX |   999K|  4882K|   610   (1)| 00:00:01 |  Q1,00 | PCWP |            |
---------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   6 - access(:Z>=:Z AND :Z<=:Z)
       filter("N1">1)

Unfortunately there is no Note indicating that the above parallel execution plan is due to the parallel degree of the index T_PART_IDX.

Create a free website or blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud's blog

Just another blog : Databases, Linux and other stuffs

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)