Ășt 20. 11. 2018 v 8:50 odesĂ­latel Michael Paquier <mich...@paquier.xyz>
napsal:

> On Mon, Nov 05, 2018 at 11:43:16AM +0100, Pavel Stehule wrote:
> > should be fixed now.
>
> Here are some notes on the last version.
>
> +   "              FROM pg_inherits i\n"
> Missing schema qualification.
>
>
fixed


> +           case 'P':
> +               if (cmd[2] == 'i')
> +                   success = listPartitions(pattern, show_verbose,
> true, false);
> +               else if (cmd[2] == 't')
> +                   success = listPartitions(pattern, show_verbose,
> false, true);
> +               else if (cmd[2] == '+' || cmd[2] == '\0')
> +                   success = listPartitions(pattern, show_verbose,
> false, false);
> +               else
> +                   status = PSQL_CMD_UNKNOWN;
> +               break;
> The style is heavy.  Perhaps it would be cleaner to have a
> switch/case..  Not a big deal visibly.  show_indexes is true only if the
> subcommand is 'i'.  show_tables is true only if the subcommand is 't'.
>
> Using "\dP" with a pattern matching a partitioned index should show a
> partitioned index, no?  As far as I know, a partitioned relation can be
> either an index or a table.
>

I don't think

\dP shows uses pg_total_relation_size as size function, and then we should
to display just tables, but with total size.

I don't see a sense to show indexes and tables too, more when we show total
relation size - see description for total relation size

"total disk space usage for the specified table and associated indexes"


>
> Testing the feature, \dP shows all partitioned relations, still does not
> show the relationship when multiple levels are used.  Could it make
> sense to also show the direct parent of a partitioned table when
> verbose mode is used?
>

it is expected - you got one number for one partitioned table. I agree, so
can be interesting to see agregated sizes per partitioning hierarchy - but
in this moment I cannot to imagine form of the result.

any table can have different number of levels - so you can get different
number of values.


>
> Could it be possible to have tests for \dP, \dPi and \dPt with matching
> patterns?  You could just place that in one of the existing tests where
> there are partitioned tables and indexes.
>

I did it

see assigned patch, please.

Regards

Pavel



> --
> Michael
>
diff --git a/doc/src/sgml/ref/psql-ref.sgml b/doc/src/sgml/ref/psql-ref.sgml
index 6e6d0f42d1..2166a25ba6 100644
--- a/doc/src/sgml/ref/psql-ref.sgml
+++ b/doc/src/sgml/ref/psql-ref.sgml
@@ -1635,6 +1635,53 @@ testdb=&gt;
         </listitem>
       </varlistentry>
 
