Add functions pg_set_attribute_stats() and pg_clear_attribute_stats().

Enable manipulation of attribute statistics. Only superficial
validation is performed, so it's possible to add nonsense, and it's up
to the planner (or other users of statistics) to behave reasonably in
that case.

Bump catalog version.

Author: Corey Huinker
Discussion: https://postgr.es/m/CADkLM=eErgzn7ECDpwFcptJKOk9SxZEk5Pot4d94eVTZsvj3gw@mail.gmail.com
This commit is contained in:
Jeff Davis 2024-10-22 15:06:55 -07:00
parent dbe6bd4343
commit ce207d2a79
11 changed files with 2263 additions and 2 deletions

View File

@ -30222,6 +30222,78 @@ DETAIL: Make sure pg_wal_replay_wait() isn't called within a transaction with a
</para>
</entry>
</row>
<row>
<entry role="func_table_entry">
<para role="func_signature">
<indexterm>
<primary>pg_set_attribute_stats</primary>
</indexterm>
<function>pg_set_attribute_stats</function> (
<parameter>relation</parameter> <type>regclass</type>,
<parameter>attname</parameter> <type>name</type>,
<parameter>inherited</parameter> <type>boolean</type>
<optional>, <parameter>null_frac</parameter> <type>real</type></optional>
<optional>, <parameter>avg_width</parameter> <type>integer</type></optional>
<optional>, <parameter>n_distinct</parameter> <type>real</type></optional>
<optional>, <parameter>most_common_vals</parameter> <type>text</type>, <parameter>most_common_freqs</parameter> <type>real[]</type> </optional>
<optional>, <parameter>histogram_bounds</parameter> <type>text</type> </optional>
<optional>, <parameter>correlation</parameter> <type>real</type> </optional>
<optional>, <parameter>most_common_elems</parameter> <type>text</type>, <parameter>most_common_elem_freqs</parameter> <type>real[]</type> </optional>
<optional>, <parameter>elem_count_histogram</parameter> <type>real[]</type> </optional>
<optional>, <parameter>range_length_histogram</parameter> <type>text</type> </optional>
<optional>, <parameter>range_empty_frac</parameter> <type>real</type> </optional>
<optional>, <parameter>range_bounds_histogram</parameter> <type>text</type> </optional> )
<returnvalue>void</returnvalue>
</para>
<para>
Creates or updates attribute-level statistics for the given relation
and attribute name to the specified values. The parameters correspond
to to attributes of the same name found in the <link
linkend="view-pg-stats"><structname>pg_stats</structname></link>
view.
</para>
<para>
Optional parameters default to <literal>NULL</literal>, which leave
the corresponding statistic unchanged.
</para>
<para>
Ordinarily, these statistics are collected automatically or updated
as a part of <xref linkend="sql-vacuum"/> or <xref
linkend="sql-analyze"/>, so it's not necessary to call this
function. However, it may be useful when testing the effects of
statistics on the planner to understand or anticipate plan changes.
</para>
<para>
The caller must have the <literal>MAINTAIN</literal> privilege on
the table or be the owner of the database.
</para>
</entry>
</row>
<row>
<entry role="func_table_entry">
<para role="func_signature">
<indexterm>
<primary>pg_clear_attribute_stats</primary>
</indexterm>
<function>pg_clear_attribute_stats</function> (
<parameter>relation</parameter> <type>regclass</type>,
<parameter>attname</parameter> <type>name</type>,
<parameter>inherited</parameter> <type>boolean</type> )
<returnvalue>boolean</returnvalue>
</para>
<para>
Clears table-level statistics for the given relation attribute, as
though the table was newly created.
</para>
<para>
The caller must have the <literal>MAINTAIN</literal> privilege on
the table or be the owner of the database.
</para>
</entry>
</row>
</tbody>
</tgroup>
</table>

View File

@ -649,6 +649,28 @@ LANGUAGE INTERNAL
CALLED ON NULL INPUT VOLATILE
AS 'pg_set_relation_stats';
CREATE OR REPLACE FUNCTION
pg_set_attribute_stats(relation regclass,
attname name,
inherited bool,
null_frac real DEFAULT NULL,
avg_width integer DEFAULT NULL,
n_distinct real DEFAULT NULL,
most_common_vals text DEFAULT NULL,
most_common_freqs real[] DEFAULT NULL,
histogram_bounds text DEFAULT NULL,
correlation real DEFAULT NULL,
most_common_elems text DEFAULT NULL,
most_common_elem_freqs real[] DEFAULT NULL,
elem_count_histogram real[] DEFAULT NULL,
range_length_histogram text DEFAULT NULL,
range_empty_frac real DEFAULT NULL,
range_bounds_histogram text DEFAULT NULL)
RETURNS void
LANGUAGE INTERNAL
CALLED ON NULL INPUT VOLATILE
AS 'pg_set_attribute_stats';
--
-- The default permissions for functions mean that anyone can execute them.
-- A number of functions shouldn't be executable by just anyone, but rather

View File

@ -13,6 +13,7 @@ top_builddir = ../../..
include $(top_builddir)/src/Makefile.global
OBJS = \
attribute_stats.o \
dependencies.o \
extended_stats.o \
mcv.o \

View File

