Commit d5eec4ee authored by Michael Paquier's avatar Michael Paquier

Add pg_partition_tree to display information about partitions

This new function is useful to display a full tree of partitions with a
partitioned table given in output, and avoids the need of any complex
WITH RECURSIVE query when looking at partition trees which are
deep multiple levels.

It returns a set of records, one for each partition, containing the
partition's name, its immediate parent's name, a boolean value telling
if the relation is a leaf in the tree and an integer telling its level
in the partition tree with given table considered as root, beginning at
zero for the root, and incrementing by one each time the scan goes one
level down.

Author: Amit Langote
Reviewed-by: Jesper Pedersen, Michael Paquier, Robert Haas
Discussion: https://postgr.es/m/8d00e51a-9a51-ad02-d53e-ba6bf50b2e52@lab.ntt.co.jp
parent 56c0484b
...@@ -20216,6 +20216,49 @@ postgres=# SELECT * FROM pg_walfile_name_offset(pg_stop_backup()); ...@@ -20216,6 +20216,49 @@ postgres=# SELECT * FROM pg_walfile_name_offset(pg_stop_backup());
The function returns the number of new collation objects it created. The function returns the number of new collation objects it created.
</para> </para>
<table id="functions-info-partition">
<title>Partitioning Information Functions</title>
<tgroup cols="3">
<thead>
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
</thead>
<tbody>
<row>
<entry><literal><function>pg_partition_tree(<type>regclass</type>)</function></literal></entry>
<entry><type>setof record</type></entry>
<entry>
List information about tables or indexes in a partition tree for a
given partitioned table or partitioned index, with one row for each
partition. Information provided includes the name of the partition,
the name of its immediate parent, a boolean value telling if the
partition is a leaf, and an integer telling its level in the hierarchy.
The value of level begins at <literal>0</literal> for the input table
or index in its role as the root of the partition tree,
<literal>1</literal> for its partitions, <literal>2</literal> for
their partitions, and so on.
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
To check the total size of the data contained in
<structname>measurement</structname> table described in
<xref linkend="ddl-partitioning-declarative-example"/>, one could use the
following query:
</para>
<programlisting>
=# SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
FROM pg_partition_tree('measurement');
total_size
------------
24 kB
(1 row)
</programlisting>
</sect2> </sect2>
<sect2 id="functions-admin-index"> <sect2 id="functions-admin-index">
......
...@@ -20,8 +20,8 @@ OBJS = acl.o amutils.o arrayfuncs.o array_expanded.o array_selfuncs.o \ ...@@ -20,8 +20,8 @@ OBJS = acl.o amutils.o arrayfuncs.o array_expanded.o array_selfuncs.o \
jsonfuncs.o like.o lockfuncs.o mac.o mac8.o misc.o name.o \ jsonfuncs.o like.o lockfuncs.o mac.o mac8.o misc.o name.o \
network.o network_gist.o network_selfuncs.o network_spgist.o \ network.o network_gist.o network_selfuncs.o network_spgist.o \
numeric.o numutils.o oid.o oracle_compat.o \ numeric.o numutils.o oid.o oracle_compat.o \
orderedsetaggs.o pg_locale.o pg_lsn.o pg_upgrade_support.o \ orderedsetaggs.o partitionfuncs.o pg_locale.o pg_lsn.o \
pgstatfuncs.o \ pg_upgrade_support.o pgstatfuncs.o \
pseudotypes.o quote.o rangetypes.o rangetypes_gist.o \ pseudotypes.o quote.o rangetypes.o rangetypes_gist.o \
rangetypes_selfuncs.o rangetypes_spgist.o rangetypes_typanalyze.o \ rangetypes_selfuncs.o rangetypes_spgist.o rangetypes_typanalyze.o \
regexp.o regproc.o ri_triggers.o rowtypes.o ruleutils.o \ regexp.o regproc.o ri_triggers.o rowtypes.o ruleutils.o \
......
/*-------------------------------------------------------------------------
*
* partitionfuncs.c
* Functions for accessing partition-related metadata
*
* Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* src/backend/utils/adt/partitionfuncs.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "access/htup_details.h"
#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_type.h"
#include "funcapi.h"
#include "utils/fmgrprotos.h"
#include "utils/lsyscache.h"
/*
* pg_partition_tree
*
* Produce a view with one row per member of a partition tree, beginning
* from the top-most parent given by the caller. This gives information
* about each partition, its immediate partitioned parent, if it is
* a leaf partition and its level in the hierarchy.
*/
Datum
pg_partition_tree(PG_FUNCTION_ARGS)
{
#define PG_PARTITION_TREE_COLS 4
Oid rootrelid = PG_GETARG_OID(0);
char relkind = get_rel_relkind(rootrelid);
FuncCallContext *funcctx;
ListCell **next;
/* Only allow relation types that can appear in partition trees. */
if (relkind != RELKIND_RELATION &&
relkind != RELKIND_FOREIGN_TABLE &&
relkind != RELKIND_INDEX &&
relkind != RELKIND_PARTITIONED_TABLE &&
relkind != RELKIND_PARTITIONED_INDEX)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is not a table, a foreign table, or an index",
get_rel_name(rootrelid))));
/* stuff done only on the first call of the function */
if (SRF_IS_FIRSTCALL())
{
MemoryContext oldcxt;
TupleDesc tupdesc;
List *partitions;
/* create a function context for cross-call persistence */
funcctx = SRF_FIRSTCALL_INIT();
/* switch to memory context appropriate for multiple function calls */
oldcxt = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx);
/*
* Find all members of inheritance set. We only need AccessShareLock
* on the children for the partition information lookup.
*/
partitions = find_all_inheritors(rootrelid, AccessShareLock, NULL);
tupdesc = CreateTemplateTupleDesc(PG_PARTITION_TREE_COLS, false);
TupleDescInitEntry(tupdesc, (AttrNumber) 1, "relid",
REGCLASSOID, -1, 0);
TupleDescInitEntry(tupdesc, (AttrNumber) 2, "parentid",
REGCLASSOID, -1, 0);
TupleDescInitEntry(tupdesc, (AttrNumber) 3, "isleaf",
BOOLOID, -1, 0);
TupleDescInitEntry(tupdesc, (AttrNumber) 4, "level",
INT4OID, -1, 0);
funcctx->tuple_desc = BlessTupleDesc(tupdesc);
/* allocate memory for user context */
next = (ListCell **) palloc(sizeof(ListCell *));
*next = list_head(partitions);
funcctx->user_fctx = (void *) next;
MemoryContextSwitchTo(oldcxt);
}
/* stuff done on every call of the function */
funcctx = SRF_PERCALL_SETUP();
next = (ListCell **) funcctx->user_fctx;
if (*next != NULL)
{
Datum result;
Datum values[PG_PARTITION_TREE_COLS];
bool nulls[PG_PARTITION_TREE_COLS];
HeapTuple tuple;
Oid parentid = InvalidOid;
Oid relid = lfirst_oid(*next);
char relkind = get_rel_relkind(relid);
int level = 0;
List *ancestors = get_partition_ancestors(lfirst_oid(*next));
ListCell *lc;
/*
* Form tuple with appropriate data.
*/
MemSet(nulls, 0, sizeof(nulls));
MemSet(values, 0, sizeof(values));
/* relid */
values[0] = ObjectIdGetDatum(relid);
/* parentid */
if (ancestors != NIL)
parentid = linitial_oid(ancestors);
if (OidIsValid(parentid))
values[1] = ObjectIdGetDatum(parentid);
else
nulls[1] = true;
/* isleaf */
values[2] = BoolGetDatum(relkind != RELKIND_PARTITIONED_TABLE &&
relkind != RELKIND_PARTITIONED_INDEX);
/* level */
if (relid != rootrelid)
{
foreach(lc, ancestors)
{
level++;
if (lfirst_oid(lc) == rootrelid)
break;
}
}
values[3] = Int32GetDatum(level);
*next = lnext(*next);
tuple = heap_form_tuple(funcctx->tuple_desc, values, nulls);
result = HeapTupleGetDatum(tuple);
SRF_RETURN_NEXT(funcctx, result);
}
/* done when there are no more elements left */
SRF_RETURN_DONE(funcctx);
}
...@@ -53,6 +53,6 @@ ...@@ -53,6 +53,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 201810251 #define CATALOG_VERSION_NO 201810301
#endif #endif
...@@ -10029,4 +10029,13 @@ ...@@ -10029,4 +10029,13 @@
proisstrict => 'f', prorettype => 'bool', proargtypes => 'oid int4 int4 any', proisstrict => 'f', prorettype => 'bool', proargtypes => 'oid int4 int4 any',
proargmodes => '{i,i,i,v}', prosrc => 'satisfies_hash_partition' }, proargmodes => '{i,i,i,v}', prosrc => 'satisfies_hash_partition' },
# information about a partition tree
{ oid => '3423', descr => 'view partition tree tables',
proname => 'pg_partition_tree', prorows => '1000', proretset => 't',
provolatile => 'v', prorettype => 'record', proargtypes => 'regclass',
proallargtypes => '{regclass,regclass,regclass,bool,int4}',
proargmodes => '{i,o,o,o,o}',
proargnames => '{rootrelid,relid,parentrelid,isleaf,level}',
prosrc => 'pg_partition_tree' }
] ]
--
-- Tests for pg_partition_tree
--
SELECT * FROM pg_partition_tree(NULL);
relid | parentrelid | isleaf | level
-------+-------------+--------+-------
(0 rows)
-- Test table partition trees
CREATE TABLE ptif_test (a int, b int) PARTITION BY range (a);
CREATE TABLE ptif_test0 PARTITION OF ptif_test
FOR VALUES FROM (minvalue) TO (0) PARTITION BY list (b);
CREATE TABLE ptif_test01 PARTITION OF ptif_test0 FOR VALUES IN (1);
CREATE TABLE ptif_test1 PARTITION OF ptif_test
FOR VALUES FROM (0) TO (100) PARTITION BY list (b);
CREATE TABLE ptif_test11 PARTITION OF ptif_test1 FOR VALUES IN (1);
CREATE TABLE ptif_test2 PARTITION OF ptif_test
FOR VALUES FROM (100) TO (maxvalue);
-- Test index partition tree
CREATE INDEX ptif_test_index ON ONLY ptif_test (a);
CREATE INDEX ptif_test0_index ON ONLY ptif_test0 (a);
ALTER INDEX ptif_test_index ATTACH PARTITION ptif_test0_index;
CREATE INDEX ptif_test01_index ON ptif_test01 (a);
ALTER INDEX ptif_test0_index ATTACH PARTITION ptif_test01_index;
CREATE INDEX ptif_test1_index ON ONLY ptif_test1 (a);
ALTER INDEX ptif_test_index ATTACH PARTITION ptif_test1_index;
CREATE INDEX ptif_test11_index ON ptif_test11 (a);
ALTER INDEX ptif_test1_index ATTACH PARTITION ptif_test11_index;
CREATE INDEX ptif_test2_index ON ptif_test2 (a);
ALTER INDEX ptif_test_index ATTACH PARTITION ptif_test2_index;
-- List all tables members of the tree
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test');
relid | parentrelid | level | isleaf
-------------+-------------+-------+--------
ptif_test | | 0 | f
ptif_test0 | ptif_test | 1 | f
ptif_test1 | ptif_test | 1 | f
ptif_test2 | ptif_test | 1 | t
ptif_test01 | ptif_test0 | 2 | t
ptif_test11 | ptif_test1 | 2 | t
(6 rows)
-- List tables from an intermediate level
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test0') p
JOIN pg_class c ON (p.relid = c.oid);
relid | parentrelid | level | isleaf
-------------+-------------+-------+--------
ptif_test0 | ptif_test | 0 | f
ptif_test01 | ptif_test0 | 1 | t
(2 rows)
-- List from leaf table
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test01') p
JOIN pg_class c ON (p.relid = c.oid);
relid | parentrelid | level | isleaf
-------------+-------------+-------+--------
ptif_test01 | ptif_test0 | 0 | t
(1 row)
-- List all indexes members of the tree
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test_index');
relid | parentrelid | level | isleaf
-------------------+------------------+-------+--------
ptif_test_index | | 0 | f
ptif_test0_index | ptif_test_index | 1 | f
ptif_test1_index | ptif_test_index | 1 | f
ptif_test2_index | ptif_test_index | 1 | t
ptif_test01_index | ptif_test0_index | 2 | t
ptif_test11_index | ptif_test1_index | 2 | t
(6 rows)
-- List indexes from an intermediate level
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test0_index') p
JOIN pg_class c ON (p.relid = c.oid);
relid | parentrelid | level | isleaf
-------------------+------------------+-------+--------
ptif_test0_index | ptif_test_index | 0 | f
ptif_test01_index | ptif_test0_index | 1 | t
(2 rows)
-- List from leaf index
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test01_index') p
JOIN pg_class c ON (p.relid = c.oid);
relid | parentrelid | level | isleaf
-------------------+------------------+-------+--------
ptif_test01_index | ptif_test0_index | 0 | t
(1 row)
DROP TABLE ptif_test;
-- A table not part of a partition tree works is the only member listed.
CREATE TABLE ptif_normal_table(a int);
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_normal_table');
relid | parentrelid | level | isleaf
-------------------+-------------+-------+--------
ptif_normal_table | | 0 | t
(1 row)
DROP TABLE ptif_normal_table;
-- Views and materialized viewS cannot be part of a partition tree.
CREATE VIEW ptif_test_view AS SELECT 1;
CREATE MATERIALIZED VIEW ptif_test_matview AS SELECT 1;
SELECT * FROM pg_partition_tree('ptif_test_view');
ERROR: "ptif_test_view" is not a table, a foreign table, or an index
SELECT * FROM pg_partition_tree('ptif_test_matview');
ERROR: "ptif_test_matview" is not a table, a foreign table, or an index
DROP VIEW ptif_test_view;
DROP MATERIALIZED VIEW ptif_test_matview;
...@@ -116,7 +116,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare without_oid c ...@@ -116,7 +116,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare without_oid c
# ---------- # ----------
# Another group of parallel tests # Another group of parallel tests
# ---------- # ----------
test: identity partition_join partition_prune reloptions hash_part indexing partition_aggregate test: identity partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info
# event triggers cannot run concurrently with any test that runs DDL # event triggers cannot run concurrently with any test that runs DDL
test: event_trigger test: event_trigger
......
...@@ -185,6 +185,7 @@ test: reloptions ...@@ -185,6 +185,7 @@ test: reloptions
test: hash_part test: hash_part
test: indexing test: indexing
test: partition_aggregate test: partition_aggregate
test: partition_info
test: event_trigger test: event_trigger
test: fast_default test: fast_default
test: stats test: stats
--
-- Tests for pg_partition_tree
--
SELECT * FROM pg_partition_tree(NULL);
-- Test table partition trees
CREATE TABLE ptif_test (a int, b int) PARTITION BY range (a);
CREATE TABLE ptif_test0 PARTITION OF ptif_test
FOR VALUES FROM (minvalue) TO (0) PARTITION BY list (b);
CREATE TABLE ptif_test01 PARTITION OF ptif_test0 FOR VALUES IN (1);
CREATE TABLE ptif_test1 PARTITION OF ptif_test
FOR VALUES FROM (0) TO (100) PARTITION BY list (b);
CREATE TABLE ptif_test11 PARTITION OF ptif_test1 FOR VALUES IN (1);
CREATE TABLE ptif_test2 PARTITION OF ptif_test
FOR VALUES FROM (100) TO (maxvalue);
-- Test index partition tree
CREATE INDEX ptif_test_index ON ONLY ptif_test (a);
CREATE INDEX ptif_test0_index ON ONLY ptif_test0 (a);
ALTER INDEX ptif_test_index ATTACH PARTITION ptif_test0_index;
CREATE INDEX ptif_test01_index ON ptif_test01 (a);
ALTER INDEX ptif_test0_index ATTACH PARTITION ptif_test01_index;
CREATE INDEX ptif_test1_index ON ONLY ptif_test1 (a);
ALTER INDEX ptif_test_index ATTACH PARTITION ptif_test1_index;
CREATE INDEX ptif_test11_index ON ptif_test11 (a);
ALTER INDEX ptif_test1_index ATTACH PARTITION ptif_test11_index;
CREATE INDEX ptif_test2_index ON ptif_test2 (a);
ALTER INDEX ptif_test_index ATTACH PARTITION ptif_test2_index;
-- List all tables members of the tree
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test');
-- List tables from an intermediate level
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test0') p
JOIN pg_class c ON (p.relid = c.oid);
-- List from leaf table
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test01') p
JOIN pg_class c ON (p.relid = c.oid);
-- List all indexes members of the tree
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test_index');
-- List indexes from an intermediate level
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test0_index') p
JOIN pg_class c ON (p.relid = c.oid);
-- List from leaf index
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_test01_index') p
JOIN pg_class c ON (p.relid = c.oid);
DROP TABLE ptif_test;
-- A table not part of a partition tree works is the only member listed.
CREATE TABLE ptif_normal_table(a int);
SELECT relid, parentrelid, level, isleaf
FROM pg_partition_tree('ptif_normal_table');
DROP TABLE ptif_normal_table;
-- Views and materialized viewS cannot be part of a partition tree.
CREATE VIEW ptif_test_view AS SELECT 1;
CREATE MATERIALIZED VIEW ptif_test_matview AS SELECT 1;
SELECT * FROM pg_partition_tree('ptif_test_view');
SELECT * FROM pg_partition_tree('ptif_test_matview');
DROP VIEW ptif_test_view;
DROP MATERIALIZED VIEW ptif_test_matview;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment