mirror of
https://github.com/postgres/postgres.git
synced 2025-06-13 07:41:39 +03:00
Add functions pg_restore_relation_stats(), pg_restore_attribute_stats().
Similar to the pg_set_*_stats() functions, except with a variadic signature that's designed to be more future-proof. Additionally, most problems are reported as WARNINGs rather than ERRORs, allowing most stats to be restored even if some cannot. These functions are intended to be called from pg_dump to avoid the need to run ANALYZE after an upgrade. Author: Corey Huinker Discussion: https://postgr.es/m/CADkLM=eErgzn7ECDpwFcptJKOk9SxZEk5Pot4d94eVTZsvj3gw@mail.gmail.com
This commit is contained in:
@ -30267,6 +30267,55 @@ DETAIL: Make sure pg_wal_replay_wait() isn't called within a transaction with a
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="func_table_entry"><para role="func_signature">
|
||||
<indexterm>
|
||||
<primary>pg_restore_relation_stats</primary>
|
||||
</indexterm>
|
||||
<function>pg_restore_relation_stats</function> (
|
||||
<literal>VARIADIC</literal> <parameter>kwargs</parameter> <type>"any"</type> )
|
||||
<returnvalue>boolean</returnvalue>
|
||||
</para>
|
||||
<para>
|
||||
Similar to <function>pg_set_relation_stats()</function>, but intended
|
||||
for bulk restore of relation statistics. The tracked statistics may
|
||||
change from version to version, so the primary purpose of this
|
||||
function is to maintain a consistent function signature to avoid
|
||||
errors when restoring statistics from previous versions.
|
||||
</para>
|
||||
<para>
|
||||
Arguments are passed as pairs of <replaceable>argname</replaceable>
|
||||
and <replaceable>argvalue</replaceable>, where
|
||||
<replaceable>argname</replaceable> corresponds to a named argument in
|
||||
<function>pg_set_relation_stats()</function> and
|
||||
<replaceable>argvalue</replaceable> is of the corresponding type.
|
||||
</para>
|
||||
<para>
|
||||
Additionally, this function supports argument name
|
||||
<literal>version</literal> of type <type>integer</type>, which
|
||||
specifies the version from which the statistics originated, improving
|
||||
intepretation of older statistics.
|
||||
</para>
|
||||
<para>
|
||||
For example, to set the <structname>relpages</structname> and
|
||||
<structname>reltuples</structname> of the table
|
||||
<structname>mytable</structname>:
|
||||
<programlisting>
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'mytable'::regclass,
|
||||
'relpages', 173::integer,
|
||||
'reltuples', 10000::float4);
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
Minor errors are reported as a <literal>WARNING</literal> and
|
||||
ignored, and remaining statistics will still be restored. If all
|
||||
specified statistics are successfully restored, return
|
||||
<literal>true</literal>, otherwise <literal>false</literal>.
|
||||
</para>
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="func_table_entry">
|
||||
<para role="func_signature">
|
||||
@ -30338,6 +30387,57 @@ DETAIL: Make sure pg_wal_replay_wait() isn't called within a transaction with a
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="func_table_entry"><para role="func_signature">
|
||||
<indexterm>
|
||||
<primary>pg_restore_attribute_stats</primary>
|
||||
</indexterm>
|
||||
<function>pg_restore_attribute_stats</function> (
|
||||
<literal>VARIADIC</literal> <parameter>kwargs</parameter> <type>"any"</type> )
|
||||
<returnvalue>boolean</returnvalue>
|
||||
</para>
|
||||
<para>
|
||||
Similar to <function>pg_set_attribute_stats()</function>, but
|
||||
intended for bulk restore of attribute statistics. The tracked
|
||||
statistics may change from version to version, so the primary purpose
|
||||
of this function is to maintain a consistent function signature to
|
||||
avoid errors when restoring statistics from previous versions.
|
||||
</para>
|
||||
<para>
|
||||
Arguments are passed as pairs of <replaceable>argname</replaceable>
|
||||
and <replaceable>argvalue</replaceable>, where
|
||||
<replaceable>argname</replaceable> corresponds to a named argument in
|
||||
<function>pg_set_attribute_stats()</function> and
|
||||
<replaceable>argvalue</replaceable> is of the corresponding type.
|
||||
</para>
|
||||
<para>
|
||||
Additionally, this function supports argument name
|
||||
<literal>version</literal> of type <type>integer</type>, which
|
||||
specifies the version from which the statistics originated, improving
|
||||
intepretation of older statistics.
|
||||
</para>
|
||||
<para>
|
||||
For example, to set the <structname>avg_width</structname> and
|
||||
<structname>null_frac</structname> for the attribute
|
||||
<structname>col1</structname> of the table
|
||||
<structname>mytable</structname>:
|
||||
<programlisting>
|
||||
SELECT pg_restore_attribute_stats(
|
||||
'relation', 'mytable'::regclass,
|
||||
'attname', 'col1'::name,
|
||||
'inherited', false,
|
||||
'avg_width', 125::integer,
|
||||
'null_frac', 0.5::real);
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
Minor errors are reported as a <literal>WARNING</literal> and
|
||||
ignored, and remaining statistics will still be restored. If all
|
||||
specified statistics are successfully restored, return
|
||||
<literal>true</literal>, otherwise <literal>false</literal>.
|
||||
</para>
|
||||
</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
@ -877,3 +877,22 @@ pg_clear_attribute_stats(PG_FUNCTION_ARGS)
|
||||
delete_pg_statistic(reloid, attnum, inherited);
|
||||
PG_RETURN_VOID();
|
||||
}
|
||||
|
||||
Datum
|
||||
pg_restore_attribute_stats(PG_FUNCTION_ARGS)
|
||||
{
|
||||
LOCAL_FCINFO(positional_fcinfo, NUM_ATTRIBUTE_STATS_ARGS);
|
||||
bool result = true;
|
||||
|
||||
InitFunctionCallInfoData(*positional_fcinfo, NULL, NUM_ATTRIBUTE_STATS_ARGS,
|
||||
InvalidOid, NULL, NULL);
|
||||
|
||||
if (!stats_fill_fcinfo_from_arg_pairs(fcinfo, positional_fcinfo,
|
||||
attarginfo, WARNING))
|
||||
result = false;
|
||||
|
||||
if (!attribute_statistics_update(positional_fcinfo, WARNING))
|
||||
result = false;
|
||||
|
||||
PG_RETURN_BOOL(result);
|
||||
}
|
||||
|
@ -67,8 +67,7 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
|
||||
bool nulls[3] = {0};
|
||||
int ncols = 0;
|
||||
TupleDesc tupdesc;
|
||||
HeapTuple newtup;
|
||||
|
||||
bool result = true;
|
||||
|
||||
stats_check_required_arg(fcinfo, relarginfo, RELATION_ARG);
|
||||
reloid = PG_GETARG_OID(RELATION_ARG);
|
||||
@ -109,11 +108,9 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
|
||||
ereport(elevel,
|
||||
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
|
||||
errmsg("relpages cannot be < -1")));
|
||||
table_close(crel, RowExclusiveLock);
|
||||
return false;
|
||||
result = false;
|
||||
}
|
||||
|
||||
if (relpages != pgcform->relpages)
|
||||
else if (relpages != pgcform->relpages)
|
||||
{
|
||||
replaces[ncols] = Anum_pg_class_relpages;
|
||||
values[ncols] = Int32GetDatum(relpages);
|
||||
@ -130,16 +127,15 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
|
||||
ereport(elevel,
|
||||
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
|
||||
errmsg("reltuples cannot be < -1.0")));
|
||||
table_close(crel, RowExclusiveLock);
|
||||
return false;
|
||||
result = false;
|
||||
}
|
||||
|
||||
if (reltuples != pgcform->reltuples)
|
||||
else if (reltuples != pgcform->reltuples)
|
||||
{
|
||||
replaces[ncols] = Anum_pg_class_reltuples;
|
||||
values[ncols] = Float4GetDatum(reltuples);
|
||||
ncols++;
|
||||
}
|
||||
|
||||
}
|
||||
|
||||
if (!PG_ARGISNULL(RELALLVISIBLE_ARG))
|
||||
@ -151,11 +147,9 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
|
||||
ereport(elevel,
|
||||
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
|
||||
errmsg("relallvisible cannot be < 0")));
|
||||
table_close(crel, RowExclusiveLock);
|
||||
return false;
|
||||
result = false;
|
||||
}
|
||||
|
||||
if (relallvisible != pgcform->relallvisible)
|
||||
else if (relallvisible != pgcform->relallvisible)
|
||||
{
|
||||
replaces[ncols] = Anum_pg_class_relallvisible;
|
||||
values[ncols] = Int32GetDatum(relallvisible);
|
||||
@ -164,22 +158,20 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
|
||||
}
|
||||
|
||||
/* only update pg_class if there is a meaningful change */
|
||||
if (ncols == 0)
|
||||
if (ncols > 0)
|
||||
{
|
||||
table_close(crel, RowExclusiveLock);
|
||||
return false;
|
||||
HeapTuple newtup;
|
||||
|
||||
newtup = heap_modify_tuple_by_cols(ctup, tupdesc, ncols, replaces, values,
|
||||
nulls);
|
||||
CatalogTupleUpdate(crel, &newtup->t_self, newtup);
|
||||
heap_freetuple(newtup);
|
||||
}
|
||||
|
||||
newtup = heap_modify_tuple_by_cols(ctup, tupdesc, ncols, replaces, values,
|
||||
nulls);
|
||||
|
||||
CatalogTupleUpdate(crel, &newtup->t_self, newtup);
|
||||
heap_freetuple(newtup);
|
||||
|
||||
/* release the lock, consistent with vac_update_relstats() */
|
||||
table_close(crel, RowExclusiveLock);
|
||||
|
||||
return true;
|
||||
return result;
|
||||
}
|
||||
|
||||
/*
|
||||
@ -215,3 +207,23 @@ pg_clear_relation_stats(PG_FUNCTION_ARGS)
|
||||
relation_statistics_update(newfcinfo, ERROR);
|
||||
PG_RETURN_VOID();
|
||||
}
|
||||
|
||||
Datum
|
||||
pg_restore_relation_stats(PG_FUNCTION_ARGS)
|
||||
{
|
||||
LOCAL_FCINFO(positional_fcinfo, NUM_RELATION_STATS_ARGS);
|
||||
bool result = true;
|
||||
|
||||
InitFunctionCallInfoData(*positional_fcinfo, NULL,
|
||||
NUM_RELATION_STATS_ARGS,
|
||||
InvalidOid, NULL, NULL);
|
||||
|
||||
if (!stats_fill_fcinfo_from_arg_pairs(fcinfo, positional_fcinfo,
|
||||
relarginfo, WARNING))
|
||||
result = false;
|
||||
|
||||
if (!relation_statistics_update(positional_fcinfo, WARNING))
|
||||
result = false;
|
||||
|
||||
PG_RETURN_BOOL(result);
|
||||
}
|
||||
|
@ -18,6 +18,7 @@
|
||||
|
||||
#include "access/relation.h"
|
||||
#include "catalog/pg_database.h"
|
||||
#include "funcapi.h"
|
||||
#include "miscadmin.h"
|
||||
#include "statistics/stat_utils.h"
|
||||
#include "utils/acl.h"
|
||||
@ -165,3 +166,128 @@ stats_lock_check_privileges(Oid reloid)
|
||||
|
||||
relation_close(rel, NoLock);
|
||||
}
|
||||
|
||||
/*
|
||||
* Find the argument number for the given argument name, returning -1 if not
|
||||
* found.
|
||||
*/
|
||||
static int
|
||||
get_arg_by_name(const char *argname, struct StatsArgInfo *arginfo, int elevel)
|
||||
{
|
||||
int argnum;
|
||||
|
||||
for (argnum = 0; arginfo[argnum].argname != NULL; argnum++)
|
||||
if (pg_strcasecmp(argname, arginfo[argnum].argname) == 0)
|
||||
return argnum;
|
||||
|
||||
ereport(elevel,
|
||||
(errmsg("unrecognized argument name: \"%s\"", argname)));
|
||||
|
||||
return -1;
|
||||
}
|
||||
|
||||
/*
|
||||
* Ensure that a given argument matched the expected type.
|
||||
*/
|
||||
static bool
|
||||
stats_check_arg_type(const char *argname, Oid argtype, Oid expectedtype, int elevel)
|
||||
{
|
||||
if (argtype != expectedtype)
|
||||
{
|
||||
ereport(elevel,
|
||||
(errmsg("argument \"%s\" has type \"%s\", expected type \"%s\"",
|
||||
argname, format_type_be(argtype),
|
||||
format_type_be(expectedtype))));
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/*
|
||||
* Translate variadic argument pairs from 'pairs_fcinfo' into a
|
||||
* 'positional_fcinfo' appropriate for calling relation_statistics_update() or
|
||||
* attribute_statistics_update() with positional arguments.
|
||||
*
|
||||
* Caller should have already initialized positional_fcinfo with a size
|
||||
* appropriate for calling the intended positional function, and arginfo
|
||||
* should also match the intended positional function.
|
||||
*/
|
||||
bool
|
||||
stats_fill_fcinfo_from_arg_pairs(FunctionCallInfo pairs_fcinfo,
|
||||
FunctionCallInfo positional_fcinfo,
|
||||
struct StatsArgInfo *arginfo,
|
||||
int elevel)
|
||||
{
|
||||
Datum *args;
|
||||
bool *argnulls;
|
||||
Oid *types;
|
||||
int nargs;
|
||||
bool result = true;
|
||||
|
||||
/* clear positional args */
|
||||
for (int i = 0; arginfo[i].argname != NULL; i++)
|
||||
{
|
||||
positional_fcinfo->args[i].value = (Datum) 0;
|
||||
positional_fcinfo->args[i].isnull = true;
|
||||
}
|
||||
|
||||
nargs = extract_variadic_args(pairs_fcinfo, 0, true,
|
||||
&args, &types, &argnulls);
|
||||
|
||||
if (nargs % 2 != 0)
|
||||
ereport(ERROR,
|
||||
errmsg("variadic arguments must be name/value pairs"),
|
||||
errhint("Provide an even number of variadic arguments that can be divided into pairs."));
|
||||
|
||||
/*
|
||||
* For each argument name/value pair, find corresponding positional
|
||||
* argument for the argument name, and assign the argument value to
|
||||
* postitional_fcinfo.
|
||||
*/
|
||||
for (int i = 0; i < nargs; i += 2)
|
||||
{
|
||||
int argnum;
|
||||
char *argname;
|
||||
|
||||
if (argnulls[i])
|
||||
ereport(ERROR,
|
||||
(errmsg("name at variadic position %d is NULL", i + 1)));
|
||||
|
||||
if (types[i] != TEXTOID)
|
||||
ereport(ERROR,
|
||||
(errmsg("name at variadic position %d has type \"%s\", expected type \"%s\"",
|
||||
i + 1, format_type_be(types[i]),
|
||||
format_type_be(TEXTOID))));
|
||||
|
||||
if (argnulls[i + 1])
|
||||
continue;
|
||||
|
||||
argname = TextDatumGetCString(args[i]);
|
||||
|
||||
/*
|
||||
* The 'version' argument is a special case, not handled by arginfo
|
||||
* because it's not a valid positional argument.
|
||||
*
|
||||
* For now, 'version' is accepted but ignored. In the future it can be
|
||||
* used to interpret older statistics properly.
|
||||
*/
|
||||
if (pg_strcasecmp(argname, "version") == 0)
|
||||
continue;
|
||||
|
||||
argnum = get_arg_by_name(argname, arginfo, elevel);
|
||||
|
||||
if (argnum < 0 || !stats_check_arg_type(argname, types[i + 1],
|
||||
arginfo[argnum].argtype,
|
||||
elevel))
|
||||
{
|
||||
result = false;
|
||||
continue;
|
||||
}
|
||||
|
||||
positional_fcinfo->args[argnum].value = args[i + 1];
|
||||
positional_fcinfo->args[argnum].isnull = false;
|
||||
}
|
||||
|
||||
return result;
|
||||
}
|
||||
|
@ -57,6 +57,6 @@
|
||||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 202410241
|
||||
#define CATALOG_VERSION_NO 202410242
|
||||
|
||||
#endif
|
||||
|
@ -12346,7 +12346,25 @@
|
||||
proallargtypes => '{int8,pg_lsn,pg_lsn,int4}', proargmodes => '{o,o,o,o}',
|
||||
proargnames => '{summarized_tli,summarized_lsn,pending_lsn,summarizer_pid}',
|
||||
prosrc => 'pg_get_wal_summarizer_state' },
|
||||
+# Statistics Import
|
||||
# Statistics Import
|
||||
{ oid => '8459',
|
||||
descr => 'restore statistics on relation',
|
||||
proname => 'pg_restore_relation_stats', provolatile => 'v', proisstrict => 'f',
|
||||
provariadic => 'any',
|
||||
proparallel => 'u', prorettype => 'bool',
|
||||
proargtypes => 'any',
|
||||
proargnames => '{kwargs}',
|
||||
proargmodes => '{v}',
|
||||
prosrc => 'pg_restore_relation_stats' },
|
||||
{ oid => '8460',
|
||||
descr => 'restore statistics on attribute',
|
||||
proname => 'pg_restore_attribute_stats', provolatile => 'v', proisstrict => 'f',
|
||||
provariadic => 'any',
|
||||
proparallel => 'u', prorettype => 'bool',
|
||||
proargtypes => 'any',
|
||||
proargnames => '{kwargs}',
|
||||
proargmodes => '{v}',
|
||||
prosrc => 'pg_restore_attribute_stats' },
|
||||
{ oid => '9162',
|
||||
descr => 'set statistics on attribute',
|
||||
proname => 'pg_set_attribute_stats', provolatile => 'v', proisstrict => 'f',
|
||||
|
@ -33,4 +33,9 @@ extern bool stats_check_arg_pair(FunctionCallInfo fcinfo,
|
||||
|
||||
extern void stats_lock_check_privileges(Oid reloid);
|
||||
|
||||
extern bool stats_fill_fcinfo_from_arg_pairs(FunctionCallInfo pairs_fcinfo,
|
||||
FunctionCallInfo positional_fcinfo,
|
||||
struct StatsArgInfo *arginfo,
|
||||
int elevel);
|
||||
|
||||
#endif /* STATS_UTILS_H */
|
||||
|
@ -228,45 +228,6 @@ SELECT pg_catalog.pg_set_attribute_stats(
|
||||
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,
|
||||
@ -655,6 +616,711 @@ SELECT pg_catalog.pg_set_attribute_stats(
|
||||
);
|
||||
ERROR: unable to determine element type of attribute "arange"
|
||||
DETAIL: Cannot set STATISTIC_KIND_MCELEM or STATISTIC_KIND_DECHIST.
|
||||
--
|
||||
-- Clear attribute stats to try again with restore functions
|
||||
-- (relation stats were already cleared).
|
||||
--
|
||||
SELECT
|
||||
pg_catalog.pg_clear_attribute_stats(
|
||||
'stats_import.test'::regclass,
|
||||
s.attname,
|
||||
s.inherited)
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
WHERE s.schemaname = 'stats_import'
|
||||
AND s.tablename = 'test'
|
||||
ORDER BY s.attname, s.inherited;
|
||||
pg_clear_attribute_stats
|
||||
--------------------------
|
||||
|
||||
|
||||
|
||||
(3 rows)
|
||||
|
||||
-- reject: argument name is NULL
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
NULL, '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
ERROR: name at variadic position 5 is NULL
|
||||
-- reject: argument name is an integer
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
17, '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
ERROR: name at variadic position 5 has type "integer", expected type "text"
|
||||
-- reject: odd number of variadic arguments cannot be pairs
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible');
|
||||
ERROR: variadic arguments must be name/value pairs
|
||||
HINT: Provide an even number of variadic arguments that can be divided into pairs.
|
||||
-- reject: object doesn't exist
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
ERROR: could not open relation with OID 0
|
||||
-- ok: set all stats
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
pg_restore_relation_stats
|
||||
---------------------------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
relpages | reltuples | relallvisible
|
||||
----------+-----------+---------------
|
||||
17 | 400 | 4
|
||||
(1 row)
|
||||
|
||||
-- ok: just relpages
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '16'::integer);
|
||||
pg_restore_relation_stats
|
||||
---------------------------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
relpages | reltuples | relallvisible
|
||||
----------+-----------+---------------
|
||||
16 | 400 | 4
|
||||
(1 row)
|
||||
|
||||
-- ok: just reltuples
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'reltuples', '500'::real);
|
||||
pg_restore_relation_stats
|
||||
---------------------------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
relpages | reltuples | relallvisible
|
||||
----------+-----------+---------------
|
||||
16 | 500 | 4
|
||||
(1 row)
|
||||
|
||||
-- ok: just relallvisible
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relallvisible', 5::integer);
|
||||
pg_restore_relation_stats
|
||||
---------------------------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
relpages | reltuples | relallvisible
|
||||
----------+-----------+---------------
|
||||
16 | 500 | 5
|
||||
(1 row)
|
||||
|
||||
-- warn and error: unrecognized argument name
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'nope', 4::integer);
|
||||
WARNING: unrecognized argument name: "nope"
|
||||
ERROR: could not open relation with OID 0
|
||||
-- warn: bad relpages type
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', 'nope'::text,
|
||||
'reltuples', 400.0::real,
|
||||
'relallvisible', 4::integer);
|
||||
WARNING: argument "relpages" has type "text", expected type "integer"
|
||||
pg_restore_relation_stats
|
||||
---------------------------
|
||||
f
|
||||
(1 row)
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
relpages | reltuples | relallvisible
|
||||
----------+-----------+---------------
|
||||
16 | 400 | 4
|
||||
(1 row)
|
||||
|
||||
-- error: object does not exist
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'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_restore_attribute_stats(
|
||||
'relation', NULL::oid,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'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_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', NULL::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
ERROR: "attname" cannot be NULL
|
||||
-- error: attname doesn't exist
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'nope'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
ERROR: column "nope" of relation "test" does not exist
|
||||
-- error: inherited null
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', NULL::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
ERROR: "inherited" cannot be NULL
|
||||
-- ok: no stakinds
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.4::real,
|
||||
'avg_width', 5::integer,
|
||||
'n_distinct', 0.6::real);
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
t
|
||||
(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.4 | 5 | 0.6 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: unrecognized argument name
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.2::real,
|
||||
'avg_width', NULL::integer,
|
||||
'nope', 0.5::real);
|
||||
WARNING: unrecognized argument name: "nope"
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.2 | 5 | 0.6 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: mcv / mcf null mismatch part 1
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.6::real,
|
||||
'avg_width', 7::integer,
|
||||
'n_distinct', -0.7::real,
|
||||
'most_common_freqs', '{0.1,0.2,0.3}'::real[]
|
||||
);
|
||||
WARNING: "most_common_vals" must be specified when "most_common_freqs" is specified
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.6 | 7 | -0.7 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: mcv / mcf null mismatch part 2
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.7::real,
|
||||
'avg_width', 8::integer,
|
||||
'n_distinct', -0.8::real,
|
||||
'most_common_vals', '{1,2,3}'::text
|
||||
);
|
||||
WARNING: "most_common_freqs" must be specified when "most_common_vals" is specified
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.7 | 8 | -0.8 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: mcv / mcf type mismatch
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.8::real,
|
||||
'avg_width', 9::integer,
|
||||
'n_distinct', -0.9::real,
|
||||
'most_common_vals', '{2,1,3}'::text,
|
||||
'most_common_freqs', '{0.2,0.1}'::double precision[]
|
||||
);
|
||||
WARNING: argument "most_common_freqs" has type "double precision[]", expected type "real[]"
|
||||
WARNING: "most_common_freqs" must be specified when "most_common_vals" is specified
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.8 | 9 | -0.9 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: mcv cast failure
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.9::real,
|
||||
'avg_width', 10::integer,
|
||||
'n_distinct', -0.4::real,
|
||||
'most_common_vals', '{2,four,3}'::text,
|
||||
'most_common_freqs', '{0.3,0.25,0.05}'::real[]
|
||||
);
|
||||
WARNING: invalid input syntax for type integer: "four"
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.9 | 10 | -0.4 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- ok: mcv+mcf
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 1::integer,
|
||||
'n_distinct', -0.1::real,
|
||||
'most_common_vals', '{2,1,3}'::text,
|
||||
'most_common_freqs', '{0.3,0.25,0.05}'::real[]
|
||||
);
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
t
|
||||
(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.1 | 1 | -0.1 | {2,1,3} | {0.3,0.25,0.05} | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: NULL in histogram array
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.2::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', -0.2::real,
|
||||
'histogram_bounds', '{1,NULL,3,4}'::text
|
||||
);
|
||||
WARNING: "histogram_bounds" array cannot contain NULL values
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.2 | 2 | -0.2 | {2,1,3} | {0.3,0.25,0.05} | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- ok: histogram_bounds
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.3::real,
|
||||
'avg_width', 3::integer,
|
||||
'n_distinct', -0.3::real,
|
||||
'histogram_bounds', '{1,2,3,4}'::text );
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
t
|
||||
(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.3 | 3 | -0.3 | {2,1,3} | {0.3,0.25,0.05} | {1,2,3,4} | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: elem_count_histogram null element
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'tags'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.4::real,
|
||||
'avg_width', 5::integer,
|
||||
'n_distinct', -0.4::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[]
|
||||
);
|
||||
WARNING: "elem_count_histogram" array cannot contain NULL values
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.4 | 5 | -0.4 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- ok: elem_count_histogram
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'tags'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.5::real,
|
||||
'avg_width', 6::integer,
|
||||
'n_distinct', -0.55::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_restore_attribute_stats
|
||||
----------------------------
|
||||
t
|
||||
(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 | 6 | -0.55 | | | | | | | {1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,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)
|
||||
|
||||
-- range stats on a scalar type
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.6::real,
|
||||
'avg_width', 7::integer,
|
||||
'n_distinct', -0.15::real,
|
||||
'range_empty_frac', 0.5::real,
|
||||
'range_length_histogram', '{399,499,Infinity}'::text
|
||||
);
|
||||
WARNING: attribute "id" is not a range type
|
||||
DETAIL: Cannot set STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM or STATISTIC_KIND_BOUNDS_HISTOGRAM.
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.6 | 7 | -0.15 | {2,1,3} | {0.3,0.25,0.05} | {1,2,3,4} | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: range_empty_frac range_length_hist null mismatch
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.7::real,
|
||||
'avg_width', 8::integer,
|
||||
'n_distinct', -0.25::real,
|
||||
'range_length_histogram', '{399,499,Infinity}'::text
|
||||
);
|
||||
WARNING: "range_empty_frac" must be specified when "range_length_histogram" is specified
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.7 | 8 | -0.25 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- warn: range_empty_frac range_length_hist null mismatch part 2
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.8::real,
|
||||
'avg_width', 9::integer,
|
||||
'n_distinct', -0.35::real,
|
||||
'range_empty_frac', 0.5::real
|
||||
);
|
||||
WARNING: "range_length_histogram" must be specified when "range_empty_frac" is specified
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.8 | 9 | -0.35 | | | | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- ok: range_empty_frac + range_length_hist
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.9::real,
|
||||
'avg_width', 1::integer,
|
||||
'n_distinct', -0.19::real,
|
||||
'range_empty_frac', 0.5::real,
|
||||
'range_length_histogram', '{399,499,Infinity}'::text
|
||||
);
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
t
|
||||
(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.9 | 1 | -0.19 | | | | | | | | {399,499,Infinity} | 0.5 |
|
||||
(1 row)
|
||||
|
||||
-- warn: range bounds histogram on scalar
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', -0.29::real,
|
||||
'range_bounds_histogram', '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
|
||||
);
|
||||
WARNING: attribute "id" is not a range type
|
||||
DETAIL: Cannot set STATISTIC_KIND_RANGE_LENGTH_HISTOGRAM or STATISTIC_KIND_BOUNDS_HISTOGRAM.
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(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.1 | 2 | -0.29 | {2,1,3} | {0.3,0.25,0.05} | {1,2,3,4} | | | | | | |
|
||||
(1 row)
|
||||
|
||||
-- ok: range_bounds_histogram
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.2::real,
|
||||
'avg_width', 3::integer,
|
||||
'n_distinct', -0.39::real,
|
||||
'range_bounds_histogram', '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
|
||||
);
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
t
|
||||
(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.2 | 3 | -0.39 | | | | | | | | {399,499,Infinity} | 0.5 | {"[-1,1)","[0,4)","[1,4)","[1,100)"}
|
||||
(1 row)
|
||||
|
||||
-- warn: too many stat kinds
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.5::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', -0.1::real,
|
||||
'most_common_vals', '{"[2,3)","[1,3)","[3,9)"}'::text,
|
||||
'most_common_freqs', '{0.3,0.25,0.05}'::real[],
|
||||
'histogram_bounds', '{"[1,2)","[2,3)","[3,4)","[4,)"}'::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);
|
||||
WARNING: unable to determine element type of attribute "arange"
|
||||
DETAIL: Cannot set STATISTIC_KIND_MCELEM or STATISTIC_KIND_DECHIST.
|
||||
pg_restore_attribute_stats
|
||||
----------------------------
|
||||
f
|
||||
(1 row)
|
||||
|
||||
--
|
||||
-- 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
|
||||
@ -848,6 +1514,217 @@ WHERE s.starelid = 'stats_import.is_odd'::regclass;
|
||||
---------+------------+-------------+----------+-------------+----------+----------+----------+----------+----------+--------+--------+--------+--------+--------+----------+----------+----------+----------+----------+-------------+-------------+-------------+-------------+-------------+-----+-----+-----+-----+-----+-----------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
relpages | reltuples | relallvisible
|
||||
----------+-----------+---------------
|
||||
1 | 4 | 0
|
||||
(1 row)
|
||||
|
||||
--
|
||||
-- Clear clone stats to try again with pg_restore_attribute_stats
|
||||
--
|
||||
SELECT
|
||||
pg_catalog.pg_clear_attribute_stats(
|
||||
('stats_import.' || s.tablename)::regclass,
|
||||
s.attname,
|
||||
s.inherited)
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
WHERE s.schemaname = 'stats_import'
|
||||
AND s.tablename IN ('test_clone', 'is_odd_clone')
|
||||
ORDER BY s.tablename, s.attname, s.inherited;
|
||||
pg_clear_attribute_stats
|
||||
--------------------------
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
(6 rows)
|
||||
|
||||
SELECT
|
||||
SELECT COUNT(*)
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
WHERE s.schemaname = 'stats_import'
|
||||
AND s.tablename IN ('test_clone', 'is_odd_clone');
|
||||
ERROR: syntax error at or near "SELECT"
|
||||
LINE 2: SELECT COUNT(*)
|
||||
^
|
||||
--
|
||||
-- Copy stats from test to test_clone, and is_odd to is_odd_clone
|
||||
--
|
||||
SELECT s.schemaname, s.tablename, s.attname, s.inherited, r.*
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
CROSS JOIN LATERAL
|
||||
pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', ('stats_import.' || s.tablename || '_clone')::regclass,
|
||||
'attname', s.attname,
|
||||
'inherited', s.inherited,
|
||||
'version', 150000,
|
||||
'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 | r
|
||||
--------------+-----------+---------+-----------+---
|
||||
stats_import | is_odd | expr | f | t
|
||||
stats_import | test | arange | f | t
|
||||
stats_import | test | comp | f | t
|
||||
stats_import | test | id | f | t
|
||||
stats_import | test | name | f | t
|
||||
stats_import | test | tags | f | t
|
||||
(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 6 other objects
|
||||
DETAIL: drop cascades to type stats_import.complex_type
|
||||
|
@ -178,33 +178,6 @@ SELECT pg_catalog.pg_set_attribute_stats(
|
||||
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,
|
||||
@ -517,6 +490,507 @@ SELECT pg_catalog.pg_set_attribute_stats(
|
||||
range_length_histogram => '{399,499,Infinity}'::text,
|
||||
range_bounds_histogram => '{"[-1,1)","[0,4)","[1,4)","[1,100)"}'::text
|
||||
);
|
||||
|
||||
--
|
||||
-- Clear attribute stats to try again with restore functions
|
||||
-- (relation stats were already cleared).
|
||||
--
|
||||
SELECT
|
||||
pg_catalog.pg_clear_attribute_stats(
|
||||
'stats_import.test'::regclass,
|
||||
s.attname,
|
||||
s.inherited)
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
WHERE s.schemaname = 'stats_import'
|
||||
AND s.tablename = 'test'
|
||||
ORDER BY s.attname, s.inherited;
|
||||
|
||||
-- reject: argument name is NULL
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
NULL, '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
|
||||
-- reject: argument name is an integer
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
17, '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
|
||||
-- reject: odd number of variadic arguments cannot be pairs
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible');
|
||||
|
||||
-- reject: object doesn't exist
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
|
||||
-- ok: set all stats
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'relallvisible', 4::integer);
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
|
||||
-- ok: just relpages
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '16'::integer);
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
|
||||
-- ok: just reltuples
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'reltuples', '500'::real);
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
|
||||
-- ok: just relallvisible
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relallvisible', 5::integer);
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
|
||||
-- warn and error: unrecognized argument name
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', '17'::integer,
|
||||
'reltuples', 400::real,
|
||||
'nope', 4::integer);
|
||||
|
||||
-- warn: bad relpages type
|
||||
SELECT pg_restore_relation_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'version', 150000::integer,
|
||||
'relpages', 'nope'::text,
|
||||
'reltuples', 400.0::real,
|
||||
'relallvisible', 4::integer);
|
||||
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
|
||||
-- error: object does not exist
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', '0'::oid::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
|
||||
-- error: relation null
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', NULL::oid,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
|
||||
-- error: attname null
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', NULL::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
|
||||
-- error: attname doesn't exist
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'nope'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
|
||||
-- error: inherited null
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', NULL::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', 0.3::real);
|
||||
|
||||
-- ok: no stakinds
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.4::real,
|
||||
'avg_width', 5::integer,
|
||||
'n_distinct', 0.6::real);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'id';
|
||||
|
||||
-- warn: unrecognized argument name
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.2::real,
|
||||
'avg_width', NULL::integer,
|
||||
'nope', 0.5::real);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'id';
|
||||
|
||||
-- warn: mcv / mcf null mismatch part 1
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.6::real,
|
||||
'avg_width', 7::integer,
|
||||
'n_distinct', -0.7::real,
|
||||
'most_common_freqs', '{0.1,0.2,0.3}'::real[]
|
||||
);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'id';
|
||||
|
||||
-- warn: mcv / mcf null mismatch part 2
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.7::real,
|
||||
'avg_width', 8::integer,
|
||||
'n_distinct', -0.8::real,
|
||||
'most_common_vals', '{1,2,3}'::text
|
||||
);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'id';
|
||||
|
||||
-- warn: mcv / mcf type mismatch
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.8::real,
|
||||
'avg_width', 9::integer,
|
||||
'n_distinct', -0.9::real,
|
||||
'most_common_vals', '{2,1,3}'::text,
|
||||
'most_common_freqs', '{0.2,0.1}'::double precision[]
|
||||
);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'id';
|
||||
|
||||
-- warn: mcv cast failure
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.9::real,
|
||||
'avg_width', 10::integer,
|
||||
'n_distinct', -0.4::real,
|
||||
'most_common_vals', '{2,four,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';
|
||||
|
||||
-- ok: mcv+mcf
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 1::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';
|
||||
|
||||
-- warn: NULL in histogram array
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.2::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', -0.2::real,
|
||||
'histogram_bounds', '{1,NULL,3,4}'::text
|
||||
);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'id';
|
||||
|
||||
-- ok: histogram_bounds
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.3::real,
|
||||
'avg_width', 3::integer,
|
||||
'n_distinct', -0.3::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';
|
||||
|
||||
-- warn: elem_count_histogram null element
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'tags'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.4::real,
|
||||
'avg_width', 5::integer,
|
||||
'n_distinct', -0.4::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[]
|
||||
);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'tags';
|
||||
|
||||
-- ok: elem_count_histogram
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'tags'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.5::real,
|
||||
'avg_width', 6::integer,
|
||||
'n_distinct', -0.55::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';
|
||||
|
||||
-- range stats on a scalar type
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.6::real,
|
||||
'avg_width', 7::integer,
|
||||
'n_distinct', -0.15::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 = 'id';
|
||||
|
||||
-- warn: range_empty_frac range_length_hist null mismatch
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.7::real,
|
||||
'avg_width', 8::integer,
|
||||
'n_distinct', -0.25::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';
|
||||
|
||||
-- warn: range_empty_frac range_length_hist null mismatch part 2
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.8::real,
|
||||
'avg_width', 9::integer,
|
||||
'n_distinct', -0.35::real,
|
||||
'range_empty_frac', 0.5::real
|
||||
);
|
||||
|
||||
SELECT *
|
||||
FROM pg_stats
|
||||
WHERE schemaname = 'stats_import'
|
||||
AND tablename = 'test'
|
||||
AND inherited = false
|
||||
AND attname = 'arange';
|
||||
|
||||
-- ok: range_empty_frac + range_length_hist
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.9::real,
|
||||
'avg_width', 1::integer,
|
||||
'n_distinct', -0.19::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';
|
||||
|
||||
-- warn: range bounds histogram on scalar
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'id'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.1::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', -0.29::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 = 'id';
|
||||
|
||||
-- ok: range_bounds_histogram
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.2::real,
|
||||
'avg_width', 3::integer,
|
||||
'n_distinct', -0.39::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';
|
||||
|
||||
-- warn: too many stat kinds
|
||||
SELECT pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', 'stats_import.test'::regclass,
|
||||
'attname', 'arange'::name,
|
||||
'inherited', false::boolean,
|
||||
'version', 150000::integer,
|
||||
'null_frac', 0.5::real,
|
||||
'avg_width', 2::integer,
|
||||
'n_distinct', -0.1::real,
|
||||
'most_common_vals', '{"[2,3)","[1,3)","[3,9)"}'::text,
|
||||
'most_common_freqs', '{0.3,0.25,0.05}'::real[],
|
||||
'histogram_bounds', '{"[1,2)","[2,3)","[3,4)","[4,)"}'::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
|
||||
@ -687,4 +1161,172 @@ 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;
|
||||
|
||||
--
|
||||
SELECT relpages, reltuples, relallvisible
|
||||
FROM pg_class
|
||||
WHERE oid = 'stats_import.test'::regclass;
|
||||
|
||||
--
|
||||
-- Clear clone stats to try again with pg_restore_attribute_stats
|
||||
--
|
||||
SELECT
|
||||
pg_catalog.pg_clear_attribute_stats(
|
||||
('stats_import.' || s.tablename)::regclass,
|
||||
s.attname,
|
||||
s.inherited)
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
WHERE s.schemaname = 'stats_import'
|
||||
AND s.tablename IN ('test_clone', 'is_odd_clone')
|
||||
ORDER BY s.tablename, s.attname, s.inherited;
|
||||
SELECT
|
||||
|
||||
SELECT COUNT(*)
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
WHERE s.schemaname = 'stats_import'
|
||||
AND s.tablename IN ('test_clone', 'is_odd_clone');
|
||||
|
||||
--
|
||||
-- Copy stats from test to test_clone, and is_odd to is_odd_clone
|
||||
--
|
||||
SELECT s.schemaname, s.tablename, s.attname, s.inherited, r.*
|
||||
FROM pg_catalog.pg_stats AS s
|
||||
CROSS JOIN LATERAL
|
||||
pg_catalog.pg_restore_attribute_stats(
|
||||
'relation', ('stats_import.' || s.tablename || '_clone')::regclass,
|
||||
'attname', s.attname,
|
||||
'inherited', s.inherited,
|
||||
'version', 150000,
|
||||
'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;
|
||||
|
Reference in New Issue
Block a user