Mohamed Houri’s Oracle Notes

March 18, 2017

12cR2: SPM and cursor bind awareness property

Filed under: Oracle — hourim @ 7:24 am

In the previous article we knew that, as of Oracle 12cR2, it is now possible to capture SPM baselined plans from AWR historical tables. In this article we are going to see how in 12cR2 a cursor will immediately stop to be bind aware when it is protected by a single SPM plan. The basic idea driving this new implementation is that, since the Adaptive Cursor Sharing main goal is to generate multiple optimal execution plans, if you decide to constrain it with a single SPM plan, you are implicitly asking Oracle to stop generating multiple execution plans.

Let’s demonstrate this new ACS-SPM relationship using the same model as that of the preceding article

Setting the Scenes

create table t_acs(n1 number, n2 number);

BEGIN
 for j in 1..1200150 loop
  if j = 1 then
    insert into t_acs values (j, 1);
  elsif j>1 and j<=101 then
    insert into t_acs values(j, 100);
  elsif j>101 and j<=1101 then
    insert into t_acs values (j, 1000);
  elsif j>10001 and j<= 110001 then
    insert into t_acs values(j,10000); 
  else
    insert into t_acs values(j, 1000000); end if;
 end loop; 
commit;
END;
/

create index t_acs_i1 on t_acs(n2);

BEGIN 
  dbms_stats.gather_table_stats
     (user
     ,'t_acs'
     ,method_opt => 'for all columns size skewonly' 
     ,cascade => true
     ,estimate_percent => dbms_stats.auto_sample_size );
END; 
/

var ln2 number;
exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;

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

exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;


Observation

The execution of the above script will end up by producing two bind sensitive, bind aware and shareable cursors as shown below:

select 
    sql_id
  ,child_number
  ,is_bind_sensitive 
  ,is_bind_aware
  ,executions
from
   v$sql 
where
   sql_id = 'f2pmwazy1rnfd'
and is_shareable = 'Y';

SQL_ID        CHILD_NUMBER I I EXECUTIONS
------------- ------------ - - ----------
f2pmwazy1rnfd            1 Y Y          1 → full scan plan
f2pmwazy1rnfd            2 Y Y          1 → index range scan plan

So far so good.
What if I decide to create a SPM execution plan in order to constrain the above query to use always the index range scan plan?

SQL> alter session set optimizer_capture_sql_plan_baselines = TRUE;

SQL> select count(1) from t_acs where n2 = :ln2;

  COUNT(1)
----------
       100

SQL> select count(1) from t_acs where n2 = :ln2;

  COUNT(1)
----------
       100

SQL> alter session set optimizer_capture_sql_plan_baselines = FALSE;

SQL> col plan_name format a40
SQL> select 
        plan_name ,origin, accepted, enabled
     from dba_sql_plan_baselines;

PLAN_NAME                        ORIGIN          ACC ENA
------------------------------- ---------------- --- ---
SQL_PLAN_fn4mhg52jx5z125348c47  AUTO-CAPTURE     YES YES

As such the next time I will run this query it will use the index range scan SPM baselined plan as shown below:

SQL> select count(1) from t_acs where n2 = :ln2;

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

SQL_ID  f2pmwazy1rnfd, child number 1                                                                                                                                              
-------------------------------------                                                                                                                                                                                                                                                                                                                                                                                                                                                                      
Plan hash value: 1882749816                                                                                                                                                                                                                                                                                                                                    
----------------------------------------------                                                                                                    
| Id  | Operation         | Name     | Rows  |                                                                                                   
----------------------------------------------                                                                                                    
|   0 | SELECT STATEMENT  |          |       |                                                                                                    
|   1 |  SORT AGGREGATE   |          |     1 |                                                                                                     
|*  2 |   INDEX RANGE SCAN| T_ACS_I1 |   100 |                                                                                                  
----------------------------------------------                                                                                                    
                                                                                                                                                                                   
