Mohamed Houri’s Oracle Notes

December 17, 2014

Adaptive plan

Filed under: Oracle — hourim @ 1:12 pm

Have you ever seen such kind of execution plan

------------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Starts | A-Rows |   A-Time   | Buffers |
------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |      1 |      5 |00:00:00.04 |       4 |
|   1 |  MAT_VIEW REWRITE ACCESS FULL| T1_T2_MV |      1 |      5 |00:00:00.04 |       4 |
------------------------------------------------------------------------------------------

Note
-----
   - this is an adaptive plan

Or this one:

SQL> select * from table(dbms_xplan.display_cursor(null, null, 'allstats last +adaptive'));

-----------------------------------------------------------------------------
| Id  | Operation                    | Name     | Starts | A-Rows | Buffers |
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |      1 |      5 |       4 |
|   1 |  MAT_VIEW REWRITE ACCESS FULL| T1_T2_MV |      1 |      5 |       4 |
-----------------------------------------------------------------------------

Note
-----
   - this is an adaptive plan (rows marked '-' are inactive)    

Where are those inactive rows marked ‘-‘ in the plan?

I was writing an article on tuning disjunctive subqueries when I have been prompted to check something with materialized views. Coincidentaly at the time the materialized view question kicks in, I was finishing the model for the disjunctive subquery purpose. Thereofe, I’ve decided to created a materialied view using this model and here what happens.

select /*+ qb_name(parent) */
     id,
     n1
from
     t1 
where
     n1 = 100
and  exists
      (select /*+ qb_name(child) */  
            null 
       from t2 
       where 
            t2.id = t1.id
       and  t2.x1 = 100
       );     
-------------------------------------------------------------------------------------------
|   Id  | Operation                                | Name     | Starts | A-Rows | Buffers |
-------------------------------------------------------------------------------------------
|     0 | SELECT STATEMENT                         |          |      1 |      5 |      13 |
|- *  1 |  HASH JOIN                               |          |      1 |      5 |      13 |
|     2 |   NESTED LOOPS                           |          |      1 |      5 |      13 |
|     3 |    NESTED LOOPS                          |          |      1 |      5 |      11 |
|-    4 |     STATISTICS COLLECTOR                 |          |      1 |      5 |       3 |
|     5 |      SORT UNIQUE                         |          |      1 |      5 |       3 |
|     6 |       TABLE ACCESS BY INDEX ROWID BATCHED| T2       |      1 |      5 |       3 |
|  *  7 |        INDEX RANGE SCAN                  | T2_X1_I1 |      1 |      5 |       2 |
|  *  8 |     INDEX RANGE SCAN                     | T1_ID_I1 |      5 |      5 |       8 |
|  *  9 |    TABLE ACCESS BY INDEX ROWID           | T1       |      5 |      5 |       2 |
|- * 10 |   TABLE ACCESS FULL                      | T1       |      0 |      0 |       0 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T2"."ID"="T1"."ID")
   7 - access("T2"."X1"=100)
   8 - access("T2"."ID"="T1"."ID")
   9 - filter("N1"=100)
  10 - filter("N1"=100)

Note
-----
   - this is an adaptive plan (rows marked '-' are inactive)

The materialized view on the top of the above query resembles to this:

create materialized view t1_t2_mv as
select /*+ qb_name(parent) */
     id,
     n1
from
     t1 
where
     n1 = 100
and  exists
      (select /*+ qb_name(child) */  
            null 
       from t2 
       where 
            t2.id = t1.id
       and  t2.x1 = 100
       );     
Materialized view created.

And I have finished the setup by enabling query rewrite on the materialized view:

alter materialized view t1_t2_mv enable query rewrite;
Materialized view altered.

Finally I re-executed the initial query and get the corresponding execution plan as usual

select /*+ qb_name(parent) */
     id,
     n1
from
     t1 
where
     n1 = 100
and  exists
      (select /*+ qb_name(child) */  
            null 
       from t2 
       where 
            t2.id = t1.id
       and  t2.x1 = 100
       );     
------------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Starts | A-Rows |   A-Time   | Buffers |
------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |      1 |      5 |00:00:00.04 |       4 |
|   1 |  MAT_VIEW REWRITE ACCESS FULL| T1_T2_MV |      1 |      5 |00:00:00.04 |       4 |
------------------------------------------------------------------------------------------

Note
-----
   - this is an adaptive plan

And the corresponding outline is:

Outline Data:
  /*+
    BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('12.1.0.1')
      DB_VERSION('12.1.0.1')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$35C14E55")
      REWRITE(@"SEL$F743C7BF" "T1_T2_MV")
      OUTLINE(@"SEL$F743C7BF")
      REWRITE(@"PARENT" "T1_T2_MV")
      OUTLINE(@"PARENT")
      FULL(@"SEL$35C14E55" "T1_T2_MV"@"SEL$518C1272")
    END_OUTLINE_DATA
  */	   

Spot in passing how the number of Buffers drops from 13 to 4 when the CBO decided to use the materialized view instead of the initial query.

Bottom line: The Note about adaptive plan you might see when materialized views are used is related to the SQL behind the materialized view and not to the materialized view itself.

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: