Example: Splitting a RANGE partition v17
This example divides the q4_2012
partition of the range-partitioned sales
table into two partitions and redistributes the partition's contents. Use this command to create the sales
table:
CREATE TABLE sales ( dept_no number, part_no varchar2, country varchar2(20), date date, amount number ) PARTITION BY RANGE(date) ( PARTITION q1_2012 VALUES LESS THAN('2012-Apr-01'), PARTITION q2_2012 VALUES LESS THAN('2012-Jul-01'), PARTITION q3_2012 VALUES LESS THAN('2012-Oct-01'), PARTITION q4_2012 VALUES LESS THAN('2013-Jan-01') );
The table definition creates four partitions: q1_2012
, q2_2012
, q3_2012
, and q4_2012
). This command adds rows to each partition:
INSERT INTO sales VALUES (10, '4519b', 'FRANCE', '17-Jan-2012', '45000'), (20, '3788a', 'INDIA', '01-Mar-2012', '75000'), (40, '9519b', 'US', '12-Apr-2012', '145000'), (20, '3788a', 'PAKISTAN', '04-Jun-2012', '37500'), (40, '4577b', 'US', '11-Nov-2012', '25000'), (30, '7588b', 'CANADA', '14-Dec-2012', '50000'), (30, '9519b', 'CANADA', '01-Feb-2012', '75000'), (30, '4519b', 'CANADA', '08-Apr-2012', '120000'), (40, '3788a', 'US', '12-May-2012', '4950'), (10, '9519b', 'ITALY', '07-Jul-2012', '15000'), (10, '9519a', 'FRANCE', '18-Aug-2012', '650000'), (10, '9519b', 'FRANCE', '18-Aug-2012', '650000'), (20, '3788b', 'INDIA', '21-Sept-2012', '5090'), (40, '4788a', 'US', '23-Sept-2012', '4950'), (40, '4788b', 'US', '09-Oct-2012', '15000'), (20, '4519a', 'INDIA', '18-Oct-2012', '650000'), (20, '4519b', 'INDIA', '2-Dec-2012', '5090');
A SELECT
statement confirms that the rows are distributed among the partitions:
edb=# SELECT tableoid::regclass, * FROM sales;
Output
tableoid | dept_no | part_no | country | date | amount ---------------+---------+---------+----------+--------------------+-------- sales_q1_2012 | 10 | 4519b | FRANCE | 17-JAN-12 00:00:00 | 45000 sales_q1_2012 | 20 | 3788a | INDIA | 01-MAR-12 00:00:00 | 75000 sales_q1_2012 | 30 | 9519b | CANADA | 01-FEB-12 00:00:00 | 75000 sales_q2_2012 | 40 | 9519b | US | 12-APR-12 00:00:00 | 145000 sales_q2_2012 | 20 | 3788a | PAKISTAN | 04-JUN-12 00:00:00 | 37500 sales_q2_2012 | 30 | 4519b | CANADA | 08-APR-12 00:00:00 | 120000 sales_q2_2012 | 40 | 3788a | US | 12-MAY-12 00:00:00 | 4950 sales_q3_2012 | 10 | 9519b | ITALY | 07-JUL-12 00:00:00 | 15000 sales_q3_2012 | 10 | 9519a | FRANCE | 18-AUG-12 00:00:00 | 650000 sales_q3_2012 | 10 | 9519b | FRANCE | 18-AUG-12 00:00:00 | 650000 sales_q3_2012 | 20 | 3788b | INDIA | 21-SEP-12 00:00:00 | 5090 sales_q3_2012 | 40 | 4788a | US | 23-SEP-12 00:00:00 | 4950 sales_q4_2012 | 40 | 4577b | US | 11-NOV-12 00:00:00 | 25000 sales_q4_2012 | 30 | 7588b | CANADA | 14-DEC-12 00:00:00 | 50000 sales_q4_2012 | 40 | 4788b | US | 09-OCT-12 00:00:00 | 15000 sales_q4_2012 | 20 | 4519a | INDIA | 18-OCT-12 00:00:00 | 650000 sales_q4_2012 | 20 | 4519b | INDIA | 02-DEC-12 00:00:00 | 5090 (17 rows)
This command splits the q4_2012
partition into two partitions named q4_2012_p1
and q4_2012_p2
:
ALTER TABLE sales SPLIT PARTITION q4_2012 AT ('15-Nov-2012') INTO ( PARTITION q4_2012_p1, PARTITION q4_2012_p2 );
A SELECT
statement confirms that the rows were redistributed across the new partitions:
edb=# SELECT tableoid::regclass, * FROM sales;
Output
tableoid | dept_no | part_no | country | date |amount -----------------+---------+---------+----------+--------------------+------ sales_q1_2012 | 10 | 4519b | FRANCE | 17-JAN-12 00:00:00 | 45000 sales_q1_2012 | 20 | 3788a | INDIA | 01-MAR-12 00:00:00 | 75000 sales_q1_2012 | 30 | 9519b | CANADA | 01-FEB-12 00:00:00 | 75000 sales_q2_2012 | 40 | 9519b | US | 12-APR-12 00:00:00 |145000 sales_q2_2012 | 20 | 3788a | PAKISTAN | 04-JUN-12 00:00:00 | 37500 sales_q2_2012 | 30 | 4519b | CANADA | 08-APR-12 00:00:00 |120000 sales_q2_2012 | 40 | 3788a | US | 12-MAY-12 00:00:00 | 4950 sales_q3_2012 | 10 | 9519b | ITALY | 07-JUL-12 00:00:00 | 15000 sales_q3_2012 | 10 | 9519a | FRANCE | 18-AUG-12 00:00:00 |650000 sales_q3_2012 | 10 | 9519b | FRANCE | 18-AUG-12 00:00:00 |650000 sales_q3_2012 | 20 | 3788b | INDIA | 21-SEP-12 00:00:00 | 5090 sales_q3_2012 | 40 | 4788a | US | 23-SEP-12 00:00:00 | 4950 sales_q4_2012_p1| 40 | 4577b | US | 11-NOV-12 00:00:00 | 25000 sales_q4_2012_p1| 40 | 4788b | US | 09-OCT-12 00:00:00 | 15000 sales_q4_2012_p1| 20 | 4519a | INDIA | 18-OCT-12 00:00:00 |650000 sales_q4_2012_p2| 30 | 7588b | CANADA | 14-DEC-12 00:00:00 | 50000 sales_q4_2012_p2| 20 | 4519b | INDIA | 02-DEC-12 00:00:00 | 5090 (17 rows)