This commit adds three attributes to the system view pg_stats_ext_exprs,
whose data can exist when involving a range type in an expression:
range_length_histogram
range_empty_frac
range_bounds_histogram
These statistics fields exist since
918eee0c497c, and have become
viewable in pg_stats later in
bc3c8db8ae2f. This puts the definition of
pg_stats_ext_exprs on par with pg_stats.
This issue has showed up during the discussion about the restore of
extended statistics for expressions, so as it becomes possible to query
the stats data to restore from the catalogs. Having access to this data
is useful on its own, without the restore part.
Some documentation and some tests are added, written by me. Corey has
authored the part in system_views.sql.
Bump catalog version.
Author: Corey Huinker <corey.huinker@gmail.com>
Co-authored-by: Michael Paquier <michael@paquier.xyz>
Discussion: https://postgr.es/m/aYmCUx9VvrKiZQLL@paquier.xyz
non-null elements. (Null for scalar types.)
</para></entry>
</row>
+
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>range_length_histogram</structfield> <type>anyarray</type>
+ </para>
+ <para>
+ A histogram of the lengths of non-empty and non-null range values of an
+ expression. (Null for non-range types.)
+ </para>
+ <para>
+ This histogram is calculated using the <function>subtype_diff</function>
+ range function regardless of whether range bounds are inclusive.
+ </para></entry>
+ </row>
+
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>range_empty_frac</structfield> <type>float4</type>
+ </para>
+ <para>
+ Fraction of expression entries whose values are empty ranges.
+ (Null for non-range types.)
+ </para></entry>
+ </row>
+
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>range_bounds_histogram</structfield> <type>anyarray</type>
+ </para>
+ <para>
+ A histogram of lower and upper bounds of non-empty and non-null range
+ values. (Null for non-range types.)
+ </para>
+ <para>
+ These two histograms are represented as a single array of ranges, whose
+ lower bounds represent the histogram of lower bounds, and upper bounds
+ represent the histogram of upper bounds.
+ </para></entry>
+ </row>
</tbody>
</tgroup>
</table>
WHEN (stat.a).stakind3 = 5 THEN (stat.a).stanumbers3
WHEN (stat.a).stakind4 = 5 THEN (stat.a).stanumbers4
WHEN (stat.a).stakind5 = 5 THEN (stat.a).stanumbers5
- END) AS elem_count_histogram
+ END) AS elem_count_histogram,
+ (CASE
+ WHEN (stat.a).stakind1 = 6 THEN (stat.a).stavalues1
+ WHEN (stat.a).stakind2 = 6 THEN (stat.a).stavalues2
+ WHEN (stat.a).stakind3 = 6 THEN (stat.a).stavalues3
+ WHEN (stat.a).stakind4 = 6 THEN (stat.a).stavalues4
+ WHEN (stat.a).stakind5 = 6 THEN (stat.a).stavalues5
+ END) AS range_length_histogram,
+ (CASE
+ WHEN (stat.a).stakind1 = 6 THEN (stat.a).stanumbers1[1]
+ WHEN (stat.a).stakind2 = 6 THEN (stat.a).stanumbers2[1]
+ WHEN (stat.a).stakind3 = 6 THEN (stat.a).stanumbers3[1]
+ WHEN (stat.a).stakind4 = 6 THEN (stat.a).stanumbers4[1]
+ WHEN (stat.a).stakind5 = 6 THEN (stat.a).stanumbers5[1]
+ END) AS range_empty_frac,
+ (CASE
+ WHEN (stat.a).stakind1 = 7 THEN (stat.a).stavalues1
+ WHEN (stat.a).stakind2 = 7 THEN (stat.a).stavalues2
+ WHEN (stat.a).stakind3 = 7 THEN (stat.a).stavalues3
+ WHEN (stat.a).stakind4 = 7 THEN (stat.a).stavalues4
+ WHEN (stat.a).stakind5 = 7 THEN (stat.a).stavalues5
+ END) AS range_bounds_histogram
FROM pg_statistic_ext s JOIN pg_class c ON (c.oid = s.stxrelid)
LEFT JOIN pg_statistic_ext_data sd ON (s.oid = sd.stxoid)
LEFT JOIN pg_namespace cn ON (cn.oid = c.relnamespace)
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 202602051
+#define CATALOG_VERSION_NO 202602101
#endif
WHEN ((stat.a).stakind4 = 5) THEN (stat.a).stanumbers4
WHEN ((stat.a).stakind5 = 5) THEN (stat.a).stanumbers5
ELSE NULL::real[]
- END AS elem_count_histogram
+ END AS elem_count_histogram,
+ CASE
+ WHEN ((stat.a).stakind1 = 6) THEN (stat.a).stavalues1
+ WHEN ((stat.a).stakind2 = 6) THEN (stat.a).stavalues2
+ WHEN ((stat.a).stakind3 = 6) THEN (stat.a).stavalues3
+ WHEN ((stat.a).stakind4 = 6) THEN (stat.a).stavalues4
+ WHEN ((stat.a).stakind5 = 6) THEN (stat.a).stavalues5
+ ELSE NULL::anyarray
+ END AS range_length_histogram,
+ CASE
+ WHEN ((stat.a).stakind1 = 6) THEN (stat.a).stanumbers1[1]
+ WHEN ((stat.a).stakind2 = 6) THEN (stat.a).stanumbers2[1]
+ WHEN ((stat.a).stakind3 = 6) THEN (stat.a).stanumbers3[1]
+ WHEN ((stat.a).stakind4 = 6) THEN (stat.a).stanumbers4[1]
+ WHEN ((stat.a).stakind5 = 6) THEN (stat.a).stanumbers5[1]
+ ELSE NULL::real
+ END AS range_empty_frac,
+ CASE
+ WHEN ((stat.a).stakind1 = 7) THEN (stat.a).stavalues1
+ WHEN ((stat.a).stakind2 = 7) THEN (stat.a).stavalues2
+ WHEN ((stat.a).stakind3 = 7) THEN (stat.a).stavalues3
+ WHEN ((stat.a).stakind4 = 7) THEN (stat.a).stavalues4
+ WHEN ((stat.a).stakind5 = 7) THEN (stat.a).stavalues5
+ ELSE NULL::anyarray
+ END AS range_bounds_histogram
FROM (((((pg_statistic_ext s
JOIN pg_class c ON ((c.oid = s.stxrelid)))
LEFT JOIN pg_statistic_ext_data sd ON ((s.oid = sd.stxoid)))
-- Tidy up
DROP TABLE sb_1, sb_2 CASCADE;
+-- Check statistics generated for range type and expressions.
+CREATE TABLE stats_ext_tbl_range(name text, irange int4range);
+INSERT INTO stats_ext_tbl_range VALUES
+ ('red', '[1,7)'::int4range),
+ ('blue', '[2,8]'::int4range),
+ ('green', '[3,9)'::int4range);
+CREATE STATISTICS stats_ext_range (mcv)
+ ON irange, (irange + '[4,10)'::int4range)
+ FROM stats_ext_tbl_range;
+ANALYZE stats_ext_tbl_range;
+SELECT attnames, most_common_vals
+ FROM pg_stats_ext
+ WHERE statistics_name = 'stats_ext_range';
+ attnames | most_common_vals
+----------+------------------------------------------------------------
+ {irange} | {{"[1,7)","[1,10)"},{"[2,9)","[2,10)"},{"[3,9)","[3,10)"}}
+(1 row)
+
+SELECT range_length_histogram, range_empty_frac, range_bounds_histogram
+ FROM pg_stats_ext_exprs
+ WHERE statistics_name = 'stats_ext_range';
+ range_length_histogram | range_empty_frac | range_bounds_histogram
+------------------------+------------------+------------------------------
+ {7,8,9} | 0 | {"[1,10)","[2,10)","[3,10)"}
+(1 row)
+
+DROP TABLE stats_ext_tbl_range;
-- Tidy up
DROP TABLE sb_1, sb_2 CASCADE;
+
+-- Check statistics generated for range type and expressions.
+CREATE TABLE stats_ext_tbl_range(name text, irange int4range);
+INSERT INTO stats_ext_tbl_range VALUES
+ ('red', '[1,7)'::int4range),
+ ('blue', '[2,8]'::int4range),
+ ('green', '[3,9)'::int4range);
+CREATE STATISTICS stats_ext_range (mcv)
+ ON irange, (irange + '[4,10)'::int4range)
+ FROM stats_ext_tbl_range;
+ANALYZE stats_ext_tbl_range;
+SELECT attnames, most_common_vals
+ FROM pg_stats_ext
+ WHERE statistics_name = 'stats_ext_range';
+SELECT range_length_histogram, range_empty_frac, range_bounds_histogram
+ FROM pg_stats_ext_exprs
+ WHERE statistics_name = 'stats_ext_range';
+DROP TABLE stats_ext_tbl_range;