+
+      <varlistentry>
+        <term><literal>\dP[+] [ <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 relation name or schema name matches
+        the pattern are listed. If the form <literal>\dP+</literal>
+        is used, the sum of size of related partitions (including the
+        table and indexes, if any) and a description
+        are also displayed.
+        </para>
+        </listitem>
+      </varlistentry>
+
+
+      <varlistentry>
+        <term><literal>\dPi[+] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
+        <listitem>
+        <para>
+        Lists partitioned indexes. If <replaceable
+        class="parameter">pattern</replaceable> is specified, only
+        entries whose index name or schema name matches
+        the pattern are listed. If the form <literal>\dPi+</literal>
+        is used, the sum of size of related indexes and a description
+        are also displayed.
+        </para>
+        </listitem>
+      </varlistentry>
+
+
+      <varlistentry>
+        <term><literal>\dPt[+] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
+        <listitem>
+        <para>
+        Lists partitioned tables. If <replaceable
+        class="parameter">pattern</replaceable> is specified, only
+        entries whose table name or schema name matches
+        the pattern are listed. If the form <literal>\dPt+</literal>
+        is used, the sum of size of related tables and a description
+        are also displayed.
+        </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>
diff --git a/src/bin/psql/command.c b/src/bin/psql/command.c
index ee88e1ca5c..d5c9b19ec6 100644
--- a/src/bin/psql/command.c
+++ b/src/bin/psql/command.c
@@ -782,6 +782,27 @@ exec_command_d(PsqlScanState scan_state, bool active_branch, const char *cmd)
 			case 'p':
 				success = permissionsList(pattern);
 				break;
+			case 'P':
+				switch (cmd[2])
+				{
+					case 'i':
+						/* show indexes only */
+						success = listPartitions(pattern, show_verbose, true, false);
+						break;
+					case 't':
+						/* show tables only */
+						success = listPartitions(pattern, show_verbose, false, true);
+						break;
+					case '+':
+					case '\0':
+						/* show relations - tables + indexes */
+						success = listPartitions(pattern, show_verbose, false, false);
+						break;
+					default:
+						status = PSQL_CMD_UNKNOWN;
+						break;
+				}
+				break;
 			case 'T':
 				success = describeTypes(pattern, show_verbose, show_system);
 				break;
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 0a181b01d9..6c9c980138 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -3659,6 +3659,183 @@ listTables(const char *tabtypes, const char *pattern, bool verbose, bool showSys
 	return true;
 }
 
+/*
+ * listPartitions()
+ *
+ * handler for \dP, \dPt and \dPi
+ */
+bool
+listPartitions(const char *pattern, bool verbose, bool show_indexes, bool show_tables)
+{
+	PQExpBufferData buf;
+	PGresult   *res;
+	printQueryOpt myopt = pset.popt;
+	static const bool translate_columns[] = {false, false, true, false, false, false, false};
+	const char *size_function;
+	const char *relkind_str;
+	const char *object_name;
+	const char *objects_name;
+
+	/*
+	 * Note: Declarative table partitions are only supported as of Pg 10.0.
+	 */
+	if (pset.sversion < 100000)
+	{
+		char		sverbuf[32];
+
+		psql_error("The server (version %s) does not support declarative table partitioning.\n",
+				   formatPGVersionNumber(pset.sversion, false,
+										 sverbuf, sizeof(sverbuf)));
+		return true;
+	}
+
+	if (show_indexes)
+	{
+		size_function = "pg_table_size";
+		relkind_str = CppAsString2(RELKIND_PARTITIONED_INDEX);
+		object_name = gettext_noop("index");
+		objects_name = gettext_noop("indexes");
+	}
+	else if (show_tables)
+	{
+		size_function = "pg_table_size";
+		relkind_str = CppAsString2(RELKIND_PARTITIONED_TABLE);
+		object_name = gettext_noop("table");
+		objects_name = gettext_noop("tables");
+	}
+	else
+	{
+		size_function = "pg_total_relation_size";
+		relkind_str = CppAsString2(RELKIND_PARTITIONED_TABLE);
+		object_name = gettext_noop("relation");
+		objects_name = gettext_noop("relations");
+	}
+
+	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 (show_indexes)
+		appendPQExpBuffer(&buf,
+						  ",\n c2.relname as \"%s\"",
+						  gettext_noop("Table"));
+
+	if (verbose)
+	{
+		if (pset.sversion < 120000)
+		{
+			appendPQExpBuffer(&buf,
+							  ",\n  (WITH RECURSIVE d\n"
+							  "        AS (SELECT inhrelid AS oid\n"
+							  "              FROM pg_catalog.pg_inherits\n"
+							  "             WHERE inhparent = c.oid\n"
+							  "            UNION ALL\n"
+							  "            SELECT inhrelid\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.%s("
+							  "oid))) FROM d) AS \"%s\""
+							  ",\n  pg_catalog.obj_description(c.oid, 'pg_class') as \"%s\"",
+							  size_function,
+							  gettext_noop("Size"),
+							  gettext_noop("Description"));
+		}
+		else
+		{
+			/* PostgreSQL 12 has pg_partition_tree function */
+			appendPQExpBuffer(&buf,
+							  ",\n  (SELECT pg_catalog.pg_size_pretty(sum(pg_catalog.%s("
+							  "relid)))\n"
+							  "     FROM pg_catalog.pg_partition_tree(c.oid)) AS \"%s\""
+							  ",\n  pg_catalog.obj_description(c.oid, 'pg_class') as \"%s\"",
+							  size_function,
+							  gettext_noop("Size"),
+							  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 (show_indexes)
+		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");
+
+	appendPQExpBuffer(&buf, "\nWHERE c.relkind IN (%s)\n",
+						 relkind_str);
+
+	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)");
+
+	appendPQExpBufferStr(&buf, "ORDER BY 1,2;");
+
+	res = PSQLexec(buf.data);
+	termPQExpBuffer(&buf);
+	if (!res)
+		return false;
+
+	/*
+	 * Most functions in this file are content to print an empty table when
+	 * there are no matching objects.  We intentionally deviate from that
+	 * here, but only in !quiet mode, for historical reasons.
+	 */
+	if (PQntuples(res) == 0 && !pset.quiet)
+	{
+		if (pattern)
+			/* translator: objects_name is "indexes", "tables" or "relations" */
+			psql_error("Did not find any partitioned %s named \"%s\".\n",
+					   objects_name,
+					   pattern);
+		else
+			/* translator: object_name is "index", "table" or "relation" */
+			psql_error("Did not find any partitioned %s.\n",
+					  object_name);
+	}
+	else
+	{
+		PQExpBufferData title;
+
+		initPQExpBuffer(&title);
+
+		/* translator: objects_name is "indexes", "tables" or "relations" */
+		appendPQExpBuffer(&title, _("List of partitioned %s"), objects_name);
+
+		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
diff --git a/src/bin/psql/describe.h b/src/bin/psql/describe.h
index a4cc5efae0..c2138c26b9 100644
--- a/src/bin/psql/describe.h
+++ b/src/bin/psql/describe.h
@@ -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, \dPi, \dPt */
+extern bool listPartitions(const char *pattern, bool verbose, bool show_indexes, bool show_tables);
+
 /* \dD */
 extern bool listDomains(const char *pattern, bool verbose, bool showSystem);
 
diff --git a/src/bin/psql/help.c b/src/bin/psql/help.c
index 586aebddd3..84c014993f 100644
--- a/src/bin/psql/help.c
+++ b/src/bin/psql/help.c
@@ -167,7 +167,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(125, pager ? &(pset.popt.topt) : NULL);
+	output = PageOutput(129, pager ? &(pset.popt.topt) : NULL);
 
 	fprintf(output, _("General\n"));
 	fprintf(output, _("  \\copyright             show PostgreSQL usage and distribution terms\n"));
@@ -249,6 +249,9 @@ 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[+]  [PATTERN]      list partitioned relations\n"));
+	fprintf(output, _("  \\dPi[+] [PATTERN]      list partitioned indexes\n"));
+	fprintf(output, _("  \\dPt[+] [PATTERN]      list partitioned tables\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"));
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 9dbd555166..7eb43f8bf3 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -452,6 +452,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",
@@ -460,6 +469,15 @@ 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 = " CppAsString2(RELKIND_PARTITIONED_TABLE),
+	.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",
@@ -1332,7 +1350,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",
@@ -3447,6 +3465,10 @@ 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("\\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*"))
diff --git a/src/test/regress/expected/psql.out b/src/test/regress/expected/psql.out
index 3818cfea7e..ab0cda7474 100644
--- a/src/test/regress/expected/psql.out
+++ b/src/test/regress/expected/psql.out
@@ -3243,3 +3243,67 @@ last error message: division by zero
 \echo 'last error code:' :LAST_ERROR_SQLSTATE
 last error code: 22012
 \unset FETCH_COUNT
+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
+  List of partitioned relations
+ Schema |      Name       | Owner 
+--------+-----------------+-------
+ public | mlparted        | pavel
+ public | mlparted1       | pavel
+ public | mlparted_def    | pavel
+ public | testpart_apple  | pavel
+ public | testpart_orange | pavel
+(5 rows)
+
+\dPt
+    List of partitioned tables
+ Schema |      Name       | Owner 
+--------+-----------------+-------
+ public | mlparted        | pavel
+ public | mlparted1       | pavel
+ public | mlparted_def    | pavel
+ public | testpart_apple  | pavel
+ public | testpart_orange | pavel
+(5 rows)
+
+\dPi
+               List of partitioned indexes
+ Schema |         Name          | Owner |      Table      
+--------+-----------------------+-------+-----------------
+ public | testpart_apple_index  | pavel | testpart_apple
+ public | testpart_orange_index | pavel | testpart_orange
+(2 rows)
+
+\dP *apple*
+  List of partitioned relations
+ Schema |      Name      | Owner 
+--------+----------------+-------
+ public | testpart_apple | pavel
+(1 row)
+
+\dPt *apple*
+   List of partitioned tables
+ Schema |      Name      | Owner 
+--------+----------------+-------
+ public | testpart_apple | pavel
+(1 row)
+
+\dPi *apple*
+              List of partitioned indexes
+ Schema |         Name         | Owner |     Table      
+--------+----------------------+-------+----------------
+ public | testpart_apple_index | pavel | testpart_apple
+(1 row)
+
+drop table testtable_apple;
+drop table testtable_orange;
+drop table testpart_apple;
+drop table testpart_orange;
diff --git a/src/test/regress/sql/psql.sql b/src/test/regress/sql/psql.sql
index b45da9bb8d..329e1320c8 100644
--- a/src/test/regress/sql/psql.sql
+++ b/src/test/regress/sql/psql.sql
@@ -688,3 +688,28 @@ select 1/(15-unique2) from tenk1 order by unique2 limit 19;
 \echo 'last error code:' :LAST_ERROR_SQLSTATE
 
 \unset FETCH_COUNT
+
+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
+\dPt
+\dPi
+
+\dP *apple*
+\dPt *apple*
+\dPi *apple*
+
+drop table testtable_apple;
+drop table testtable_orange;
+drop table testpart_apple;
+drop table testpart_orange;

Reply via email to