Hi,

The above query is so simple so that we would better to use the following query:

# This query works on PG10 or later
SELECT
     es.stxnamespace::pg_catalog.regnamespace::text AS "Schema",
     es.stxname AS "Name",
     pg_catalog.format('%s FROM %s',
         (SELECT pg_catalog.string_agg(pg_catalog.quote_ident(a.attname),', ')
          FROM pg_catalog.unnest(es.stxkeys) s(attnum)
          JOIN pg_catalog.pg_attribute a
          ON (es.stxrelid = a.attrelid
          AND a.attnum = s.attnum
          AND NOT a.attisdropped)),
     es.stxrelid::regclass) AS "Definition",
     CASE WHEN 'd' = any(es.stxkind) THEN 'defined'
     END AS "Ndistinct",
     CASE WHEN 'f' = any(es.stxkind) THEN 'defined'
     END AS "Dependencies",
     CASE WHEN 'm' = any(es.stxkind) THEN 'defined'
     END AS "MCV"
FROM pg_catalog.pg_statistic_ext es
ORDER BY 1, 2;

  Schema |    Name    |    Definition    | Ndistinct | Dependencies | 
Dependencies
--------+------------+------------------+-----------+--------------+--------------
  public | hoge1_ext  | a, b FROM hoge1  | defined   | defined      | defined
  public | hoge_t_ext | a, b FROM hoge_t | defined   | defined      | defined
(2 rows)


I'm going to create the WIP patch to use the above query.
Any comments welcome. :-D


Attached patch is WIP patch.

The changes are:
  - Use pg_statistic_ext only
  - Remove these statuses: "required" and "built"
  - Add new status: "defined"
  - Remove the size columns
  - Fix document

I'll create and send the regression test on the next patch if there is
no objection. Is it Okay?

Regards,
Tatsuro Yamada

diff --git a/doc/src/sgml/ref/psql-ref.sgml b/doc/src/sgml/ref/psql-ref.sgml
index 221a967bfe..36a79d9e3f 100644
--- a/doc/src/sgml/ref/psql-ref.sgml
+++ b/doc/src/sgml/ref/psql-ref.sgml
@@ -1918,6 +1918,26 @@ testdb=>
         </para>
         </listitem>
       </varlistentry>
+      
+      <varlistentry>
+        <term><literal>\dX [ <link linkend="app-psql-patterns"><replaceable 
class="parameter">pattern</replaceable></link> ]</literal></term>
+        <listitem>
+        <para>
+        Lists extended statistics.
+        If <replaceable class="parameter">pattern</replaceable>
+        is specified, only those extended statistics whose names match the
+        pattern are listed.
+        </para>
+
+        <para>
+        The column of the kind of extended stats (e.g. Ndistinct) shows its 
status.
+        NULL means that it doesn't exists. "defined" means that it is declared.
+        You can use pg_stats_ext if you'd like to know whether <link 
linkend="sql-analyze">
+        <command>ANALYZE</command></link> was run and statistics are available 
to the
+        planner.
+        </para>
+        </listitem>
+      </varlistentry>
 
       <varlistentry>
         <term><literal>\dy[+] [ <link linkend="app-psql-patterns"><replaceable 
class="parameter">pattern</replaceable></link> ]</literal></term>
diff --git a/src/bin/psql/command.c b/src/bin/psql/command.c
index 303e7c3ad8..c98e3d31d0 100644
--- a/src/bin/psql/command.c
+++ b/src/bin/psql/command.c
@@ -928,6 +928,9 @@ exec_command_d(PsqlScanState scan_state, bool 
active_branch, const char *cmd)
                                else
                                        success = listExtensions(pattern);
                                break;
+                       case 'X':                       /* Extended Statistics 
*/
+                               success = listExtendedStats(pattern);
+                               break;
                        case 'y':                       /* Event Triggers */
                                success = listEventTriggers(pattern, 
show_verbose);
                                break;
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index caf97563f4..899fe5d85c 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -4392,6 +4392,89 @@ listEventTriggers(const char *pattern, bool verbose)
        return true;
 }
 
