Example: Emptying a subpartition v17
This example removes the data from a subpartition of the sales
table.
Create the sales
table:
CREATE TABLE sales ( dept_no number, part_no varchar2, country varchar2(20), date date, amount number ) PARTITION BY RANGE(date) SUBPARTITION BY LIST (country) ( PARTITION "2011" VALUES LESS THAN('01-JAN-2012') ( SUBPARTITION europe_2011 VALUES ('ITALY', 'FRANCE'), SUBPARTITION asia_2011 VALUES ('PAKISTAN', 'INDIA'), SUBPARTITION americas_2011 VALUES ('US', 'CANADA') ), PARTITION "2012" VALUES LESS THAN('01-JAN-2013') ( SUBPARTITION europe_2012 VALUES ('ITALY', 'FRANCE'), SUBPARTITION asia_2012 VALUES ('PAKISTAN', 'INDIA'), SUBPARTITION americas_2012 VALUES ('US', 'CANADA') ), PARTITION "2013" VALUES LESS THAN('01-JAN-2015') ( SUBPARTITION europe_2013 VALUES ('ITALY', 'FRANCE'), SUBPARTITION asia_2013 VALUES ('PAKISTAN', 'INDIA'), SUBPARTITION americas_2013 VALUES ('US', 'CANADA') ) );
Populate the sales
table:
INSERT INTO sales VALUES (10, '4519b', 'FRANCE', '17-Jan-2011', '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-2011', '50000'), (30, '4519b', 'CANADA', '08-Apr-2012', '120000'), (40, '3788a', 'US', '12-May-2011', '4950'), (20, '3788a', 'US', '04-Apr-2012', '37500'), (40, '4577b', 'INDIA', '11-Jun-2011', '25000'), (10, '9519b', 'ITALY', '07-Jul-2012', '15000'), (20, '4519b', 'INDIA', '2-Dec-2012', '5090');
Query the sales
table to show that the rows were distributed among the subpartitions:
edb=# SELECT tableoid::regclass, * FROM sales;
Output
tableoid | dept_no| part_no | country| date | amount -------------------+--------+---------+--------+--------------------+-------- sales_americas_2011| 30| 7588b | CANADA | 14-DEC-11 00:00:00 | 50000 sales_americas_2011| 40| 3788a | US | 12-MAY-11 00:00:00 | 4950 sales_europe_2011 | 10| 4519b | FRANCE | 17-JAN-11 00:00:00 | 45000 sales_asia_2011 | 40| 4577b | INDIA | 11-JUN-11 00:00:00 | 25000 sales_americas_2012| 40| 9519b | US | 12-APR-12 00:00:00 |145000 sales_americas_2012| 40| 4577b | US | 11-NOV-12 00:00:00 | 25000 sales_americas_2012| 30| 4519b | CANADA | 08-APR-12 00:00:00 |120000 sales_americas_2012| 20| 3788a | US | 04-APR-12 00:00:00 | 37500 sales_europe_2012 | 10| 9519b | ITALY | 07-JUL-12 00:00:00 | 15000 sales_asia_2012 | 20| 3788a | INDIA | 01-MAR-12 00:00:00 | 75000 sales_asia_2012 | 20| 3788a |PAKISTAN| 04-JUN-12 00:00:00 | 37500 sales_asia_2012 | 20| 4519b | INDIA | 02-DEC-12 00:00:00 | 5090 (12 rows)
Delete the contents of the 2012_americas
partition:
ALTER TABLE sales TRUNCATE SUBPARTITION "americas_2012";
Query the sales
table to show that the contents of the americas_2012
partition were removed:
edb=# SELECT tableoid::regclass, * FROM sales;
Output
tableoid | dept_no| part_no | country | date |amount -------------------+--------+---------+----------+--------------------+------ sales_americas_2011| 30| 7588b | CANADA | 14-DEC-11 00:00:00 |50000 sales_americas_2011| 40| 3788a | US | 12-MAY-11 00:00:00 | 4950 sales_europe_2011 | 10| 4519b | FRANCE | 17-JAN-11 00:00:00 |45000 sales_asia_2011 | 40| 4577b | INDIA | 11-JUN-11 00:00:00 |25000 sales_europe_2012 | 10| 9519b | ITALY | 07-JUL-12 00:00:00 |15000 sales_asia_2012 | 20| 3788a | INDIA | 01-MAR-12 00:00:00 |75000 sales_asia_2012 | 20| 3788a | PAKISTAN | 04-JUN-12 00:00:00 |37500 sales_asia_2012 | 20| 4519b | INDIA | 02-DEC-12 00:00:00 | 5090 (8 rows)
The rows were removed, but the structure of the 2012_americas
partition is intact:
edb=# SELECT subpartition_name, high_value FROM ALL_TAB_SUBPARTITIONS;
Output
subpartition_name | high_value -------------------+--------------------- EUROPE_2011 | 'ITALY', 'FRANCE' ASIA_2011 | 'PAKISTAN', 'INDIA' AMERICAS_2011 | 'US', 'CANADA' EUROPE_2012 | 'ITALY', 'FRANCE' ASIA_2012 | 'PAKISTAN', 'INDIA' AMERICAS_2012 | 'US', 'CANADA' EUROPE_2013 | 'ITALY', 'FRANCE' ASIA_2013 | 'PAKISTAN', 'INDIA' AMERICAS_2013 | 'US', 'CANADA' (9 rows)