Mohamed Houri’s Oracle Notes

December 31, 2013

2013 in review

Filed under: Oracle — hourim @ 8:11 am

I would like to share with you a summary of my annual blogging stuff. My 2013 blogging activity was more accurate than it was the last year. I have published 33 new posts growing the total archive to 96 posts (97 including the current post). Friends who are working close to me know that I promised them to reach 100 posts by the end of 2013. Unfortunately, I will not achieve this goal. I would have been, nevertheless, able to achieve it as far as I still have a couple of drafts almost ready to publish. But, being one of the active writing style adept, it always takes me time before publishing even a simple article: I need to test, re-test, read and re-read before approving the post.

For this coming new year I want to fix a new challenge: publish 100 posts.

Will it be possible? Wait and see.

Click here to see the complete report.

Best wishes

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.

December 25, 2013

Tuning via row source execution plan

Filed under: explain plan — hourim @ 4:25 pm

Browsing over draft blogs I have not finished and forget to come back to, I found one article about a sub optimal execution plan of a query suffering terrible performance problem. If my memory is still servicing me well, I think this execution plan has been sent to me by one of my ex-colleague with whom I have had several e-mail exchange and have supplied him with a proposition. I was waiting for his answer before publishing this blog article. It seems he has never answered since then :-). Anyway, I thought it is, nevertheless, worth sharing with you at least my starting investigations on this query performance problem.

This is the execution plan with row source statistics showing the estimations done by the CBO based on available statistics

 ----------------------------------------------------------------------------------------------------------------------
 | Id  | Operation                            | Name                          | Starts | E-Rows | A-Rows |   A-Time   |
 ----------------------------------------------------------------------------------------------------------------------
 |   1 |  SORT UNIQUE                         |                               |      1 |      1 |    109 |00:00:35.22 | --> 35sec
 |   2 |   WINDOW BUFFER                      |                               |      1 |      1 |    109 |00:00:35.22 |
 |*  3 |    FILTER                            |                               |      1 |        |    109 |00:00:35.21 |
 |   4 |     SORT GROUP BY                    |                               |      1 |      1 |    760 |00:00:35.21 |
 |*  5 |      FILTER                          |                               |      1 |        |   9938 |00:00:35.00 |
 |   6 |       NESTED LOOPS OUTER             |                               |      1 |      1 |  14546 |00:00:34.93 |
 |   7 |        NESTED LOOPS                  |                               |      1 |      1 |  14546 |00:00:33.58 |
 |   8 |         NESTED LOOPS OUTER           |                               |      1 |      1 |    952 |00:00:00.52 |
 |   9 |          NESTED LOOPS OUTER          |                               |      1 |      1 |    952 |00:00:00.31 |
 |* 10 |           TABLE ACCESS BY INDEX ROWID| XXX_TABLE1                    |      1 |      2 |    760 |00:00:00.09 |
 |* 11 |            INDEX RANGE SCAN          | XXX_TAB1_IND_1                |      1 |      2 |   8766 |00:00:00.02 |
 |  12 |           TABLE ACCESS BY INDEX ROWID| XXX_TABLE2                    |    760 |      1 |    248 |00:00:00.22 |
 |* 13 |            INDEX RANGE SCAN          | XXX_TAB2_IND_FK               |    760 |      4 |    248 |00:00:00.19 |
 |* 14 |          TABLE ACCESS BY INDEX ROWID | XXX_TABLE3                    |    952 |      1 |    952 |00:00:00.20 |
 |* 15 |           INDEX RANGE SCAN           | XXX_TABLE3_PK                 |    952 |      1 |   4833 |00:00:00.12 |
 |* 16 |         TABLE ACCESS BY INDEX ROWID  | XXX_TABLE1                    |    952 |      1 |  14546 |00:00:33.04 |
 |* 17 |          INDEX RANGE SCAN            | XXX_TAB1_IND_1                |    952 |      1 |   7980K|00:00:00.05 |
 |* 18 |        TABLE ACCESS BY INDEX ROWID   | XXX_TABLE5                    |  14546 |      1 |     15 |00:00:01.29 |
 |* 19 |         INDEX RANGE SCAN             | XXX_TAB5_IND_1                |  14546 |      1 |     15 |00:00:01.21 |
 |  20 |       SORT AGGREGATE                 |                               |      3 |      1 |      3 |00:00:00.01 |
 |* 21 |        TABLE ACCESS BY INDEX ROWID   | XXX_TABLE2                    |      3 |      1 |     11 |00:00:00.01 |
 |* 22 |         INDEX RANGE SCAN             | XXX_TAB2_IND_FK               |      3 |      4 |     11 |00:00:00.01 |
 ----------------------------------------------------------------------------------------------------------------------
 

where I have deliberately omitted the predicate part for clarity (I will show it in a moment).

Have you already pointed out the most time consuming operation?

If not yet then look at the different operations (from 1 to 22) and isolate  the most consuming child/parent operation  by looking at the A-Time column.

Have you already found it?

Here it is together with its predicate part:

 ----------------------------------------------------------------------------------------------------------------------
 | Id  | Operation                            | Name                          | Starts | E-Rows | A-Rows |   A-Time   |
 ----------------------------------------------------------------------------------------------------------------------
 |* 16 |         TABLE ACCESS BY INDEX ROWID  | XXX_TABLE1                    |    952 |      1 |  14546 |00:00:33.04 |
 |* 17 |          INDEX RANGE SCAN            | XXX_TAB1_IND_1                |    952 |      1 |   7980K|00:00:00.05 |
 ----------------------------------------------------------------------------------------------------------------------
 16 - filter(("TAB1_2"."N1">=20000 AND "TAB1"."XXX_ID"="TAB1_2"."XXX_ID"))
 17 - access("TAB1_2"."DATH">SYSDATE@!-.041666 AND "TAB1"."DAT_TRD"="TAB1_2"."DAT_TRD" AND "TAB1_2"."DATH" IS NOT NULL)
      filter("TAB1"."DAT_TRD"="TAB1_2"."DAT_TRD")
 

This is how to proceed generally to identify the most consuming operation in an execution plan. By the way, this is also my method of tuning a query not performing in a client acceptable response time i.e. (a) I get the row source execution plan including the estimations and actuals (b) and I then scrutinize or scan this plan looking through the A-Time column for the most consuming operation. Thanks to this method, I end up in the majority of cases (there are of course exceptions) by isolating the operation on which attention should be concentrated.

So back to my execution plan. The most consuming operation being found, what observations can be done? Well, without bothering yourself trying to understand the above filter operation, you can, however, obviously point out two major facts

  1. Looking at the high number (7980,000) of rowid the index range scan operation 17 has supplied its parent operation 16 and finally to the very small number of those row-rowids (14,546) that survived the filter operation number 16, I end up by realizing that this is an enormous waste of time and resource spent discarding rows that would have not been sent to the table access operation at all.
  2. Looking at the estimations done by the CBO and the actuals rows generated I ended up by realizing that there is obviously a statistics problem my colleague should look at very urgently.
  3. Almost all E-Rows of the above execution plan has a cardinality equal to one. This particular cardinality is typically suspicious. It is a clear indication of the absence of fresh statistics

Whether the most consuming operation is due to the not up-to-date statistics or to an imprecise index (XXX_TAB1_IND_1) depends on my colleague answer that will probably not come at all.

Bottom line: when you have to tune a query you can proceed using the following steps:

  1. get the row source execution plan from memory using dbms_xplan package that includes Estimations and Actuals, then track the most consuming operation and the accuracy of statistics (table and columns statistics)
  2. get a SQL monitoring report and analyze it if you have a license for
  3. use Tanel Poder snapper
  4. use Carlos Sierra SQLTXPLAN
  5. etc…

Partition pruning with hash partitioned tables

Filed under: Partitioning — hourim @ 9:27 am