@ -0,0 +1,869 @@
/*-------------------------------------------------------------------------
* attribute_stats.c
*
* PostgreSQL relation attribute statistics manipulation.
*
* Code supporting the direct import of relation attribute statistics, similar
* to what is done by the ANALYZE command.
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* src/backend/statistics/attribute_stats.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "access/heapam.h"
#include "catalog/indexing.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_operator.h"
#include "nodes/nodeFuncs.h"
#include "statistics/statistics.h"
#include "statistics/stat_utils.h"
#include "utils/array.h"
#include "utils/builtins.h"
#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/syscache.h"
#define DEFAULT_NULL_FRAC Float4GetDatum(0.0)
#define DEFAULT_AVG_WIDTH Int32GetDatum(0) /* unknown */
#define DEFAULT_N_DISTINCT Float4GetDatum(0.0) /* unknown */
enum attribute_stats_argnum
{
ATTRELATION_ARG = 0,
ATTNAME_ARG,
INHERITED_ARG,
NULL_FRAC_ARG,
AVG_WIDTH_ARG,
N_DISTINCT_ARG,
MOST_COMMON_VALS_ARG,
MOST_COMMON_FREQS_ARG,
HISTOGRAM_BOUNDS_ARG,
CORRELATION_ARG,
MOST_COMMON_ELEMS_ARG,
MOST_COMMON_ELEM_FREQS_ARG,
ELEM_COUNT_HISTOGRAM_ARG,
RANGE_LENGTH_HISTOGRAM_ARG,
RANGE_EMPTY_FRAC_ARG,
RANGE_BOUNDS_HISTOGRAM_ARG,
NUM_ATTRIBUTE_STATS_ARGS
};
static struct StatsArgInfo attarginfo[] =
{
[ATTRELATION_ARG] = {"relation", REGCLASSOID},
[ATTNAME_ARG] = {"attname", NAMEOID},
[INHERITED_ARG] = {"inherited", BOOLOID},
[NULL_FRAC_ARG] = {"null_frac", FLOAT4OID},
[AVG_WIDTH_ARG] = {"avg_width", INT4OID},
[N_DISTINCT_ARG] = {"n_distinct", FLOAT4OID},
[MOST_COMMON_VALS_ARG] = {"most_common_vals", TEXTOID},
[MOST_COMMON_FREQS_ARG] = {"most_common_freqs", FLOAT4ARRAYOID},
[HISTOGRAM_BOUNDS_ARG] = {"histogram_bounds", TEXTOID},
[CORRELATION_ARG] = {"correlation", FLOAT4OID},
[MOST_COMMON_ELEMS_ARG] = {"most_common_elems", TEXTOID},
[MOST_COMMON_ELEM_FREQS_ARG] = {"most_common_elem_freqs", FLOAT4ARRAYOID},
[ELEM_COUNT_HISTOGRAM_ARG] = {"elem_count_histogram", FLOAT4ARRAYOID},
[RANGE_LENGTH_HISTOGRAM_ARG] = {"range_length_histogram", TEXTOID},
[RANGE_EMPTY_FRAC_ARG] = {"range_empty_frac", FLOAT4OID},
[RANGE_BOUNDS_HISTOGRAM_ARG] = {"range_bounds_histogram", TEXTOID},
[NUM_ATTRIBUTE_STATS_ARGS] = {0}
};
static bool attribute_statistics_update(FunctionCallInfo fcinfo, int elevel);
static Node *get_attr_expr(Relation rel, int attnum);
static void get_attr_stat_type(Oid reloid, AttrNumber attnum, int elevel,
Oid *atttypid, int32 *atttypmod,
char *atttyptype, Oid *atttypcoll,
Oid *eq_opr, Oid *lt_opr);
static bool get_elem_stat_type(Oid atttypid, char atttyptype, int elevel,
Oid *elemtypid, Oid *elem_eq_opr);
static Datum text_to_stavalues(const char *staname, FmgrInfo *array_in, Datum d,
Oid typid, int32 typmod, int elevel, bool *ok);
static void set_stats_slot(Datum *values, bool *nulls, bool *replaces,
int16 stakind, Oid staop, Oid stacoll,
Datum stanumbers, bool stanumbers_isnull,
Datum stavalues, bool stavalues_isnull);
static void upsert_pg_statistic(Relation starel, HeapTuple oldtup,
Datum *values, bool *nulls, bool *replaces);
static bool delete_pg_statistic(Oid reloid, AttrNumber attnum, bool stainherit);
static void init_empty_stats_tuple(Oid reloid, int16 attnum, bool inherited,
Datum *values, bool *nulls, bool *replaces);
/*
* Insert or Update Attribute Statistics
*
* See pg_statistic.h for an explanation of how each statistic kind is
* stored. Custom statistics kinds are not supported.
*
* Depending on the statistics kind, we need to derive information from the
* attribute for which we're storing the stats. For instance, the MCVs are
* stored as an anyarray, and the representation of the array needs to store
* the correct element type, which must be derived from the attribute.
*
* Major errors, such as the table not existing, the attribute not existing,
* or a permissions failure are always reported at ERROR. Other errors, such
* as a conversion failure on one statistic kind, are reported at 'elevel',
* and other statistic kinds may still be updated.
*/
static bool
attribute_statistics_update(FunctionCallInfo fcinfo, int elevel)
{
Oid reloid;
Name attname;
bool inherited;
AttrNumber attnum;
Relation starel;
HeapTuple statup;
Oid atttypid = InvalidOid;
int32 atttypmod;
char atttyptype;
Oid atttypcoll = InvalidOid;
Oid eq_opr = InvalidOid;
Oid lt_opr = InvalidOid;
Oid elemtypid = InvalidOid;
Oid elem_eq_opr = InvalidOid;
FmgrInfo array_in_fn;
bool do_mcv = !PG_ARGISNULL(MOST_COMMON_FREQS_ARG) &&
!PG_ARGISNULL(MOST_COMMON_VALS_ARG);
bool do_histogram = !PG_ARGISNULL(HISTOGRAM_BOUNDS_ARG);
bool do_correlation = !PG_ARGISNULL(CORRELATION_ARG);
bool do_mcelem = !PG_ARGISNULL(MOST_COMMON_ELEMS_ARG) &&
!PG_ARGISNULL(MOST_COMMON_ELEM_FREQS_ARG);
bool do_dechist = !PG_ARGISNULL(ELEM_COUNT_HISTOGRAM_ARG);
bool do_bounds_histogram = !PG_ARGISNULL(RANGE_BOUNDS_HISTOGRAM_ARG);
bool do_range_length_histogram = !PG_ARGISNULL(RANGE_LENGTH_HISTOGRAM_ARG) &&
!PG_ARGISNULL(RANGE_EMPTY_FRAC_ARG);
Datum values[Natts_pg_statistic] = {0};
bool nulls[Natts_pg_statistic] = {0};
bool replaces[Natts_pg_statistic] = {0};
bool result = true;
stats_check_required_arg(fcinfo, attarginfo, ATTRELATION_ARG);
reloid = PG_GETARG_OID(ATTRELATION_ARG);
/* lock before looking up attribute */
stats_lock_check_privileges(reloid);
stats_check_required_arg(fcinfo, attarginfo, ATTNAME_ARG);
attname = PG_GETARG_NAME(ATTNAME_ARG);
attnum = get_attnum(reloid, NameStr(*attname));
stats_check_required_arg(fcinfo, attarginfo, INHERITED_ARG);
inherited = PG_GETARG_BOOL(INHERITED_ARG);
/*
* Check argument sanity. If some arguments are unusable, emit at elevel
* and set the corresponding argument to NULL in fcinfo.
*/
if (!stats_check_arg_array(fcinfo, attarginfo, MOST_COMMON_FREQS_ARG,
elevel))
{
do_mcv = false;
result = false;
}
if (!stats_check_arg_array(fcinfo, attarginfo, MOST_COMMON_ELEM_FREQS_ARG,
elevel))
{
do_mcelem = false;
result = false;
}
if (!stats_check_arg_array(fcinfo, attarginfo, ELEM_COUNT_HISTOGRAM_ARG,
elevel))
{
do_dechist = false;
result = false;
}
if (!stats_check_arg_pair(fcinfo, attarginfo,
MOST_COMMON_VALS_ARG, MOST_COMMON_FREQS_ARG,
elevel))
{
do_mcv = false;
result = false;
}
if (!stats_check_arg_pair(fcinfo, attarginfo,
MOST_COMMON_ELEMS_ARG,
MOST_COMMON_ELEM_FREQS_ARG, elevel))
{
do_mcelem = false;
result = false;
}
if (!stats_check_arg_pair(fcinfo, attarginfo,
RANGE_LENGTH_HISTOGRAM_ARG,
RANGE_EMPTY_FRAC_ARG, elevel))
{
do_range_length_histogram = false;
result = false;
}
/* derive information from attribute */
get_attr_stat_type(reloid, attnum, elevel,
&atttypid, &atttypmod,
&atttyptype, &atttypcoll,
&eq_opr, &lt_opr);
/* if needed, derive element type */
if (do_mcelem || do_dechist)
{
if (!get_elem_stat_type(atttypid, atttyptype, elevel,
&elemtypid, &elem_eq_opr))
{
ereport(elevel,
(errmsg("unable to determine element type of attribute \"%s\"", NameStr(*attname)),
errdetail("Cannot set STATISTIC_KIND_MCELEM or STATISTIC_KIND_DECHIST.")));
elemtypid = InvalidOid;
elem_eq_opr = InvalidOid;
do_mcelem = false;
do_dechist = false;
result = false;
}
}
/* histogram and correlation require less-than operator */
if ((do_histogram || do_correlation) && !OidIsValid(lt_opr))
{
ereport(elevel,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("could not determine less-than operator for attribute \"%s\"", NameStr(*attname)),
errdetail("Cannot set STATISTIC_KIND_HISTOGRAM or STATISTIC_KIND_CORRELATION.")));
do_histogram = false;
do_correlation = false;
result = false;
}
/* only range types can have range stats */
if ((do_range_length_histogram || do_bounds_histogram) &&
!(atttyptype == TYPTYPE_RANGE || atttyptype == TYPTYPE_MULTIRANGE))
{
ereport(elevel,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("attribute \"%s\" is not a range type", NameStr(*attname)),
errdetail("Cannot set STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM or STATISTIC_KIND_BOUNDS_HISTOGRAM.")));
do_bounds_histogram = false;
do_range_length_histogram = false;
result = false;
}
fmgr_info(F_ARRAY_IN, &array_in_fn);
starel = table_open(StatisticRelationId, RowExclusiveLock);
statup = SearchSysCache3(STATRELATTINH, reloid, attnum, inherited);
/* initialize from existing tuple if exists */
if (HeapTupleIsValid(statup))
heap_deform_tuple(statup, RelationGetDescr(starel), values, nulls);
else
init_empty_stats_tuple(reloid, attnum, inherited, values, nulls,
replaces);
/* if specified, set to argument values */
if (!PG_ARGISNULL(NULL_FRAC_ARG))
{
values[Anum_pg_statistic_stanullfrac - 1] = PG_GETARG_DATUM(NULL_FRAC_ARG);
replaces[Anum_pg_statistic_stanullfrac - 1] = true;
}
if (!PG_ARGISNULL(AVG_WIDTH_ARG))
{
values[Anum_pg_statistic_stawidth - 1] = PG_GETARG_DATUM(AVG_WIDTH_ARG);
replaces[Anum_pg_statistic_stawidth - 1] = true;
}
if (!PG_ARGISNULL(N_DISTINCT_ARG))
{
values[Anum_pg_statistic_stadistinct - 1] = PG_GETARG_DATUM(N_DISTINCT_ARG);
replaces[Anum_pg_statistic_stadistinct - 1] = true;
}
/* STATISTIC_KIND_MCV */
if (do_mcv)
{
bool converted;
Datum stanumbers = PG_GETARG_DATUM(MOST_COMMON_FREQS_ARG);
Datum stavalues = text_to_stavalues("most_common_vals",
&array_in_fn,
PG_GETARG_DATUM(MOST_COMMON_VALS_ARG),
atttypid, atttypmod,
elevel, &converted);
if (converted)
{
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_MCV,
eq_opr, atttypcoll,
stanumbers, false, stavalues, false);
}
else
result = false;
}
/* STATISTIC_KIND_HISTOGRAM */
if (do_histogram)
{
Datum stavalues;
bool converted = false;
stavalues = text_to_stavalues("histogram_bounds",
&array_in_fn,
PG_GETARG_DATUM(HISTOGRAM_BOUNDS_ARG),
atttypid, atttypmod, elevel,
&converted);
if (converted)
{
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_HISTOGRAM,
lt_opr, atttypcoll,
0, true, stavalues, false);
}
else
result = false;
}
/* STATISTIC_KIND_CORRELATION */
if (do_correlation)
{
Datum elems[] = {PG_GETARG_DATUM(CORRELATION_ARG)};
ArrayType *arry = construct_array_builtin(elems, 1, FLOAT4OID);
Datum stanumbers = PointerGetDatum(arry);
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_CORRELATION,
lt_opr, atttypcoll,
stanumbers, false, 0, true);
}
/* STATISTIC_KIND_MCELEM */
if (do_mcelem)
{
Datum stanumbers = PG_GETARG_DATUM(MOST_COMMON_ELEM_FREQS_ARG);
bool converted = false;
Datum stavalues;
stavalues = text_to_stavalues("most_common_elems",
&array_in_fn,
PG_GETARG_DATUM(MOST_COMMON_ELEMS_ARG),
elemtypid, atttypmod,
elevel, &converted);
if (converted)
{
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_MCELEM,
elem_eq_opr, atttypcoll,
stanumbers, false, stavalues, false);
}
else
result = false;
}
/* STATISTIC_KIND_DECHIST */
if (do_dechist)
{
Datum stanumbers = PG_GETARG_DATUM(ELEM_COUNT_HISTOGRAM_ARG);
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_DECHIST,
elem_eq_opr, atttypcoll,
stanumbers, false, 0, true);
}
/*
* STATISTIC_KIND_BOUNDS_HISTOGRAM
*
* This stakind appears before STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM even
* though it is numerically greater, and all other stakinds appear in
* numerical order. We duplicate this quirk for consistency.
*/
if (do_bounds_histogram)
{
bool converted = false;
Datum stavalues;
stavalues = text_to_stavalues("range_bounds_histogram",
&array_in_fn,
PG_GETARG_DATUM(RANGE_BOUNDS_HISTOGRAM_ARG),
atttypid, atttypmod,
elevel, &converted);
if (converted)
{
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_BOUNDS_HISTOGRAM,
InvalidOid, InvalidOid,
0, true, stavalues, false);
}
else
result = false;
}
/* STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM */
if (do_range_length_histogram)
{
/* The anyarray is always a float8[] for this stakind */
Datum elems[] = {PG_GETARG_DATUM(RANGE_EMPTY_FRAC_ARG)};
ArrayType *arry = construct_array_builtin(elems, 1, FLOAT4OID);
Datum stanumbers = PointerGetDatum(arry);
bool converted = false;
Datum stavalues;
stavalues = text_to_stavalues("range_length_histogram",
&array_in_fn,
PG_GETARG_DATUM(RANGE_LENGTH_HISTOGRAM_ARG),
FLOAT8OID, 0, elevel, &converted);
if (converted)
{
set_stats_slot(values, nulls, replaces,
STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM,
Float8LessOperator, InvalidOid,
stanumbers, false, stavalues, false);
}
else
result = false;
}
upsert_pg_statistic(starel, statup, values, nulls, replaces);
if (HeapTupleIsValid(statup))
ReleaseSysCache(statup);
table_close(starel, RowExclusiveLock);
return result;
}
/*
* If this relation is an index and that index has expressions in it, and
* the attnum specified is known to be an expression, then we must walk
* the list attributes up to the specified attnum to get the right
* expression.
*/
static Node *
get_attr_expr(Relation rel, int attnum)
{
if ((rel->rd_rel->relkind == RELKIND_INDEX
|| (rel->rd_rel->relkind == RELKIND_PARTITIONED_INDEX))
&& (rel->rd_indexprs != NIL)
&& (rel->rd_index->indkey.values[attnum - 1] == 0))
{
ListCell *indexpr_item = list_head(rel->rd_indexprs);
for (int i = 0; i < attnum - 1; i++)
if (rel->rd_index->indkey.values[i] == 0)
indexpr_item = lnext(rel->rd_indexprs, indexpr_item);
if (indexpr_item == NULL) /* shouldn't happen */
elog(ERROR, "too few entries in indexprs list");
return (Node *) lfirst(indexpr_item);
}
return NULL;
}
/*
* Derive type information from the attribute.
*/
static void
get_attr_stat_type(Oid reloid, AttrNumber attnum, int elevel,
Oid *atttypid, int32 *atttypmod,
char *atttyptype, Oid *atttypcoll,
Oid *eq_opr, Oid *lt_opr)
{
Relation rel = relation_open(reloid, AccessShareLock);
Form_pg_attribute attr;
HeapTuple atup;
Node *expr;
TypeCacheEntry *typcache;
atup = SearchSysCache2(ATTNUM, ObjectIdGetDatum(reloid),
Int16GetDatum(attnum));
/* Attribute not found */
if (!HeapTupleIsValid(atup))
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_COLUMN),
errmsg("attribute %d of relation \"%s\" does not exist",
attnum, RelationGetRelationName(rel))));
attr = (Form_pg_attribute) GETSTRUCT(atup);
if (attr->attisdropped)
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_COLUMN),
errmsg("attribute %d of relation \"%s\" does not exist",
attnum, RelationGetRelationName(rel))));
expr = get_attr_expr(rel, attr->attnum);
/*
* When analyzing an expression index, believe the expression tree's type
* not the column datatype --- the latter might be the opckeytype storage
* type of the opclass, which is not interesting for our purposes. This
* mimics the behvior of examine_attribute().
*/
if (expr == NULL)
{
*atttypid = attr->atttypid;
*atttypmod = attr->atttypmod;
*atttypcoll = attr->attcollation;
}
else
{
*atttypid = exprType(expr);
*atttypmod = exprTypmod(expr);
if (OidIsValid(attr->attcollation))
*atttypcoll = attr->attcollation;
else
*atttypcoll = exprCollation(expr);
}
ReleaseSysCache(atup);
/*
* If it's a multirange, step down to the range type, as is done by
* multirange_typanalyze().
*/
if (type_is_multirange(*atttypid))
*atttypid = get_multirange_range(*atttypid);
/* finds the right operators even if atttypid is a domain */
typcache = lookup_type_cache(*atttypid, TYPECACHE_LT_OPR | TYPECACHE_EQ_OPR);
*atttyptype = typcache->typtype;
*eq_opr = typcache->eq_opr;
*lt_opr = typcache->lt_opr;
/*
* Special case: collation for tsvector is DEFAULT_COLLATION_OID. See
* compute_tsvector_stats().
*/
if (*atttypid == TSVECTOROID)
*atttypcoll = DEFAULT_COLLATION_OID;
relation_close(rel, NoLock);
}
/*
* Derive element type information from the attribute type.
*/
static bool
get_elem_stat_type(Oid atttypid, char atttyptype, int elevel,
Oid *elemtypid, Oid *elem_eq_opr)
{
TypeCacheEntry *elemtypcache;
if (atttypid == TSVECTOROID)
{
/*
* Special case: element type for tsvector is text. See
* compute_tsvector_stats().
*/
*elemtypid = TEXTOID;
}
else
{
/* find underlying element type through any domain */
*elemtypid = get_base_element_type(atttypid);
}
if (!OidIsValid(*elemtypid))
return false;
/* finds the right operator even if elemtypid is a domain */
elemtypcache = lookup_type_cache(*elemtypid, TYPECACHE_EQ_OPR);
if (!OidIsValid(elemtypcache->eq_opr))
return false;
*elem_eq_opr = elemtypcache->eq_opr;
return true;
}
/*
* Cast a text datum into an array with element type elemtypid.
*
* If an error is encountered, capture it and re-throw at elevel, and set ok
* to false. If the resulting array contains NULLs, raise an error at elevel
* and set ok to false. Otherwise, set ok to true.
*/
static Datum
text_to_stavalues(const char *staname, FmgrInfo *array_in, Datum d, Oid typid,
int32 typmod, int elevel, bool *ok)
{
LOCAL_FCINFO(fcinfo, 8);
char *s;
Datum result;
ErrorSaveContext escontext = {T_ErrorSaveContext};
escontext.details_wanted = true;
s = TextDatumGetCString(d);
InitFunctionCallInfoData(*fcinfo, array_in, 3, InvalidOid,
(Node *) &escontext, NULL);
fcinfo->args[0].value = CStringGetDatum(s);
fcinfo->args[0].isnull = false;
fcinfo->args[1].value = ObjectIdGetDatum(typid);
fcinfo->args[1].isnull = false;
fcinfo->args[2].value = Int32GetDatum(typmod);
fcinfo->args[2].isnull = false;
result = FunctionCallInvoke(fcinfo);
pfree(s);
if (SOFT_ERROR_OCCURRED(&escontext))
{
if (elevel != ERROR)
escontext.error_data->elevel = elevel;
ThrowErrorData(escontext.error_data);
*ok = false;
return (Datum) 0;
}
if (array_contains_nulls(DatumGetArrayTypeP(result)))
{
ereport(elevel,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("\"%s\" array cannot contain NULL values", staname)));
*ok = false;
return (Datum) 0;
}
*ok = true;
return result;
}
/*
* Find and update the slot with the given stakind, or use the first empty
* slot.
*/
static void
set_stats_slot(Datum *values, bool *nulls, bool *replaces,
int16 stakind, Oid staop, Oid stacoll,
Datum stanumbers, bool stanumbers_isnull,
Datum stavalues, bool stavalues_isnull)
{
int slotidx;
int first_empty = -1;
AttrNumber stakind_attnum;
AttrNumber staop_attnum;
AttrNumber stacoll_attnum;
/* find existing slot with given stakind */
for (slotidx = 0; slotidx < STATISTIC_NUM_SLOTS; slotidx++)
{
stakind_attnum = Anum_pg_statistic_stakind1 - 1 + slotidx;
if (first_empty < 0 &&
DatumGetInt16(values[stakind_attnum]) == 0)
first_empty = slotidx;
if (DatumGetInt16(values[stakind_attnum]) == stakind)
break;
}
if (slotidx >= STATISTIC_NUM_SLOTS && first_empty >= 0)
slotidx = first_empty;
if (slotidx >= STATISTIC_NUM_SLOTS)
ereport(ERROR,
(errmsg("maximum number of statistics slots exceeded: %d",
slotidx + 1)));
stakind_attnum = Anum_pg_statistic_stakind1 - 1 + slotidx;
staop_attnum = Anum_pg_statistic_staop1 - 1 + slotidx;
stacoll_attnum = Anum_pg_statistic_stacoll1 - 1 + slotidx;
if (DatumGetInt16(values[stakind_attnum]) != stakind)
{
values[stakind_attnum] = Int16GetDatum(stakind);
replaces[stakind_attnum] = true;
}
if (DatumGetObjectId(values[staop_attnum]) != staop)
{
values[staop_attnum] = ObjectIdGetDatum(staop);
replaces[staop_attnum] = true;
}
if (DatumGetObjectId(values[stacoll_attnum]) != stacoll)
{
values[stacoll_attnum] = ObjectIdGetDatum(stacoll);
replaces[stacoll_attnum] = true;
}
if (!stanumbers_isnull)
{
values[Anum_pg_statistic_stanumbers1 - 1 + slotidx] = stanumbers;
nulls[Anum_pg_statistic_stanumbers1 - 1 + slotidx] = false;
replaces[Anum_pg_statistic_stanumbers1 - 1 + slotidx] = true;
}
if (!stavalues_isnull)
{
values[Anum_pg_statistic_stavalues1 - 1 + slotidx] = stavalues;
nulls[Anum_pg_statistic_stavalues1 - 1 + slotidx] = false;
replaces[Anum_pg_statistic_stavalues1 - 1 + slotidx] = true;
}
}
/*
* Upsert the pg_statistic record.
*/
static void
upsert_pg_statistic(Relation starel, HeapTuple oldtup,
Datum *values, bool *nulls, bool *replaces)
{
HeapTuple newtup;
if (HeapTupleIsValid(oldtup))
{
newtup = heap_modify_tuple(oldtup, RelationGetDescr(starel),
values, nulls, replaces);
CatalogTupleUpdate(starel, &newtup->t_self, newtup);
}
else
{
newtup = heap_form_tuple(RelationGetDescr(starel), values, nulls);
CatalogTupleInsert(starel, newtup);
}
heap_freetuple(newtup);
}
/*
* Delete pg_statistic record.
*/
static bool
delete_pg_statistic(Oid reloid, AttrNumber attnum, bool stainherit)
{
Relation sd = table_open(StatisticRelationId, RowExclusiveLock);
HeapTuple oldtup;
/* Is there already a pg_statistic tuple for this attribute? */
oldtup = SearchSysCache3(STATRELATTINH,
ObjectIdGetDatum(reloid),
Int16GetDatum(attnum),
BoolGetDatum(stainherit));
if (HeapTupleIsValid(oldtup))
{
CatalogTupleDelete(sd, &oldtup->t_self);
ReleaseSysCache(oldtup);
table_close(sd, RowExclusiveLock);
return true;
}
table_close(sd, RowExclusiveLock);
return false;
}
/*
* Initialize values and nulls for a new stats tuple.
*/
static void
init_empty_stats_tuple(Oid reloid, int16 attnum, bool inherited,
Datum *values, bool *nulls, bool *replaces)
{
memset(nulls, true, sizeof(bool) * Natts_pg_statistic);
memset(replaces, true, sizeof(bool) * Natts_pg_statistic);
/* must initialize non-NULL attributes */
values[Anum_pg_statistic_starelid - 1] = ObjectIdGetDatum(reloid);
nulls[Anum_pg_statistic_starelid - 1] = false;
values[Anum_pg_statistic_staattnum - 1] = Int16GetDatum(attnum);
nulls[Anum_pg_statistic_staattnum - 1] = false;
values[Anum_pg_statistic_stainherit - 1] = BoolGetDatum(inherited);
nulls[Anum_pg_statistic_stainherit - 1] = false;
values[Anum_pg_statistic_stanullfrac - 1] = DEFAULT_NULL_FRAC;
nulls[Anum_pg_statistic_stanullfrac - 1] = false;
values[Anum_pg_statistic_stawidth - 1] = DEFAULT_AVG_WIDTH;
nulls[Anum_pg_statistic_stawidth - 1] = false;
values[Anum_pg_statistic_stadistinct - 1] = DEFAULT_N_DISTINCT;
nulls[Anum_pg_statistic_stadistinct - 1] = false;
/* initialize stakind, staop, and stacoll slots */
for (int slotnum = 0; slotnum < STATISTIC_NUM_SLOTS; slotnum++)
{
values[Anum_pg_statistic_stakind1 + slotnum - 1] = (Datum) 0;
nulls[Anum_pg_statistic_stakind1 + slotnum - 1] = false;
values[Anum_pg_statistic_staop1 + slotnum - 1] = InvalidOid;
nulls[Anum_pg_statistic_staop1 + slotnum - 1] = false;
values[Anum_pg_statistic_stacoll1 + slotnum - 1] = InvalidOid;
nulls[Anum_pg_statistic_stacoll1 + slotnum - 1] = false;
}
}
/*
* Import statistics for a given relation attribute.
*
* Inserts or replaces a row in pg_statistic for the given relation and
* attribute name. It takes input parameters that correspond to columns in the
* view pg_stats.
*
* Parameters null_frac, avg_width, and n_distinct all correspond to NOT NULL
* columns in pg_statistic. The remaining parameters all belong to a specific
* stakind. Some stakinds require multiple parameters, which must be specified
* together (or neither specified).
*
* Parameters are only superficially validated. Omitting a parameter or
* passing NULL leaves the statistic unchanged.
*
* Parameters corresponding to ANYARRAY columns are instead passed in as text
* values, which is a valid input string for an array of the type or element
* type of the attribute. Any error generated by the array_in() function will
* in turn fail the function.
*/
Datum
pg_set_attribute_stats(PG_FUNCTION_ARGS)
{
attribute_statistics_update(fcinfo, ERROR);
PG_RETURN_VOID();
}
/*
* Delete statistics for the given attribute.
*/
Datum
pg_clear_attribute_stats(PG_FUNCTION_ARGS)
{
Oid reloid;
Name attname;
AttrNumber attnum;
bool inherited;
stats_check_required_arg(fcinfo, attarginfo, ATTRELATION_ARG);
reloid = PG_GETARG_OID(ATTRELATION_ARG);
stats_lock_check_privileges(reloid);
stats_check_required_arg(fcinfo, attarginfo, ATTNAME_ARG);
attname = PG_GETARG_NAME(ATTNAME_ARG);
attnum = get_attnum(reloid, NameStr(*attname));
stats_check_required_arg(fcinfo, attarginfo, INHERITED_ARG);
inherited = PG_GETARG_BOOL(INHERITED_ARG);
delete_pg_statistic(reloid, attnum, inherited);
PG_RETURN_VOID();
}

