mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
Add pg_stats_ext view for extended statistics
Regular per-column statistics are stored in pg_statistics catalog, which is however rather difficult to read, so we also have pg_stats view with a human-reablable version of the data. For extended statistic the catalog was fairly easy to read, so we did not have such human-readable view so far. Commit 9b6babfa2d however did split the catalog into two, which makes querying harder. Furthermore, we want to show the multi-column MCV list in a way similar to per-column stats (and not as a bytea value). This commit introduces pg_stats_ext view, joining the two catalogs and massaging the data to produce human-readable output similar to pg_stats. It also considers RLS and access privileges - the data is shown only when the user has access to all columns the extended statistic is defined on. Bumped CATVERSION due to adding new system view. Author: Dean Rasheed, with improvements by me Reviewed-by: Dean Rasheed, John Naylor Discussion: https://postgr.es/m/CAEZATCUhT9rt7Ui%3DVdx4N%3D%3DVV5XOK5dsXfnGgVOz_JhAicB%3DZA%40mail.gmail.com
This commit is contained in:
@ -2284,6 +2284,35 @@ pg_stats| SELECT n.nspname AS schemaname,
|
||||
JOIN pg_attribute a ON (((c.oid = a.attrelid) AND (a.attnum = s.staattnum))))
|
||||
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
|
||||
WHERE ((NOT a.attisdropped) AND has_column_privilege(c.oid, a.attnum, 'select'::text) AND ((c.relrowsecurity = false) OR (NOT row_security_active(c.oid))));
|
||||
pg_stats_ext| SELECT cn.nspname AS schemaname,
|
||||
c.relname AS tablename,
|
||||
sn.nspname AS statistics_schemaname,
|
||||
s.stxname AS statistics_name,
|
||||
pg_get_userbyid(s.stxowner) AS statistics_owner,
|
||||
( SELECT array_agg(a.attname ORDER BY a.attnum) AS array_agg
|
||||
FROM (unnest(s.stxkeys) k(k)
|
||||
JOIN pg_attribute a ON (((a.attrelid = s.stxrelid) AND (a.attnum = k.k))))) AS attnames,
|
||||
s.stxkind AS kinds,
|
||||
sd.stxdndistinct AS n_distinct,
|
||||
sd.stxddependencies AS dependencies,
|
||||
m.most_common_vals,
|
||||
m.most_common_val_nulls,
|
||||
m.most_common_freqs,
|
||||
m.most_common_base_freqs
|
||||
FROM (((((pg_statistic_ext s
|
||||
JOIN pg_class c ON ((c.oid = s.stxrelid)))
|
||||
JOIN pg_statistic_ext_data sd ON ((s.oid = sd.stxoid)))
|
||||
LEFT JOIN pg_namespace cn ON ((cn.oid = c.relnamespace)))
|
||||
LEFT JOIN pg_namespace sn ON ((sn.oid = s.stxnamespace)))
|
||||
LEFT JOIN LATERAL ( SELECT array_agg(pg_mcv_list_items."values") AS most_common_vals,
|
||||
array_agg(pg_mcv_list_items.nulls) AS most_common_val_nulls,
|
||||
array_agg(pg_mcv_list_items.frequency) AS most_common_freqs,
|
||||
array_agg(pg_mcv_list_items.base_frequency) AS most_common_base_freqs
|
||||
FROM pg_mcv_list_items(sd.stxdmcv) pg_mcv_list_items(index, "values", nulls, frequency, base_frequency)) m ON ((sd.stxdmcv IS NOT NULL)))
|
||||
WHERE ((NOT (EXISTS ( SELECT 1
|
||||
FROM (unnest(s.stxkeys) k(k)
|
||||
JOIN pg_attribute a ON (((a.attrelid = s.stxrelid) AND (a.attnum = k.k))))
|
||||
WHERE (NOT has_column_privilege(c.oid, a.attnum, 'select'::text))))) AND ((c.relrowsecurity = false) OR (NOT row_security_active(c.oid))));
|
||||
pg_tables| SELECT n.nspname AS schemaname,
|
||||
c.relname AS tablename,
|
||||
pg_get_userbyid(c.relowner) AS tableowner,
|
||||
|
Reference in New Issue
Block a user