psql \dX: list extended statistics objects
The new command lists extended statistics objects. All past releases with extended statistics are supported. This is a simplified version of commit 891a1d0bca, which had to be reverted due to not considering pg_statistic_ext_data is not accessible by regular users. Fields requiring access to this catalog were removed. It's possible to add them, but it'll require changes to core. Author: Tatsuro Yamada Reviewed-by: Julien Rouhaud, Alvaro Herrera, Tomas Vondra, Noriyoshi Shinoda Discussion: https://postgr.es/m/c027a541-5856-75a5-0868-341301e1624b%40nttcom.co.jp_1
This commit is contained in:
parent
9d23c15a03
commit
ad600bba04
@ -1919,6 +1919,27 @@ testdb=>
|
|||||||
</listitem>
|
</listitem>
|
||||||
</varlistentry>
|
</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 was requested
|
||||||
|
when creating the statistics.
|
||||||
|
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>
|
<varlistentry>
|
||||||
<term><literal>\dy[+] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
|
<term><literal>\dy[+] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
|
||||||
<listitem>
|
<listitem>
|
||||||
|
@ -928,6 +928,9 @@ exec_command_d(PsqlScanState scan_state, bool active_branch, const char *cmd)
|
|||||||
else
|
else
|
||||||
success = listExtensions(pattern);
|
success = listExtensions(pattern);
|
||||||
break;
|
break;
|
||||||
|
case 'X': /* Extended Statistics */
|
||||||
|
success = listExtendedStats(pattern);
|
||||||
|
break;
|
||||||
case 'y': /* Event Triggers */
|
case 'y': /* Event Triggers */
|
||||||
success = listEventTriggers(pattern, show_verbose);
|
success = listEventTriggers(pattern, show_verbose);
|
||||||
break;
|
break;
|
||||||
|
@ -4392,6 +4392,89 @@ listEventTriggers(const char *pattern, bool verbose)
|
|||||||
return true;
|
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"));
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Include 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
|
* \dC
|
||||||
*
|
*
|
||||||
|
@ -102,6 +102,9 @@ extern bool listExtensions(const char *pattern);
|
|||||||
/* \dx+ */
|
/* \dx+ */
|
||||||
extern bool listExtensionContents(const char *pattern);
|
extern bool listExtensionContents(const char *pattern);
|
||||||
|
|
||||||
|
/* \dX */
|
||||||
|
extern bool listExtendedStats(const char *pattern);
|
||||||
|
|
||||||
/* \dy */
|
/* \dy */
|
||||||
extern bool listEventTriggers(const char *pattern, bool verbose);
|
extern bool listEventTriggers(const char *pattern, bool verbose);
|
||||||
|
|
||||||
|
@ -267,6 +267,7 @@ slashUsage(unsigned short int pager)
|
|||||||
fprintf(output, _(" \\du[S+] [PATTERN] list roles\n"));
|
fprintf(output, _(" \\du[S+] [PATTERN] list roles\n"));
|
||||||
fprintf(output, _(" \\dv[S+] [PATTERN] list views\n"));
|
fprintf(output, _(" \\dv[S+] [PATTERN] list views\n"));
|
||||||
fprintf(output, _(" \\dx[+] [PATTERN] list extensions\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, _(" \\dy [PATTERN] list event triggers\n"));
|
||||||
fprintf(output, _(" \\l[+] [PATTERN] list databases\n"));
|
fprintf(output, _(" \\l[+] [PATTERN] list databases\n"));
|
||||||
fprintf(output, _(" \\sf[+] FUNCNAME show a function's definition\n"));
|
fprintf(output, _(" \\sf[+] FUNCNAME show a function's definition\n"));
|
||||||
|
@ -1505,7 +1505,7 @@ psql_completion(const char *text, int start, int end)
|
|||||||
"\\dF", "\\dFd", "\\dFp", "\\dFt", "\\dg", "\\di", "\\dl", "\\dL",
|
"\\dF", "\\dFd", "\\dFp", "\\dFt", "\\dg", "\\di", "\\dl", "\\dL",
|
||||||
"\\dm", "\\dn", "\\do", "\\dO", "\\dp", "\\dP", "\\dPi", "\\dPt",
|
"\\dm", "\\dn", "\\do", "\\dO", "\\dp", "\\dP", "\\dPi", "\\dPt",
|
||||||
"\\drds", "\\dRs", "\\dRp", "\\ds", "\\dS",
|
"\\drds", "\\dRs", "\\dRp", "\\ds", "\\dS",
|
||||||
"\\dt", "\\dT", "\\dv", "\\du", "\\dx", "\\dy",
|
"\\dt", "\\dT", "\\dv", "\\du", "\\dx", "\\dX", "\\dy",
|
||||||
"\\e", "\\echo", "\\ef", "\\elif", "\\else", "\\encoding",
|
"\\e", "\\echo", "\\ef", "\\elif", "\\else", "\\encoding",
|
||||||
"\\endif", "\\errverbose", "\\ev",
|
"\\endif", "\\errverbose", "\\ev",
|
||||||
"\\f",
|
"\\f",
|
||||||
@ -3974,6 +3974,8 @@ psql_completion(const char *text, int start, int end)
|
|||||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_views, NULL);
|
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_views, NULL);
|
||||||
else if (TailMatchesCS("\\dx*"))
|
else if (TailMatchesCS("\\dx*"))
|
||||||
COMPLETE_WITH_QUERY(Query_for_list_of_extensions);
|
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*"))
|
else if (TailMatchesCS("\\dm*"))
|
||||||
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_matviews, NULL);
|
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_matviews, NULL);
|
||||||
else if (TailMatchesCS("\\dE*"))
|
else if (TailMatchesCS("\\dE*"))
|
||||||
|
@ -1727,6 +1727,122 @@ INSERT INTO tststats.priv_test_tbl
|
|||||||
CREATE STATISTICS tststats.priv_test_stats (mcv) ON a, b
|
CREATE STATISTICS tststats.priv_test_stats (mcv) ON a, b
|
||||||
FROM tststats.priv_test_tbl;
|
FROM tststats.priv_test_tbl;
|
||||||
ANALYZE 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 role regress_stats_ext nosuperuser;
|
||||||
|
set role regress_stats_ext;
|
||||||
|
\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)
|
||||||
|
|
||||||
|
reset role;
|
||||||
|
drop table stts_t1, stts_t2, stts_t3;
|
||||||
|
drop schema stts_s1, stts_s2 cascade;
|
||||||
|
drop user regress_stats_ext;
|
||||||
-- User with no access
|
-- User with no access
|
||||||
CREATE USER regress_stats_user1;
|
CREATE USER regress_stats_user1;
|
||||||
GRANT USAGE ON SCHEMA tststats TO regress_stats_user1;
|
GRANT USAGE ON SCHEMA tststats TO regress_stats_user1;
|
||||||
|
@ -914,6 +914,43 @@ CREATE STATISTICS tststats.priv_test_stats (mcv) ON a, b
|
|||||||
|
|
||||||
ANALYZE 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
|
||||||
|
\dX stts_?
|
||||||
|
\dX *stts_hoge
|
||||||
|
\dX+
|
||||||
|
\dX+ stts_?
|
||||||
|
\dX+ *stts_hoge
|
||||||
|
\dX+ stts_s2.stts_yama
|
||||||
|
|
||||||
|
create role regress_stats_ext nosuperuser;
|
||||||
|
set role regress_stats_ext;
|
||||||
|
\dX
|
||||||
|
reset role;
|
||||||
|
|
||||||
|
drop table stts_t1, stts_t2, stts_t3;
|
||||||
|
drop schema stts_s1, stts_s2 cascade;
|
||||||
|
drop user regress_stats_ext;
|
||||||
|
|
||||||
-- User with no access
|
-- User with no access
|
||||||
CREATE USER regress_stats_user1;
|
CREATE USER regress_stats_user1;
|
||||||
GRANT USAGE ON SCHEMA tststats TO regress_stats_user1;
|
GRANT USAGE ON SCHEMA tststats TO regress_stats_user1;
|
||||||
|
Loading…
x
Reference in New Issue
Block a user