PostgreSQL 10 版本已支持分区表,但不支持分区表根据分区键UPDATE记录,PostgreSQL 11 版本这方面得到增加,当分区表的分区键字段被UPDATE后,会自动将该记录转移至新的分区中。
官网Release说明如下:
UPDATE statements that change a partition key now move affected rows to the appropriate partitions
本文以UPDATE列表分区表分区键为例进行演示。
测试环境准备
创建列表分区表并插入测试数据,为演示做准备。
创建父表
1 | CREATE TABLE cities ( |
创建子表
1 | CREATE TABLE cities_a PARTITION OF cities ( CONSTRAINT city_id_nonzero CHECK (city_id != 0)) FOR VALUES IN ('a'); |
插入测试数据
1 | INSERT INTO cities(city_id,name,population) VALUES (1,'a_city','100000'); |
PostgreSQL 10 测试
PostgreSQL 10 版本UPDATE分区键报错,如下:1
2
3
4
5
6
7
8
9
10mydb=> SELECT version();
version
---------------------------------------------------------------------------------------------------------
PostgreSQL 10.0 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-11), 64-bit
(1 row)
mydb=> UPDATE cities SET name='ca_city' WHERE city_id=1;
ERROR: new row for relation "cities_a" violates partition constraint
DETAIL: Failing row contains (1, ca_city, 100000).
PostgreSQL 11 测试
PostgreSQL 11 版本支持更新分区键,如下:1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16francs=> SELECT version();
version
------------------------------------------------------------------------------------------------------------
PostgreSQL 11beta3 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-11), 64-bit
(1 row)
francs=> UPDATE cities SET name='ca_city' WHERE city_id=1;
UPDATE 1
francs=> SELECT * FROM cities;
city_id | name | population
---------+---------+------------
2 | b_city | 200000
3 | c_city | 300000
1 | ca_city | 100000
(3 rows)
查看cities_c分区,发现city_id为1的记录已转移到此分区,如下:1
2
3
4
5
6francs=> SELECT * from cities_c;
city_id | name | population
---------+---------+------------
3 | c_city | 300000
1 | ca_city | 100000
(2 rows)