+/*
+ * \dX
+ *
+ * Describes extended statistics.
+ */
+bool
+listExtendedStats(const char *pattern)
+{
+       PQExpBufferData buf;
+       PGresult   *res;
+       printQueryOpt myopt = pset.popt;
+
+       if (pset.sversion < 100000)
+       {
+               char            sverbuf[32];
+
+               pg_log_error("The server (version %s) does not support extended 
statistics.",
+                                        formatPGVersionNumber(pset.sversion, 
false,
+                                                                               
   sverbuf, sizeof(sverbuf)));
+               return true;
+       }
+
+       initPQExpBuffer(&buf);
+       printfPQExpBuffer(&buf,
+                                         "SELECT \n"
+                                         
"es.stxnamespace::pg_catalog.regnamespace::text AS \"%s\", \n"
+                                         "es.stxname AS \"%s\", \n"
+                                         "pg_catalog.format('%%s FROM %%s', \n"
+                                         "  (SELECT 
pg_catalog.string_agg(pg_catalog.quote_ident(a.attname),', ') \n"
+                                         "   FROM 
pg_catalog.unnest(es.stxkeys) s(attnum) \n"
+                                         "   JOIN pg_catalog.pg_attribute a \n"
+                                         "   ON (es.stxrelid = a.attrelid \n"
+                                         "   AND a.attnum = s.attnum \n"
+                                         "   AND NOT a.attisdropped)), \n"
+                                         "es.stxrelid::regclass) AS \"%s\"",
+                                         gettext_noop("Schema"),
+                                         gettext_noop("Name"),
+                                         gettext_noop("Definition"));
+
+       appendPQExpBuffer(&buf,
+                                         ",\nCASE WHEN 'd' = any(es.stxkind) 
THEN 'defined' \n"
+                                         "END AS \"%s\", \n"
+                                         "CASE WHEN 'f' = any(es.stxkind) THEN 
'defined' \n"
+                                         "END AS \"%s\"",
+                                         gettext_noop("Ndistinct"),
+                                         gettext_noop("Dependencies"));
+
+       /*
+        * Add the MCV statistics kind.
+        */     
+       if (pset.sversion >= 120000)
+       {
+               appendPQExpBuffer(&buf,
+                                                 ",\nCASE WHEN 'm' = 
any(es.stxkind) THEN 'defined' \n"
+                                                 "END AS \"%s\" ",
+                                                 gettext_noop("MCV"));
+       }
+
+       appendPQExpBufferStr(&buf,
+                                                " \nFROM 
pg_catalog.pg_statistic_ext es \n");
+
+       processSQLNamePattern(pset.db, &buf, pattern, false,
+                                                 false, NULL,
+                                                 "es.stxname", NULL,
+                                                 NULL);
+
+       appendPQExpBufferStr(&buf, "ORDER BY 1, 2;");
+
+       res = PSQLexec(buf.data);
+       termPQExpBuffer(&buf);
+       if (!res)
+               return false;
+
+       myopt.nullPrint = NULL;
+       myopt.title = _("List of extended statistics");
+       myopt.translate_header = true;
+
+       printQuery(res, &myopt, pset.queryFout, false, pset.logfile);
+
+       PQclear(res);
+       return true;
+}
+
 /*
  * \dC
  *
diff --git a/src/bin/psql/describe.h b/src/bin/psql/describe.h
index 6044e3a082..39856a0c7e 100644
--- a/src/bin/psql/describe.h
+++ b/src/bin/psql/describe.h
@@ -102,6 +102,9 @@ extern bool listExtensions(const char *pattern);
 /* \dx+ */
 extern bool listExtensionContents(const char *pattern);
 
+/* \dX */
+extern bool listExtendedStats(const char *pattern);
+
 /* \dy */
 extern bool listEventTriggers(const char *pattern, bool verbose);
 
diff --git a/src/bin/psql/help.c b/src/bin/psql/help.c
index 9ec1c4e810..4883ebd2ed 100644
--- a/src/bin/psql/help.c
+++ b/src/bin/psql/help.c
@@ -267,6 +267,7 @@ slashUsage(unsigned short int pager)
        fprintf(output, _("  \\du[S+] [PATTERN]      list roles\n"));
        fprintf(output, _("  \\dv[S+] [PATTERN]      list views\n"));
        fprintf(output, _("  \\dx[+]  [PATTERN]      list extensions\n"));
+       fprintf(output, _("  \\dX     [PATTERN]      list extended 
statistics\n"));
        fprintf(output, _("  \\dy     [PATTERN]      list event triggers\n"));
        fprintf(output, _("  \\l[+]   [PATTERN]      list databases\n"));
        fprintf(output, _("  \\sf[+]  FUNCNAME       show a function's 
definition\n"));
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 6abcbea963..17f7265038 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1505,7 +1505,7 @@ psql_completion(const char *text, int start, int end)
                "\\dF", "\\dFd", "\\dFp", "\\dFt", "\\dg", "\\di", "\\dl", 
"\\dL",
                "\\dm", "\\dn", "\\do", "\\dO", "\\dp", "\\dP", "\\dPi", 
"\\dPt",
                "\\drds", "\\dRs", "\\dRp", "\\ds", "\\dS",
-               "\\dt", "\\dT", "\\dv", "\\du", "\\dx", "\\dy",
+               "\\dt", "\\dT", "\\dv", "\\du", "\\dx", "\\dX", "\\dy",
                "\\e", "\\echo", "\\ef", "\\elif", "\\else", "\\encoding",
                "\\endif", "\\errverbose", "\\ev",
                "\\f",
@@ -3974,6 +3974,8 @@ psql_completion(const char *text, int start, int end)
                COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_views, NULL);
        else if (TailMatchesCS("\\dx*"))
                COMPLETE_WITH_QUERY(Query_for_list_of_extensions);
+       else if (TailMatchesCS("\\dX*"))
+               COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_statistics, NULL);
        else if (TailMatchesCS("\\dm*"))
                COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_matviews, NULL);
        else if (TailMatchesCS("\\dE*"))

Reply via email to