Mohamed Houri’s Oracle Notes

January 27, 2018

Adaptive Cursor Sharing and parallel execution plan

Filed under: Oracle — hourim @ 7:33 am

I have shown and demonstrated at different places that there exist three pre-requisites for a cursor, using natural or forced bind variable, to be bind sensitive:

  • it uses a range (inequality) predicate
  • it uses an equality predicate and histogram
  • it uses a partition key in its predicate

I think that from now on we can add a fourth pre-requisite which is:

  • the very first execution of this cursor should not be run via a parallel execution plan.

Let’s demonstrate this point (the model should be taken from this post):

alter system flush shared_pool;
alter session set cursor_sharing= force;
alter table t_acs parallel;

select count(1) from t_acs where n2 = 1;

SQL_ID  7ck8k47bnqpnv, child number 0
-------------------------------------
------------------------------------------------
| Id  | Operation         | Name       | Rows  |
------------------------------------------------
|   0 | SELECT STATEMENT  |            |       |
|   1 |  SORT AGGREGATE   |            |     1 |
|*  2 |   INDEX RANGE SCAN| T_ACS_IDX1 |     1 |
------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("N2"=:SYS_B_1)

select
    child_number
   ,is_bind_sensitive
   ,is_bind_aware
 from 
   gv$sql
 where
    sql_id ='7ck8k47bnqpnv';

CHILD_NUMBER I I
------------ - -
           0 Y N

The very first execution of the above cursor used a serial execution plan and an equality predicate on a skewed column having Frequency histogram. This is why it has been marked bind sensitive.

But what would have happened to the cursor if its very first execution has been ran parallely?

alter system flush shared_pool;
select count(1) from t_acs where n2 = 1e6;
-----------------------------------------------------------
| Id  | Operation              | Name     | Rows  | Bytes |
-----------------------------------------------------------
|   0 | SELECT STATEMENT       |          |       |       |
|   1 |  SORT AGGREGATE        |          |     1 |     3 |
|   2 |   PX COORDINATOR       |          |       |       |
|   3 |    PX SEND QC (RANDOM) | :TQ10000 |     1 |     3 |
|   4 |     SORT AGGREGATE     |          |     1 |     3 |
|   5 |      PX BLOCK ITERATOR |          |  1099K|  3220K|
|*  6 |       TABLE ACCESS FULL| T_ACS    |  1099K|  3220K|
-----------------------------------------------------------

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

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

select
    child_number
   ,is_bind_sensitive
   ,is_bind_aware
 from 
   gv$sql
 where
    sql_id ='7ck8k47bnqpnv';

CHILD_NUMBER I I
------------ - -
           0 N N

Since the very first execution of the cursor uses a parallel execution plan Oracle refuses to set its bind sensitive property. And from this stage and on, until a cursor is flushed out from the library cache, all cursor executions will share the same parallel execution plan.

But what would have happened if the very first cursor execution would have used a serial plan?

alter system flush shared_pool;

select count(1) from t_acs where n2 = 100;
select count(1) from t_acs where n2 = 100;
select count(1) from t_acs where n2 = 100;
------------------------------------------------
| Id  | Operation         | Name       | Rows  |
------------------------------------------------
|   0 | SELECT STATEMENT  |            |       |
|   1 |  SORT AGGREGATE   |            |     1 |
|*  2 |   INDEX RANGE SCAN| T_ACS_IDX1 |   100 |
------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 – access("N2"=:SYS_B_1)

select
    child_number
   ,is_bind_sensitive
   ,is_bind_aware
   ,executions
 from 
   gv$sql
 where
    sql_id ='7ck8k47bnqpnv';

CHILD_NUMBER I I EXECUTIONS
------------ - - ----------
           0 Y N          3

As expected the cursor is bind sensitive. Let’s now make it bind aware :

select count(1) from t_acs where n2 = 1000;
select count(1) from t_acs where n2 = 1000;
select count(1) from t_acs where n2 = 1000;
select count(1) from t_acs where n2 = 1000;

select
    child_number
   ,is_bind_sensitive
   ,is_bind_aware
   ,executions
 from 
   gv$sql
 where
    sql_id ='7ck8k47bnqpnv';

CHILD_NUMBER I I EXECUTIONS
------------ - - ----------
           0 Y N          6
           1 Y Y          1

And here where the serious stuff starts. I will show you how Oracle will unset the bind sensitive and bind awareness property of the above cursor whenever the execution plan triggered by the ECS layer code and produced by CBO is a parallel plan:

select count(1) from t_acs where n2 = 1e6;

SQL_ID  7ck8k47bnqpnv, child number 2
-------------------------------------
-----------------------------------------------------------
| Id  | Operation              | Name     | Rows  | Bytes |
-----------------------------------------------------------
|   0 | SELECT STATEMENT       |          |       |       |
|   1 |  SORT AGGREGATE        |          |     1 |     3 |
|   2 |   PX COORDINATOR       |          |       |       |
|   3 |    PX SEND QC (RANDOM) | :TQ10000 |     1 |     3 |
|   4 |     SORT AGGREGATE     |          |     1 |     3 |
|   5 |      PX BLOCK ITERATOR |          |  1099K|  3219K|
|*  6 |       TABLE ACCESS FULL| T_ACS    |  1099K|  3219K|
-----------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   6 - access(:Z>=:Z AND :Z<=:Z)
       filter("N2"=:SYS_B_1)

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

select
    child_number
   ,is_bind_sensitive
   ,is_bind_aware
   ,executions
 from 
   gv$sql
 where
    sql_id ='7ck8k47bnqpnv';

CHILD_NUMBER I I EXECUTIONS
------------ - - ----------
           0 Y N          6
           1 Y Y          1
           2 N N          1

The new child number 2 is not anymore bind sensistive nor bind aware. That’s the most important conclusion of this article : Oracle doesn’t allow ACS to work with parallelism.

Summary

ACS has been implemented for very frequently used queries having different set of bind variables values each of which generating different amount of I/O. In this context, Oracle decided to cancel ACS whenever a parallel plan is triggred by ECS. Before 12cR2 there was a bug identified by Bug 16226575 in which ACS was disabled for query having decorated parallel object irrespective of the plan being chosen serial or parallel. As we saw in this article this has been fixed in 12cR2. ACS will be disabled only if its produced execution plan is parallel.

Advertisements

Leave a Comment »

No comments yet.

RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

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 Oracle's blog

Just another Oracle blog : Database topics and techniques

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.

EU Careers info

Your career in the European Union

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)

%d bloggers like this: