创建和管理分区表
背景信息
GaussDB数据库支持的分区表为范围分区表。
范围分区表:将数据基于范围映射到每一个分区,这个范围是由创建分区表时指定的分区键决定的。这种分区方式是最为常用的,并且分区键经常采用日期,例如将销售数据按照月份进行分区。
分区表和普通表相比具有以下优点:
- 改善查询性能:对分区对象的查询可以仅搜索自己关心的分区,提高检索效率。
- 增强可用性:如果分区表的某个分区出现故障,表在其他分区的数据仍然可用。
- 方便维护:如果分区表的某个分区出现故障,需要修复数据,只修复该分区即可。
普通表若要转成分区表,需要新建分区表,然后把普通表中的数据导入到新建的分区表中。因此在初始设计表时,请根据业务提前规划是否使用分区表。
操作步骤
- 创建分区表(假设用户已创建tpcds schema)
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29
openGauss=# CREATE TABLE tpcds.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) , ca_city character varying(60) , ca_county character varying(30) , ca_state character(2) , ca_zip character(10) , ca_country character varying(20) , ca_gmt_offset numeric(5,2) , ca_location_type character(20) ) DISTRIBUTE BY HASH (ca_address_sk) PARTITION BY RANGE (ca_address_sk) ( PARTITION P1 VALUES LESS THAN(5000), PARTITION P2 VALUES LESS THAN(10000), PARTITION P3 VALUES LESS THAN(15000), PARTITION P4 VALUES LESS THAN(20000), PARTITION P5 VALUES LESS THAN(25000), PARTITION P6 VALUES LESS THAN(30000), PARTITION P7 VALUES LESS THAN(40000), PARTITION P8 VALUES LESS THAN(MAXVALUE) ) ENABLE ROW MOVEMENT;
当结果显示为如下信息,则表示创建成功。
1
CREATE TABLE
- 插入数据
将表tpcds.customer_address的数据插入到表tpcds.web_returns_p2中。
例如在数据库中创建了一个表tpcds.customer_address的备份表tpcds.web_returns_p2,现在需要将表tpcds.customer_address中的数据插入到表tpcds.web_returns_p2中,则可以执行如下命令。1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32
openGauss=# CREATE TABLE tpcds.web_returns_p2 ( 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) , ca_city character varying(60) , ca_county character varying(30) , ca_state character(2) , ca_zip character(10) , ca_country character varying(20) , ca_gmt_offset numeric(5,2) , ca_location_type character(20) ) DISTRIBUTE BY HASH (ca_address_sk) PARTITION BY RANGE (ca_address_sk) ( PARTITION P1 VALUES LESS THAN(5000), PARTITION P2 VALUES LESS THAN(10000), PARTITION P3 VALUES LESS THAN(15000), PARTITION P4 VALUES LESS THAN(20000), PARTITION P5 VALUES LESS THAN(25000), PARTITION P6 VALUES LESS THAN(30000), PARTITION P7 VALUES LESS THAN(40000), PARTITION P8 VALUES LESS THAN(MAXVALUE) ) ENABLE ROW MOVEMENT; CREATE TABLE openGauss=# INSERT INTO tpcds.web_returns_p2 SELECT * FROM tpcds.customer_address; INSERT 0 0
- 修改分区表行迁移属性
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 DISABLE ROW MOVEMENT; ALTER TABLE
- 删除分区
- 增加分区
增加分区P8,范围为 40000<= P8<=MAXVALUE。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 ADD PARTITION P8 VALUES LESS THAN (MAXVALUE); ALTER TABLE
- 重命名分区
- 重命名分区P8为P_9。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION P8 TO P_9; ALTER TABLE
- 重命名分区P_9为P8。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION FOR (40000) TO P8; ALTER TABLE
- 重命名分区P8为P_9。
- 查询分区
- 删除分区表和表空间
1 2 3 4
openGauss=# DROP TABLE tpcds.customer_address; DROP TABLE openGauss=# DROP TABLE tpcds.web_returns_p2; DROP TABLE
示例二:使用用户自定义表空间
- 创建表空间
1 2 3 4
openGauss=# CREATE TABLESPACE example1 RELATIVE LOCATION 'tablespace1/tablespace_1'; openGauss=# CREATE TABLESPACE example2 RELATIVE LOCATION 'tablespace2/tablespace_2'; openGauss=# CREATE TABLESPACE example3 RELATIVE LOCATION 'tablespace3/tablespace_3'; openGauss=# CREATE TABLESPACE example4 RELATIVE LOCATION 'tablespace4/tablespace_4';
当结果显示为如下信息,则表示创建成功。
1
CREATE TABLESPACE
- 创建分区表
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30
openGauss=# CREATE TABLE tpcds.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) , ca_city character varying(60) , ca_county character varying(30) , ca_state character(2) , ca_zip character(10) , ca_country character varying(20) , ca_gmt_offset numeric(5,2) , ca_location_type character(20) ) TABLESPACE example1 DISTRIBUTE BY HASH (ca_address_sk) PARTITION BY RANGE (ca_address_sk) ( PARTITION P1 VALUES LESS THAN(5000), PARTITION P2 VALUES LESS THAN(10000), PARTITION P3 VALUES LESS THAN(15000), PARTITION P4 VALUES LESS THAN(20000), PARTITION P5 VALUES LESS THAN(25000), PARTITION P6 VALUES LESS THAN(30000), PARTITION P7 VALUES LESS THAN(40000), PARTITION P8 VALUES LESS THAN(MAXVALUE) TABLESPACE example2 ) ENABLE ROW MOVEMENT;
当结果显示为如下信息,则表示创建成功。
1
CREATE TABLE
- 插入数据
将表tpcds.customer_address的数据插入到表tpcds.web_returns_p2中。
例如在数据库中创建了一个表tpcds.customer_address的备份表tpcds.web_returns_p2,现在需要将表tpcds.customer_address中的数据插入到表tpcds.web_returns_p2中,则可以执行如下命令。1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33
openGauss=# CREATE TABLE tpcds.web_returns_p2 ( 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) , ca_city character varying(60) , ca_county character varying(30) , ca_state character(2) , ca_zip character(10) , ca_country character varying(20) , ca_gmt_offset numeric(5,2) , ca_location_type character(20) ) TABLESPACE example1 DISTRIBUTE BY HASH (ca_address_sk) PARTITION BY RANGE (ca_address_sk) ( PARTITION P1 VALUES LESS THAN(5000), PARTITION P2 VALUES LESS THAN(10000), PARTITION P3 VALUES LESS THAN(15000), PARTITION P4 VALUES LESS THAN(20000), PARTITION P5 VALUES LESS THAN(25000), PARTITION P6 VALUES LESS THAN(30000), PARTITION P7 VALUES LESS THAN(40000), PARTITION P8 VALUES LESS THAN(MAXVALUE) TABLESPACE example2 ) ENABLE ROW MOVEMENT; CREATE TABLE openGauss=# INSERT INTO tpcds.web_returns_p2 SELECT * FROM tpcds.customer_address; INSERT 0 0
- 修改分区表行迁移属性
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 DISABLE ROW MOVEMENT; ALTER TABLE
- 删除分区
- 增加分区
增加分区P8,范围为 40000<= P8<=MAXVALUE。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 ADD PARTITION P8 VALUES LESS THAN (MAXVALUE); ALTER TABLE
- 重命名分区
- 重命名分区P8为P_9。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION P8 TO P_9; ALTER TABLE
- 重命名分区P_9为P8。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 RENAME PARTITION FOR (40000) TO P8; ALTER TABLE
- 重命名分区P8为P_9。
- 修改分区的表空间
- 修改分区P6的表空间为example3。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 MOVE PARTITION P6 TABLESPACE example3; ALTER TABLE
- 修改分区P4的表空间为example4。
1 2
openGauss=# ALTER TABLE tpcds.web_returns_p2 MOVE PARTITION P4 TABLESPACE example4; ALTER TABLE
- 修改分区P6的表空间为example3。
- 查询分区
- 删除分区表和表空间
1 2 3 4 5 6 7 8 9
openGauss=# DROP TABLE tpcds.customer_address; DROP TABLE openGauss=# DROP TABLE tpcds.web_returns_p2; DROP TABLE openGauss=# DROP TABLESPACE example1; openGauss=# DROP TABLESPACE example2; openGauss=# DROP TABLESPACE example3; openGauss=# DROP TABLESPACE example4; DROP TABLESPACE