View File

@ -1,6 +1,7 @@
# Copyright (c) 2022-2024, PostgreSQL Global Development Group
backend_sources += files(
'attribute_stats.c',
'dependencies.c',
'extended_stats.c',
'mcv.c',

View File

@ -40,6 +40,79 @@ stats_check_required_arg(FunctionCallInfo fcinfo,
arginfo[argnum].argname)));
}
/*
* Check that argument is either NULL or a one dimensional array with no
* NULLs.
*
* If a problem is found, emit at elevel, and return false. Otherwise return
* true.
*/
bool
stats_check_arg_array(FunctionCallInfo fcinfo,
struct StatsArgInfo *arginfo,
int argnum, int elevel)
{
ArrayType *arr;
if (PG_ARGISNULL(argnum))
return true;
arr = DatumGetArrayTypeP(PG_GETARG_DATUM(argnum));
if (ARR_NDIM(arr) != 1)
{
ereport(elevel,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("\"%s\" cannot be a multidimensional array",
arginfo[argnum].argname)));
return false;
}
if (array_contains_nulls(arr))
{
ereport(elevel,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("\"%s\" array cannot contain NULL values",
arginfo[argnum].argname)));
return false;
}
return true;
}
/*
* Enforce parameter pairs that must be specified together (or not at all) for
* a particular stakind, such as most_common_vals and most_common_freqs for
* STATISTIC_KIND_MCV.
*
* If a problem is found, emit at elevel, and return false. Otherwise return
* true.
*/
bool
stats_check_arg_pair(FunctionCallInfo fcinfo,
struct StatsArgInfo *arginfo,
int argnum1, int argnum2, int elevel)
{
if (PG_ARGISNULL(argnum1) && PG_ARGISNULL(argnum2))
return true;
if (PG_ARGISNULL(argnum1) || PG_ARGISNULL(argnum2))
{
int nullarg = PG_ARGISNULL(argnum1) ? argnum1 : argnum2;
int otherarg = PG_ARGISNULL(argnum1) ? argnum2 : argnum1;
ereport(elevel,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("\"%s\" must be specified when \"%s\" is specified",
arginfo[nullarg].argname,
arginfo[otherarg].argname)));
return false;
}
return true;
}
/*
* Lock relation in ShareUpdateExclusive mode, check privileges, and close the
* relation (but retain the lock).

View File

@ -57,6 +57,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 202410221
#define CATALOG_VERSION_NO 202410222
#endif

View File

@ -12342,6 +12342,20 @@
proargnames => '{summarized_tli,summarized_lsn,pending_lsn,summarizer_pid}',
prosrc => 'pg_get_wal_summarizer_state' },
+# Statistics Import
{ oid => '9162',
descr => 'set statistics on attribute',
proname => 'pg_set_attribute_stats', provolatile => 'v', proisstrict => 'f',
proparallel => 'u', prorettype => 'void',
proargtypes => 'regclass name bool float4 int4 float4 text _float4 text float4 text _float4 _float4 text float4 text',
proargnames => '{relation,attname,inherited,null_frac,avg_width,n_distinct,most_common_vals,most_common_freqs,histogram_bounds,correlation,most_common_elems,most_common_elem_freqs,elem_count_histogram,range_length_histogram,range_empty_frac,range_bounds_histogram}',
prosrc => 'pg_set_attribute_stats' },
{ oid => '9163',
descr => 'clear statistics on attribute',
proname => 'pg_clear_attribute_stats', provolatile => 'v', proisstrict => 'f',
proparallel => 'u', prorettype => 'void',
proargtypes => 'regclass name bool',
proargnames => '{relation,attname,inherited}',
prosrc => 'pg_clear_attribute_stats' },
{ oid => '9944',
descr => 'set statistics on relation',
proname => 'pg_set_relation_stats', provolatile => 'v', proisstrict => 'f',

View File

@ -24,6 +24,13 @@ struct StatsArgInfo
extern void stats_check_required_arg(FunctionCallInfo fcinfo,
struct StatsArgInfo *arginfo,
int argnum);
extern bool stats_check_arg_array(FunctionCallInfo fcinfo,
struct StatsArgInfo *arginfo, int argnum,
int elevel);
extern bool stats_check_arg_pair(FunctionCallInfo fcinfo,
struct StatsArgInfo *arginfo,
int argnum1, int argnum2, int elevel);
extern void stats_lock_check_privileges(Oid reloid);
#endif /* STATS_UTILS_H */

View File

@ -171,10 +171,667 @@ SELECT
(1 row)
-- error: object doesn't exist
SELECT pg_catalog.pg_set_attribute_stats(
relation => '0'::oid,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
ERROR: could not open relation with OID 0
-- error: relation null
SELECT pg_catalog.pg_set_attribute_stats(
relation => NULL::oid,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
ERROR: "relation" cannot be NULL
-- error: attname null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => NULL::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
ERROR: "attname" cannot be NULL
-- error: inherited null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => NULL::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
ERROR: "inherited" cannot be NULL
-- error: null_frac null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => NULL::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
pg_set_attribute_stats
------------------------
(1 row)
-- error: avg_width null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => NULL::integer,
n_distinct => 0.3::real);
pg_set_attribute_stats
------------------------
(1 row)
-- error: avg_width null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => NULL::real);
pg_set_attribute_stats
------------------------
(1 row)
-- ok: no stakinds
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
pg_set_attribute_stats
------------------------
(1 row)
SELECT stanullfrac, stawidth, stadistinct
FROM pg_statistic
WHERE starelid = 'stats_import.test'::regclass;
stanullfrac | stawidth | stadistinct
-------------+----------+-------------
0.1 | 2 | 0.3
(1 row)
-- error: mcv / mcf null mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_freqs => '{0.1,0.2,0.3}'::real[]
);
ERROR: "most_common_vals" must be specified when "most_common_freqs" is specified
-- error: mcv / mcf null mismatch part 2
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{1,2,3}'::text
);
ERROR: "most_common_freqs" must be specified when "most_common_vals" is specified
-- error: mcv / mcf type mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{2023-09-30,2024-10-31,3}'::text,
most_common_freqs => '{0.2,0.1}'::real[]
);
ERROR: invalid input syntax for type integer: "2023-09-30"
-- warning: mcv cast failure
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{2,four,3}'::text,
most_common_freqs => '{0.3,0.25,0.05}'::real[]
);
ERROR: invalid input syntax for type integer: "four"
-- ok: mcv+mcf
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{2,1,3}'::text,
most_common_freqs => '{0.3,0.25,0.05}'::real[]
);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'id';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+----------------------+------------------------+------------------+------------------------
stats_import | test | id | f | 0.5 | 2 | -0.1 | {2,1,3} | {0.3,0.25,0.05} | | | | | | | |
(1 row)
-- error: histogram elements null value
-- this generates no warnings, but perhaps it should
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
histogram_bounds => '{1,NULL,3,4}'::text
);
ERROR: "histogram_bounds" array cannot contain NULL values
-- ok: histogram_bounds
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
histogram_bounds => '{1,2,3,4}'::text
);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'id';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+----------------------+------------------------+------------------+------------------------
stats_import | test | id | f | 0.5 | 2 | -0.1 | {2,1,3} | {0.3,0.25,0.05} | {1,2,3,4} | | | | | | |
(1 row)
-- ok: correlation
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
correlation => 0.5::real);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'id';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+----------------------+------------------------+------------------+------------------------
stats_import | test | id | f | 0.5 | 2 | -0.1 | {2,1,3} | {0.3,0.25,0.05} | {1,2,3,4} | 0.5 | | | | | |
(1 row)
-- error: scalars can't have mcelem
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elems => '{1,3}'::text,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3,0.0}'::real[]
);
ERROR: unable to determine element type of attribute "id"
DETAIL: Cannot set STATISTIC_KIND_MCELEM or STATISTIC_KIND_DECHIST.
-- error: mcelem / mcelem mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elems => '{one,two}'::text
);
ERROR: "most_common_elem_freqs" must be specified when "most_common_elems" is specified
-- error: mcelem / mcelem null mismatch part 2
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3}'::real[]
);
ERROR: "most_common_elems" must be specified when "most_common_elem_freqs" is specified
-- ok: mcelem
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elems => '{one,three}'::text,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3,0.0}'::real[]
);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'tags';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+----------------------+------------------------+------------------+------------------------
stats_import | test | tags | f | 0.5 | 2 | -0.1 | | | | | {one,three} | {0.3,0.2,0.2,0.3,0} | | | |
(1 row)
-- error: scalars can't have elem_count_histogram
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
elem_count_histogram => '{1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1}'::real[]
);
ERROR: unable to determine element type of attribute "id"
DETAIL: Cannot set STATISTIC_KIND_MCELEM or STATISTIC_KIND_DECHIST.
-- error: elem_count_histogram null element
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
elem_count_histogram => '{1,1,NULL,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1}'::real[]
);
ERROR: "elem_count_histogram" array cannot contain NULL values
-- ok: elem_count_histogram
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
elem_count_histogram => '{1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1}'::real[]
);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'tags';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+------------------------+------------------+------------------------
stats_import | test | tags | f | 0.5 | 2 | -0.1 | | | | | {one,three} | {0.3,0.2,0.2,0.3,0} | {1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1} | | |
(1 row)
-- error: scalars can't have range stats
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_empty_frac => 0.5::real,
range_length_histogram => '{399,499,Infinity}'::text
);
ERROR: attribute "id" is not a range type
DETAIL: Cannot set STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM or STATISTIC_KIND_BOUNDS_HISTOGRAM.
-- error: range_empty_frac range_length_hist null mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_length_histogram => '{399,499,Infinity}'::text
);
ERROR: "range_empty_frac" must be specified when "range_length_histogram" is specified
-- error: range_empty_frac range_length_hist null mismatch part 2
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_empty_frac => 0.5::real
);
ERROR: "range_length_histogram" must be specified when "range_empty_frac" is specified
-- ok: range_empty_frac + range_length_hist
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_empty_frac => 0.5::real,
range_length_histogram => '{399,499,Infinity}'::text
);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'arange';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+----------------------+------------------------+------------------+------------------------
stats_import | test | arange | f | 0.5 | 2 | -0.1 | | | | | | | | {399,499,Infinity} | 0.5 |
(1 row)
-- error: scalars can't have range stats
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
);
ERROR: attribute "id" is not a range type
DETAIL: Cannot set STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM or STATISTIC_KIND_BOUNDS_HISTOGRAM.
-- ok: range_bounds_histogram
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
);
pg_set_attribute_stats
------------------------
(1 row)
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'arange';
schemaname | tablename | attname | inherited | null_frac | avg_width | n_distinct | most_common_vals | most_common_freqs | histogram_bounds | correlation | most_common_elems | most_common_elem_freqs | elem_count_histogram | range_length_histogram | range_empty_frac | range_bounds_histogram
--------------+-----------+---------+-----------+-----------+-----------+------------+------------------+-------------------+------------------+-------------+-------------------+------------------------+----------------------+------------------------+------------------+--------------------------------------
stats_import | test | arange | f | 0.5 | 2 | -0.1 | | | | | | | | {399,499,Infinity} | 0.5 | {"[-1,1)","[0,4)","[1,4)","[1,100)"}
(1 row)
-- error: cannot set most_common_elems for range type
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{"[2,3)","[1,2)","[3,4)"}'::text,
most_common_freqs => '{0.3,0.25,0.05}'::real[],
histogram_bounds => '{"[1,2)","[2,3)","[3,4)","[4,5)"}'::text,
correlation => 1.1::real,
most_common_elems => '{3,1}'::text,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3,0.0}'::real[],
range_empty_frac => -0.5::real,
range_length_histogram => '{399,499,Infinity}'::text,
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
);
ERROR: unable to determine element type of attribute "arange"
DETAIL: Cannot set STATISTIC_KIND_MCELEM or STATISTIC_KIND_DECHIST.
--
-- Test the ability to exactly copy data from one table to an identical table,
-- correctly reconstructing the stakind order as well as the staopN and
-- stacollN values. Because oids are not stable across databases, we can only
-- test this when the source and destination are on the same database
-- instance. For that reason, we borrow and adapt a query found in fe_utils
-- and used by pg_dump/pg_upgrade.
--
INSERT INTO stats_import.test
SELECT 1, 'one', (1, 1.1, 'ONE', '2001-01-01', '{ "xkey": "xval" }')::stats_import.complex_type, int4range(1,4), array['red','green']
UNION ALL
SELECT 2, 'two', (2, 2.2, 'TWO', '2002-02-02', '[true, 4, "six"]')::stats_import.complex_type, int4range(1,4), array['blue','yellow']
UNION ALL
SELECT 3, 'tre', (3, 3.3, 'TRE', '2003-03-03', NULL)::stats_import.complex_type, int4range(-1,1), array['"orange"', 'purple', 'cyan']
UNION ALL
SELECT 4, 'four', NULL, int4range(0,100), NULL;
CREATE INDEX is_odd ON stats_import.test(((comp).a % 2 = 1));
-- Generate statistics on table with data
ANALYZE stats_import.test;
CREATE TABLE stats_import.test_clone ( LIKE stats_import.test )
WITH (autovacuum_enabled = false);
CREATE INDEX is_odd_clone ON stats_import.test_clone(((comp).a % 2 = 1));
--
-- Copy stats from test to test_clone, and is_odd to is_odd_clone
--
SELECT s.schemaname, s.tablename, s.attname, s.inherited
FROM pg_catalog.pg_stats AS s
CROSS JOIN LATERAL
pg_catalog.pg_set_attribute_stats(
relation => ('stats_import.' || s.tablename || '_clone')::regclass::oid,
attname => s.attname,
inherited => s.inherited,
null_frac => s.null_frac,
avg_width => s.avg_width,
n_distinct => s.n_distinct,
most_common_vals => s.most_common_vals::text,
most_common_freqs => s.most_common_freqs,
histogram_bounds => s.histogram_bounds::text,
correlation => s.correlation,
most_common_elems => s.most_common_elems::text,
most_common_elem_freqs => s.most_common_elem_freqs,
elem_count_histogram => s.elem_count_histogram,
range_bounds_histogram => s.range_bounds_histogram::text,
range_empty_frac => s.range_empty_frac,
range_length_histogram => s.range_length_histogram::text) AS r
WHERE s.schemaname = 'stats_import'
AND s.tablename IN ('test', 'is_odd')
ORDER BY s.tablename, s.attname, s.inherited;
schemaname | tablename | attname | inherited
--------------+-----------+---------+-----------
stats_import | is_odd | expr | f
stats_import | test | arange | f
stats_import | test | comp | f
stats_import | test | id | f
stats_import | test | name | f
stats_import | test | tags | f
(6 rows)
SELECT c.relname, COUNT(*) AS num_stats
FROM pg_class AS c
JOIN pg_statistic s ON s.starelid = c.oid
WHERE c.relnamespace = 'stats_import'::regnamespace
AND c.relname IN ('test', 'test_clone', 'is_odd', 'is_odd_clone')
GROUP BY c.relname
ORDER BY c.relname;
relname | num_stats
--------------+-----------
is_odd | 1
is_odd_clone | 1
test | 5
test_clone | 5
(4 rows)
-- check test minus test_clone
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test_clone'::regclass;
attname | stainherit | stanullfrac | stawidth | stadistinct | stakind1 | stakind2 | stakind3 | stakind4 | stakind5 | staop1 | staop2 | staop3 | staop4 | staop5 | stacoll1 | stacoll2 | stacoll3 | stacoll4 | stacoll5 | stanumbers1 | stanumbers2 | stanumbers3 | stanumbers4 | stanumbers5 | sv1 | sv2 | sv3 | sv4 | sv5 | direction
---------+------------+-------------+----------+-------------+----------+----------+----------+----------+----------+--------+--------+--------+--------+--------+----------+----------+----------+----------+----------+-------------+-------------+-------------+-------------+-------------+-----+-----+-----+-----+-----+-----------
(0 rows)
-- check test_clone minus test
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test_clone'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test'::regclass;
attname | stainherit | stanullfrac | stawidth | stadistinct | stakind1 | stakind2 | stakind3 | stakind4 | stakind5 | staop1 | staop2 | staop3 | staop4 | staop5 | stacoll1 | stacoll2 | stacoll3 | stacoll4 | stacoll5 | stanumbers1 | stanumbers2 | stanumbers3 | stanumbers4 | stanumbers5 | sv1 | sv2 | sv3 | sv4 | sv5 | direction
---------+------------+-------------+----------+-------------+----------+----------+----------+----------+----------+--------+--------+--------+--------+--------+----------+----------+----------+----------+----------+-------------+-------------+-------------+-------------+-------------+-----+-----+-----+-----+-----+-----------
(0 rows)
-- check is_odd minus is_odd_clone
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd_clone'::regclass;
attname | stainherit | stanullfrac | stawidth | stadistinct | stakind1 | stakind2 | stakind3 | stakind4 | stakind5 | staop1 | staop2 | staop3 | staop4 | staop5 | stacoll1 | stacoll2 | stacoll3 | stacoll4 | stacoll5 | stanumbers1 | stanumbers2 | stanumbers3 | stanumbers4 | stanumbers5 | sv1 | sv2 | sv3 | sv4 | sv5 | direction
---------+------------+-------------+----------+-------------+----------+----------+----------+----------+----------+--------+--------+--------+--------+--------+----------+----------+----------+----------+----------+-------------+-------------+-------------+-------------+-------------+-----+-----+-----+-----+-----+-----------
(0 rows)
-- check is_odd_clone minus is_odd
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd_clone'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd'::regclass;
attname | stainherit | stanullfrac | stawidth | stadistinct | stakind1 | stakind2 | stakind3 | stakind4 | stakind5 | staop1 | staop2 | staop3 | staop4 | staop5 | stacoll1 | stacoll2 | stacoll3 | stacoll4 | stacoll5 | stanumbers1 | stanumbers2 | stanumbers3 | stanumbers4 | stanumbers5 | sv1 | sv2 | sv3 | sv4 | sv5 | direction
---------+------------+-------------+----------+-------------+----------+----------+----------+----------+----------+--------+--------+--------+--------+--------+----------+----------+----------+----------+----------+-------------+-------------+-------------+-------------+-------------+-----+-----+-----+-----+-----+-----------
(0 rows)
DROP SCHEMA stats_import CASCADE;
NOTICE: drop cascades to 5 other objects
NOTICE: drop cascades to 6 other objects
DETAIL: drop cascades to type stats_import.complex_type
drop cascades to table stats_import.test
drop cascades to sequence stats_import.testseq
drop cascades to view stats_import.testview
drop cascades to table stats_import.part_parent
drop cascades to table stats_import.test_clone

View File

@ -121,4 +121,549 @@ SELECT
relation => 'stats_import.part_parent'::regclass,
relpages => -1::integer);
-- error: object doesn't exist
SELECT pg_catalog.pg_set_attribute_stats(
relation => '0'::oid,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
-- error: relation null
SELECT pg_catalog.pg_set_attribute_stats(
relation => NULL::oid,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
-- error: attname null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => NULL::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
-- error: inherited null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => NULL::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
-- error: null_frac null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => NULL::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
-- error: avg_width null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => NULL::integer,
n_distinct => 0.3::real);
-- error: avg_width null
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => NULL::real);
-- ok: no stakinds
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.1::real,
avg_width => 2::integer,
n_distinct => 0.3::real);
SELECT stanullfrac, stawidth, stadistinct
FROM pg_statistic
WHERE starelid = 'stats_import.test'::regclass;
-- error: mcv / mcf null mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_freqs => '{0.1,0.2,0.3}'::real[]
);
-- error: mcv / mcf null mismatch part 2
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{1,2,3}'::text
);
-- error: mcv / mcf type mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{2023-09-30,2024-10-31,3}'::text,
most_common_freqs => '{0.2,0.1}'::real[]
);
-- warning: mcv cast failure
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{2,four,3}'::text,
most_common_freqs => '{0.3,0.25,0.05}'::real[]
);
-- ok: mcv+mcf
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{2,1,3}'::text,
most_common_freqs => '{0.3,0.25,0.05}'::real[]
);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'id';
-- error: histogram elements null value
-- this generates no warnings, but perhaps it should
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
histogram_bounds => '{1,NULL,3,4}'::text
);
-- ok: histogram_bounds
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
histogram_bounds => '{1,2,3,4}'::text
);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'id';
-- ok: correlation
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
correlation => 0.5::real);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'id';
-- error: scalars can't have mcelem
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elems => '{1,3}'::text,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3,0.0}'::real[]
);
-- error: mcelem / mcelem mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elems => '{one,two}'::text
);
-- error: mcelem / mcelem null mismatch part 2
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3}'::real[]
);
-- ok: mcelem
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_elems => '{one,three}'::text,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3,0.0}'::real[]
);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'tags';
-- error: scalars can't have elem_count_histogram
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
elem_count_histogram => '{1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1}'::real[]
);
-- error: elem_count_histogram null element
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
elem_count_histogram => '{1,1,NULL,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1}'::real[]
);
-- ok: elem_count_histogram
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'tags'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
elem_count_histogram => '{1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1}'::real[]
);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'tags';
-- error: scalars can't have range stats
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_empty_frac => 0.5::real,
range_length_histogram => '{399,499,Infinity}'::text
);
-- error: range_empty_frac range_length_hist null mismatch
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_length_histogram => '{399,499,Infinity}'::text
);
-- error: range_empty_frac range_length_hist null mismatch part 2
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_empty_frac => 0.5::real
);
-- ok: range_empty_frac + range_length_hist
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_empty_frac => 0.5::real,
range_length_histogram => '{399,499,Infinity}'::text
);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'arange';
-- error: scalars can't have range stats
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'id'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
);
-- ok: range_bounds_histogram
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
);
SELECT *
FROM pg_stats
WHERE schemaname = 'stats_import'
AND tablename = 'test'
AND inherited = false
AND attname = 'arange';
-- error: cannot set most_common_elems for range type
SELECT pg_catalog.pg_set_attribute_stats(
relation => 'stats_import.test'::regclass,
attname => 'arange'::name,
inherited => false::boolean,
null_frac => 0.5::real,
avg_width => 2::integer,
n_distinct => -0.1::real,
most_common_vals => '{"[2,3)","[1,2)","[3,4)"}'::text,
most_common_freqs => '{0.3,0.25,0.05}'::real[],
histogram_bounds => '{"[1,2)","[2,3)","[3,4)","[4,5)"}'::text,
correlation => 1.1::real,
most_common_elems => '{3,1}'::text,
most_common_elem_freqs => '{0.3,0.2,0.2,0.3,0.0}'::real[],
range_empty_frac => -0.5::real,
range_length_histogram => '{399,499,Infinity}'::text,
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
);
--
-- Test the ability to exactly copy data from one table to an identical table,
-- correctly reconstructing the stakind order as well as the staopN and
-- stacollN values. Because oids are not stable across databases, we can only
-- test this when the source and destination are on the same database
-- instance. For that reason, we borrow and adapt a query found in fe_utils
-- and used by pg_dump/pg_upgrade.
--
INSERT INTO stats_import.test
SELECT 1, 'one', (1, 1.1, 'ONE', '2001-01-01', '{ "xkey": "xval" }')::stats_import.complex_type, int4range(1,4), array['red','green']
UNION ALL
SELECT 2, 'two', (2, 2.2, 'TWO', '2002-02-02', '[true, 4, "six"]')::stats_import.complex_type, int4range(1,4), array['blue','yellow']
UNION ALL
SELECT 3, 'tre', (3, 3.3, 'TRE', '2003-03-03', NULL)::stats_import.complex_type, int4range(-1,1), array['"orange"', 'purple', 'cyan']
UNION ALL
SELECT 4, 'four', NULL, int4range(0,100), NULL;
CREATE INDEX is_odd ON stats_import.test(((comp).a % 2 = 1));
-- Generate statistics on table with data
ANALYZE stats_import.test;
CREATE TABLE stats_import.test_clone ( LIKE stats_import.test )
WITH (autovacuum_enabled = false);
CREATE INDEX is_odd_clone ON stats_import.test_clone(((comp).a % 2 = 1));
--
-- Copy stats from test to test_clone, and is_odd to is_odd_clone
--
SELECT s.schemaname, s.tablename, s.attname, s.inherited
FROM pg_catalog.pg_stats AS s
CROSS JOIN LATERAL
pg_catalog.pg_set_attribute_stats(
relation => ('stats_import.' || s.tablename || '_clone')::regclass::oid,
attname => s.attname,
inherited => s.inherited,
null_frac => s.null_frac,
avg_width => s.avg_width,
n_distinct => s.n_distinct,
most_common_vals => s.most_common_vals::text,
most_common_freqs => s.most_common_freqs,
histogram_bounds => s.histogram_bounds::text,
correlation => s.correlation,
most_common_elems => s.most_common_elems::text,
most_common_elem_freqs => s.most_common_elem_freqs,
elem_count_histogram => s.elem_count_histogram,
range_bounds_histogram => s.range_bounds_histogram::text,
range_empty_frac => s.range_empty_frac,
range_length_histogram => s.range_length_histogram::text) AS r
WHERE s.schemaname = 'stats_import'
AND s.tablename IN ('test', 'is_odd')
ORDER BY s.tablename, s.attname, s.inherited;
SELECT c.relname, COUNT(*) AS num_stats
FROM pg_class AS c
JOIN pg_statistic s ON s.starelid = c.oid
WHERE c.relnamespace = 'stats_import'::regnamespace
AND c.relname IN ('test', 'test_clone', 'is_odd', 'is_odd_clone')
GROUP BY c.relname
ORDER BY c.relname;
-- check test minus test_clone
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test_clone'::regclass;
-- check test_clone minus test
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test_clone'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'test_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.test'::regclass;
-- check is_odd minus is_odd_clone
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd_clone'::regclass;
-- check is_odd_clone minus is_odd
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd_clone'::regclass
EXCEPT
SELECT
a.attname, s.stainherit, s.stanullfrac, s.stawidth, s.stadistinct,
s.stakind1, s.stakind2, s.stakind3, s.stakind4, s.stakind5,
s.staop1, s.staop2, s.staop3, s.staop4, s.staop5,
s.stacoll1, s.stacoll2, s.stacoll3, s.stacoll4, s.stacoll5,
s.stanumbers1, s.stanumbers2, s.stanumbers3, s.stanumbers4, s.stanumbers5,
s.stavalues1::text AS sv1, s.stavalues2::text AS sv2,
s.stavalues3::text AS sv3, s.stavalues4::text AS sv4,
s.stavalues5::text AS sv5, 'is_odd_clone' AS direction
FROM pg_statistic s
JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum
WHERE s.starelid = 'stats_import.is_odd'::regclass;
DROP SCHEMA stats_import CASCADE;