This is a simple reminder on how partition pruning with hash partitioned table could be different from range partitioned ones. If you have a range partitioned table, a query using a partition key in the where clause can eliminate partitions either dynamically (dynamic pruning) or at hard parse time. This partition pruning might occur even if the predicate on the partition key is not an equality (>= or <=). This is, however, not the case for a hash partitioned table. For this partioning method you have to apply an equality or an in list predicate on the partitioned key to see the CBO pruning your hash partitions.

drop table t1;
create table t1
(n1             number not null,
creation_date  date   not null,
comments       varchar2(500))
partition by hash (n1)
partitions 16;

insert into t1 select rownum, sysdate + (rownum-1), lpad('x',10)
from dual
connect by level <= 1000;

commit;

I am going to execute 3 queries against the above engineered hash partitioned table. The first one will use an equality predicate against the partition key (n1) while in the second one I will be using an in list operator on the same partition key. And finally in the last query I will compare the partition key to a value using a greater than predicate operator.


select * from t1
where n1 = 42;

select * from t1
where n1 in(42,100);

select * from t1
where n1 > 42;

The corresponding execution plans are given below respectively

----------------------------------------------------------------------
| Id  | Operation             | Name | Rows  | Bytes | Pstart| Pstop |
----------------------------------------------------------------------
|   0 | SELECT STATEMENT      |      |     1 |  1024 |       |       |
|   1 |  PARTITION HASH SINGLE|      |     1 |  1024 |    14 |    14 |
|*  2 |   TABLE ACCESS FULL   | T1   |     1 |  1024 |    14 |    14 |
----------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("N1"=42)

----------------------------------------------------------------------
| Id  | Operation             | Name | Rows  | Bytes | Pstart| Pstop |
----------------------------------------------------------------------
|   0 | SELECT STATEMENT      |      |     2 |  2048 |       |       |
|   1 |  PARTITION HASH INLIST|      |     2 |  2048 |KEY(I) |KEY(I) |
|*  2 |   TABLE ACCESS FULL   | T1   |     2 |  2048 |KEY(I) |KEY(I) |
----------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("N1"=42 OR "N1"=100)

-------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Pstart| Pstop |
-------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   737 |   737K|       |       |
|   1 |  PARTITION HASH ALL|      |   737 |   737K|     1 |    16 |
|*  2 |   TABLE ACCESS FULL| T1   |   737 |   737K|     1 |    16 |
-------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("N1">42)

A partition pruning occurs, at hard parse time, for the first query (equality predicate against the hash partitioned key). A dynamic partition pruning occurs for the second query (in list predicate against the partition key) and there was no partition pruning for the third query (an inequality predicate on the partition key).

Simply put, when selecting from a hash partitioned table, if you want to prune your partitions and accelerate your query response time, you need to apply an equality predicate (or in list) on the partition key.

Spot the resemblance (or coincidence) with the hash join method that works only when the join condition is an equality.

Up to now we are using a single hash partition key. What if I hash partition by a composite key?

create table t1
(n1             number not null,
 n2             number not null,
 creation_date  date   not null,
 comments       varchar2(500))
partition by hash (n1,n2) --> composite partition key
partitions 16;

insert into t1 select rownum,rownum*2, sysdate + (rownum-1), lpad('x',10)
from dual
connect by level <= 1000;

commit;

In the following query I will use a single equality predicate on the first column of the composed partition key as shown below:

explain plan for
select * from t1
where n1 = 42;

-------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Pstart| Pstop |
-------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |     8 |  8296 |       |       |
|   1 |  PARTITION HASH ALL|      |     8 |  8296 |     1 |    16 |
|*  2 |   TABLE ACCESS FULL| T1   |     8 |  8296 |     1 |    16 |
-------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("N1"=42)

Despite the existence of an equality predicate on the first partition key, partition pruning didn’t occurred. However if I add to the above query an extra predicate on the second partition key, partition pruning will this time occur as shown below:

explain plan for
select * from t1
where n1 = 42
and   n2 = 84;

