psql \dP: list partitioned tables and indexes
The new command lists partitioned relations (tables and/or indexes), possibly with their sizes, possibly including partitioned partitions; their parents (if not top-level); if indexes show the tables they belong to; and their descriptions. While there are various possible improvements to this, having it in this form is already a great improvement over not having any way to obtain this report. Author: Pavel Stěhule, with help from Mathias Brossard, Amit Langote and Justin Pryzby. Reviewed-by: Amit Langote, Mathias Brossard, Melanie Plageman, Michaël Paquier, Álvaro Herrera
This commit is contained in:
parent
159970bcad
commit
1c5d9270e3
@ -1659,6 +1659,39 @@ testdb=>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>\dP[itn+] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Lists partitioned relations.
|
||||
If <replaceable class="parameter">pattern</replaceable>
|
||||
is specified, only entries whose name matches the pattern are listed.
|
||||
The modifiers <literal>t</literal> (tables) and <literal>i</literal>
|
||||
(indexes) can be appended to the command, filtering the kind of
|
||||
relations to list. By default, partitioned tables and indexes are
|
||||
listed.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If the modifier <literal>n</literal> (<quote>nested</quote>) is used,
|
||||
or a pattern is specified, then non-root partitioned tables are
|
||||
included, and a column is shown displaying the parent of each
|
||||
partitioned relation.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If <literal>+</literal> is appended to the command, the sum of sizes of
|
||||
table's partitions (including that of their indexes) is also displayed,
|
||||
along with the associated description.
|
||||
If <literal>n</literal> is combined with <literal>+</literal>, two
|
||||
sizes are shown: one including the total size of directly-attached
|
||||
leaf partitions, and another showing the total size of all partitions,
|
||||
including indirectly attached sub-partitions.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>\drds [ <link linkend="app-psql-patterns"><replaceable class="parameter">role-pattern</replaceable></link> [ <link linkend="app-psql-patterns"><replaceable class="parameter">database-pattern</replaceable></link> ] ]</literal></term>
|
||||
<listitem>
|
||||
|
@ -784,6 +784,23 @@ exec_command_d(PsqlScanState scan_state, bool active_branch, const char *cmd)
|
||||
case 'p':
|
||||
success = permissionsList(pattern);
|
||||
break;
|
||||
case 'P':
|
||||
{
|
||||
switch (cmd[2])
|
||||
{
|
||||
case '\0':
|
||||
case '+':
|
||||
case 't':
|
||||
case 'i':
|
||||
case 'n':
|
||||
success = listPartitionedTables(&cmd[2], pattern, show_verbose);
|
||||
break;
|
||||
default:
|
||||
status = PSQL_CMD_UNKNOWN;
|
||||
break;
|
||||
}
|
||||
}
|
||||
break;
|
||||
case 'T':
|
||||
success = describeTypes(pattern, show_verbose, show_system);
|
||||
break;
|
||||
|
@ -3777,6 +3777,220 @@ listTables(const char *tabtypes, const char *pattern, bool verbose, bool showSys
|
||||
return true;
|
||||
}
|
||||
|
||||
/*
|
||||
* \dP
|
||||
* Takes an optional regexp to select particular relations
|
||||
*
|
||||
* As with \d, you can specify the kinds of relations you want:
|
||||
*
|
||||
* t for tables
|
||||
* i for indexes
|
||||
*
|
||||
* And there's additional flags:
|
||||
*
|
||||
* n to list non-leaf partitioned tables
|
||||
*
|
||||
* and you can mix and match these in any order.
|
||||
*/
|
||||
bool
|
||||
listPartitionedTables(const char *reltypes, const char *pattern, bool verbose)
|
||||
{
|
||||
bool showTables = strchr(reltypes, 't') != NULL;
|
||||
bool showIndexes = strchr(reltypes, 'i') != NULL;
|
||||
bool showNested = strchr(reltypes, 'n') != NULL;
|
||||
PQExpBufferData buf;
|
||||
PQExpBufferData title;
|
||||
PGresult *res;
|
||||
printQueryOpt myopt = pset.popt;
|
||||
bool translate_columns[] = {false, false, false, false, false, false, false, false, false};
|
||||
const char *tabletitle;
|
||||
bool mixed_output = false;
|
||||
|
||||
/*
|
||||
* Note: Declarative table partitioning is only supported as of Pg 10.0.
|
||||
*/
|
||||
if (pset.sversion < 100000)
|
||||
{
|
||||
char sverbuf[32];
|
||||
|
||||
pg_log_error("The server (version %s) does not support declarative table partitioning.",
|
||||
formatPGVersionNumber(pset.sversion, false,
|
||||
sverbuf, sizeof(sverbuf)));
|
||||
return true;
|
||||
}
|
||||
|
||||
/* If no relation kind was selected, show them all */
|
||||
if (!showTables && !showIndexes)
|
||||
showTables = showIndexes = true;
|
||||
|
||||
if (showIndexes && !showTables)
|
||||
tabletitle = _("List of partitioned indexes"); /* \dPi */
|
||||
else if (showTables && !showIndexes)
|
||||
tabletitle = _("List of partitioned tables"); /* \dPt */
|
||||
else
|
||||
{
|
||||
/* show all kinds */
|
||||
tabletitle = _("List of partitioned relations");
|
||||
mixed_output = true;
|
||||
}
|
||||
|
||||
initPQExpBuffer(&buf);
|
||||
|
||||
printfPQExpBuffer(&buf,
|
||||
"SELECT n.nspname as \"%s\",\n"
|
||||
" c.relname as \"%s\",\n"
|
||||
" pg_catalog.pg_get_userbyid(c.relowner) as \"%s\"",
|
||||
gettext_noop("Schema"),
|
||||
gettext_noop("Name"),
|
||||
gettext_noop("Owner"));
|
||||
|
||||
if (mixed_output)
|
||||
{
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n CASE c.relkind"
|
||||
" WHEN " CppAsString2(RELKIND_PARTITIONED_TABLE) " THEN '%s'"
|
||||
" WHEN " CppAsString2(RELKIND_PARTITIONED_INDEX) " THEN '%s'"
|
||||
" END as \"%s\"",
|
||||
gettext_noop("partitioned table"),
|
||||
gettext_noop("partitioned index"),
|
||||
gettext_noop("Type"));
|
||||
|
||||
translate_columns[3] = true;
|
||||
}
|
||||
|
||||
if (showNested || pattern)
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n c3.oid::regclass as \"%s\"",
|
||||
gettext_noop("Parent name"));
|
||||
|
||||
if (showIndexes)
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n c2.oid::regclass as \"%s\"",
|
||||
gettext_noop("On table"));
|
||||
|
||||
if (verbose)
|
||||
{
|
||||
if (showNested)
|
||||
{
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n s.dps as \"%s\"",
|
||||
gettext_noop("Leaf partition size"));
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n s.tps as \"%s\"",
|
||||
gettext_noop("Total size"));
|
||||
}
|
||||
else
|
||||
/* Sizes of all partitions are considered in this case. */
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n s.tps as \"%s\"",
|
||||
gettext_noop("Total size"));
|
||||
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n pg_catalog.obj_description(c.oid, 'pg_class') as \"%s\"",
|
||||
gettext_noop("Description"));
|
||||
}
|
||||
|
||||
appendPQExpBufferStr(&buf,
|
||||
"\nFROM pg_catalog.pg_class c"
|
||||
"\n LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace");
|
||||
|
||||
if (showIndexes)
|
||||
appendPQExpBufferStr(&buf,
|
||||
"\n LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid"
|
||||
"\n LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid");
|
||||
|
||||
if (showNested || pattern)
|
||||
appendPQExpBufferStr(&buf,
|
||||
"\n LEFT JOIN pg_catalog.pg_inherits inh ON c.oid = inh.inhrelid"
|
||||
"\n LEFT JOIN pg_catalog.pg_class c3 ON c3.oid = inh.inhparent");
|
||||
|
||||
if (verbose)
|
||||
{
|
||||
if (pset.sversion < 120000)
|
||||
{
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n LATERAL (WITH RECURSIVE d\n"
|
||||
" AS (SELECT inhrelid AS oid, 1 AS level\n"
|
||||
" FROM pg_catalog.pg_inherits\n"
|
||||
" WHERE inhparent = c.oid\n"
|
||||
" UNION ALL\n"
|
||||
" SELECT inhrelid, level + 1\n"
|
||||
" FROM pg_catalog.pg_inherits i\n"
|
||||
" JOIN d ON i.inhparent = d.oid)\n"
|
||||
" SELECT pg_catalog.pg_size_pretty(sum(pg_catalog.pg_table_size("
|
||||
"d.oid))) AS tps,\n"
|
||||
" pg_catalog.pg_size_pretty(sum("
|
||||
"\n CASE WHEN d.level = 1"
|
||||
" THEN pg_catalog.pg_table_size(d.oid) ELSE 0 END)) AS dps\n"
|
||||
" FROM d) s");
|
||||
}
|
||||
else
|
||||
{
|
||||
/* PostgreSQL 12 has pg_partition_tree function */
|
||||
appendPQExpBuffer(&buf,
|
||||
",\n LATERAL (SELECT pg_catalog.pg_size_pretty(sum("
|
||||
"\n CASE WHEN ppt.isleaf AND ppt.level = 1"
|
||||
"\n THEN pg_catalog.pg_table_size(ppt.relid)"
|
||||
" ELSE 0 END)) AS dps"
|
||||
",\n pg_catalog.pg_size_pretty(sum("
|
||||
"pg_catalog.pg_table_size(ppt.relid))) AS tps"
|
||||
"\n FROM pg_catalog.pg_partition_tree(c.oid) ppt) s");
|
||||
}
|
||||
}
|
||||
|
||||
appendPQExpBufferStr(&buf, "\nWHERE c.relkind IN (");
|
||||
if (showTables)
|
||||
appendPQExpBufferStr(&buf, CppAsString2(RELKIND_PARTITIONED_TABLE) ",");
|
||||
if (showIndexes)
|
||||
appendPQExpBufferStr(&buf, CppAsString2(RELKIND_PARTITIONED_INDEX) ",");
|
||||
appendPQExpBufferStr(&buf, "''"); /* dummy */
|
||||
appendPQExpBufferStr(&buf, ")\n");
|
||||
|
||||
appendPQExpBufferStr(&buf, !showNested && !pattern ?
|
||||
" AND NOT c.relispartition\n" : "");
|
||||
|
||||
if (!pattern)
|
||||
appendPQExpBufferStr(&buf, " AND n.nspname <> 'pg_catalog'\n"
|
||||
" AND n.nspname <> 'information_schema'\n");
|
||||
|
||||
/*
|
||||
* TOAST objects are suppressed unconditionally. Since we don't provide
|
||||
* any way to select RELKIND_TOASTVALUE above, we would never show toast
|
||||
* tables in any case; it seems a bit confusing to allow their indexes to
|
||||
* be shown. Use plain \d if you really need to look at a TOAST
|
||||
* table/index.
|
||||
*/
|
||||
appendPQExpBufferStr(&buf, " AND n.nspname !~ '^pg_toast'\n");
|
||||
|
||||
processSQLNamePattern(pset.db, &buf, pattern, true, false,
|
||||
"n.nspname", "c.relname", NULL,
|
||||
"pg_catalog.pg_table_is_visible(c.oid)");
|
||||
|
||||
appendPQExpBuffer(&buf, "ORDER BY \"Schema\", %s%s\"Name\";",
|
||||
mixed_output ? "\"Type\" DESC, " : "",
|
||||
showNested || pattern ? "\"Parent name\" NULLS FIRST, " : "");
|
||||
|
||||
res = PSQLexec(buf.data);
|
||||
termPQExpBuffer(&buf);
|
||||
if (!res)
|
||||
return false;
|
||||
|
||||
initPQExpBuffer(&title);
|
||||
appendPQExpBuffer(&title, "%s", tabletitle);
|
||||
|
||||
myopt.nullPrint = NULL;
|
||||
myopt.title = title.data;
|
||||
myopt.translate_header = true;
|
||||
myopt.translate_columns = translate_columns;
|
||||
myopt.n_translate_columns = lengthof(translate_columns);
|
||||
|
||||
printQuery(res, &myopt, pset.queryFout, false, pset.logfile);
|
||||
|
||||
termPQExpBuffer(&title);
|
||||
|
||||
PQclear(res);
|
||||
return true;
|
||||
}
|
||||
|
||||
/*
|
||||
* \dL
|
||||
|
@ -63,6 +63,9 @@ extern bool listAllDbs(const char *pattern, bool verbose);
|
||||
/* \dt, \di, \ds, \dS, etc. */
|
||||
extern bool listTables(const char *tabtypes, const char *pattern, bool verbose, bool showSystem);
|
||||
|
||||
/* \dP */
|
||||
extern bool listPartitionedTables(const char *reltypes, const char *pattern, bool verbose);
|
||||
|
||||
/* \dD */
|
||||
extern bool listDomains(const char *pattern, bool verbose, bool showSystem);
|
||||
|
||||
|
@ -169,7 +169,7 @@ slashUsage(unsigned short int pager)
|
||||
* Use "psql --help=commands | wc" to count correctly. It's okay to count
|
||||
* the USE_READLINE line even in builds without that.
|
||||
*/
|
||||
output = PageOutput(126, pager ? &(pset.popt.topt) : NULL);
|
||||
output = PageOutput(127, pager ? &(pset.popt.topt) : NULL);
|
||||
|
||||
fprintf(output, _("General\n"));
|
||||
fprintf(output, _(" \\copyright show PostgreSQL usage and distribution terms\n"));
|
||||
@ -251,6 +251,7 @@ slashUsage(unsigned short int pager)
|
||||
fprintf(output, _(" \\do[S] [PATTERN] list operators\n"));
|
||||
fprintf(output, _(" \\dO[S+] [PATTERN] list collations\n"));
|
||||
fprintf(output, _(" \\dp [PATTERN] list table, view, and sequence access privileges\n"));
|
||||
fprintf(output, _(" \\dP[tin+] [PATTERN] list [only table/index] partitioned relations\n"));
|
||||
fprintf(output, _(" \\drds [PATRN1 [PATRN2]] list per-database role settings\n"));
|
||||
fprintf(output, _(" \\dRp[+] [PATTERN] list replication publications\n"));
|
||||
fprintf(output, _(" \\dRs[+] [PATTERN] list replication subscriptions\n"));
|
||||
|
@ -464,6 +464,15 @@ static const SchemaQuery Query_for_list_of_indexes = {
|
||||
.result = "pg_catalog.quote_ident(c.relname)",
|
||||
};
|
||||
|
||||
static const SchemaQuery Query_for_list_of_partitioned_indexes = {
|
||||
.catname = "pg_catalog.pg_class c",
|
||||
.selcondition = "c.relkind = " CppAsString2(RELKIND_PARTITIONED_INDEX),
|
||||
.viscondition = "pg_catalog.pg_table_is_visible(c.oid)",
|
||||
.namespace = "c.relnamespace",
|
||||
.result = "pg_catalog.quote_ident(c.relname)",
|
||||
};
|
||||
|
||||
|
||||
/* All relations */
|
||||
static const SchemaQuery Query_for_list_of_relations = {
|
||||
.catname = "pg_catalog.pg_class c",
|
||||
@ -472,6 +481,16 @@ static const SchemaQuery Query_for_list_of_relations = {
|
||||
.result = "pg_catalog.quote_ident(c.relname)",
|
||||
};
|
||||
|
||||
/* partitioned relations */
|
||||
static const SchemaQuery Query_for_list_of_partitioned_relations = {
|
||||
.catname = "pg_catalog.pg_class c",
|
||||
.selcondition = "c.relkind IN (" CppAsString2(RELKIND_PARTITIONED_TABLE)
|
||||
", " CppAsString2(RELKIND_PARTITIONED_INDEX) ")",
|
||||
.viscondition = "pg_catalog.pg_table_is_visible(c.oid)",
|
||||
.namespace = "c.relnamespace",
|
||||
.result = "pg_catalog.quote_ident(c.relname)",
|
||||
};
|
||||
|
||||
/* Relations supporting INSERT, UPDATE or DELETE */
|
||||
static const SchemaQuery Query_for_list_of_updatables = {
|
||||
.catname = "pg_catalog.pg_class c",
|
||||
@ -1382,7 +1401,7 @@ psql_completion(const char *text, int start, int end)
|
||||
"\\d", "\\da", "\\dA", "\\db", "\\dc", "\\dC", "\\dd", "\\ddp", "\\dD",
|
||||
"\\des", "\\det", "\\deu", "\\dew", "\\dE", "\\df",
|
||||
"\\dF", "\\dFd", "\\dFp", "\\dFt", "\\dg", "\\di", "\\dl", "\\dL",
|
||||
"\\dm", "\\dn", "\\do", "\\dO", "\\dp",
|
||||
"\\dm", "\\dn", "\\do", "\\dO", "\\dp", "\\dP", "\\dPi", "\\dPt",
|
||||
"\\drds", "\\dRs", "\\dRp", "\\ds", "\\dS",
|
||||
"\\dt", "\\dT", "\\dv", "\\du", "\\dx", "\\dy",
|
||||
"\\e", "\\echo", "\\ef", "\\elif", "\\else", "\\encoding",
|
||||
@ -3527,6 +3546,12 @@ psql_completion(const char *text, int start, int end)
|
||||
COMPLETE_WITH_QUERY(Query_for_list_of_schemas);
|
||||
else if (TailMatchesCS("\\dp") || TailMatchesCS("\\z"))
|
||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_grantables, NULL);
|
||||
else if (TailMatchesCS("\\dPi*"))
|
||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_partitioned_indexes, NULL);
|
||||
else if (TailMatchesCS("\\dPt*"))
|
||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_partitioned_tables, NULL);
|
||||
else if (TailMatchesCS("\\dP*"))
|
||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_partitioned_relations, NULL);
|
||||
else if (TailMatchesCS("\\ds*"))
|
||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_sequences, NULL);
|
||||
else if (TailMatchesCS("\\dt*"))
|
||||
|
@ -4598,3 +4598,134 @@ last error message: division by zero
|
||||
\echo 'last error code:' :LAST_ERROR_SQLSTATE
|
||||
last error code: 22012
|
||||
\unset FETCH_COUNT
|
||||
create schema testpart;
|
||||
create role testrole_partitioning;
|
||||
alter schema testpart owner to testrole_partitioning;
|
||||
set role to testrole_partitioning;
|
||||
-- run test inside own schema and hide other partitions
|
||||
set search_path to testpart;
|
||||
create table testtable_apple(logdate date);
|
||||
create table testtable_orange(logdate date);
|
||||
create index testtable_apple_index on testtable_apple(logdate);
|
||||
create index testtable_orange_index on testtable_orange(logdate);
|
||||
create table testpart_apple(logdate date) partition by range(logdate);
|
||||
create table testpart_orange(logdate date) partition by range(logdate);
|
||||
create index testpart_apple_index on testpart_apple(logdate);
|
||||
create index testpart_orange_index on testpart_orange(logdate);
|
||||
-- only partition related object should be displayed
|
||||
\dP test*apple*
|
||||
List of partitioned relations
|
||||
Schema | Name | Owner | Type | Parent name | On table
|
||||
----------+----------------------+-----------------------+-------------------+-------------+----------------
|
||||
testpart | testpart_apple | testrole_partitioning | partitioned table | |
|
||||
testpart | testpart_apple_index | testrole_partitioning | partitioned index | | testpart_apple
|
||||
(2 rows)
|
||||
|
||||
\dPt test*apple*
|
||||
List of partitioned tables
|
||||
Schema | Name | Owner | Parent name
|
||||
----------+----------------+-----------------------+-------------
|
||||
testpart | testpart_apple | testrole_partitioning |
|
||||
(1 row)
|
||||
|
||||
\dPi test*apple*
|
||||
List of partitioned indexes
|
||||
Schema | Name | Owner | Parent name | On table
|
||||
----------+----------------------+-----------------------+-------------+----------------
|
||||
testpart | testpart_apple_index | testrole_partitioning | | testpart_apple
|
||||
(1 row)
|
||||
|
||||
drop table testtable_apple;
|
||||
drop table testtable_orange;
|
||||
drop table testpart_apple;
|
||||
drop table testpart_orange;
|
||||
create table parent_tab (id int) partition by range (id);
|
||||
create index parent_index on parent_tab (id);
|
||||
create table child_0_10 partition of parent_tab
|
||||
for values from (0) to (10);
|
||||
create table child_10_20 partition of parent_tab
|
||||
for values from (10) to (20);
|
||||
create table child_20_30 partition of parent_tab
|
||||
for values from (20) to (30);
|
||||
insert into parent_tab values (generate_series(0,29));
|
||||
create table child_30_40 partition of parent_tab
|
||||
for values from (30) to (40)
|
||||
partition by range(id);
|
||||
create table child_30_35 partition of child_30_40
|
||||
for values from (30) to (35);
|
||||
create table child_35_40 partition of child_30_40
|
||||
for values from (35) to (40);
|
||||
insert into parent_tab values (generate_series(30,39));
|
||||
\dPt
|
||||
List of partitioned tables
|
||||
Schema | Name | Owner
|
||||
----------+------------+-----------------------
|
||||
testpart | parent_tab | testrole_partitioning
|
||||
(1 row)
|
||||
|
||||
\dPi
|
||||
List of partitioned indexes
|
||||
Schema | Name | Owner | On table
|
||||
----------+--------------+-----------------------+------------
|
||||
testpart | parent_index | testrole_partitioning | parent_tab
|
||||
(1 row)
|
||||
|
||||
\dP testpart.*
|
||||
List of partitioned relations
|
||||
Schema | Name | Owner | Type | Parent name | On table
|
||||
----------+--------------------+-----------------------+-------------------+--------------+-------------
|
||||
testpart | parent_tab | testrole_partitioning | partitioned table | |
|
||||
testpart | child_30_40 | testrole_partitioning | partitioned table | parent_tab |
|
||||
testpart | parent_index | testrole_partitioning | partitioned index | | parent_tab
|
||||
testpart | child_30_40_id_idx | testrole_partitioning | partitioned index | parent_index | child_30_40
|
||||
(4 rows)
|
||||
|
||||
\dP
|
||||
List of partitioned relations
|
||||
Schema | Name | Owner | Type | On table
|
||||
----------+--------------+-----------------------+-------------------+------------
|
||||
testpart | parent_tab | testrole_partitioning | partitioned table |
|
||||
testpart | parent_index | testrole_partitioning | partitioned index | parent_tab
|
||||
(2 rows)
|
||||
|
||||
\dPtn
|
||||
List of partitioned tables
|
||||
Schema | Name | Owner | Parent name
|
||||
----------+-------------+-----------------------+-------------
|
||||
testpart | parent_tab | testrole_partitioning |
|
||||
testpart | child_30_40 | testrole_partitioning | parent_tab
|
||||
(2 rows)
|
||||
|
||||
\dPin
|
||||
List of partitioned indexes
|
||||
Schema | Name | Owner | Parent name | On table
|
||||
----------+--------------------+-----------------------+--------------+-------------
|
||||
testpart | parent_index | testrole_partitioning | | parent_tab
|
||||
testpart | child_30_40_id_idx | testrole_partitioning | parent_index | child_30_40
|
||||
(2 rows)
|
||||
|
||||
\dPn
|
||||
List of partitioned relations
|
||||
Schema | Name | Owner | Type | Parent name | On table
|
||||
----------+--------------------+-----------------------+-------------------+--------------+-------------
|
||||
testpart | parent_tab | testrole_partitioning | partitioned table | |
|
||||
testpart | child_30_40 | testrole_partitioning | partitioned table | parent_tab |
|
||||
testpart | parent_index | testrole_partitioning | partitioned index | | parent_tab
|
||||
testpart | child_30_40_id_idx | testrole_partitioning | partitioned index | parent_index | child_30_40
|
||||
(4 rows)
|
||||
|
||||
\dPn testpart.*
|
||||
List of partitioned relations
|
||||
Schema | Name | Owner | Type | Parent name | On table
|
||||
----------+--------------------+-----------------------+-------------------+--------------+-------------
|
||||
testpart | parent_tab | testrole_partitioning | partitioned table | |
|
||||
testpart | child_30_40 | testrole_partitioning | partitioned table | parent_tab |
|
||||
testpart | parent_index | testrole_partitioning | partitioned index | | parent_tab
|
||||
testpart | child_30_40_id_idx | testrole_partitioning | partitioned index | parent_index | child_30_40
|
||||
(4 rows)
|
||||
|
||||
drop table parent_tab cascade;
|
||||
drop schema testpart;
|
||||
set search_path to default;
|
||||
set role to default;
|
||||
drop role testrole_partitioning;
|
||||
|
@ -1046,3 +1046,72 @@ select 1/(15-unique2) from tenk1 order by unique2 limit 19;
|
||||
\echo 'last error code:' :LAST_ERROR_SQLSTATE
|
||||
|
||||
\unset FETCH_COUNT
|
||||
|
||||
create schema testpart;
|
||||
create role testrole_partitioning;
|
||||
|
||||
alter schema testpart owner to testrole_partitioning;
|
||||
|
||||
set role to testrole_partitioning;
|
||||
|
||||
-- run test inside own schema and hide other partitions
|
||||
set search_path to testpart;
|
||||
|
||||
create table testtable_apple(logdate date);
|
||||
create table testtable_orange(logdate date);
|
||||
create index testtable_apple_index on testtable_apple(logdate);
|
||||
create index testtable_orange_index on testtable_orange(logdate);
|
||||
|
||||
create table testpart_apple(logdate date) partition by range(logdate);
|
||||
create table testpart_orange(logdate date) partition by range(logdate);
|
||||
|
||||
create index testpart_apple_index on testpart_apple(logdate);
|
||||
create index testpart_orange_index on testpart_orange(logdate);
|
||||
|
||||
-- only partition related object should be displayed
|
||||
\dP test*apple*
|
||||
\dPt test*apple*
|
||||
\dPi test*apple*
|
||||
|
||||
drop table testtable_apple;
|
||||
drop table testtable_orange;
|
||||
drop table testpart_apple;
|
||||
drop table testpart_orange;
|
||||
|
||||
create table parent_tab (id int) partition by range (id);
|
||||
create index parent_index on parent_tab (id);
|
||||
create table child_0_10 partition of parent_tab
|
||||
for values from (0) to (10);
|
||||
create table child_10_20 partition of parent_tab
|
||||
for values from (10) to (20);
|
||||
create table child_20_30 partition of parent_tab
|
||||
for values from (20) to (30);
|
||||
insert into parent_tab values (generate_series(0,29));
|
||||
create table child_30_40 partition of parent_tab
|
||||
for values from (30) to (40)
|
||||
partition by range(id);
|
||||
create table child_30_35 partition of child_30_40
|
||||
for values from (30) to (35);
|
||||
create table child_35_40 partition of child_30_40
|
||||
for values from (35) to (40);
|
||||
insert into parent_tab values (generate_series(30,39));
|
||||
|
||||
\dPt
|
||||
\dPi
|
||||
|
||||
\dP testpart.*
|
||||
\dP
|
||||
|
||||
\dPtn
|
||||
\dPin
|
||||
\dPn
|
||||
\dPn testpart.*
|
||||
|
||||
drop table parent_tab cascade;
|
||||
|
||||
drop schema testpart;
|
||||
|
||||
set search_path to default;
|
||||
|
||||
set role to default;
|
||||
drop role testrole_partitioning;
|
||||
|
Loading…
x
Reference in New Issue
Block a user