Monthly Archives: September 2016

12c Adaptive Query Optimization – Getting Started

In Oracle Database 12c, adaptive query optimization is a set of capabilities that enables the optimizer to make run-time adjustments to execution plans and discover additional information that can lead to better statistics. Adaptive optimization is helpful when existing statistics are not sufficient to generate an optimal plan.

aqo

Below are a series of blog posts that I have written, that explains the Basics of how these features work.

Dynamic Statistics – Some Notes

Adaptive Plans – Adaptive Joins

Adaptive Plans – Adaptive Parallel Distribution Methods

AQO – Dynamic Statistics Examples

AQO – ReOptimization

AQP – SQL Plan Directives

 

Below are some oracle white papers and Mos notes that you could read, to familiarize yourselves with these new features.

Understanding Optimizer Statistics with Oracle 12c

Best practices for gathering statistics with Oracle 12c

What to expect with the optimizer, with Oracle 12c.

Adaptive Query Optimization – Mos Note : 2031605.1

Automatic Dynamic Statistics – Mos Note : 2002108.1

Adaptive Execution Plans – Mos Note : 1409636.1

How to Approach Issues Related to Adaptive Optimizations – Mos Note : 2068807.1

Optimizer Statistics – Master Note – Mos Note : 1369591.1

Resolving Issues of Library Cache Pin or Cursor Pin S Wait on X – Mos Note : 1476663.1

Troubleshooting Cursor Pin S Wait on X – Mos Note : 1349387.1

Cursor Pin S Wait on X, Finding Blocker – Mos Note : 786507.1

Parameter Recommendations for Oracle 12c – Part 1 (Upgrade PM Blog)

Parameter Recommendations for Oracle 12c – Part 2 (Upgrade PM Blog)

Things to consider before upgrading to 12.1.0.2 (Upgrade PM Blog)

Adaptive Query Optimization configuration : Parameters, Preferences and Fix controls (Christian Antognini Blog)

Adaptive Query Optimization – SQL Plan Directives

Sql plan directives are automatically created based on information learned via Automatic Reoptimization. The optimizer uses Sql Plan Directives to generate a more optimal execution plan. For eg: When joining two tables that have a data skew in their join columns, a Sql plan directive can direct the optimizer to use dynamic statistics to obtain a more accurate join cardinality estimate.

Key thing to note is that SPD’s are not created on Queries or Objects. They are created on query expressions. So the SPD’s generated by one sql statement can be used by multiple sql statements. It is possible for one Sql statement to use more than one SPD. SPD’s are persisted in the SYSAUX tablespace. Any SPD that is unused for 53 weeks will be automatically purged.

After a SQL directive is used the optimizer decides if the cardinality missestimate could be resolved with a column group. If so it will create the column group, the next time statistics are gathered on the appropriate table.

Let us take a look at an example.

We are using the same sql statement from the example in my post about Adaptive ReOptimization

SQL_ID  faca0yc2h1cdr, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ gather_plan_statistics */ count(*)  FROM   customers  WHERE                                                                                                                                  
cust_state_province = 'CA'  AND    country_id=52790                                                                                                                                                     
 
Plan hash value: 296924608                                                                                                                                                                              
 
--------------------------------------------------------------------------------------------------------------------------                                                                              
| Id  | Operation          | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
|   0 | SELECT STATEMENT   |           |      1 |        |       |   405 (100)|          |      1 |00:00:00.01 |    1458 |                                                                              
|   1 |  SORT AGGREGATE    |           |      1 |      1 |    16 |            |          |      1 |00:00:00.01 |    1458 |                                                                              
|*  2 |   TABLE ACCESS FULL| CUSTOMERS |      1 |   1115 | 17840 |   405   (1)| 00:00:01 |   3341 |00:00:00.01 |    1458 |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / CUSTOMERS@SEL$1                                                                                                                                                                          
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   2 - filter(("CUST_STATE_PROVINCE"='CA' AND "COUNTRY_ID"=52790))                                                                                                                                      
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - (#keys=0) COUNT(*)[22]                                                                                                                                                                           
   2 - (rowset=906)

Next I will flush the plan directive

BEGIN
DBMS_SPD.FLUSH_SQL_PLAN_DIRECTIVE;
END;
/

Lets check the plan directives that have been created

DIR_ID                                   OWNER OBJECT_NAME               COL_NAME             OBJECT_TYPE               TYPE                    STATE      INST
---------------------------------------- ----- ------------------------- -------------------- ------------------------- ----------------------- ---------- -------------
REASON                               DC                          LU                         
------------------------------------ --------------------------- ---------------------------
1581183467014446692                      SH    CUSTOMERS                 COUNTRY_ID           COLUMN                    DYNAMIC_SAMPLING        USABLE     NEW           
SINGLE TABLE CARDINALITY MISESTIMATE 20-SEP-16 08:32:22                                     
 
1581183467014446692                      SH    CUSTOMERS                 CUST_STATE_PROVINCE  COLUMN                    DYNAMIC_SAMPLING        USABLE     NEW           
SINGLE TABLE CARDINALITY MISESTIMATE 20-SEP-16 08:32:22                                     
 
1581183467014446692                      SH    CUSTOMERS                                      TABLE                     DYNAMIC_SAMPLING        USABLE     NEW           
SINGLE TABLE CARDINALITY MISESTIMATE 20-SEP-16 08:32:22

Then let us a execute a new statement, by just changing one of the predicates.

SQL_ID  aj2w592n68s4s, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ gather_plan_statistics */ count(*)  FROM   customers  WHERE                                                                                                                                  
cust_state_province = 'FL'  AND    country_id=52790                                                                                                                                                     
 
Plan hash value: 296924608                                                                                                                                                                              
 
--------------------------------------------------------------------------------------------------------------------------                                                                              
| Id  | Operation          | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
|   0 | SELECT STATEMENT   |           |      1 |        |       |   405 (100)|          |      1 |00:00:00.01 |    1457 |                                                                              
|   1 |  SORT AGGREGATE    |           |      1 |      1 |    16 |            |          |      1 |00:00:00.01 |    1457 |                                                                              
|*  2 |   TABLE ACCESS FULL| CUSTOMERS |      1 |   2549 | 40784 |   405   (1)| 00:00:01 |   2438 |00:00:00.01 |    1457 |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / CUSTOMERS@SEL$1                                                                                                                                                                          
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   2 - filter(("CUST_STATE_PROVINCE"='FL' AND "COUNTRY_ID"=52790))                                                                                                                                      
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - (#keys=0) COUNT(*)[22]                                                                                                                                                                           
   2 - (rowset=906)                                                                                                                                                                                     
 
Note                                                                                                                                                                                                    
-----                                                                                                                                                                                                   
   - dynamic statistics used: dynamic sampling (level=2)                                                                                                                                                
   - 1 Sql Plan Directive used for this statement

In the notes section we can see that the plan directive has been used by this new statement.

Adaptive Query Optimization – Adaptive ReOptimization

Adaptive plans can choose between multiple operations during the execution of a sql to pottentially choose better access methods. But it cannot change the join orders. 11gR2 had cardinality feedback which allowed oracle to choose a better plan based on the information gathered at the end of the execution. In 12c Cardinality feedback has been renamed as Statistics Feedback.

Statistics Feedback

During the first execution of the statement, the optimizer generates an execution plan and decides if it should enable statistics feedback monitoring for the cursor. Statistics feedback is enabled in the following cases.

  • Table with no statistics
  • Multiple Conjunctive or Disjunctive predicates
  • Predicates containing complex operators for which optimizer cannot accurately compute cardinality estimates.

At the end of the excution if the actual cardinalities are different from the estimated cardinalities, the actual cardinalities are stored for subsequent use. It also creates sql plan directives, so other sql statements can benefit from this information. The statement is marked as ReOptimizable and will be Re-Parsed at the next execution and creates a new child cursor. The actual cardinalities are used during the Re-Parsing to determine a good execution plan.

Lets look at an example

SQL_ID  faca0yc2h1cdr, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ gather_plan_statistics */ count(*)  FROM   customers  WHERE                                                                                                                                  
cust_state_province = 'CA'  AND    country_id=52790                                                                                                                                                     
 
Plan hash value: 296924608                                                                                                                                                                              
 
--------------------------------------------------------------------------------------------------------------------------                                                                              
| Id  | Operation          | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
|   0 | SELECT STATEMENT   |           |      1 |        |       |   405 (100)|          |      1 |00:00:00.01 |    1458 |                                                                              
|   1 |  SORT AGGREGATE    |           |      1 |      1 |    16 |            |          |      1 |00:00:00.01 |    1458 |                                                                              
|*  2 |   TABLE ACCESS FULL| CUSTOMERS |      1 |   1115 | 17840 |   405   (1)| 00:00:01 |   3341 |00:00:00.01 |    1458 |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / CUSTOMERS@SEL$1                                                                                                                                                                          
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   2 - filter(("CUST_STATE_PROVINCE"='CA' AND "COUNTRY_ID"=52790))                                                                                                                                      
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - (#keys=0) COUNT(*)[22]                                                                                                                                                                           
   2 - (rowset=906)

Let us check the details of the cursor

select plan_hash_value phv,child_number,parse_calls,executions,is_bind_sensitive ibs
      ,is_bind_aware iba,is_reoptimizable ropt,is_resolved_adaptive_plan aplan 
from v$sql where sql_id = 'faca0yc2h1cdr'
 
       PHV CHILD_NUMBER PARSE_CALLS EXECUTIONS I I R A
---------- ------------ ----------- ---------- - - - -
 296924608	      0 	  1	     1 N N Y

So we can see that the cursor has been flagged as ReOptimizable.

Let’s Execute the Same Sql again.

SQL_ID  faca0yc2h1cdr, child number 1                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ gather_plan_statistics */ count(*)  FROM   customers  WHERE                                                                                                                                  
cust_state_province = 'CA'  AND    country_id=52790                                                                                                                                                     
 
Plan hash value: 296924608                                                                                                                                                                              
 
--------------------------------------------------------------------------------------------------------------------------                                                                              
| Id  | Operation          | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
|   0 | SELECT STATEMENT   |           |      1 |        |       |   405 (100)|          |      1 |00:00:00.01 |    1457 |                                                                              
|   1 |  SORT AGGREGATE    |           |      1 |      1 |    16 |            |          |      1 |00:00:00.01 |    1457 |                                                                              
|*  2 |   TABLE ACCESS FULL| CUSTOMERS |      1 |   3341 | 53456 |   405   (1)| 00:00:01 |   3341 |00:00:00.01 |    1457 |                                                                              
--------------------------------------------------------------------------------------------------------------------------                                                                              
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / CUSTOMERS@SEL$1                                                                                                                                                                          
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   2 - filter(("CUST_STATE_PROVINCE"='CA' AND "COUNTRY_ID"=52790))                                                                                                                                      
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - (#keys=0) COUNT(*)[22]                                                                                                                                                                           
   2 - (rowset=906)                                                                                                                                                                                     
 
Note                                                                                                                                                                                                    
-----                                                                                                                                                                                                   
   - statistics feedback used for this statement

Let’s check the details of the cursor

       PHV CHILD_NUMBER PARSE_CALLS EXECUTIONS I I R A
---------- ------------ ----------- ---------- - - - -
 296924608	      0 	  1	     1 N N Y
 296924608	      1 	  1	     1 N N N

We can see that a new child cursor has been created.
The notes secton indicates that Statistics feedback has been used for this statement.

Performance Feedback

When AutoDOP is enabled in Adaptive mode, during first execution of the statement, the optimizer determines whether the statement should execute in parallel, and what DOP should be used. After the first execution, the execution stats is used to compute a DOP. If the computed DOP is different from the original DOP the statement is marked for re-optimization and the execution statistics is stored. When the statement is executed again the executio statistics is used to compute a new DOP.

12c Adaptive Query Optimization – Dynamic Statistics – Examples

Dynamic sampling is used to compensate for missing or insufficient statistics, that would otherwise lead to a bad plan. In earlier versions, dynamic sampling used to kick in for tables that had missing statistics or stale statistics. Dynamic sampling has been enhanced in 12c and is now called dynamic statistics (And most of the functionality, including the new level 11 has been back ported to 11.2.0.4). The optimizer bases its decision to use dynamic statistics, on the complexity of the predicates used, existing base statistics, total execution time expected,Statistics feedback, Sql plan directives etc. The optimizer automatically decides whether dynamic statistics are useful, and what level to use.

Automatic dynamic statistics are enabled when optimizer_dynamic_statistics=2 (Default) or 11.

I have outlined some nuances of Dynamic Statistics in this previous article.

In this article i will show you examples of Dynamic Statistics kicking in for the following situations.

Missing statistics
Stale statistics
Parallel query
Complex where clause
Group by clause

In this Blog post I am not addressing the scenario where dynamic statistics is used , when Sql plan directives are present. I will address that in a future post regarding sql plan directives.

Heads up, this will be a long blog post.

Missing Statistics

When a new table is created, and statistics was not gathered on the table, then oracle will perform dynamic sampling during the optimization of the query, so it can choose a good execution plan.

In the example below, I am creating a new table with data in it, Creating an index on it, and then deleting the statistics on the table.

create table t1
as
select
         *
from
         customers
;
 
create index t1_idx1 on t1 (cust_state_province)
;
 
exec dbms_stats.delete_table_stats(upper('SH'),upper('T1'));
commit;
 
select /*+ gather_plan_statistics */ count(*) from t1 where cust_state_province  = 'CA'

Then I execute a query against the table.

SQL_ID  3azum47vccux0, child number 0                                                                                                                                                                   
-------------------------------------   
select /*+ gather_plan_statistics */ count(*) from t1 where                                                                                                                                             
cust_state_province  = 'CA'                                                                                                                                                                             
 
Plan hash value: 3695297570                                                                                                                                                                             
 
--------------------------------------------------------------------------------------------------------------------------------                                                                        
| Id  | Operation         | Name    | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers | Reads  |                                                                        
--------------------------------------------------------------------------------------------------------------------------------                                                                        
|   0 | SELECT STATEMENT  |         |      1 |        |       |    12 (100)|          |      1 |00:00:00.01 |       9 |      2 |                                                                        
|   1 |  SORT AGGREGATE   |         |      1 |      1 |    22 |            |          |      1 |00:00:00.01 |       9 |      2 |                                                                        
|*  2 |   INDEX RANGE SCAN| T1_IDX1 |      1 |   4054 | 89188 |    12   (0)| 00:00:01 |   3341 |00:00:00.01 |       9 |      2 |                                                                        
--------------------------------------------------------------------------------------------------------------------------------                                                                        
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / T1@SEL$1                                                                                                                                                                                 
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   2 - access("CUST_STATE_PROVINCE"='CA')                                                                                                                                                               
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - (#keys=0) COUNT(*)[22]                                                                                                                                                                           
 
Note                                                                                                                                                                                                    
-----                                                                                                                                                                                                   
   - dynamic statistics used: dynamic sampling (level=2)

In the Notes section of the execution plan, we can see that dynamic statistics was used with level 2.Since there was no statistics on the table or index, the optimizer performed dynamic sampling, to get estimates. When we review the 10046 trace file and its tkprof output we can see that there are 2 statements executed which has the hint /*+ OPT_DYN_SAMP */ that tells us that dynamic sampling has been performed.

Stale Statistics

In the example below, in order to simulate the behavior of stale statistics, I have done the following

  • Created a table, gathered stats
  • Run a query, and flushed the usage statistics.
  • Inserted more rows into the table.
  • Run a new query, on the table whose statistics is now stale.
  • In order to get the dynamic sampling to kick in, i had to set the optimizer_dynamic_sampling to 11. (Does not kick in when level is 2)

Here is the setup for the example.

create table t1
compress
as
select
         *
from
         customers
;
 
create index t1_idx1 on t1 (cust_state_province)
;
 
exec dbms_stats.gather_table_stats(upper('SH'),upper('T1'));
commit;
 
select /*+ gather_plan_statistics */ count(*) from t1 where cust_state_province  = 'CA'
;
 
connect sh/sh@10.1.1.202:1521/rkpdb1
 
insert into t1 select * from t1;
commit;
 
connect system/manager@10.1.1.202:1521/rkpdb1
exec DBMS_STATS.FLUSH_DATABASE_MONITORING_INFO;
 
connect sh/sh@10.1.1.202:1521/rkpdb1
alter session set optimizer_dynamic_sampling=11
;
@traceon
select /*+ gather_plan_statistics q2 */ count(*) from t1 where cust_state_province  = 'CA'
;

Here is the execution plan for the statement

PLAN_TABLE_OUTPUT                                                                                                                                                                                       
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  1gwst4v211h86, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
select /*+ gather_plan_statistics q2 */ count(*) from t1 where                                                                                                                                          
cust_state_province  = 'CA'                                                                                                                                                                             
 
Plan hash value: 3695297570                                                                                                                                                                             
 
-----------------------------------------------------------------------------------------------------------------------                                                                                 
| Id  | Operation         | Name    | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |                                                                                 
-----------------------------------------------------------------------------------------------------------------------                                                                                 
|   0 | SELECT STATEMENT  |         |      1 |        |       |    21 (100)|          |      1 |00:00:00.01 |      20 |                                                                                 
|   1 |  SORT AGGREGATE   |         |      1 |      1 |    11 |            |          |      1 |00:00:00.01 |      20 |                                                                                 
|*  2 |   INDEX RANGE SCAN| T1_IDX1 |      1 |   6591 | 72501 |    21   (0)| 00:00:01 |   6682 |00:00:00.01 |      20 |                                                                                 
-----------------------------------------------------------------------------------------------------------------------                                                                                 
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / T1@SEL$1                                                                                                                                                                                 
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   2 - access("CUST_STATE_PROVINCE"='CA')                                                                                                                                                               
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - (#keys=0) COUNT(*)[22]                                                                                                                                                                           
 
Note                                                                                                                                                                                                    
-----                                                                                                                                                                                                   
   - dynamic statistics used: dynamic sampling (level=AUTO)

Now you can see in the note section that dynamic sampling with level AUTO, has been utilized for this query. If you examine the 10046  trace file you will see that there are 2 queries that are executed with the DS_SVC hint in it.

Parallel Query

The following parallel query selects from the tables in the SSB  (Star Schema Benchmark) schema. The execution plan is rather large, so I am not including it below. I am only including the Notes section.

 

SQL_ID  6af5d5js0m4wg, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ gather_plan_statistics parallel(4) */                                                                                                                                                        
d_month,s_region,c_region,sum(lo_quantity) FROM                                                                                                                                                         
ssb.lineorder,ssb.date_dim,ssb.customer,ssb.supplier,ssb.part  where                                                                                                                                    
lo_orderdate = d_datekey and    lo_custkey   = c_custkey and                                                                                                                                            
lo_suppkey   = s_suppkey and    lo_partkey   = p_partkey and    d_year                                                                                                                                  
     = 1997 and    p_mfgr       = 'MFGR#1' and    p_category   =                                                                                                                                        
'MFGR#11' and    p_brand1     = 'MFGR#1110' and    s_nation     =                                                                                                                                       
'UNITED STATES' and    c_nation     = 'CHINA' group by                                                                                                                                                  
d_month,s_region,c_region                                                                                                                                                                               
 
Plan hash value: 1014051437                                                                                                                                                                             
 
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
---                                                                                                                                                                                                     
 
| Id  | Operation                          | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   |    TQ  |IN-OUT| PQ Distrib | A-Rows |   A-Time   | Buffers | Reads  |  OMem |  1Mem |  O/1/M 
  |                                                                                                                                                                                                     
 
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
---                                                                                                                                                                                                     
 
|   0 | SELECT STATEMENT                   |           |      1 |        |       | 14066 (100)|          |        |      |            |      3 |00:00:24.64 |      56 |      0 |       |       |        
  |                                                                                                                                                                                                     
 
|   1 |  PX COORDINATOR                    |           |      1 |        |       |            |          |        |      |            |      3 |00:00:24.64 |      56 |      0 | 73728 | 73728 |        
 
...
...
...
Note                                                                                                                                                                                                    
 
PLAN_TABLE_OUTPUT                                                                                                                                                                                       
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
-----                                                                                                                                                                                                   
   - dynamic statistics used: dynamic sampling (level=5)                                                                                                                                                
   - Degree of Parallelism is 4 because of hint

As you can see in the Note section, the query has performed dynamic sampling. If you remove the parallel hint and run the query then dynamic sampling does not occur.
Here I did not have to modify the optimizer_dynamic_sampling from the default, dynamic statistics still kicks in because it is a parallel query.

Complex Where Clause

Below is a sql with conjunctive predicates in the where clause. This causes oracle to collect dynamic statistics for this query.

 

SELECT /*+ gather_plan_statistics */ *  FROM   customers  WHERE                                                                                                                                         
cust_state_province='CA'  AND    country_id=52790                                                                                                                                                       
 
Plan hash value: 2008213504                                                                                                                                                                             
 
-------------------------------------------------------------------------------------------------------------------------                                                                               
| Id  | Operation         | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |                                                                               
-------------------------------------------------------------------------------------------------------------------------                                                                               
|   0 | SELECT STATEMENT  |           |      1 |        |       |   405 (100)|          |   3341 |00:00:00.01 |    1677 |                                                                               
|*  1 |  TABLE ACCESS FULL| CUSTOMERS |      1 |   3354 |   592K|   405   (1)| 00:00:01 |   3341 |00:00:00.01 |    1677 |                                                                               
-------------------------------------------------------------------------------------------------------------------------                                                                               
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1 / CUSTOMERS@SEL$1                                                                                                                                                                          
 
Predicate Information (identified by operation id):                                                                                                                                                     
---------------------------------------------------                                                                                                                                                     
 
   1 - filter(("CUST_STATE_PROVINCE"='CA' AND "COUNTRY_ID"=52790))                                                                                                                                      
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - "CUSTOMERS"."CUST_ID"[NUMBER,22], "CUSTOMERS"."CUST_FIRST_NAME"[VARCHAR2,20],                                                                                                                    
       "CUSTOMERS"."CUST_LAST_NAME"[VARCHAR2,40], "CUSTOMERS"."CUST_GENDER"[CHARACTER,1],                                                                                                               
       "CUSTOMERS"."CUST_YEAR_OF_BIRTH"[NUMBER,22], "CUSTOMERS"."CUST_MARITAL_STATUS"[VARCHAR2,20],                                                                                                     
       "CUSTOMERS"."CUST_STREET_ADDRESS"[VARCHAR2,40], "CUSTOMERS"."CUST_POSTAL_CODE"[VARCHAR2,10],                                                                                                     
       "CUSTOMERS"."CUST_CITY"[VARCHAR2,30], "CUSTOMERS"."CUST_CITY_ID"[NUMBER,22], "CUST_STATE_PROVINCE"[VARCHAR2,40],                                                                                 
       "CUSTOMERS"."CUST_STATE_PROVINCE_ID"[NUMBER,22], "COUNTRY_ID"[NUMBER,22],                                                                                                                        
       "CUSTOMERS"."CUST_MAIN_PHONE_NUMBER"[VARCHAR2,25], "CUSTOMERS"."CUST_INCOME_LEVEL"[VARCHAR2,30],                                                                                                 
       "CUSTOMERS"."CUST_CREDIT_LIMIT"[NUMBER,22], "CUSTOMERS"."CUST_EMAIL"[VARCHAR2,30],                                                                                                               
       "CUSTOMERS"."CUST_TOTAL"[VARCHAR2,14], "CUSTOMERS"."CUST_TOTAL_ID"[NUMBER,22],                                                                                                                   
       "CUSTOMERS"."CUST_SRC_ID"[NUMBER,22], "CUSTOMERS"."CUST_EFF_FROM"[DATE,7], "CUSTOMERS"."CUST_EFF_TO"[DATE,7],                                                                                    
       "CUSTOMERS"."CUST_VALID"[VARCHAR2,1]                                                                                                                                                             
 
Note                                                                                                                                                                                                    
-----                                                                                                                                                                                                   
   - dynamic statistics used: dynamic sampling (level=AUTO)

Here we can see that oracle performed dynamic sampling with level Auto.
I had to set optimizer_dynamic_sampling=11 for this query to perform dynamic sampling.

Group By Clause

The statement below performs dynamic sampling because the groupby clause causes a cardinality misestimate.

 

SQL_ID  8at4un9zmq38c, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ gather_plan_statistics */ count(*)  FROM   sh.customers                                                                                                                                      
group by COUNTRY_ID,CUST_STATE_PROVINCE                                                                                                                                                                 
 
Plan hash value: 1577413243                                                                                                                                                                             
 
-----------------------------------------------------------------------------------------------------------------------------------------------------                                                   
| Id  | Operation          | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |  OMem |  1Mem |  O/1/M   |                                                   
-----------------------------------------------------------------------------------------------------------------------------------------------------                                                   
|   0 | SELECT STATEMENT   |           |      1 |        |       |   407 (100)|          |    145 |00:00:00.01 |    1457 |       |       |          |                                                   
|   1 |  HASH GROUP BY     |           |      1 |    145 |  2320 |   407   (1)| 00:00:01 |    145 |00:00:00.01 |    1457 |  1016K|  1016K|     1/0/0|                                                   
|   2 |   TABLE ACCESS FULL| CUSTOMERS |      1 |  55500 |   867K|   405   (1)| 00:00:01 |  55500 |00:00:00.01 |    1457 |       |       |          |                                                   
-----------------------------------------------------------------------------------------------------------------------------------------------------                                                   
 
Query Block Name / Object Alias (identified by operation id):                                                                                                                                           
-------------------------------------------------------------                                                                                                                                           
 
   1 - SEL$1                                                                                                                                                                                            
   2 - SEL$1 / CUSTOMERS@SEL$1                                                                                                                                                                          
 
Column Projection Information (identified by operation id):                                                                                                                                             
-----------------------------------------------------------                                                                                                                                             
 
   1 - "COUNTRY_ID"[NUMBER,22], "CUST_STATE_PROVINCE"[VARCHAR2,40], COUNT(*)[22]                                                                                                                        
   2 - (rowset=256) "CUST_STATE_PROVINCE"[VARCHAR2,40], "COUNTRY_ID"[NUMBER,22]                                                                                                                         
 
Note                                                                                                                                                                                                    
-----                                                                                                                                                                                                   
   - dynamic statistics used: dynamic sampling (level=AUTO)

Here you can see that dynamic sampling was used with level Auto.
Once you execute this query, if you check the sql plan directives, you will see sql plan directives on this table with Reason of GROUP BY MISSESTIMATE.
I had to set optimizer_dynamic_sampling=11 to get dynamic statistics to kick in.

DIR_ID                                   OWNER OBJECT_NAME               COL_NAME             OBJECT_TYPE               TYPE                    STATE      INST          REASON
---------------------------------------- ----- ------------------------- -------------------- ------------------------- ----------------------- ---------- ------------- ------------------------------------
DC                          LU                         
--------------------------- ---------------------------
13371066972565290282                     SH    CUSTOMERS                 COUNTRY_ID           COLUMN                    DYNAMIC_SAMPLING        USABLE     NEW           GROUP BY CARDINALITY MISESTIMATE     
20-SEP-16 06:39:58                                     
 
13371066972565290282                     SH    CUSTOMERS                 CUST_STATE_PROVINCE  COLUMN                    DYNAMIC_SAMPLING        USABLE     NEW           GROUP BY CARDINALITY MISESTIMATE     
20-SEP-16 06:39:58                                     
 
13371066972565290282                     SH    CUSTOMERS                                      TABLE                     DYNAMIC_SAMPLING        USABLE     NEW           GROUP BY CARDINALITY MISESTIMATE     
20-SEP-16 06:39:58

The examples above can give you some working knowledge of when Dynamic Statistics comes into play with Oracle 12c.

12c Adaptive Query Optimization – Adaptive Plans – Adaptive Parallel Distribution Methods

In oracle 11gR2, oracle uses one of broadcast, hash, round robin, range or key distribution methods, to redistribute data among  parallel query servers. If the cardinality estimation at a given step happened to be incorrect (eg: the estimate was about a 100 rows and in reality there was 100,000 rows), oracle could end up broadcasting a lot of rows to all the receiving  parallel query servers. Another issue frequently encountered was that there could be skew in the popular values, resulting in hash distribution sending most of the values to one or a small subset of the receiving pq servers (Causing them to do most of the work).

To address such situations in 12cR1, as part of the new Adaptive Query Optimization techniques, oracle introduced the ability to switch the distribution method from hash to broadcast, if the actual number of rows was less than the threshold .  In 12.1 the threshold was 2X degree of parallelism .  This new functionality is called Adaptive Parallel Distribution Methods.

If you check the execution plan you will see that a “Statistics Collector” has been inserted before the send operation , and the send operation is called “PX Send Hybrid Hash”.

Let us look at an example of a simple hybrid hash distribution.

SQL_ID  d1qmm37g288qz, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
select /*+ full(emp) full(dept) parallel(4) */                                                                                                                                                          
dept.deptno,dept.dname,emp.empno,emp.ename from dept,emp where                                                                                                                                          
dept.deptno = emp.deptno                                                                                                                                                                                
 
Plan hash value: 717794318                                                                                                                                                                              
 
------------------------------------------------------------------------------------------------------------------------------------------------                                                        
| Id  | Operation                  | Name     | E-Rows |E-Bytes| Cost (%CPU)| E-Time   |    TQ  |IN-OUT| PQ Distrib |  OMem |  1Mem |  O/1/M   |                                                        
------------------------------------------------------------------------------------------------------------------------------------------------                                                        
|   0 | SELECT STATEMENT           |          |        |       |     4 (100)|          |        |      |            |       |       |          |                                                        
|   1 |  PX COORDINATOR            |          |        |       |            |          |        |      |            | 73728 | 73728 |          |                                                        
|   2 |   PX SEND QC (RANDOM)      | :TQ10002 |     14 |   770 |     4   (0)| 00:00:01 |  Q1,02 | P->S | QC (RAND)  |       |       |          |                                                        
|*  3 |    HASH JOIN BUFFERED      |          |     14 |   770 |     4   (0)| 00:00:01 |  Q1,02 | PCWP |            |  3105K|  2823K|     4/0/0|                                                        
|   4 |     PX RECEIVE             |          |      4 |    88 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |       |       |          |                                                        
|   5 |      PX SEND HYBRID HASH   | :TQ10000 |      4 |    88 |     2   (0)| 00:00:01 |  Q1,00 | P->P | HYBRID HASH|       |       |          |                                                        
|   6 |       STATISTICS COLLECTOR |          |        |       |            |          |  Q1,00 | PCWC |            |       |       |          |                                                        
|   7 |        PX BLOCK ITERATOR   |          |      4 |    88 |     2   (0)| 00:00:01 |  Q1,00 | PCWC |            |       |       |          |                                                        
|*  8 |         TABLE ACCESS FULL  | DEPT     |      4 |    88 |     2   (0)| 00:00:01 |  Q1,00 | PCWP |            |       |       |          |                                                        
|   9 |     PX RECEIVE             |          |     14 |   462 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |       |       |          |                                                        
|  10 |      PX SEND HYBRID HASH   | :TQ10001 |     14 |   462 |     2   (0)| 00:00:01 |  Q1,01 | P->P | HYBRID HASH|       |       |          |                                                        
|  11 |       PX BLOCK ITERATOR    |          |     14 |   462 |     2   (0)| 00:00:01 |  Q1,01 | PCWC |            |       |       |          |                                                        
|* 12 |        TABLE ACCESS FULL   | EMP      |     14 |   462 |     2   (0)| 00:00:01 |  Q1,01 | PCWP |            |       |       |          |                                                        
------------------------------------------------------------------------------------------------------------------------------------------------

In the execution plan you can see that in steps 5 and 10 the operation is “PX SEND HYBRID HASH”. During execution, the statistics collector  in step 6 buffers the rows being retrieved from DEPT. If the number of rows are below a threshold, then all rows from DEPT are broadcast to each of the PQ servers that perform the join. If the number of rows exceed a threshold then the rows from DEPT are send using a HASH distribution to the PQ servers that perform the join.

Immediately after the query above is executed, from the same session, you can execute the script pqstat to see how the rows were distributed among the producers and consumers.

SQL> @pqstat
 
DFO_NUMBER      TQ_ID SERVER_TYPE                              PROCESS                    NUM_ROWS      BYTES      WAITS   TIMEOUTS AVG_LATENCY
---------- ---------- ---------------------------------------- ------------------------ ---------- ---------- ---------- ---------- -----------
         1          0 Producer                                 P004                              0         96          0          0           0
                                                               P005                             16        324          0          0           0
                                                               P006                              0         96          0          0           0
                                                               P007                              0         96          0          0           0
                      Consumer                                 P000                              4        153        125        119           0
                                                               P001                              4        153        127        119           0
                                                               P002                              4        153        127        119           0
                                                               P003                              4        153        125        119           0
                    2 Producer                                 P000                              0         24          0          0           0
                                                               P001                             14        375          1          0           0
                                                               P002                              0         24          0          0           0
                                                               P003                              0         24          0          0           0
                      Consumer                                 QC                               14        447          2          0           0

 

Now let us take a look at a variation of the hybrid hash distribution operation , which is denoted as “PX SEND HYBRID HASH (SKEW)”

SQL_ID  20fky17tasvn9, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
SELECT /*+ parallel(4) full(e) full(d) gather_plan_statistics */                                                                                                                                        
department_name, sum(salary)   FROM   employees e, departments d                                                                                                                                        
WHERE  d.department_id=e.department_id   GROUP BY department_name                                                                                                                                       
 
Plan hash value: 2940813933                                                                                                                                                                             
 
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------    
| Id  | Operation                          | Name        | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   |    TQ  |IN-OUT| PQ Distrib | A-Rows |   A-Time   | Buffers |  OMem |  1Mem |  O/1/M   |    
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------    
|   0 | SELECT STATEMENT                   |             |      1 |        |       |     5 (100)|          |        |      |            |     11 |00:00:00.04 |      24 |       |       |          |    
|   1 |  PX COORDINATOR                    |             |      1 |        |       |            |          |        |      |            |     11 |00:00:00.04 |      24 | 73728 | 73728 |          |    
|   2 |   PX SEND QC (RANDOM)              | :TQ10003    |      0 |     27 |   621 |     5  (20)| 00:00:01 |  Q1,03 | P->S | QC (RAND)  |      0 |00:00:00.01 |       0 |       |       |          |    
|   3 |    HASH GROUP BY                   |             |      4 |     27 |   621 |     5  (20)| 00:00:01 |  Q1,03 | PCWP |            |     11 |00:00:00.01 |       0 |  1071K|  1071K|     4/0/0|    
|   4 |     PX RECEIVE                     |             |      4 |     27 |   621 |     5  (20)| 00:00:01 |  Q1,03 | PCWP |            |     12 |00:00:00.01 |       0 |       |       |          |    
|   5 |      PX SEND HASH                  | :TQ10002    |      0 |     27 |   621 |     5  (20)| 00:00:01 |  Q1,02 | P->P | HASH       |      0 |00:00:00.01 |       0 |       |       |          |    
|   6 |       HASH GROUP BY                |             |      4 |     27 |   621 |     5  (20)| 00:00:01 |  Q1,02 | PCWP |            |     12 |00:00:00.03 |      18 |  1063K|  1063K|     4/0/0|    
|*  7 |        HASH JOIN                   |             |      4 |    106 |  2438 |     4   (0)| 00:00:01 |  Q1,02 | PCWP |            |    106 |00:00:00.03 |      18 |  1572K|  1572K|     4/0/0|    
|   8 |         PX RECEIVE                 |             |      4 |     27 |   432 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |    108 |00:00:00.02 |       0 |       |       |          |    
|   9 |          PX SEND HYBRID HASH       | :TQ10000    |      0 |     27 |   432 |     2   (0)| 00:00:01 |  Q1,00 | P->P | HYBRID HASH|      0 |00:00:00.01 |       0 |       |       |          |    
|  10 |           STATISTICS COLLECTOR     |             |      4 |        |       |            |          |  Q1,00 | PCWC |            |     27 |00:00:00.01 |       9 |       |       |          |    
|  11 |            PX BLOCK ITERATOR       |             |      4 |     27 |   432 |     2   (0)| 00:00:01 |  Q1,00 | PCWC |            |     27 |00:00:00.01 |       9 |       |       |          |    
|* 12 |             TABLE ACCESS FULL      | DEPARTMENTS |      1 |     27 |   432 |     2   (0)| 00:00:01 |  Q1,00 | PCWP |            |     27 |00:00:00.01 |       9 |       |       |          |    
|  13 |         PX RECEIVE                 |             |      4 |    107 |   749 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |    107 |00:00:00.01 |      18 |       |       |          |    
|  14 |          PX SEND HYBRID HASH (SKEW)| :TQ10001    |      4 |    107 |   749 |     2   (0)| 00:00:01 |  Q1,01 | P->P | HYBRID HASH|    107 |00:00:00.01 |      18 |       |       |          |    
|  15 |           PX BLOCK ITERATOR        |             |      4 |    107 |   749 |     2   (0)| 00:00:01 |  Q1,01 | PCWC |            |    107 |00:00:00.01 |      18 |       |       |          |    
|* 16 |            TABLE ACCESS FULL       | EMPLOYEES   |      2 |    107 |   749 |     2   (0)| 00:00:01 |  Q1,01 | PCWP |            |    107 |00:00:00.01 |      18 |       |       |          |    
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

In the execution plans you can see the steps “PX SEND HYBRID HASH” (Step 9) and “PX SEND HYBRID HASH (SKEW)” (Step 14).

“PX SEND HYBRID HASH (SKEW)” is a technique used by 12c parallel query to avoid hash distribution of skewed popular key values. During optimization of the query, if histograms are present on the join expression, oracle finds and keeps the popular values in the cursor. At execution time , when the build table is being read, all values with matches in the popular values, are BROADCAST to all receiving pq serves  and non matching values are distributed by HASH. When the probe table is being read all values with matches in the popular values are send ROUND ROBIN/RANDOM to the receiving pq serves and the non matching values are distributed by HASH.

Please read Randolf Geist’s excellent Articles Linked below for indepth info on this topic.

Parallel Execution Skew – 12c Hybrid Hash Distribution with Skew Detection

12c Hybrid Hash Distribution with Skew Detection / Handling.