范围分区表添加新分区报错upper boundary of adding partition MUST overtop last existing partition
问题现象
创建范围分区表后增加新的分区,使用ALTER TABLE ADD PARTITION语句报错upper boundary of adding partition MUST overtop last existing partition。
1 2 3 4 5 6 7 8 9 10 11 12 13 14 |
——创建范围分区表studentinfo CREATE TABLE studentinfo (stuno smallint, sname varchar(20), score varchar(20), examate timestamp) PARTITION BY RANGE (examate) ( PARTITION p1 VALUES LESS THAN ('2022-10-10 00:00:00+08'), PARTITION p2 VALUES LESS THAN ('2022-10-11 00:00:00+08'), PARTITION p3 VALUES LESS THAN ('2022-10-12 00:00:00+08'), PARTITION p4 VALUES LESS THAN (maxvalue) ); ——添加边界值为2022-10-9 00:00:00+08的分区p0 ALTER TABLE studentinfo ADD PARTITION p0 values less than ('2022-10-9 00:00:00+08'); ERROR: the boundary of partition "p0" is less than previous partition's boundary ——添加边界值为2022-10-13 00:00:00+08的分区p5 ALTER TABLE studentinfo ADD PARTITION p5 values less than ('2022-10-13 00:00:00+08'); ERROR: the boundary of partition "p5" is equal to previous partition's boundary |
原因分析
增加分区时需同时满足以下条件:
- 新增分区名不能与已有分区名相同。
- 新增分区的边界值必须大于最后一个分区的上边界。
- 新增分区的边界值要和分区表的分区键的类型一致。
已有分区p1的边界为(-∞,20221010),而新增分区p0的上边界为20221009,落在分区p1内;已有分区p4的边界为[20221012,+∞),而新增分区p5的上界为20221013,落在分区p4内。新增分区p0、p5不满足使用ADD PARTITION增加分区的条件,因此执行新增分区语句报错。
处理方法
使用ALTER TABLE SPLIT PARTITION分割已有分区,也能达到新增分区的目的。同样, SPLIT PARTITION的新分区名称也不能与已有分区相同。
使用split子句分割p4分区[20221012,+∞)为p4a分区范围为[20221012,20221013)和p4b分区范围为[20221013,+∞)。
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 |
——SPLIT PARTITION分割前的分区 SELECT relname, boundaries FROM pg_partition p where p.parentid='studentinfo'::regclass ORDER BY 1; relname | boundaries -------------+------------------------- p1 | {"2022-10-10 00:00:00"} p2 | {"2022-10-11 00:00:00"} p3 | {"2022-10-12 00:00:00"} p4 | {NULL} studentinfo | (5 rows) ALTER TABLE studentinfo SPLIT PARTITION p1 AT('2022-10-09 00:00:00+08') INTO (PARTITION P1a,PARTITION P1b); ALTER TABLE studentinfo SPLIT PARTITION p4 AT('2022-10-13 00:00:00+08') INTO (PARTITION P4a,PARTITION P4b); ——执行SPLIT PARTITION分割后的分区 SELECT relname, boundaries FROM pg_partition p where p.parentid='studentinfo'::regclass ORDER BY 1; relname | boundaries -------------+------------------------- p1a | {"2022-10-09 00:00:00"} p1b | {"2022-10-10 00:00:00"} p2 | {"2022-10-11 00:00:00"} p3 | {"2022-10-12 00:00:00"} p4a | {"2022-10-13 00:00:00"} p4b | {NULL} studentinfo | (7 rows) |
如果对分区名称有要求,可以在分割后再使用rename partition统一分区名。
ALTER TABLE studentinfo RENAME PARTITION p1a to p0;