ALTER TABLE PARTITION modifies table partitioning, including adding, deleting, splitting, merging partitions, and modifying partition attributes.
1 2 | ALTER TABLE [ IF EXISTS ] { table_name [*] | ONLY table_name | ONLY ( table_name )} action [, ... ]; |
1 2 3 4 5 6 7 | exchange_clause | row_clause | merge_clause | modify_clause | split_clause | add_clause | drop_clause |
1 2 3 | EXCHANGE PARTITION { ( partition_name ) | FOR ( partition_value [, ...] ) } WITH TABLE {[ ONLY ] ordinary_table_name | ordinary_table_name * | ONLY ( ordinary_table_name )} [ { WITH | WITHOUT } VALIDATION ] [ VERBOSE ] |
The ordinary table and the partitioned table whose data is to be exchanged must meet the following requirements:
When the execution is complete, the data and tablespace of the ordinary table and the partitioned table are exchanged. In this case, statistics about the ordinary table and the partitioned table become unreliable. Both tables should be analyzed again.
1 | { ENABLE | DISABLE } ROW MOVEMENT |
1 | MERGE PARTITIONS { partition_name } [, ...] INTO PARTITION partition_name |
1 | MODIFY PARTITION partition_name { UNUSABLE LOCAL INDEXES | REBUILD UNUSABLE LOCAL INDEXES } |
The split_clause syntax for range partitioning is as follows:
1 | SPLIT PARTITION { partition_name | FOR ( partition_value [, ...] ) } { split_point_clause | no_split_point_clause } |
1 | AT ( partition_value ) INTO ( PARTITION partition_name , PARTITION partition_name ) |
The size of split point should be in the range of splitting partition key. The split point can only split one partition into two.
1 | INTO { ( partition_less_than_item [, ...] ) | ( partition_start_end_item [, ...] ) } |
1 2 | PARTITION partition_name VALUES LESS THAN ( { partition_value | MAXVALUE } [, ...] ) |
1 2 3 4 5 6 | PARTITION partition_name { {START(partition_value) END (partition_value) EVERY (interval_value)} | {START(partition_value) END ({partition_value | MAXVALUE})} | {START(partition_value)} | {END({partition_value | MAXVALUE})} } |
1 | SPLIT PARTITION { partition_name | FOR ( partition_value [, ...] ) } { split_values_clause | split_no_values_clause } |
1 | VALUES ( { (partition_value) [, ...] } | DEFAULT } ) INTO ( PARTITION partition_name , PARTITION partition_name ) |
1 | INTO ( list_partition_item [, ....], PARTITION partition_name ) |
1 | ADD { partition_less_than_item... | partition_start_end_item } |
The add_clause syntax for list partitioning is as follows:
1 | ADD list_partition_item |
1 | DROP PARTITION { partition_name | FOR ( partition_value [, ...] ) } |
1 | DROP PARTITION { partition_name [, ... ] } |
1 2 | ALTER TABLE [ IF EXISTS ] { table_name [*] | ONLY table_name | ONLY ( table_name )} RENAME PARTITION { partition_name | FOR ( partition_value [, ...] ) } TO partition_new_name; |
Specifies the name of a partitioned table.
Value range: an existing partitioned table name
Specifies the name of a partition.
Value range: an existing partition name
Specifies the key value of a partition.
The value specified by PARTITION FOR ( partition_value [, ...] ) can uniquely identify a partition.
Value range: value range of the partition key for the partition to be renamed
Sets all the indexes unusable in the partition.
Rebuilds all the indexes in the partition.
Specifies the row movement switch.
Valid value:
The switch is disabled by default.
Specifies the name of the ordinary table whose data is to be migrated.
Value range: an existing ordinary table name
Checks whether the ordinary table data meets the specified partition key range of the partition to be migrated.
Valid value:
The default value is WITH.
The check is time consuming, especially when the data volume is large. Therefore, use WITHOUT when you are sure that the current common table data meets the partition key range of the partition to be exchanged.
When VALIDATION is WITH, if the ordinary table contains data that is out of the partition key range, insert the data to the correct partition. If there is no correct partition where the data can be route to, an error is reported.
Only when VALIDATION is WITH, VERBOSE can be specified.
Specifies the new name of a partition.
Value range: a string. It must comply with the naming convention.
Create a range partitioned table customer_address.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | DROP TABLE IF EXISTS customer_address; CREATE TABLE customer_address ( ca_address_sk INTEGER NOT NULL , ca_address_id CHARACTER(16) NOT NULL , ca_street_number CHARACTER(10) , ca_street_name CHARACTER varying(60) , ca_street_type CHARACTER(15) , ca_suite_number CHARACTER(10) ) DISTRIBUTE BY HASH (ca_address_sk) PARTITION BY RANGE(ca_address_sk) ( PARTITION P1 VALUES LESS THAN(100), PARTITION P2 VALUES LESS THAN(200), PARTITION P3 VALUES LESS THAN(300) ); |
Create a list partitioned table.
DROP TABLE IF EXISTS data_list; CREATE TABLE data_list( id int, time int, sarlay decimal(12,2) )PARTITION BY LIST (time)( PARTITION P1 VALUES (202209), PARTITION P2 VALUES (202210,202208), PARTITION P3 VALUES (202211), PARTITION P4 VALUES (202212), PARTITION P5 VALUES (202301) );
Create the local index student_grade_index for the partitioned table customer_address and set partition index names:
1 2 3 4 5 6 | CREATE INDEX customer_address_index ON customer_address(ca_address_id) LOCAL ( PARTITION P1_index, PARTITION P2_index, PARTITION P3_inde ); |
Rebuild all indexes on partition P1 in the partitioned table customer_address:
1 | ALTER TABLE customer_address MODIFY PARTITION P1 REBUILD UNUSABLE LOCAL INDEXES; |
Disable all indexes on partition P3 of the partitioned table customer_address:
1 | ALTER TABLE customer_address MODIFY PARTITION P3 UNUSABLE LOCAL INDEXES; |
Add a partition to the range partitioned table customer_address.
1 | ALTER TABLE customer_address ADD PARTITION P5 VALUES LESS THAN (500); |
Add the following partitions to the range partitioned table customer_address: [500, 600), [600, 700):
1 | ALTER TABLE customer_address ADD PARTITION p6 START(500) END(700) EVERY(100); |
Add the MAXVALUE partition p7 to the range partitioned table customer_address:
1 | ALTER TABLE customer_address ADD PARTITION p7 END(MAXVALUE); |
Add partition P6 to the list partitioned table:
1 | ALTER TABLE data_list ADD PARTITION P6 VALUES (202302,202303); |
Split partition P7 in the range partitioned table customer_address at 800:
1 | ALTER TABLE customer_address SPLIT PARTITION P7 AT(800) INTO (PARTITION P6a,PARTITION P6b); |
Split the partition at 400 in the range partitioned table customer_address into multiple partitions:
1 | ALTER TABLE customer_address SPLIT PARTITION FOR(400) INTO(PARTITION p_part START(300) END(500) EVERY(100)); |
Split partition P2 in the list partitioned table data_list into two partitions: p2a and p2b.
1 | ALTER TABLE data_list SPLIT PARTITION P2 VALUES(202210) INTO (PARTITION p2a,PARTITION p2b); |
The following example demonstrates how to migrate data from table math_grade to partition math in partition table student_grade. Create a partitioned table student_grade.
1 2 3 4 5 6 7 8 9 10 11 12 13 | CREATE TABLE student_grade ( stu_name char(5), stu_no integer, grade integer, subject varchar(30) ) PARTITION BY LIST(subject) ( PARTITION gym VALUES('gymnastics'), PARTITION phys VALUES('physics'), PARTITION history VALUES('history'), PARTITION math VALUES('math') ); |
Add data to the partition table student_grade.
1 2 3 4 5 6 7 | INSERT INTO student_grade VALUES ('Ann', 20220101, 75, 'gymnastics'), ('Jeck', 20220103, 60, 'math'), ('Anna', 20220108, 56, 'history'), ('Jann', 20220107, 82, 'physics'), ('Molly', 20220104, 91, 'physics'), ('Sam', 20220105, 72, 'math'); |
Query the records of partition math in student_grade.
1 2 3 4 5 6 | SELECT * FROM student_grade PARTITION (math); stu_name | stu_no | grade | subject ----------+----------+-------+--------- Jeck | 20220103 | 60 | math Sam | 20220105 | 72 | math (2 rows) |
Create an ordinary table math_grade that matches the definition of the partitioned table student_grade.
1 2 3 4 5 6 7 | CREATE TABLE math_grade ( stu_name char(5), stu_no integer, grade integer, subject varchar(30) ); |
Add data to table math_grade. The data is in line with the partition rule of partition math in the partition table student_grade.
1 2 3 4 5 | INSERT INTO math_grade VALUES ('Ann', 20220101, 75, 'math'), ('Jeck', 20220103, 60, 'math'), ('Anna', 20220108, 56, 'math'), ('Jann', 20220107, 82, 'math'); |
Migrate data from table math_grade to partition math in the partition table student_grade.
1 | ALTER TABLE student_grade EXCHANGE PARTITION (math) WITH TABLE math_grade; |
The query results of table student_grade shows that the data in table math_grade has been exchanged with the data in partition math.
1 2 3 4 5 6 7 8 | SELECT * FROM student_grade PARTITION (math); stu_name | stu_no | grade | subject ----------+----------+-------+--------- Anna | 20220108 | 56 | math Jeck | 20220103 | 60 | math Ann | 20220101 | 75 | math Jann | 20220107 | 82 | math (4 rows) |
The query result of table math_grade shows that the records previously stored in partition math have been moved to table student_grade.
1 2 3 4 5 6 | SELECT * FROM math_grade; stu_name | stu_no | grade | subject ----------+----------+-------+--------- Jeck | 20220103 | 60 | math Sam | 20220105 | 72 | math (2 rows) |
Enable migration for the partitioned table customer_address:
1 | ALTER TABLE customer_address ENABLE ROW MOVEMENT; |
Combine partitions P2 and P3 in the range partitioned table customer_address into one:
1 | ALTER TABLE customer_address MERGE PARTITIONS P2, P3 INTO PARTITION P_M; |
Delete partition P2 from the partitioned table customer_address:
1 | ALTER TABLE customer_address DROP PARTITION P2; |
Delete partitions P6a and P6b from the partition table customer_address:
1 | ALTER TABLE customer_address DROP PARTITION P6a, P6b; |