ALTER TABLE…SPLIT SUBPARTITION命令用於將子分區添加到現有的子分區表中。
文法介紹
使用ALTER TABLE…SPLIT SUBPARTITION命令將一個子分區劃分為兩個子分區,並重新分配子分區的內容。ALTER TABLE…SPLIT SUBPARTITION命令有兩種形式:
ALTER TABLE table_name SPLIT SUBPARTITION subpartition_name
AT (range_part_value)
INTO
(
SUBPARTITION new_subpart1
[TABLESPACE tablespace_name],
SUBPARTITION new_subpart2
[TABLESPACE tablespace_name]
);
ALTER TABLE table_name SPLIT SUBPARTITION subpartition_name
VALUES (value[, value]...)
INTO
(
SUBPARTITION new_subpart1
[TABLESPACE tablespace_name],
SUBPARTITION new_subpart2
[TABLESPACE tablespace_name]
);
描述
ALTER TABLE…SPLIT SUBPARTITION命令用於將子分區添加到現有的子分區表中。對於定義的子分區數量沒有上限要求。當您執行ALTER TABLE…SPLIT SUBPARTITION命令時,PolarDB會建立兩個子分區,把所有包含(由指定子分區規則約束的)值的記錄轉移到new_subpartl中,留下的其他記錄則會轉移到new_subpart2中。
新分區規則必須引用在定義現有子分區的規則中指定的列。
包括TABLESPACE子句指定新的子分區要所屬的資料表空間。如果您沒有指定資料表空間, 那麼子分區將建立於預設資料表空間。
如果對錶進行了索引設定, 那麼索引將建立在新的子分區上。
要使用ALTER TABLE…SPLIT SUBPARTITION命令,您必須是表的擁有者或有超級使用者(或管理員)的許可權。
參數
參數 | 參數說明 |
table name | 分區表名稱(可以採用模式限定的方式引用)。 |
subpartition name | 要劃分的子分區名稱。 |
new subpartl |
要建立的第一個新的子分區名稱。在所有分區和子分區當中,子分區名稱必須是唯一的,且必須遵循給物件識別碼命名的慣例。
|
new subpart2 |
要建立的第二個新的子分區名稱。在所有分區和子分區當中,子分區名稱必須是唯一的,且必須遵循給物件識別碼命名的慣例。
|
(value[, value]...) |
使用 更多關於建立 |
tablespace name | 分區或子分區所屬的資料表空間名稱。 |
劃分LIST子分區樣本
下面樣本劃分了一個列表子分區,並重新分配了兩個新的子分區之間的子分區內容。樣本表(sales)是通過下列命令建立的:
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 first_half_2012 VALUES LESS THAN('01-JUL-2012')
(
SUBPARTITION p1_europe VALUES ('ITALY', 'FRANCE'),
SUBPARTITION p1_americas VALUES ('US', 'CANADA')
),
PARTITION second_half_2012 VALUES LESS THAN('01-JAN-2013')
(
SUBPARTITION p2_europe VALUES ('ITALY', 'FRANCE'),
SUBPARTITION p2_americas VALUES ('US', 'CANADA')
)
);
acctg=# SELECT partition_name, subpartition_name, high_value FROM ALL_TAB_SUBPARTITIONS;
partition_name | subpartition_name | high_value
------------------+-------------------+-------------------
second_half_2012 | p2_europe | 'ITALY', 'FRANCE'
first_half_2012 | p1_europe | 'ITALY', 'FRANCE'
second_half_2012 | p2_americas | 'US', 'CANADA'
first_half_2012 | p1_americas | 'US', 'CANADA'
(4 rows)
INSERT INTO sales VALUES
(10, '4519b', 'FRANCE', '17-Jan-2012', '45000'),
(40, '9519b', 'US', '12-Apr-2012', '145000'),
(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'),
(40, '4788a', 'US', '23-Sept-2012', '4950'),
(40, '4788b', 'US', '09-Oct-2012', '15000');
acctg=# SELECT tableoid::regclass, * FROM sales;
tableoid | dept_no | part_no | country| date |amount
-------------------+---------+---------+--------+--------------------+------
sales_p1_europe | 10 | 4519b | FRANCE | 17-JAN-12 00:00:00 | 45000
sales_p1_americas | 40 | 9519b | US | 12-APR-12 00:00:00 | 145000
sales_p1_americas | 30 | 9519b | CANADA | 01-FEB-12 00:00:00 | 75000
sales_p1_americas | 30 | 4519b | CANADA | 08-APR-12 00:00:00 | 120000
sales_p1_americas | 40 | 3788a | US | 12-MAY-12 00:00:00 | 4950
sales_p2_europe | 10 | 9519b | ITALY | 07-JUL-12 00:00:00 | 15000
sales_p2_europe | 10 | 9519a | FRANCE | 18-AUG-12 00:00:00 | 650000
sales_p2_europe | 10 | 9519b | FRANCE | 18-AUG-12 00:00:00 | 650000
sales_p2_americas | 40 | 4577b | US | 11-NOV-12 00:00:00 | 25000
sales_p2_americas | 30 | 7588b | CANADA | 14-DEC-12 00:00:00 | 50000
sales_p2_americas | 40 | 4788a | US | 23-SEP-12 00:00:00 | 4950
sales_p2_americas | 40 | 4788b | US | 09-OCT-12 00:00:00 | 15000
(12 rows)
ALTER TABLE sales SPLIT SUBPARTITION p2_americas
VALUES ('US')
INTO
(
SUBPARTITION p2_us,
SUBPARTITION p2_canada
);
acctg=# SELECT partition_name, subpartition_name, high_value FROM ALL_TAB_SUBPARTITIONS;
partition_name | subpartition_name | high_value
------------------+-------------------+-------------------
first_half_2012 | p1_europe | 'ITALY', 'FRANCE'
first_half_2012 | p1_americas | 'US', 'CANADA'
second_half_2012 | p2_europe | 'ITALY', 'FRANCE'
second_half_2012 | p2_canada | 'CANADA'
second_half_2012 | p2_us | 'US'
(5 rows)
acctg=# SELECT tableoid::regclass, * FROM sales;
tableoid | dept_no | part_no | country | date |amount
-------------------+---------+---------+---------+--------------------+------
sales_p1_europe | 10 | 4519b | FRANCE | 17-JAN-12 00:00:00 | 45000
sales_p1_americas | 40 | 9519b | US | 12-APR-12 00:00:00 |145000
sales_p1_americas | 30 | 9519b | CANADA | 01-FEB-12 00:00:00 | 75000
sales_p1_americas | 30 | 4519b | CANADA | 08-APR-12 00:00:00 |120000
sales_p1_americas | 40 | 3788a | US | 12-MAY-12 00:00:00 | 4950
sales_p2_europe | 10 | 9519b | ITALY | 07-JUL-12 00:00:00 | 15000
sales_p2_europe | 10 | 9519a | FRANCE | 18-AUG-12 00:00:00 |650000
sales_p2_europe | 10 | 9519b | FRANCE | 18-AUG-12 00:00:00 |650000
sales_p2_us | 40 | 4577b | US | 11-NOV-12 00:00:00 | 25000
sales_p2_us | 40 | 4788a | US | 23-SEP-12 00:00:00 | 4950
sales_p2_us | 40 | 4788b | US | 09-OCT-12 00:00:00 | 15000
sales_p2_canada | 30 | 7588b | CANADA | 14-DEC-12 00:00:00 | 50000
(12 rows)
劃分 RANGE 子分區樣本
CREATE TABLE sales
(
dept_no number,
part_no varchar2,
country varchar2(20),
date date,
amount number
)
PARTITION BY LIST(country)
SUBPARTITION BY RANGE(date)
(
PARTITION europe VALUES('FRANCE', 'ITALY')
(
SUBPARTITION europe_2011
VALUES LESS THAN('2012-Jan-01'),
SUBPARTITION europe_2012
VALUES LESS THAN('2013-Jan-01')
),
PARTITION asia VALUES('INDIA', 'PAKISTAN')
(
SUBPARTITION asia_2011
VALUES LESS THAN('2012-Jan-01'),
SUBPARTITION asia_2012
VALUES LESS THAN('2013-Jan-01')
),
PARTITION americas VALUES('US', 'CANADA')
(
SUBPARTITION americas_2011
VALUES LESS THAN('2012-Jan-01'),
SUBPARTITION americas_2012
VALUES LESS THAN('2013-Jan-01')
)
);
acctg=# SELECT partition_name, subpartition_name, high_value FROM ALL_TAB_SUBPARTITIONS;
partition_name | subpartition_name | high_value
----------------+-------------------+---------------
europe | europe_2011 | '2012-Jan-01'
europe | europe_2012 | '2013-Jan-01'
asia | asia_2011 | '2012-Jan-01'
asia | asia_2012 | '2013-Jan-01'
americas | americas_2011 | '2012-Jan-01'
americas | americas_2012 | '2013-Jan-01'
(6 rows)
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');
acctg=# SELECT tableoid::regclass, * FROM sales;
tableoid | dept_no|part_no| country | date |amount
---------------------+--------+-------+---------+--------------------+---
sales_europe_2012 | 10| 4519b | FRANCE | 17-JAN-12 00:00:00 | 45000
sales_europe_2012 | 10| 9519b | ITALY | 07-JUL-12 00:00:00 | 15000
sales_europe_2012 | 10| 9519a | FRANCE | 18-AUG-12 00:00:00 | 650000
sales_europe_2012 | 10| 9519b | FRANCE | 18-AUG-12 00:00:00 | 650000
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| 3788b | INDIA | 21-SEP-12 00:00:00 | 5090
sales_asia_2012 | 20| 4519a | INDIA | 18-OCT-12 00:00:00 | 650000
sales_asia_2012 | 20| 4519b | INDIA | 02-DEC-12 00:00:00 | 5090
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| 7588b | CANADA | 14-DEC-12 00:00:00 | 50000
sales_americas_2012 | 30| 9519b | CANADA | 01-FEB-12 00:00:00 | 75000
sales_americas_2012 | 30| 4519b | CANADA | 08-APR-12 00:00:00 | 120000
sales_americas_2012 | 40| 3788a | US | 12-MAY-12 00:00:00 | 4950
sales_americas_2012 | 40| 4788a | US | 23-SEP-12 00:00:00 | 4950
sales_americas_2012 | 40| 4788b | US | 09-OCT-12 00:00:00 | 15000
(17 rows)
ALTER TABLE sales
SPLIT SUBPARTITION americas_2012
AT('2012-Jun-01')
INTO
(
SUBPARTITION americas_p1_2012,
SUBPARTITION americas_p2_2012
);
acctg=# SELECT partition_name, subpartition_name, high_value FROM ALL_TAB_SUBPARTITIONS;
partition_name | subpartition_name | high_value
----------------+-------------------+---------------
europe | europe_2012 | '2013-Jan-01'
europe | europe_2011 | '2012-Jan-01'
americas | americas_2011 | '2012-Jan-01'
americas | americas_p2_2012 | '2013-Jan-01'
americas | americas_p1_2012 | '2012-Jun-01'
asia | asia_2012 | '2013-Jan-01'
asia | asia_2011 | '2012-Jan-01'
(7 rows)
acctg=# SELECT tableoid::regclass, * FROM sales;
tableoid | dept_no|part_no|country | date |amount
-----------------------+--------+-------+--------+-------------------+------- sales_europe_2012 | 10| 4519b |FRANCE | 17-JAN-12 00:00:00| 45000
sales_europe_2012 | 10| 9519b |ITALY | 07-JUL-12 00:00:00| 15000
sales_europe_2012 | 10| 9519a |FRANCE | 18-AUG-12 00:00:00| 650000
sales_europe_2012 | 10| 9519b |FRANCE | 18-AUG-12 00:00:00| 650000
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| 3788b |INDIA | 21-SEP-12 00:00:00| 5090
sales_asia_2012 | 20| 4519a |INDIA | 18-OCT-12 00:00:00| 650000
sales_asia_2012 | 20| 4519b |INDIA | 02-DEC-12 00:00:00| 5090
sales_americas_p1_2012| 40| 9519b |US | 12-APR-12 00:00:00| 145000
sales_americas_p1_2012| 30| 9519b |CANADA | 01-FEB-12 00:00:00| 75000
sales_americas_p1_2012| 30| 4519b |CANADA | 08-APR-12 00:00:00| 120000
sales_americas_p1_2012| 40| 3788a |US | 12-MAY-12 00:00:00| 4950
sales_americas_p2_2012| 40| 4577b |US | 11-NOV-12 00:00:00| 25000
sales_americas_p2_2012| 30| 7588b |CANADA | 14-DEC-12 00:00:00| 50000
sales_americas_p2_2012| 40| 4788a |US | 23-SEP-12 00:00:00| 4950
sales_americas_p2_2012| 40| 4788b |US | 09-OCT-12 00:00:00| 15000
(17 rows)