One of my favourite new features in Oracle Database 12c is the ability to perform partition maintenance operations on multiple partitions. This means we can now add, drop, truncate and merge multiple partitions in one operation, and can split a single partition into more than two partitions also in just one command. This would certainly have made my life slightly easier had it been available when I administered a data warehouse at Oracle 9i.
To demonstrate this new functionality and syntax, I am going to create two tables, ORDERS and ORDERS_ITEMS which have a parent-child relationship. ORDERS is to be partitioned using range partitioning on the ORDER_DATE column, and ORDER_ITEMS is going to partitioned using reference partitioning and its foreign key relationship with the ORDERS table. This form of partitioning was a new feature in 11g and means that any partition maintenance operations performed on the ORDERS table will also take place on the ORDER_ITEMS table as well.
First create the ORDERS table -
SQL CREATE TABLE orders
( order_id NUMBER(12),
order_date TIMESTAMP,
order_mode VARCHAR2(8),
customer_id NUMBER(6),
order_status NUMBER(2),
order_total NUMBER(8,2),
sales_rep_id NUMBER(6),
promotion_id NUMBER(6),
CONSTRAINT orders_pk PRIMARY KEY(order_id)
)
PARTITION BY RANGE(order_date)
(PARTITION Q1_2007 VALUES LESS THAN (TO_DATE('01-APR-2007','DD-MON-YYYY')),
PARTITION Q2_2007 VALUES LESS THAN (TO_DATE('01-JUL-2007','DD-MON-YYYY')),
PARTITION Q3_2007 VALUES LESS THAN (TO_DATE('01-OCT-2007','DD-MON-YYYY')),
PARTITION Q4_2007 VALUES LESS THAN (TO_DATE('01-JAN-2008','DD-MON-YYYY'))
);
Table created.
Now the ORDER_ITEMS table
SQL CREATE TABLE order_items
( order_id NUMBER(12) NOT NULL,
line_item_id NUMBER(3) NOT NULL,
product_id NUMBER(6) NOT NULL,
unit_price NUMBER(8,2),
quantity NUMBER(8),
CONSTRAINT order_items_fk
FOREIGN KEY(order_id) REFERENCES orders(order_id) on delete cascade)
PARTITION BY REFERENCE(order_items_fk) tablespace example;
Table created.
Now look at DBA_TAB_PARTITIONS to get details of what partitions we have in the two tables –
SQL select table_name,partition_name,
partition_position position, high_value
from dba_tab_partitions
where table_owner='SH' and
table_name like 'ORDER_%'
order by partition_position, table_name;
TABLE_NAME PARTITION_NAME POSITION HIGH_VALUE
-------------- --------------- -------- -------------------------
ORDERS Q1_2007 1 TIMESTAMP' 2007-04-01 00:00:00'
ORDER_ITEMS Q1_2007 1
ORDERS Q2_2007 2 TIMESTAMP' 2007-07-01 00:00:00'
ORDER_ITEMS Q2_2007 2
ORDERS Q3_2007 3 TIMESTAMP' 2007-10-01 00:00:00'
ORDER_ITEMS Q3_2007 3
ORDERS Q4_2007 4 TIMESTAMP' 2008-01-01 00:00:00'
ORDER_ITEMS Q4_2007 4
Just as an aside it is also now possible in 12c to use interval partitioning on reference partitioned tables. In 11g it was not possible to combine these two new partitioning features.
For our first example of the new 12cfunctionality, let us add all the partitions necessary for 2008 to the tables using one command. Notice that the partition specification part of the add command is identical in format to the partition specification part of the create command as shown above -
SQL alter table orders add
PARTITION Q1_2008 VALUES LESS THAN (TO_DATE('01-APR-2008','DD-MON-YYYY')),
PARTITION Q2_2008 VALUES LESS THAN (TO_DATE('01-JUL-2008','DD-MON-YYYY')),
PARTITION Q3_2008 VALUES LESS THAN (TO_DATE('01-OCT-2008','DD-MON-YYYY')),
PARTITION Q4_2008 VALUES LESS THAN (TO_DATE('01-JAN-2009','DD-MON-YYYY'));
Table altered.
Now look at DBA_TAB_PARTITIONS and we can see that the 4 new partitions have been added to both tables –
SQL select table_name,partition_name,
partition_position position, high_value
from dba_tab_partitions
where table_owner='SH' and
table_name like 'ORDER_%'
order by partition_position, table_name;
TABLE_NAME PARTITION_NAME POSITION HIGH_VALUE
-------------- --------------- -------- -------------------------
ORDERS Q1_2007 1 TIMESTAMP' 2007-04-01 00:00:00'
ORDER_ITEMS Q1_2007 1
ORDERS Q2_2007 2 TIMESTAMP' 2007-07-01 00:00:00'
ORDER_ITEMS Q2_2007 2
ORDERS Q3_2007 3 TIMESTAMP' 2007-10-01 00:00:00'
ORDER_ITEMS Q3_2007 3
ORDERS Q4_2007 4 TIMESTAMP' 2008-01-01 00:00:00'
ORDER_ITEMS Q4_2007 4
ORDERS Q1_2008 5 TIMESTAMP' 2008-04-01 00:00:00'
ORDER_ITEMS Q1_2008 5
ORDERS Q2_2008 6 TIMESTAMP' 2008-07-01 00:00:00'
ORDER_ITEM Q2_2008 6
ORDERS Q3_2008 7 TIMESTAMP' 2008-10-01 00:00:00'
ORDER_ITEMS Q3_2008 7
ORDERS Q4_2008 8 TIMESTAMP' 2009-01-01 00:00:00'
ORDER_ITEMS Q4_2008 8
Next, we can drop or truncate multiple partitions by giving a comma separated list in the alter table command. Note the use of the plural ‘partitions’ in the command as opposed to the singular ‘partition’ prior to 12c–
SQL alter table orders drop partitions Q3_2008,Q2_2008,Q1_2008;
Table altered.
Now look at DBA_TAB_PARTITIONS and we can see that the 3 partitions have been dropped in both the two tables –
TABLE_NAME PARTITION_NAME POSITION HIGH_VALUE
-------------- --------------- -------- -------------------------
ORDERS Q1_2007 1 TIMESTAMP' 2007-04-01 00:00:00'
ORDER_ITEMS Q1_2007 1
ORDERS Q2_2007 2 TIMESTAMP' 2007-07-01 00:00:00'
ORDER_ITEMS Q2_2007 2
ORDERS Q3_2007 3 TIMESTAMP' 2007-10-01 00:00:00'
ORDER_ITEMS Q3_2007 3
ORDERS Q4_2007 4 TIMESTAMP' 2008-01-01 00:00:00'
ORDER_ITEMS Q4_2007 4
ORDERS Q4_2008 5 TIMESTAMP' 2009-01-01 00:00:00'
ORDER_ITEMS Q4_2008 5
Now let us merge all the 2007 partitions together to form one single partition –
SQL alter table orders merge partitions
Q1_2005, Q2_2005, Q3_2005, Q4_2005
into partition Y_2007;
Table altered.
TABLE_NAME PARTITION_NAME POSITION HIGH_VALUE
-------------- --------------- -------- -------------------------
ORDERS Y_2007 1 TIMESTAMP' 2008-01-01 00:00:00'
ORDER_ITEMS Y_2007 1
ORDERS Q4_2008 2 TIMESTAMP' 2009-01-01 00:00:00'
ORDER_ITEMS Q4_2008 2
Splitting partitions is a slightly more involved. In the case of range partitioning one of the new partitions must have no high value defined, and in list partitioning one of the new partitions must have no list of values defined. I call these partitions the ‘everything else’ partitions, and will contain any rows contained in the original partition that are not contained in the any of the other new partitions.
For example, let us split the Y_2007 partition back into 4 quarterly partitions –
SQL alter table orders split partition Y_2007 into
(PARTITION Q1_2007 VALUES LESS THAN (TO_DATE('01-APR-2007','DD-MON-YYYY')),
PARTITION Q2_2007 VALUES LESS THAN (TO_DATE('01-JUL-2007','DD-MON-YYYY')),
PARTITION Q3_2007 VALUES LESS THAN (TO_DATE('01-OCT-2007','DD-MON-YYYY')),
PARTITION Q4_2007);
Now look at DBA_TAB_PARTITIONS to get details of the new partitions –
TABLE_NAME PARTITION_NAME POSITION HIGH_VALUE
-------------- --------------- -------- -------------------------
ORDERS Q1_2007 1 TIMESTAMP' 2007-04-01 00:00:00'
ORDER_ITEMS Q1_2007 1
ORDERS Q2_2007 2 TIMESTAMP' 2007-07-01 00:00:00'
ORDER_ITEMS Q2_2007 2
ORDERS Q3_2007 3 TIMESTAMP' 2007-10-01 00:00:00'
ORDER_ITEMS Q3_2007 3
ORDERS Q4_2007 4 TIMESTAMP' 2008-01-01 00:00:00'
ORDER_ITEMS Q4_2007 4
ORDERS Q4_2008 5 TIMESTAMP' 2009-01-01 00:00:00'
ORDER_ITEMS Q4_2008 5
Partition Q4_2007 has a high value equal to the high value of the original Y_2007 partition, and so has inherited its upper boundary from the partition that was split.
As for a list partitioning example let look at the following another table, SALES_PAR_LIST, which has 2 partitions, Americas and Europe and a partitioning key of country_name.
SQL select table_name,partition_name,
high_value
from dba_tab_partitions
where table_owner='SH' and
table_name = 'SALES_PAR_LIST';
TABLE_NAME PARTITION_NAME HIGH_VALUE
-------------- --------------- -----------------------------
SALES_PAR_LIST AMERICAS 'Argentina', 'Canada', 'Peru',
'USA', 'Honduras', 'Brazil', 'Nicaragua'
SALES_PAR_LIST EUROPE 'France', 'Spain', 'Ireland', 'Germany',
'Belgium', 'Portugal', 'Denmark'
Now split the Americas partition into 3 partitions –
SQL alter table sales_par_list split partition americas into
(partition south_america values ('Argentina','Peru','Brazil'),
partition north_america values('Canada','USA'),
partition central_america);
Table altered.
Note that no list of values was given for the ‘Central America’ partition. However it should have inherited any values in the original ‘Americas’ partition that were not assigned to either the ‘North America’ or ‘South America’ partitions. We can confirm this by looking at the DBA_TAB_PARTITIONS view.
SQL select table_name,partition_name,
high_value
from dba_tab_partitions
where table_owner='SH' and
table_name = 'SALES_PAR_LIST';
TABLE_NAME PARTITION_NAME HIGH_VALUE
--------------- --------------- --------------------------------
SALES_PAR_LIST SOUTH_AMERICA 'Argentina', 'Peru', 'Brazil'
SALES_PAR_LIST NORTH_AMERICA 'Canada', 'USA'
SALES_PAR_LIST CENTRAL_AMERICA 'Honduras', 'Nicaragua'
SALES_PAR_LIST EUROPE 'France', 'Spain', 'Ireland', 'Germany',
'Belgium', 'Portugal', 'Denmark'
In conclusion, I hope that DBA’s whose work involves maintaining partitions will find the operations a bit more straight forward to carry out once they have upgraded to Oracle Database 12c.
Gwen Lazenby is a Principal Training Consultant at Oracle.
She is part of Oracle University's Core Technology delivery team based in the UK, teaching Database Administration and Linux courses. Her specialist topics include using Oracle Partitioning and Parallelism in Data Warehouse environments, as well as Oracle Spatial and RMAN.