Mohamed Houri’s Oracle Notes

June 7, 2018

12cR2 Partitioning: auto-list and the disk space threat

Filed under: Partitioning — hourim @ 5:55 pm

Oracle 12cR2 comes with the auto-list partitioning option; It allows for system named partitions to be created on the fly as data arrives:

SQL> select banner from v$version where rownum=1;

BANNER
--------------------------------------------------------------------------------
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

SQL> create table auto_list_part
  	( n1 number  
       ,n2 number 
       ,vc1 varchar2(30)
      )
     partition by list(n1)
     AUTOMATIC  
     (partition p1 values(1,2,3,4,5)
     ,partition p2 values(6,7,8,9,10)
     ,partition p3 values(11,12,13,14,15) 
      )
     /

You only need to add the AUTOMATIC clause to the old way of creating list partitioned tables to have this feature enabled.

There is, however, a subtlety to consider: the AUTOMATIC clause doesn’t work with the DEFAULT clause:

SQL> create table auto_list_part
  	( n1 number  
       ,n2 number 
       ,vc1 varchar2(30)
      )
     partition by list(n1)
     AUTOMATIC
     (partition p1 values(1,2,3,4,5)
     ,partition p2 values(6,7,8,9,10)
     ,partition p3 values(11,12,13,14,15) 
     ,partition p_default values (default)
      )
     /
create table auto_list_part
*
ERROR at line 1:
ORA-14851: DEFAULT [sub]partition cannot be specified for AUTOLIST [sub]partitioned objects.

This is perfectly coherent as you don’t want to ask Oracle creating automatic list partitions for each of your newly arrived partition key values and ask it in the same time to put them into the DEFAULT partition.

That’s said let’s insert into the above automatic list partitioned table, rows that will go both in the already pre-created partitions and rows that need to go into non-existent ones:

SQL> insert into auto_list_part
     select
          rownum
         ,mod(rownum,5)
         ,'v'
     from dual
     connect by level <= 20;

 20 rows created.

SQL> exec dbms_stats.gather_table_stats(user, 'auto_list_part');

PL/SQL procedure successfully completed.



SQL> @getPartTab
Enter value for table_name: auto_list_part

TABLE_NAME           PARTITION_NAME  PARTITION_POSITION   NUM_ROWS TABLESPACE_NAME
-------------------- --------------- ------------------ ---------- ---------------
AUTO_LIST_PART       P1                               1          5 USERS
AUTO_LIST_PART       P2                               2          5 USERS
AUTO_LIST_PART       P3                               3          5 USERS
AUTO_LIST_PART       SYS_P3054                        4          1 USERS
AUTO_LIST_PART       SYS_P3055                        5          1 USERS
AUTO_LIST_PART       SYS_P3056                        6          1 USERS
AUTO_LIST_PART       SYS_P3057                        7          1 USERS
AUTO_LIST_PART       SYS_P3058                        8          1 USERS
                                                        ----------
Total num_rows                                                  20

8 rows selected.

I inserted 20 rows of which 5 have been embedded into 5 new SYS-partitions created automatically to store not foreseen partition key values greater than 15. It is important to note as well that the AUTOMATIC clause creates one partition per partition key. This is why you should absolutely take care in basing your partition strategy upon a data load pattern that will insert a reasonable amount of rows per partition key.

Let’s now get the size of the partitioned table:

SQL> @SizeBySegNameMB
Enter value for segment_name: auto_list_part
Enter value for owner: c##mhouri

SEGMENT_TYPE       TABLESPACE_NAME  SEGMENT_NAME         PARTITION_NAME          MB
------------------ ---------------- -------------------- --------------- ----------
TABLE PARTITION    USERS            AUTO_LIST_PART       P1                       8
TABLE PARTITION    USERS            AUTO_LIST_PART       P2                       8
TABLE PARTITION    USERS            AUTO_LIST_PART       P3                       8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3054                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3055                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3056                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3057                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3058                8
                                                                         ----------
Total Segment Size                                                               64

8 rows selected.

As you can see the 8 partitions occupy 64MB of disk space as their initial extend is 8MB regardless of the tiny number of rows they contain:

SQL> select 
        initial_extent/power(1024,2) initial_extentMB
       ,next_extent/power(1024,2)    next_extentMB
       ,extents
     from
        sys_dba_segs
     where
        segment_name = 'AUTO_LIST_PART'
     and
        owner        = 'C##MHOURI'
     and rownum      = 1   -- show only for one partition 
   ; 
INITIAL_EXTENTMB NEXT_EXTENTMB    EXTENTS
---------------- ------------- ----------
               8             1          1

And now the question that motivated this blog post: what happens when a very big insert into an auto-list partitioned table fails and is rolled back (by the transaction itself or via an explicit user rollback):

SQL> insert into auto_list_part
     select
          rownum
         ,mod(rownum,5)
         ,'w'
     from dual
     connect by level <= 100;

100 rows created.

SQL> rollback;

Rollback complete.

SQL> @sizebySegnameMB
Enter value for segment_name: auto_list_part
Enter value for owner: c##mhouri

SEGMENT_TYPE       TABLESPACE_NAME  SEGMENT_NAME         PARTITION_NAME          MB
------------------ ---------------- -------------------- --------------- ----------
TABLE PARTITION    USERS            AUTO_LIST_PART       P1                       8
TABLE PARTITION    USERS            AUTO_LIST_PART       P2                       8
TABLE PARTITION    USERS            AUTO_LIST_PART       P3                       8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3054                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3055                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3056                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3057                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3058                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3069                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3070                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3071                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3072                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3073                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3074                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3075                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3076                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3077                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3078                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3079                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3080                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3081                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3082                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3083                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3084                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3085                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3086                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3087                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3088                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3089                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3090                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3091                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3092                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3093                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3094                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3095                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3096                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3097                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3098                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3099                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3100                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3101                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3102                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3103                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3104                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3105                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3106                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3107                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3108                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3109                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3110                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3111                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3112                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3113                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3114                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3115                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3116                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3117                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3118                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3119                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3120                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3121                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3122                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3123                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3124                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3125                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3126                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3127                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3128                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3129                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3130                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3131                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3132                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3133                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3134                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3135                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3136                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3137                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3138                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3139                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3140                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3141                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3142                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3143                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3144                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3145                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3146                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3147                8
TABLE PARTITION    USERS            AUTO_LIST_PART       SYS_P3148                8
                                                                         ----------
Total Segment Size                                                              704

88 rows selected.

As you might have already pointed it out, it doesn’t matter whether I commit or rollback, Oracle will create on the fly, as much partitions as the distinct partition key values I have tried to insert. The immediate consequence is that I ended up with an almost empty partitioned table having 704MB worth of disk space.

If you want to shrink this ”wasted” space then you can move those partitions to use a less bigger initial extent:

SQL> alter table auto_list_part move partition SYS_P3148 
          storage(initial 65536 next 1M);

Table altered.
SQL> @sizeBySegNameMB
Enter value for segment_name: auto_list_part
Enter value for owner: c##mhouri

SEGMENT_TYPE       TABLESPACE_NAME SEGMENT_NAME         PARTITION_NAME          MB
------------------ --------------- -------------------- --------------- ----------
TABLE PARTITION    USERS           AUTO_LIST_PART       P1                       8
TABLE PARTITION    USERS           AUTO_LIST_PART       P2                       8
TABLE PARTITION    USERS           AUTO_LIST_PART       P3                       8
TABLE PARTITION    USERS           AUTO_LIST_PART       SYS_P3054                8
TABLE PARTITION    USERS           AUTO_LIST_PART       SYS_P3055                8
../..
TABLE PARTITION    USERS           AUTO_LIST_PART       SYS_P3148              ,06
                                                                        ----------
Total Segment Size                                                          696,06

you can also prevent such a disk space explosion due to the future automatically created list partitions by un-setting the following parameter (make sure you have read this before):

SQL> alter system set "_partition_large_extents"=false;

SQL> insert into auto_list_part values (9999, 3, 'z');

SQL>@sizebysegNameMB
Enter value for segment_name: auto_list_part
Enter value for owner: c##mhouri

SEGMENT_TYPE       TABLESPACE_NAME SEGMENT_NAME         PARTITION_NAME          MB
------------------ --------------- -------------------- --------------- ----------
TABLE PARTITION    USERS           AUTO_LIST_PART       P1                       8
TABLE PARTITION    USERS           AUTO_LIST_PART       P2                       8
TABLE PARTITION    USERS           AUTO_LIST_PART       P3                       8
TABLE PARTITION    USERS           AUTO_LIST_PART       SYS_P3054                8
../..
TABLE PARTITION    USERS           AUTO_LIST_PART       SYS_P3148              ,06
TABLE PARTITION    USERS           AUTO_LIST_PART       SYS_P3149              ,06
                                                                        ----------
Total Segment Size                                                          696,12

Bottom Line
While the new 12cR2 auto-list partitioning option releases you from foreseeing in advance the creation of new partitions as data arrives, it puts you under two threats (1) a roll backed insert can leave you with a bunch of empty partitions having potentially 8MB of disk space each increasing the total space occupied by your partitioned table (2) since this automatic feature creates one partition per partition key you should make sure to have many rows per partition key; otherwise the one row per partition doesn’t make sense.

Advertisements

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

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.

March 15, 2011

Partition DDL and global indexes

Filed under: Partitioning — hourim @ 7:03 pm

This is just a simple reminder for me and for those who have experienced ORA-01502 error after a DDL on a partitioned table

ORA-01502: index 'XXX.ZZZ_TII_PK' or partition of such index is in unusable state

Let’s explain this situation through a simple demo:


create table TAB1 ( Value number(10))
partition by range(value)
(
partition p1 values less than (10),
partition p2 values less than (20),
partition p3 values less than (30),
partition p4 values less than (40),
partition p5 values less than (50)
);

insert into tab1
select rownum
from dual connect by rownum < 50;

commit;
sql>create index tab1_indx1 on tab1(value);

sql> select index_name, status
2  from user_indexes
3  where index_name = 'TAB1_INDX1';

INDEX_NAME                     STATUS
------------------------------ --------
TAB1_INDX1                     VALID

sql> alter table tab1 drop partition p2 UPDATE GLOBAL INDEXES;

Table altered.

sql> select index_name, status
2  from user_indexes
3  where index_name = 'TAB1_INDX1';

INDEX_NAME                     STATUS
------------------------------ --------
TAB1_INDX1                     VALID

sql> alter table tab1 drop partition p3;

Table altered.

sql> select index_name, status
2  from user_indexes
3  where index_name = 'TAB1_INDX1';

INDEX_NAME                     STATUS
------------------------------ --------
TAB1_INDX1                     UNUSABLE

Footnote: always think about the status of the global indexes when doing DDL on a partitioned table. If you want to keep those indexes in a valid status then you need to add the UPDATE GLOBAL INDEXES clause to your partition DDL

February 8, 2007

Using Oracle Partitioning (I)

Filed under: Partitioning — hourim @ 12:13 pm

The Partitioning aspect brought by Oracle since its release 8i has been considered as a major improvement by the oracle data base developers and Administrators.

However, partitioning can make a system run many orders of magnitude slower when it is inappropriately applied. When a SQL statement accesses one or more partitioned tables, the Oracle optimizer attempts to use the information in the WHERE clause to eliminate some of the partitions from consideration during statement execution. This process, called partition pruning, speeds statement execution by ignoring partitions that cannot satisfy the statement’s WHERE clause. To do so, the optimizer uses information from the table definition with information from the statement’s WHERE clause.

In order for the oracle optimizer to make this type of decision, the WHERE clause must reference at least one column from the set of columns that comprise the partition key.

Hence, the partition type (range, hash, list or hash-range) design together with the partition key choice is the most important issue when you decide to partition your tables.

I am not going here to explain those different types of partitions largely documented in several excellent books as Practical Oracle 8i by Jonathan Lewis and Expert Oracle Data Base Architecture by Thomas Kyte. What I want to emphasize here is how to best partition, how to best choose the key partition and how to index using locally or globally partitioned index.

I would like to work by example. Let’s create a simple table called Mho_Arc_Mast described as:


Name             Type
 --------------- ---------
 Ide               NUMBER
 Dat_Part          DATE
 Nmfi_Ide          NUMBER
 Ptfl_ide          NUMBER

I would like to range partition this table using the DAT_PART column as the key partition.
I would like also to create 16 partitions for DAT_PART on a quarter time base:

P_MHO_20040331 for DAT_PART less than 2004-04-01
 P_MHO_20040631 for DAT_PART less than 2004-07-01
 …
 P_MHO_20081231 for DAT_PART less than 2009-01-01

So, what have conducted me to choose this column as the key partition? This is the most fundamental question every one should ask when designing a table partition.

Do the DAT_PART means any thing in my business? Or will my application be using many queries involving WHERE CLAUSES such as:
WHERE DAT_PART = SYSDATE
If answers to the above question are YES then you got a nice candidate to the key partition column. However if answers are NO then maintaining this column as a key partition will be at least not useful and in the worst case disastrous.

Let’s considers the YES and the NO cases in order to see the differences between them. Consider, the YES case and examine the following select and its corresponding explain plan:

select mast.*
 from mho_arc_mast mast
 where mast.DAT_PART = SYSDATE;

Execution Plan
 ----------------------------------------------------------
 SELECT STATEMENT Optimizer=CHOOSE (Cost=11 Card=2835 Bytes= 68040)
 1 0 PARTITION RANGE (SINGLE)
 2 1 TABLE ACCESS (FULL) OF 'MHO_ARC_MAST'(Cost=11 Card=2835 Bytes= 68040)

MHO_ARC_MAST table is range partitioned by DAT_PART. And there is no yet any index applied to it. This table contains 283467 rows.

You can point out that the optimizer is doing a single partition range.

In the NO case where the key DAT_PART do not figure in any where clause, the following select:

</pre>
select mast.*

from mho_arc_mast mast
 where mast.nmfi_ide = 35689;

generates this kind of explain plan

Execution Plan
 ----------------------------------------------------------
 SELECT STATEMENT Optimizer=CHOOSE (Cost=157 Card=100 Bytes=2400)
 1 0 PARTITION RANGE (ALL)
 2 1 TABLE ACCESS (FULL) OF 'MHO_ARC_MAST' (Cost=157 Card=100 Bytes=2400)

where the oracle optimiser chooses to do a Partition Range All, starting from partition 1 (Pstart 1) to partition 16 (Pstop 16).

When the key partition is used in the where query clauses then a partition pruning (partition elimination) will occur improving performance. When the key partition is not used in the where query clauses, then selects not using the key partition are candidate to a full scan all partitions.

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)