在PG 12以前的版本,获取分区表中的分区以及子分区等信息需要使用递归CTE查询脚本来获取,不直观而且麻烦,在PG 12中新增了pg_partition_tree和pg_partition_root系统函数分别用于获取分区树和分区的root relation.
下面以一个简单的例子进行说明.
测试脚本
-- Hash Partitiondrop table if exists t_hash1;create table t_hash1 (c1 int not null,c2 varchar(40),c3 varchar(40)) partition by hash(c1);-- Level 1create table t_hash1_1 partition of t_hash1 for values with (modulus 6,remainder 0) partition by hash(c1);create table t_hash1_2 partition of t_hash1 for values with (modulus 6,remainder 1) partition by hash(c1);create table t_hash1_3 partition of t_hash1 for values with (modulus 6,remainder 2);create table t_hash1_4 partition of t_hash1 for values with (modulus 6,remainder 3);create table t_hash1_5 partition of t_hash1 for values with (modulus 6,remainder 4);create table t_hash1_6 partition of t_hash1 for values with (modulus 6,remainder 5);-- Level 2create table t_hash1_1_1 partition of t_hash1_1 for values with (modulus 2,remainder 0);create table t_hash1_1_2 partition of t_hash1_1 for values with (modulus 2,remainder 1);create table t_hash1_2_1 partition of t_hash1_2 for values with (modulus 2,remainder 0);create table t_hash1_2_2 partition of t_hash1_2 for values with (modulus 2,remainder 1);
t_hash1是一张Hash分区表,有6个子分区,其中子分区中的t_hash1_1和t_hash1_2也是分区表,分别有2个分区.
在PG 11中,需要使用CTE递归查询来查询该分区的相关信息:
-- PG11WITH RECURSIVE partition_info (relid, -- oid relname, -- 名称 relsize, -- 大小 relispartition, -- 是否分区表 relkind) AS ( SELECT oid AS relid, relname, pg_relation_size(oid) AS relsize, relispartition, relkind FROM pg_catalog.pg_classWHERE relname = 't_hash1' AND -- 最顶层的分区表 relkind = 'p' UNION ALL SELECT c.oid AS relid, c.relname AS relname, pg_relation_size(c.oid) AS relsize, c.relispartition AS relispartition, c.relkind AS relkind FROM partition_info AS p, pg_catalog.pg_inherits AS i, pg_catalog.pg_class AS c WHERE p.relid = i.inhparent AND -- 从最顶层的分区表(即t_hash1)开始递归 c.oid = i.inhrelid AND -- 寻找子分区 c.relispartition -- 分区表标记 )SELECT * FROM partition_info; relid | relname | relsize | relispartition | relkind -------+-------------+---------+----------------+--------- 57457 | t_hash1 | 0 | f | p 57466 | t_hash1_3 | 0 | t | r 57469 | t_hash1_4 | 0 | t | r 57472 | t_hash1_5 | 0 | t | r 57475 | t_hash1_6 | 0 | t | r 57460 | t_hash1_1 | 0 | t | p 57463 | t_hash1_2 | 0 | t | p 57487 | t_hash1_2_2 | 0 | t | r 57478 | t_hash1_1_1 | 0 | t | r 57481 | t_hash1_1_2 | 0 | t | r 57484 | t_hash1_2_1 | 0 | t | r(11 rows)
而在PG 12中,则可以直接使用系统函数获取相关信息:
testdb=# \sf pg_partition_treeCREATE OR REPLACE FUNCTION pg_catalog.pg_partition_tree(rootrelid regclass, OUT relid regclass, OUT parentrelid regclass, OUT isleaf boolean, OUT level integer) RETURNS SETOF record LANGUAGE internal PARALLEL SAFE STRICTAS $function$pg_partition_tree$function$testdb=# select pg_partition_tree('t_hash1'); pg_partition_tree ----------------------------- (t_hash1,,f,0) (t_hash1_1,t_hash1,f,1) (t_hash1_2,t_hash1,f,1) (t_hash1_3,t_hash1,t,1) (t_hash1_4,t_hash1,t,1) (t_hash1_5,t_hash1,t,1) (t_hash1_6,t_hash1,t,1) (t_hash1_1_1,t_hash1_1,t,2) (t_hash1_1_2,t_hash1_1,t,2) (t_hash1_2_1,t_hash1_2,t,2) (t_hash1_2_2,t_hash1_2,t,2)(11 rows)
返回的信息包括:
relid -> 该分区的relid parentrelid -> 父分区 isleaf —> 是否叶子节点 level —> 层次通过pg_partition_root可以获取分区表的root节点
testdb=# \sf pg_partition_rootCREATE OR REPLACE FUNCTION pg_catalog.pg_partition_root(regclass) RETURNS regclass LANGUAGE internal IMMUTABLE PARALLEL SAFE STRICTAS $function$pg_partition_root$function$testdb=# select pg_partition_root('t_hash1_2_2'); pg_partition_root ------------------- t_hash1(1 row)
参考资料