更新时间:2024-11-12 GMT+08:00
二级分区
二级分区(Sub Partition,也叫组合分区)是基本数据分区类型的组合,将表通过一种数据分布方法进行分区,然后使用第二种数据分布方式将每个分区进一步细分为子分区。给定分区的所有子分区表示数据的逻辑子集。常见的二级分区组合如下所示:
- Range-Range
- Range-List
- Range-Hash
- List-Range
- List-List
- List-Hash
- Hash-Range
- Hash-List
- Hash-Hash
示例如下:
gaussdb=# --Range-Range CREATE TABLE t_range_range ( c1 INT, c2 INT, c3 INT ) PARTITION BY RANGE (c1) SUBPARTITION BY RANGE (c2) ( PARTITION p1 VALUES LESS THAN (10) ( SUBPARTITION p1sp1 VALUES LESS THAN (5), SUBPARTITION p1sp2 VALUES LESS THAN (10) ), PARTITION p2 VALUES LESS THAN (20) ( SUBPARTITION p2sp1 VALUES LESS THAN (15), SUBPARTITION p2sp2 VALUES LESS THAN (20) ) ); DROP TABLE t_range_range; --Range-List CREATE TABLE t_range_list ( c1 INT, c2 INT, c3 INT ) PARTITION BY RANGE (c1) SUBPARTITION BY LIST (c2) ( PARTITION p1 VALUES LESS THAN (10) ( SUBPARTITION p1sp1 VALUES (1, 2), SUBPARTITION p1sp2 VALUES (3, 4) ), PARTITION p2 VALUES LESS THAN (20) ( SUBPARTITION p2sp1 VALUES (1, 2), SUBPARTITION p2sp2 VALUES (3, 4) ) ); DROP TABLE t_range_list; --Range-Hash CREATE TABLE t_range_hash ( c1 INT, c2 INT, c3 INT ) PARTITION BY RANGE (c1) SUBPARTITION BY HASH (c2) SUBPARTITIONS 2 ( PARTITION p1 VALUES LESS THAN (10), PARTITION p2 VALUES LESS THAN (20) ); DROP TABLE t_range_hash; --List-Range CREATE TABLE t_list_range ( c1 INT, c2 INT, c3 INT ) PARTITION BY LIST (c1) SUBPARTITION BY RANGE (c2) ( PARTITION p1 VALUES (1, 2) ( SUBPARTITION p1sp1 VALUES LESS THAN (5), SUBPARTITION p1sp2 VALUES LESS THAN (10) ), PARTITION p2 VALUES (3, 4) ( SUBPARTITION p2sp1 VALUES LESS THAN (5), SUBPARTITION p2sp2 VALUES LESS THAN (10) ) ); DROP TABLE t_list_range; --List-List CREATE TABLE t_list_list ( c1 INT, c2 INT, c3 INT ) PARTITION BY LIST (c1) SUBPARTITION BY LIST (c2) ( PARTITION p1 VALUES (1, 2) ( SUBPARTITION p1sp1 VALUES (1, 2), SUBPARTITION p1sp2 VALUES (3, 4) ), PARTITION p2 VALUES (3, 4) ( SUBPARTITION p2sp1 VALUES (1, 2), SUBPARTITION p2sp2 VALUES (3, 4) ) ); DROP TABLE t_list_list; --List-Hash CREATE TABLE t_list_hash ( c1 INT, c2 INT, c3 INT ) PARTITION BY LIST (c1) SUBPARTITION BY HASH (c2) SUBPARTITIONS 2 ( PARTITION p1 VALUES (1, 2), PARTITION p2 VALUES (3, 4) ); DROP TABLE t_list_hash; --Hash-Range CREATE TABLE t_hash_range ( c1 INT, c2 INT, c3 INT ) PARTITION BY HASH (c1) PARTITIONS 2 SUBPARTITION BY RANGE (c2) ( PARTITION p1 ( SUBPARTITION p1sp1 VALUES LESS THAN (5), SUBPARTITION p1sp2 VALUES LESS THAN (10) ), PARTITION p2 ( SUBPARTITION p2sp1 VALUES LESS THAN (5), SUBPARTITION p2sp2 VALUES LESS THAN (10) ) ); DROP TABLE t_hash_range; --Hash-List CREATE TABLE t_hash_list ( c1 INT, c2 INT, c3 INT ) PARTITION BY HASH (c1) PARTITIONS 2 SUBPARTITION BY LIST (c2) ( PARTITION p1 ( SUBPARTITION p1sp1 VALUES (1, 2), SUBPARTITION p1sp2 VALUES (3, 4) ), PARTITION p2 ( SUBPARTITION p2sp1 VALUES (1, 2), SUBPARTITION p2sp2 VALUES (3, 4) ) ); DROP TABLE t_hash_list; --Hash-Hash CREATE TABLE t_hash_hash ( c1 INT, c2 INT, c3 INT ) PARTITION BY HASH (c1) PARTITIONS 2 SUBPARTITION BY HASH (c2) SUBPARTITIONS 2 ( PARTITION p1, PARTITION p2 ); DROP TABLE t_hash_hash; -- list-list CREATE TABLE list_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY LIST (month_code) SUBPARTITION BY LIST (dept_code, user_no) ( PARTITION p_201901 VALUES ( '201902' ), PARTITION p_201902 VALUES ( '201903' ) ( SUBPARTITION p_201902_a VALUES (('1','120')), SUBPARTITION p_201902_b VALUES (('2','240')) ) ); SELECT * FROM pg_get_tabledef('list_list'); INSERT INTO list_list VALUES('201902', '1', '120', 1); INSERT INTO list_list VALUES('201902', '2', '240', 1); INSERT INTO list_list VALUES('201902', '1', '120', 1); INSERT INTO list_list VALUES('201903', '2', '240', 1); INSERT INTO list_list VALUES('201903', '1', '120', 1); INSERT INTO list_list VALUES('201903', '2', '240', 1); SELECT * FROM list_list ORDER BY month_code; DROP TABLE list_list; -- hash-range CREATE TABLE hash_range ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY hash (month_code) SUBPARTITION BY range (dept_code,user_no) ( PARTITION p_201901, PARTITION p_201902 ( SUBPARTITION p_201902_a VALUES LESS THAN ( '2' ,'2'), SUBPARTITION p_201902_b VALUES LESS THAN ( '3' ,'4') ) ); INSERT INTO hash_range VALUES('201901', '1', '1', 1); INSERT INTO hash_range VALUES('201901', '2', '1', 1); INSERT INTO hash_range VALUES('201901', '1', '1', 1); INSERT INTO hash_range VALUES('201903', '2', '1', 1); INSERT INTO hash_range VALUES('201903', '1', '1', 1); INSERT INTO hash_range VALUES('201903', '2', '1', 1); SELECT * FROM hash_range; DROP TABLE hash_range;
Interval分区看成是范围分区的一种特殊形式,目前不支持二级分区场景中定义Interval分区。
父主题: 分区策略