Hi Tomas,
On 2021/01/20 11:35, Tatsuro Yamada wrote:
Apologies for all the extra work - I haven't realized this flaw when pushing
for showing more stuff :-(
Don't worry about it. We didn't notice the problem even when viewed by multiple
people on -hackers. Let's keep moving forward. :-D
I'll send a patch including a regression test on the next patch.
I created patches and my test results on PG10, 11, 12, and 14 are fine.
0001:
- Fix query to use pg_statistic_ext only
- Replace statuses "required" and "built" with "defined"
- Remove the size columns
- Fix document
- Add schema name as a filter condition on the query
0002:
- Fix all results of \dX
- Add new testcase by non-superuser
Please find attached files. :-D
Regards,
Tatsuro Yamada
From 1aac3df2af2f6c834ffab10ddd1be1dee5970eb3 Mon Sep 17 00:00:00 2001
From: Tatsuro Yamada <yamatat...@gmail.com>
Date: Wed, 20 Jan 2021 15:33:04 +0900
Subject: [PATCH 2/2] psql \dX regression test
Add a test by non-superuser
---
src/test/regress/expected/stats_ext.out | 116 ++++++++++++++++++++++++++++++++
src/test/regress/sql/stats_ext.sql | 37 ++++++++++
2 files changed, 153 insertions(+)
diff --git a/src/test/regress/expected/stats_ext.out
b/src/test/regress/expected/stats_ext.out
index f094731e32..0ff4e51055 100644
--- a/src/test/regress/expected/stats_ext.out
+++ b/src/test/regress/expected/stats_ext.out
@@ -1727,6 +1727,122 @@ INSERT INTO tststats.priv_test_tbl
CREATE STATISTICS tststats.priv_test_stats (mcv) ON a, b
FROM tststats.priv_test_tbl;
ANALYZE tststats.priv_test_tbl;
+-- Check printing info about extended statistics by \dX
+create table stts_t1 (a int, b int);
+create statistics stts_1 (ndistinct) on a, b from stts_t1;
+create statistics stts_2 (ndistinct, dependencies) on a, b from stts_t1;
+create statistics stts_3 (ndistinct, dependencies, mcv) on a, b from stts_t1;
+create table stts_t2 (a int, b int, c int);
+create statistics stts_4 on b, c from stts_t2;
+create table stts_t3 (col1 int, col2 int, col3 int);
+create statistics stts_hoge on col1, col2, col3 from stts_t3;
+create schema stts_s1;
+create schema stts_s2;
+create statistics stts_s1.stts_foo on col1, col2 from stts_t3;
+create statistics stts_s2.stts_yama (dependencies, mcv) on col1, col3 from
stts_t3;
+insert into stts_t1 select i,i from generate_series(1,100) i;
+analyze stts_t1;
+\dX
+ List of extended statistics
+ Schema | Name | Definition |
Ndistinct | Dependencies | MCV
+----------+------------------------+--------------------------------------+-----------+--------------+---------
+ public | func_deps_stat | a, b, c FROM functional_dependencies |
| defined |
+ public | mcv_lists_arrays_stats | a, b, c FROM mcv_lists_arrays |
| | defined
+ public | mcv_lists_bool_stats | a, b, c FROM mcv_lists_bool |
| | defined
+ public | mcv_lists_stats | a, b, d FROM mcv_lists |
| | defined
+ public | stts_1 | a, b FROM stts_t1 |
defined | |
+ public | stts_2 | a, b FROM stts_t1 |
defined | defined |
+ public | stts_3 | a, b FROM stts_t1 |
defined | defined | defined
+ public | stts_4 | b, c FROM stts_t2 |
defined | defined | defined
+ public | stts_hoge | col1, col2, col3 FROM stts_t3 |
defined | defined | defined
+ stts_s1 | stts_foo | col1, col2 FROM stts_t3 |
defined | defined | defined
+ stts_s2 | stts_yama | col1, col3 FROM stts_t3 |
| defined | defined
+ tststats | priv_test_stats | a, b FROM tststats.priv_test_tbl |
| | defined
+(12 rows)
+
+\dX stts_?
+ List of extended statistics
+ Schema | Name | Definition | Ndistinct | Dependencies | MCV
+--------+--------+-------------------+-----------+--------------+---------
+ public | stts_1 | a, b FROM stts_t1 | defined | |
+ public | stts_2 | a, b FROM stts_t1 | defined | defined |
+ public | stts_3 | a, b FROM stts_t1 | defined | defined | defined
+ public | stts_4 | b, c FROM stts_t2 | defined | defined | defined
+(4 rows)
+
+\dX *stts_hoge
+ List of extended statistics
+ Schema | Name | Definition | Ndistinct | Dependencies
| MCV
+--------+-----------+-------------------------------+-----------+--------------+---------
+ public | stts_hoge | col1, col2, col3 FROM stts_t3 | defined | defined
| defined
+(1 row)
+
+\dX+
+ List of extended statistics
+ Schema | Name | Definition |
Ndistinct | Dependencies | MCV
+----------+------------------------+--------------------------------------+-----------+--------------+---------
+ public | func_deps_stat | a, b, c FROM functional_dependencies |
| defined |
+ public | mcv_lists_arrays_stats | a, b, c FROM mcv_lists_arrays |
| | defined
+ public | mcv_lists_bool_stats | a, b, c FROM mcv_lists_bool |
| | defined
+ public | mcv_lists_stats | a, b, d FROM mcv_lists |
| | defined
+ public | stts_1 | a, b FROM stts_t1 |
defined | |
+ public | stts_2 | a, b FROM stts_t1 |
defined | defined |
+ public | stts_3 | a, b FROM stts_t1 |
defined | defined | defined
+ public | stts_4 | b, c FROM stts_t2 |
defined | defined | defined
+ public | stts_hoge | col1, col2, col3 FROM stts_t3 |
defined | defined | defined
+ stts_s1 | stts_foo | col1, col2 FROM stts_t3 |
defined | defined | defined
+ stts_s2 | stts_yama | col1, col3 FROM stts_t3 |
| defined | defined
+ tststats | priv_test_stats | a, b FROM tststats.priv_test_tbl |
| | defined
+(12 rows)
+
+\dX+ stts_?
+ List of extended statistics
+ Schema | Name | Definition | Ndistinct | Dependencies | MCV
+--------+--------+-------------------+-----------+--------------+---------
+ public | stts_1 | a, b FROM stts_t1 | defined | |
+ public | stts_2 | a, b FROM stts_t1 | defined | defined |
+ public | stts_3 | a, b FROM stts_t1 | defined | defined | defined
+ public | stts_4 | b, c FROM stts_t2 | defined | defined | defined
+(4 rows)
+
+\dX+ *stts_hoge
+ List of extended statistics
+ Schema | Name | Definition | Ndistinct | Dependencies
| MCV
+--------+-----------+-------------------------------+-----------+--------------+---------
+ public | stts_hoge | col1, col2, col3 FROM stts_t3 | defined | defined
| defined
+(1 row)
+
+\dX+ stts_s2.stts_yama
+ List of extended statistics
+ Schema | Name | Definition | Ndistinct | Dependencies |
MCV
+---------+-----------+-------------------------+-----------+--------------+---------
+ stts_s2 | stts_yama | col1, col3 FROM stts_t3 | | defined |
defined
+(1 row)
+
+create user non_superuser password 'hoge';
+\connect regression non_superuser
+\dX
+ List of extended statistics
+ Schema | Name | Definition |
Ndistinct | Dependencies | MCV
+----------+------------------------+--------------------------------------+-----------+--------------+---------
+ public | func_deps_stat | a, b, c FROM functional_dependencies |
| defined |
+ public | mcv_lists_arrays_stats | a, b, c FROM mcv_lists_arrays |
| | defined
+ public | mcv_lists_bool_stats | a, b, c FROM mcv_lists_bool |
| | defined
+ public | mcv_lists_stats | a, b, d FROM mcv_lists |
| | defined
+ public | stts_1 | a, b FROM stts_t1 |
defined | |
+ public | stts_2 | a, b FROM stts_t1 |
defined | defined |
+ public | stts_3 | a, b FROM stts_t1 |
defined | defined | defined
+ public | stts_4 | b, c FROM stts_t2 |
defined | defined | defined
+ public | stts_hoge | col1, col2, col3 FROM stts_t3 |
defined | defined | defined
+ stts_s1 | stts_foo | col1, col2 FROM stts_t3 |
defined | defined | defined
+ stts_s2 | stts_yama | col1, col3 FROM stts_t3 |
| defined | defined
+ tststats | priv_test_stats | a, b FROM tststats.priv_test_tbl |
| | defined
+(12 rows)
+
+\connect regression postgres
+drop table stts_t1, stts_t2, stts_t3;
+drop schema stts_s1, stts_s2 cascade;
+drop user non_superuser;
-- User with no access
CREATE USER regress_stats_user1;
GRANT USAGE ON SCHEMA tststats TO regress_stats_user1;
diff --git a/src/test/regress/sql/stats_ext.sql
b/src/test/regress/sql/stats_ext.sql
index cb08b478a4..a946c350bd 100644
--- a/src/test/regress/sql/stats_ext.sql
+++ b/src/test/regress/sql/stats_ext.sql
@@ -914,6 +914,43 @@ CREATE STATISTICS tststats.priv_test_stats (mcv) ON a, b
ANALYZE tststats.priv_test_tbl;
+-- Check printing info about extended statistics by \dX
+create table stts_t1 (a int, b int);
+create statistics stts_1 (ndistinct) on a, b from stts_t1;
+create statistics stts_2 (ndistinct, dependencies) on a, b from stts_t1;
+create statistics stts_3 (ndistinct, dependencies, mcv) on a, b from stts_t1;
+
+create table stts_t2 (a int, b int, c int);
+create statistics stts_4 on b, c from stts_t2;
+
+create table stts_t3 (col1 int, col2 int, col3 int);
+create statistics stts_hoge on col1, col2, col3 from stts_t3;
+
+create schema stts_s1;
+create schema stts_s2;
+create statistics stts_s1.stts_foo on col1, col2 from stts_t3;
+create statistics stts_s2.stts_yama (dependencies, mcv) on col1, col3 from
stts_t3;
+
+insert into stts_t1 select i,i from generate_series(1,100) i;
+analyze stts_t1;
+
+\dX
+\dX stts_?
+\dX *stts_hoge
+\dX+
+\dX+ stts_?
+\dX+ *stts_hoge
+\dX+ stts_s2.stts_yama
+
+create user non_superuser password 'hoge';
+\connect regression non_superuser
+\dX
+\connect regression postgres
+
+drop table stts_t1, stts_t2, stts_t3;
+drop schema stts_s1, stts_s2 cascade;
+drop user non_superuser;
+
-- User with no access
CREATE USER regress_stats_user1;
GRANT USAGE ON SCHEMA tststats TO regress_stats_user1;
--
2.16.5
From e42b671f930765e16491f0dee5c1cfc1e57a9daa Mon Sep 17 00:00:00 2001
From: Tatsuro Yamada <yamatat...@gmail.com>
Date: Wed, 20 Jan 2021 15:09:27 +0900
Subject: [PATCH 1/2] psql \dX: list extended statistics objects take2
The new command lists extended statistics objects.
All past releases with extended statistics are supported.
Author: Tatsuro Yamada
Reviewed-by: Julien Rouhaud, Alvaro Herrera, Tomas Vondra, Justin Pryzby
Discussion:
https://postgr.es/m/c027a541-5856-75a5-0868-341301e1624b%40nttcom.co.jp_1
---
doc/src/sgml/ref/psql-ref.sgml | 20 ++++++++++
src/bin/psql/command.c | 3 ++
src/bin/psql/describe.c | 83 ++++++++++++++++++++++++++++++++++++++++++
src/bin/psql/describe.h | 3 ++
src/bin/psql/help.c | 1 +
src/bin/psql/tab-complete.c | 4 +-
6 files changed, 113 insertions(+), 1 deletion(-)
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..95954fc319 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,
+
"es.stxnamespace::pg_catalog.regnamespace::text", "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*"))
--
2.16.5