----------------------------------------------------------------------
| Id  | Operation             | Name | Rows  | Bytes | Pstart| Pstop |
----------------------------------------------------------------------
|   0 | SELECT STATEMENT      |      |     1 |  1037 |       |       |
|   1 |  PARTITION HASH SINGLE|      |     1 |  1037 |    13 |    13 |
|*  2 |   TABLE ACCESS FULL   | T1   |     1 |  1037 |    13 |    13 |
----------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("N1"=42 AND "N2"=84)

Put is simply, when you have a hash partitioned table, partitioned via a composite partition key, to eliminate partitions, you need to have an equality (or an in list) predicate on the complete set of the partition keys( in any order).

I will not finish this hash partition pruning visit without extending the above cases to a composite range hash partition

drop table t1;

create table t1
(n1             number not null,
creation_date  date   not null,
comments       varchar2(500)
 )
partition by range (creation_date)
subpartition by hash(n1)
subpartitions 16
(
partition p1 values less than (to_date('01/01/2011','DD/MM/YYYY'))
,partition p2 values less than (to_date('01/01/2012','DD/MM/YYYY'))
,partition p3 values less than (to_date('01/01/2013','DD/MM/YYYY'))
,partition p4 values less than (to_date('31/12/2014','DD/MM/YYYY'))
);

insert into t1 values (1, to_date('29032010','ddmmyyyy'), '2010_Part');
insert into t1 values (42, to_date('17022011','ddmmyyyy'), '2011_Part');
insert into t1 values (17, to_date('15022012','ddmmyyyy'), '2012_Part');
insert into t1 values (25, to_date('13/02/2013','dd/mm/yyyy'), '2013_Part');

commit;

And the usual selects with their corresponding execution plans

explain plan for
select * from t1
here creation_date = to_date('29032010','ddmmyyyy')
and  n1 = 42;

-----------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes | Pstart| Pstop |
-----------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      |     1 |   274 |       |       |
|   1 |  PARTITION RANGE SINGLE|      |     1 |   274 |     1 |     1 | --> range partition pruning
|   2 |   PARTITION HASH SINGLE|      |     1 |   274 |    14 |    14 | --> hash partition pruning
|*  3 |    TABLE ACCESS FULL   | T1   |     1 |   274 |    14 |    14 |
-----------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
3 - filter("CREATION_DATE"=TO_DATE(' 2010-03-29 00:00:00', 'syyyy-mm-dd
hh24:mi:ss') AND "N1"=42)

explain plan for
select * from t1
where creation_date = to_date('29032010','ddmmyyyy')
and  n1 >= 42;

-----------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes | Pstart| Pstop |
-----------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      |     1 |   274 |       |       |
|   1 |  PARTITION RANGE SINGLE|      |     1 |   274 |     1 |     1 | --> range partition pruning
|   2 |   PARTITION HASH ALL   |      |     1 |   274 |     1 |    16 | --> no hash partition pruning due to n1>42
|*  3 |    TABLE ACCESS FULL   | T1   |     1 |   274 |     1 |    16 |
-----------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
3 - filter("CREATION_DATE"=TO_DATE(' 2010-03-29 00:00:00', 'syyyy-mm-dd
hh24:mi:ss') AND "N1">=42)

Bottom line : was it a simple hash partitioned table or a composite range-hash one, to have a partition pruning within the hash partitioned bit of the table you need to apply an equality (or an in list) predicate on the complete partition key (single or composite key).

December 24, 2013

Dynamic Partition Pruning

Filed under: Partitioning — hourim @ 10:50 am

A recent question on otn forum prompted me to write few words about dynamic pruning. Dynamic pruning occurs when Oracle knows that it will accomplish a partition pruning (elimination) but is unable to identify, at parse time, the partitions it has to eliminate. It has to wait until the query run time to find which partitions it will prune. This is represented in the execution plan via the word KEY in the PSTART (the first scanned partition) and PSTOP (the last scanned partition). So every time you see the word (KEY) in an execution plan, this is the CBO telling you that it is going to eliminate partitions but it will do that only during the query execution time. In this article I will try to show you few examples where dynamic pruning occurs.
The first and most evident situation of dynamic pruning is when you compare the partition key to a function which, in the CBO perception, it might return different results when called at parse time and at execution time. Here below a simple example

 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');

In the first next query I am going to compare the partition key (id) to a known and fixed value (150) while in the second query I will be comparing the same partition key to a variable value (trunc(dbms_random.value(150,150))) as perceived by the CBO.


SQL> explain plan for
    select *
    from t_range
    where id = 150 ;

--------------------------------------------------------------------------
| Id  | Operation              | Name    | Rows  | Bytes | Pstart| Pstop |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |         |     1 |    15 |       |       |
|   1 |  PARTITION RANGE SINGLE|         |     1 |    15 |     1 |     1 | --> first partition
|*  2 |   TABLE ACCESS FULL    | T_RANGE |     1 |    15 |     1 |     1 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("ID"=150)

SQL> explain plan for
    select *
    from t_range
    where id = trunc(dbms_random.value(150,150)) ;

--------------------------------------------------------------------------
| Id  | Operation              | Name    | Rows  | Bytes | Pstart| Pstop |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |         |     1 |    15 |       |       |
|   1 |  PARTITION RANGE SINGLE|         |     1 |    15 |   KEY |   KEY | --> dynamic partition pruning
|*  2 |   TABLE ACCESS FULL    | T_RANGE |     1 |    15 |   KEY |   KEY |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("ID"=TRUNC("DBMS_RANDOM"."VALUE"(150,150)))

When I compared the partition key to a ”parse time unknown value then the CBO delayed the partition pruning at run time and materialized this dynamic pruning by the word KEY in the execution plan.

A more indicative and clear example is when you use a date range partitioned table and compare the partition key to the SYSDATE value.


drop table t_range;

create table t_range (id number, create_date date, rec_type varchar2(2))
partition by range (create_date)
(
 partition p1 values less than (to_date('01/01/2012','DD/MM/YYYY'))
,partition p2 values less than (to_date('01/02/2012','DD/MM/YYYY'))
,partition p3 values less than (to_date('01/03/2012','DD/MM/YYYY'))
,partition p4 values less than (to_date('01/04/2012','DD/MM/YYYY'))
,partition p5 values less than (to_date('31/12/2013','DD/MM/YYYY'))
);

insert into t_range values (1,to_date('01/01/2012', 'DD/MM/YYYY'),'RR');
insert into t_range values (2,to_date('05/03/2012', 'DD/MM/YYYY'),'RR');
insert into t_range values (3,to_date('03/02/2012', 'DD/MM/YYYY'),'RR');
insert into t_range values (4,to_date('03/02/2012', 'DD/MM/YYYY'),'ZZ');
insert into t_range values (5,to_date('06/03/2012', 'DD/MM/YYYY'),'ZZ');
insert into t_range values (6,to_date('18/03/2012', 'DD/MM/YYYY'),'WE');
insert into t_range values (7,to_date('15/01/2012', 'DD/MM/YYYY'),'ZZ');
insert into t_range values (8,to_date('24/12/2013', 'DD/MM/YYYY'),'ER');

commit;

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

explain plan for
select * from t_range
where create_date = sysdate;

--------------------------------------------------------------------------
| Id  | Operation              | Name    | Rows  | Bytes | Pstart| Pstop |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |         |     1 |    14 |       |       |
|   1 |  PARTITION RANGE SINGLE|         |     1 |    14 |   KEY |   KEY | --> dynamic pruning with sysdate
|*  2 |   TABLE ACCESS FULL    | T_RANGE |     1 |    14 |   KEY |   KEY | --> because sysdate is a function
-------------------------------------------------------------------------- --> its value changes continuously with time

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("CREATE_DATE"=SYSDATE@!)

explain plan for
select * from t_range
where create_date = to_date('24-12-2013','dd-mm-yyyy');

--------------------------------------------------------------------------
| Id  | Operation              | Name    | Rows  | Bytes | Pstart| Pstop |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |         |     1 |    14 |       |       |
|   1 |  PARTITION RANGE SINGLE|         |     1 |    14 |     5 |     5 |--> partition elimination occured
|*  2 |   TABLE ACCESS FULL    | T_RANGE |     1 |    14 |     5 |     5 |--  when sysdate has not been used
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("CREATE_DATE"=TO_DATE(' 2013-12-24 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))

SYSDATE, in contrast to the current day, which is “24-12-2013″,  is continuously changing during time. Even though that we are interested only in the date part of the  SYSDATE value, the CBO still has to wait until the query execution time to find and eliminate the untouched partitions.

There is another situation where dynamic pruning might occur; it is when the partitioned table is joined to another table using the partition key and the CBO detects that there will be partition pruning because the joined table will not join all the partitions. In the next example I will create a t_join table in which I will insert all t_range ”partition keys”

create table t_join (id number, date_rec date, vc varchar2(30));

insert into t_join values (1,to_date('01/01/2012', 'DD/MM/YYYY'),'RR');
insert into t_join values (2,to_date('05/03/2012', 'DD/MM/YYYY'),'RR');
insert into t_join values (3,to_date('03/02/2012', 'DD/MM/YYYY'),'RR');
insert into t_join values (4,to_date('03/02/2012', 'DD/MM/YYYY'),'ZZ');
insert into t_join values (5,to_date('06/03/2012', 'DD/MM/YYYY'),'ZZ');
insert into t_join values (6,to_date('18/03/2012', 'DD/MM/YYYY'),'WE');
insert into t_join values (7,to_date('15/01/2012', 'DD/MM/YYYY'),'ZZ');
insert into t_join values (8,to_date('24/12/2013', 'DD/MM/YYYY'),'ER');
commit;

explain plan for
select *
from t_range a, t_join b
where
a.create_date = b.date_rec;

------------------------------------------------------------------------
| Id  | Operation            | Name    | Rows  | Bytes | Pstart| Pstop |
------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |         |     9 |   882 |       |       |
|*  1 |  HASH JOIN           |         |     9 |   882 |       |       |
|   2 |   PARTITION RANGE ALL|         |     8 |   112 |     1 |     5 |
|   3 |    TABLE ACCESS FULL | T_RANGE |     8 |   112 |     1 |     5 |
|   4 |   TABLE ACCESS FULL  | T_JOIN  |     8 |   672 |       |       |
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - access("A"."CREATE_DATE"="B"."DATE_REC")

In this case the CBO determines, at parse time, that all partitions will be scanned and hence decided to scan all partitions (operation 2) at parse time. But what if I add a filter operation that eliminates few records?

explain plan for
select *
from t_range a, t_join b
where
a.create_date = b.date_rec
and b.id = 7;

-----------------------------------------------------------------------------
| Id  | Operation                 | Name    | Rows  | Bytes | Pstart| Pstop |
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT          |         |     1 |    98 |       |       |
|   1 |  NESTED LOOPS             |         |     1 |    98 |       |       |
|*  2 |   TABLE ACCESS FULL       | T_JOIN  |     1 |    84 |       |       |
|   3 |   PARTITION RANGE ITERATOR|         |     1 |    14 |   KEY |   KEY |
|*  4 |    TABLE ACCESS FULL      | T_RANGE |     1 |    14 |   KEY |   KEY |
-----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("B"."ID"=7)
4 - filter("A"."CREATE_DATE"="B"."DATE_REC")

Thanks to this additional filter on the t_join table , the CBO knows at parse time that it has to eliminate partitions. But as far as it has to wait until run time to apply the filter (predicate n° 2) then it is only at that time when it will be able to isolate the accessed partitions and eliminate the rest: this is dynamic pruning.

The next article will deal about partition pruning with hash partitioned tables.

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

Just another blog : Databases, Linux and other stuffs

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.

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)