Mohamed Houri’s Oracle Notes

December 28, 2013

Partition range operation: how many times it has been started

Filed under: Partitioning — hourim @ 8:34 am

It is well known that when reading row source execution plan in order to states about the accuracy of the estimations done by the CBO based on the available table and index statistics, we should use the following comparison

Starts * E-Rows = A-Rows

The more these two operands are close to each other the more are statistics accurate and the more is the chance seeing the CBO producing an optimal execution plan.

Fine, but very recently I have been reminded by one of my smart friend Ahmed Aangoour, that this formula should be considered differently when there is a partition range xxx operation followed by a table full access.

As always an example being worth a thousand words let see this in action

drop table t_range;

CREATE TABLE t_range
(
ID           NUMBER              NOT NULL,
X            VARCHAR2(30 CHAR)   NOT NULL
)
PARTITION BY RANGE (ID)
(
PARTITION P_10000 VALUES LESS THAN (10000) ,
PARTITION P_20000 VALUES LESS THAN (20000) ,
PARTITION P_30000 VALUES LESS THAN (30000) ,
PARTITION P_40000 VALUES LESS THAN (40000) ,
PARTITION P_50000 VALUES LESS THAN (50000) ,
PARTITION P_60000 VALUES LESS THAN (60000)
);

INSERT INTO t_range VALUES (150, 'First Part');
INSERT INTO t_range VALUES (11500, 'Second Part');
INSERT INTO t_range VALUES (25000, 'Third Part');
INSERT INTO t_range VALUES (34000, 'Fourt Part');
INSERT INTO t_range VALUES (44000, 'Fifth Part');
INSERT INTO t_range VALUES (53000, 'Sixth Part');

commit;

exec dbms_stats.gather_table_stats(user, 't_range');

select /*+ gather_plan_statistics */ count(1) from t_range;

select * from table (dbms_xplan.display_cursor(null,null,'ALLSTATS LAST +PARTITION'));

-----------------------------------------------------------------------------------
| Id  | Operation            | Name    | Starts | E-Rows | Pstart| Pstop | A-Rows |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |         |      1 |        |       |       |      1 |
|   1 |  SORT AGGREGATE      |         |      1 |      1 |       |       |      1 |
|   2 |   PARTITION RANGE ALL|         |      1 |      6 |     1 |     6 |      6 |
|   3 |    TABLE ACCESS FULL | T_RANGE |      6 |      6 |     1 |     6 |      6 |
-----------------------------------------------------------------------------------

I have engineered a table with 6 partitions. Each partition possess one row so that a full table scan of this table would generate 6 rows.

The Starts information related to operation 3 suggests that the table t_range has been scanned 6 times. So that Starts * E-Rows = 36 which is 6 times greater than A-Rows. But A-Rows is correct and E-Rows is also absolutely correct.

I believe that in such situation of PARTITION RANGE operation followed by a TABLE ACCESS FULL we should read the Starts operation as to be the number of scanned partitions and not the number of times the partitioned table has been fully scanned. So one has to be prudent when comparing Estimations versus Actuals in such a kind of situations.

Browsing the above Ahmed Aangour blog post, I saw a particular operation which attracted my attention


--------------------------------------------------------------------------------------------------
| Id  | Operation                              | Name                 | Starts | E-Rows | A-Rows |
--------------------------------------------------------------------------------------------------
|   7 |      PARTITION RANGE AND               |                      |     86 |      6 |   7949K|--> spot this
|*  8 |       TABLE ACCESS BY LOCAL INDEX ROWID| ODD_ASSURE           |     86 |      6 |   7949K|
|*  9 |        INDEX RANGE SCAN                | PK_ASS_ASSURE        |     86 |     56 |   7949K|
|  10 |     PARTITION RANGE AND                |                      |   7949K|      1 |     11M|--> spot this
|* 11 |      INDEX RANGE SCAN                  | PK_ADH_INFO_ADHESION |   7949K|      1 |     11M|
|  12 |    TABLE ACCESS BY LOCAL INDEX ROWID   | ODD_INFO_ADHESION    |     11M|      2 |     11M|
--------------------------------------------------------------------------------------------------

This is the first time I came across such a kind of partition operation:

 PARTITION RANGE AND

This operation not only exists but there is another one which is

 PARTITION RANGE OR

That I can simulate with my current t_range table

SQL> select /*+ gather_plan_statistics */ count(1) from t_range
where id = 142
or id between 5000 and 15000;

-----------------------------------------------------------------------------------------
| Id  | Operation           | Name    | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
-----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |         |      1 |        |      1 |00:00:00.01 |      44 |
|   1 |  SORT AGGREGATE     |         |      1 |      1 |      1 |00:00:00.01 |      44 |
|   2 |   PARTITION RANGE OR|         |      1 |      1 |      1 |00:00:00.01 |      44 |
|*  3 |    TABLE ACCESS FULL| T_RANGE |      2 |      1 |      1 |00:00:00.01 |      44 |
-----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
3 - filter((("ID"<=15000 AND "ID">=5000) OR "ID"=142))

Note
-----
- statistics feedback used for this statement

The PARTITION RANGE OR (and the AND) is a feature of partition pruning that seems to be implemented starting from 11g allowing partition elimination when the partition key is within the where clause but used several times with an OR (AND) operation.

PS : The last Note about statistics feedback is an excellent reminder to investigate deeply this new 12c optimizer feature.

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: