Monday, May 15, 2017

ORACLE 12C PARTITIONING NEW FEATURES

Online Move Partition

In Oracle 12c we can now move as well as compress partitions online while DML transactions on the partitioned table are in progress.
In earlier versions we would get an error like the one shown below if we attempted to move a partition while a DML statement on the partitioned table was in progress.
ORA-00054: resource busy and acquire with NOWAIT specified or timeout expired
This is tied in to the 12c new feature related to Information Lifecycle Management where tables (and partitions) can be moved to low cost storage and/or compressed as part of an ILM policy. So we would not like to impact any DML statements which are in progress when the partitions are being moved or compressed – hence the online feature.
Another feature in 12c is that this online partition movement will not make the associated partitioned indexes left in an unusable state. The UPDATE INDEXES ONLINE clause will maintain the global and local indexes on the table.
SQL> ALTER TABLE sales MOVE PARTITION sales_q2_1998 TABLESPACE users
2  UPDATE INDEXES ONLINE;
Table altered.

Interval Reference Partitioning

In Oracle 11g Interval as well as Reference partitioning methods were introduced. In 12c we take this one step further and combine both those partitioning methods into one. So we can now have a child table to be referenced partitioned based on a parent table which has interval partitioning defined for it.
So two things to keep in mind.
Whenever an interval partition is created in the parent table a partition is also created in the referenced child table and the  partition name inherited from the parent table.
Partitions in the child table corresponding to partitions in the parent table are created when rows are inserted into the child table.
Let us look an example using the classic ORDERS and ORDER_ITEMS table which have a parent-child relationship and the parent ORDERS table has been interval partitioned.
CREATE TABLE "OE"."ORDERS_PART"
 (    
"ORDER_ID" NUMBER(12,0) NOT NULL,
"ORDER_DATE" TIMESTAMP (6)  CONSTRAINT "ORDER_PART_DATE_NN" NOT NULL ENABLE,
"ORDER_MODE" VARCHAR2(8),
"CUSTOMER_ID" NUMBER(6,0) ,
"ORDER_STATUS" NUMBER(2,0),
"ORDER_TOTAL" NUMBER(8,2),
"SALES_REP_ID" NUMBER(6,0),
"PROMOTION_ID" NUMBER(6,0),
CONSTRAINT ORDERS_PART_pk PRIMARY KEY (ORDER_ID)
)
PARTITION BY RANGE (ORDER_DATE)
INTERVAL (NUMTOYMINTERVAL(1,'YEAR'))
(PARTITION P_2006 VALUES LESS THAN (TIMESTAMP'2007-01-01 00:00:00 +00:00'),
PARTITION P_2007 VALUES LESS THAN (TIMESTAMP'2008-01-01 00:00:00 +00:00'),
PARTITION P_2008 VALUES LESS THAN (TIMESTAMP'2009-01-01 00:00:00 +00:00')
)
;

CREATE TABLE "OE"."ORDER_ITEMS_PART"
(    
"ORDER_ID" NUMBER(12,0) NOT NULL,
"LINE_ITEM_ID" NUMBER(3,0) NOT NULL ENABLE,
"PRODUCT_ID" NUMBER(6,0) NOT NULL ENABLE,
"UNIT_PRICE" NUMBER(8,2),
"QUANTITY" NUMBER(8,0),
CONSTRAINT "ORDER_ITEMS_PART_FK" FOREIGN KEY ("ORDER_ID")
REFERENCES "OE"."ORDERS_PART" ("ORDER_ID") ON DELETE CASCADE )
PARTITION BY REFERENCE (ORDER_ITEMS_PART_FK)
;

Note the partitions in the parent table
SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDERS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008

We can see that the child table has inherited the same partitions from the parent table
SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDER_ITEMS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008
We now insert a new row into the table which leads to the creation of a new partition automatically
SQL> INSERT INTO ORDERS_PART
  2   VALUES
  3   (9999,'17-MAR-15 01.00.00.000000 PM', 'DIRECT',147,5,1000,163,NULL);

1 row created.

SQL> COMMIT;

Commit complete.

SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDERS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008
SYS_P301

Note at this point the child table still has only 3 partitions and a new partition corresponding to the parent table will only be created when rows are inserted into the child table.
We now insert some rows into the child table – note that the row insertions leads to a new partition being created in the child table corresponding to the parent table.
SQL> INSERT INTO ORDER_ITEMS_PART
  2  VALUES
  3  (9999,1,2289,10,100);

1 row created.

SQL> INSERT INTO ORDER_ITEMS_PART
  2   VALUES
  3  (9999,2,2268,500,1);

1 row created.

SQL> COMMIT;

Commit complete.

SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDER_ITEMS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008
SYS_P301

TRUNCATE CASCADE

In Oracle 12c we can add the CASCADE option to the TRUNCATE TABLE or ALTER TABLE TRUNCATE PARTITION commands.
The CASCADE option will truncate all child tables which reference the parent table and also where the referential constraint has been created with the ON DELETE CASCADE option.
The TRUNCATE CASCADE when used at the partition level in a reference partition model will also cascade to the partitions in the child table as shown in the example below.
SQL> alter table orders_part truncate partition SYS_P301 cascade;

Table truncated.


SQL> select count(*) from orders_part partition (SYS_P301);

  COUNT(*)
----------
         0

SQL>  select count(*) from order_items_part partition (SYS_P301);

  COUNT(*)
----------
         0

Multi-Partition Maintenance Operations
In Oracle 12c we can add, truncate or drop multiple partitions as part of a single operation.
In versions prior to 12c, the SPLIT and MERGE PARTITION operations could only be carried out on two partitions at a time. If we had a table with 10 partitions which say we needed to merge, we had to issue 9 separate DDL statements
Now with a single command we can roll out data into smaller partitions or roll up data into a larger partition.
CREATE TABLE sales
( prod_id       NUMBER(6)
, cust_id       NUMBER
, time_id       DATE
, channel_id    CHAR(1)
, promo_id      NUMBER(6)
, quantity_sold NUMBER(3)
, amount_sold   NUMBER(10,2)
)
PARTITION BY RANGE (time_id)
( PARTITION sales_q1_2014 VALUES LESS THAN (TO_DATE('01-APR-2014','dd-MON-yyyy'))
, PARTITION sales_q2_2014 VALUES LESS THAN (TO_DATE('01-JUL-2014','dd-MON-yyyy'))
, PARTITION sales_q3_2014 VALUES LESS THAN (TO_DATE('01-OCT-2014','dd-MON-yyyy'))
, PARTITION sales_q4_2014 VALUES LESS THAN (TO_DATE('01-JAN-2015','dd-MON-yyyy'))
);


ALTER TABLE sales ADD
PARTITION sales_q1_2015 VALUES LESS THAN (TO_DATE('01-APR-2015','dd-MON-yyyy')),
PARTITION sales_q2_2015 VALUES LESS THAN (TO_DATE('01-JUL-2015','dd-MON-yyyy')),
PARTITION sales_q3_2015 VALUES LESS THAN (TO_DATE('01-OCT-2015','dd-MON-yyyy')),
PARTITION sales_q4_2015 VALUES LESS THAN (TO_DATE('01-JAN-2016','dd-MON-yyyy'));


SQL>  ALTER TABLE sales MERGE PARTITIONS sales_q1_2015,sales_q2_2015,sales_q3_2015,sales_q4_2015  INTO PARTITION sales_2015;

Table altered.

SQL>  ALTER TABLE sales SPLIT PARTITION sales_2015 INTO
  2  (PARTITION sales_q1_2015 VALUES LESS THAN (TO_DATE('01-APR-2015','dd-MON-yyyy')),
  3  PARTITION sales_q2_2015 VALUES LESS THAN (TO_DATE('01-JUL-2015','dd-MON-yyyy')),
  4  PARTITION sales_q3_2015 VALUES LESS THAN (TO_DATE('01-OCT-2015','dd-MON-yyyy')),
  5  PARTITION sales_q4_2015);

Table altered.

Partial Indexing

In Oracle 12c we can now have a case where only certain partitions of the table are indexed while the other partitions do not have any indexes. For example we may want the recent partitions which are subject to lots of OLTP type operations to not have any indexes in order to speed up insert activity while the older partitions of the table are subject to DSS type queries and would benefit from indexing.
We can turn indexing on or off at the table level and then enable or disable it selectively at the partition level.
Have a look at the example below.
CREATE TABLE "SH"."SALES_12C"
(
"PROD_ID" NUMBER NOT NULL ENABLE,
"CUST_ID" NUMBER NOT NULL ENABLE,
"TIME_ID" DATE NOT NULL ENABLE,
"CHANNEL_ID" NUMBER NOT NULL ENABLE,
"PROMO_ID" NUMBER NOT NULL ENABLE,
"QUANTITY_SOLD" NUMBER(10,2) NOT NULL ENABLE,
"AMOUNT_SOLD" NUMBER(10,2) NOT NULL ENABLE
) 
TABLESPACE "EXAMPLE"
INDEXING OFF
PARTITION BY RANGE ("TIME_ID")
(PARTITION "SALES_1995"  VALUES LESS THAN (TO_DATE(' 1996-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1996"  VALUES LESS THAN (TO_DATE(' 1997-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1997"  VALUES LESS THAN (TO_DATE(' 1998-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1998"  VALUES LESS THAN (TO_DATE(' 1999-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1999"  VALUES LESS THAN (TO_DATE(' 2000-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_2000"  VALUES LESS THAN (TO_DATE(' 2001-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) INDEXING ON,
PARTITION "SALES_2001"  VALUES LESS THAN (TO_DATE(' 2002-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) INDEXING ON,
PARTITION "SALES_2002"  VALUES LESS THAN (TO_DATE(' 2003-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) INDEXING ON
 )
;

Create a local partitioned index on the table and note the size of the local index.
SQL> CREATE INDEX SALES_12C_IND ON SALES_12C (TIME_ID) LOCAL;

Index created.


SQL> SELECT SUM(BYTES)/1048576 FROM USER_SEGMENTS WHERE SEGMENT_NAME='SALES_12C_IND';

SUM(BYTES)/1048576
------------------
                32

We drop the index and create the same index, but this time as a partial index. Since the index has only been created on a few partitions of the table and not the entire table, it is half the size of the original index.
SQL> CREATE INDEX SALES_12C_IND ON SALES_12C (TIME_ID) LOCAL INDEXING PARTIAL;

Index created.

SQL> SELECT SUM(BYTES)/1048576 FROM USER_SEGMENTS WHERE SEGMENT_NAME='SALES_12C_IND';

SUM(BYTES)/1048576
------------------
                16

We can see that for the partitions where indexing is not enabled, the index has been created as UNUSABLE.
SQL> SELECT PARTITION_NAME,STATUS FROM USER_IND_PARTITIONS WHERE INDEX_NAME='SALES_12C_IND';

PARTITION_NAME                 STATUS
------------------------------ --------
SALES_2002                     USABLE
SALES_2001                     USABLE
SALES_2000                     USABLE
SALES_1999                     UNUSABLE
SALES_1998                     UNUSABLE
SALES_1997                     UNUSABLE
SALES_1996                     UNUSABLE
SALES_1995                     UNUSABLE

Note the difference in the EXPLAIN PLAN between two queries – which access different partitions of the same table and in one case use the local partial index and in the other case performs a full table scan.
SQL>  EXPLAIN PLAN FOR
  2  SELECT SUM(QUantity_sold) from sales_12c
  3  where time_id <'01-JAN-97'; Explained. SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2557626605

-------------------------------------------------------------------------------------------------------
| Id  | Operation                 | Name      | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT          |           |     1 |    11 |  1925   (1)| 00:00:01 |       |       |
|   1 |  SORT AGGREGATE           |           |     1 |    11 |            |          |       |       |
|   2 |   PARTITION RANGE ITERATOR|           |   472 |  5192 |  1925   (1)| 00:00:01 |     1 |   KEY |
|*  3 |    TABLE ACCESS FULL      | SALES_12C |   472 |  5192 |  1925   (1)| 00:00:01 |     1 |   KEY |





SQL>  EXPLAIN PLAN FOR
  2   SELECT SUM(QUantity_sold) from sales_12c
  3  where time_id='01-JAN-97';

Explained.

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

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------
Plan hash value: 2794067059

--------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                      | Name          | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                               |               |     1 |    22 |     2   (0)| 00:00:01 |       |       |
|   1 |  SORT AGGREGATE                                |               |     1 |    22 |            |          |       |       |
|   2 |   VIEW                                         | VW_TE_2       |     2 |    26 |     2   (0)| 00:00:01 |       |       |
|   3 |    UNION-ALL                                   |               |       |       |            |          |       |       |
|*  4 |     FILTER                                     |               |       |       |            |          |       |       |
|   5 |      PARTITION RANGE SINGLE                    |               |     1 |    22 |     1   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|   6 |       TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| SALES_12C     |     1 |    22 |     1   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|*  7 |        INDEX RANGE SCAN                        | SALES_12C_IND |     1 |       |     1   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|*  8 |     FILTER                                     |               |       |       |            |          |       |       |
|   9 |      PARTITION RANGE SINGLE                    |               |     1 |    22 |     2   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|* 10 |       TABLE ACCESS FULL                        | SALES_12C     |     1 |    22 |     2   (0)| 00:00:01 |KEY(AP)|KEY(AP)|


--------------------------------------------------------------------------------------------------------------------------------

Note the new columns INDEXING and DEF_INDEXING in the data dictionary views
SQL> select def_indexing from user_part_tables where table_name='SALES_12C';

DEF
---
OFF


SQL> select indexing from user_indexes where index_name='SALES_12C_IND';

INDEXIN
-------
PARTIAL

Asynchronous Global Index Maintenance
In earlier versions operations like TRUNCATE or DROP PARTITION on even a single partition would render the global indexes unusable and would require the indexes to be rebuilt before the application could use the indexes.
Now when we issue the same DROP or TRUNCATE partition commands we can use the UPDATE INDEXES clause and this maintains the global indexes leaving them in a USABLE state.
The global index maintenance is now deferred and is performed by a DBMS_SCHEDULER job called SYS.PMO_DEFERRED_GIDX_MAINT_JOB which is scheduled to run at 2.00 AM on a daily basis.
We can also use the DBMS_PART package which has the CLEANUP_GIDX procedure which cleans up the global indexes.
A new column ORPHANED_ENTRIES in the DBA|USER|ALL_INDEXES view keeps a track of the global index and specifies if the global index partition contains any stale entries caused by the DROP/TRUNCATE PARTITION operation.
Let us look at an example of the same. Note the important point that the global index is left in a USABLE state even after we perform a TRUNCATE operation on the partitioned table.
SQL>  alter table sales_12c truncate partition SALES_2000 UPDATE INDEXES;

Table truncated.

SQL> select distinct status from user_ind_partitions;

STATUS
--------
USABLE


SQL> select partition_name, ORPHANED_ENTRIES from user_ind_partitions
  2  where index_name='SALES_GIDX';

PARTITION_NAME                 ORP
------------------------------ ---
SYS_P348                       YES
SYS_P347                       YES
SYS_P346                       YES
SYS_P345                       YES
SYS_P344                       YES
SYS_P343                       YES
SYS_P342                       YES
SYS_P341                       YES



SQL> exec dbms_part.cleanup_gidx('SH','SALES_12C');

PL/SQL procedure successfully completed.

SQL> select partition_name, ORPHANED_ENTRIES from user_ind_partitions
  2  where index_name='SALES_GIDX';

PARTITION_NAME                 ORP
------------------------------ ---
SYS_P341                       NO
SYS_P342                       NO
SYS_P343                       NO
SYS_P344                       NO
SYS_P345                       NO
SYS_P346                       NO
SYS_P347                       NO
SYS_P348                       NO

No comments:

Post a Comment