Predicate Information (identified by operation id):                                                                                                                                
---------------------------------------------------                                                                                                                                                                                                                                                                                              
   2 - access("N2"=:LN2)                                                                                                                                                           
                                                                                                                                                                                   
Note                                                                                                                                                                               
-----                                                                                                                                                                              
- SQL plan baseline SQL_PLAN_fn4mhg52jx5z125348c47 used for this statement  

But what you might ignore is that, following the creation of this SPM baselined plan, Oracle did something behind the scene as shown via the following cursor new situation:

select 
    sql_id
  ,child_number
  ,is_bind_sensitive 
  ,is_bind_aware
  ,executions
from
   v$sql 
where
   sql_id = 'f2pmwazy1rnfd'
and is_shareable = 'Y';

SQL_ID        CHILD_NUMBER I I EXECUTIONS
------------- ------------ - - ----------
f2pmwazy1rnfd            1 N N          1

If you analyze carefully the new situation compared to the old one you will realize that the following actions have been done behind the scenes

1. The previous child cursors n°1 and n°2 has been flushed out.
2. A new no bind sensitive and no bind aware child cursor n°1 has been created

It is the number of execution (only 1) of child cursor n°1 which clearly explains that the previous two bind aware cursors have been flushed out from memory due to the new SPM baselined plan. The child cursor n°0 is still in the shared pool but is in a non shareable status.

SQL> select 
        sql_id
      ,child_number
      ,is_bind_sensitive 
      ,is_bind_aware
      ,is_shareable
      ,executions
    from
       v$sql 
   where
      sql_id = 'f2pmwazy1rnfd';

SQL_ID        CHILD_NUMBER I I I EXECUTIONS
------------- ------------ - - - ----------
f2pmwazy1rnfd            0 Y N N          2 → non shareable
f2pmwazy1rnfd            1 N N Y          1

That’s the new 12cR2 implementation managing the relationship between ACS and SPM. ACS is disabled when it is constrained by a single accepted and enabled SPM plan.

If we disable the previous SPM baseline the cursor becomes bind aware after a warm up period as usual

SQL> @disSPM.sql 
Enter value for plan_name: SQL_PLAN_fn4mhg52jx5z125348c47

SQL> select 
          plan_name ,origin, enabled
      from dba_sql_plan_baselines;

PLAN_NAME                       ORIGIN       ENA
------------------------------- ------------ ---
SQL_PLAN_fn4mhg52jx5z125348c47  AUTO-CAPTURE NO 

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

exec :ln2 := 100
select count(1) from t_acs where n2 = :ln2;

etc…./...

SQL> select 
        sql_id
      ,child_number
      ,is_bind_sensitive 
      ,is_bind_aware
      ,is_shareable
      ,executions
    from
       v$sql 
   where
      sql_id = 'f2pmwazy1rnfd'
  ;

SQL_ID        CHILD_NUMBER I I I EXECUTIONS
------------- ------------ - - - ----------
f2pmwazy1rnfd            0 Y N N          2
f2pmwazy1rnfd            1 Y N N          3
f2pmwazy1rnfd            2 Y Y Y          1 → bind aware full scan
f2pmwazy1rnfd            3 Y Y Y          1 → bind aware range scan

Summary

As of Oracle 12cR2 when an ACS cursor having multiple optimal execution plans is constrained by a single enabled and accepted SPM plan, Oracle will age it out from memory and cancel its bind sensitive and bind aware properties. This will remain intact until the SPM is dropped or disabled. In the next article we will see what happens to an ACS cursor when one of its multiple accepted and enabled SPM plan is rendered unreproducible.

Advertisements

1 Comment »

  1. […] the previous article we knew that, as of Oracle 12cR2, a cursor can’t be kept bind aware when it is protected by a […]

    Pingback by 12cR2: unreproducible SPM and cursor bind awareness | Mohamed Houri’s Oracle Notes — April 16, 2017 @ 4:53 pm | Reply


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

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: