If ANALYZE found no repeated non-null entries in its sample, it set the
column's stadistinct value to -1.0, intending to indicate that the entries
are all distinct. But what this value actually means is that the number
of distinct values is 100% of the table's rowcount, and thus it was
overestimating the number of distinct values by however many nulls there
are. This could lead to very poor selectivity estimates, as for example
in a recent report from Andreas Joseph Krogh. We should discount the
stadistinct value by whatever we've estimated the nulls fraction to be.
(That is what will happen if we choose to use a negative stadistinct for
a column that does have repeated entries, so this code path was just
inconsistent.)
In addition to fixing the stadistinct entries stored by several different
ANALYZE code paths, adjust the logic where get_variable_numdistinct()
forces an "all distinct" estimate on the basis of finding a relevant unique
index. Unique indexes don't reject nulls, so there's no reason to assume
that the null fraction doesn't apply.
Back-patch to all supported branches. Back-patching is a bit of a judgment
call, but this problem seems to affect only a few users (else we'd have
identified it long ago), and it's bad enough when it does happen that
destabilizing plan choices in a worse direction seems unlikely.
Patch by me, with documentation wording suggested by Dean Rasheed
Report: <VisenaEmail.26.
df42f82acae38a58.
156463942b8@tc7-visena>
Discussion: <16143.
1470350371@sss.pgh.pa.us>
<entry>The number of distinct nonnull data values in the column.
A value greater than zero is the actual number of distinct values.
A value less than zero is the negative of a multiplier for the number
- of rows in the table; for example, a column in which values appear about
- twice on the average could be represented by
- <structfield>stadistinct</> = -0.5.
+ of rows in the table; for example, a column in which about 80% of the
+ values are nonnull and each nonnull value appears about twice on
+ average could be represented by <structfield>stadistinct</> = -0.4.
A zero value means the number of distinct values is unknown.
</entry>
</row>
if (nmultiple == 0)
{
- /* If we found no repeated values, assume it's a unique column */
- stats->stadistinct = -1.0;
+ /*
+ * If we found no repeated non-null values, assume it's a unique
+ * column; but be sure to discount for any nulls we found.
+ */
+ stats->stadistinct = -1.0 * (1.0 - stats->stanullfrac);
}
else if (track_cnt < track_max && toowide_cnt == 0 &&
nmultiple == track_cnt)
if (nmultiple == 0)
{
- /* If we found no repeated values, assume it's a unique column */
- stats->stadistinct = -1.0;
+ /*
+ * If we found no repeated non-null values, assume it's a unique
+ * column; but be sure to discount for any nulls we found.
+ */
+ stats->stadistinct = -1.0 * (1.0 - stats->stanullfrac);
}
else if (toowide_cnt == 0 && nmultiple == ndistinct)
{
else
stats->stawidth = stats->attrtype->typlen;
/* Assume all too-wide values are distinct, so it's a unique column */
- stats->stadistinct = -1.0;
+ stats->stadistinct = -1.0 * (1.0 - stats->stanullfrac);
}
else if (null_cnt > 0)
{
stats->stawidth = total_width / (double) nonnull_cnt;
/* Assume it's a unique column (see notes above) */
- stats->stadistinct = -1.0;
+ stats->stadistinct = -1.0 * (1.0 - stats->stanullfrac);
/*
* Construct an array of the interesting hashtable items, that is,
/* Do the simple null-frac and width stats */
stats->stanullfrac = (double) null_cnt / (double) samplerows;
stats->stawidth = total_width / (double) non_null_cnt;
- stats->stadistinct = -1.0;
+
+ /* Estimate that non-null values are unique */
+ stats->stadistinct = -1.0 * (1.0 - stats->stanullfrac);
/* Must copy the target values into anl_context */
old_cxt = MemoryContextSwitchTo(stats->anl_context);
get_variable_numdistinct(VariableStatData *vardata, bool *isdefault)
{
double stadistinct;
+ double stanullfrac = 0.0;
double ntuples;
*isdefault = false;
/*
* Determine the stadistinct value to use. There are cases where we can
* get an estimate even without a pg_statistic entry, or can get a better
- * value than is in pg_statistic.
+ * value than is in pg_statistic. Grab stanullfrac too if we can find it
+ * (otherwise, assume no nulls, for lack of any better idea).
*/
if (HeapTupleIsValid(vardata->statsTuple))
{
stats = (Form_pg_statistic) GETSTRUCT(vardata->statsTuple);
stadistinct = stats->stadistinct;
+ stanullfrac = stats->stanullfrac;
}
else if (vardata->vartype == BOOLOID)
{
{
case ObjectIdAttributeNumber:
case SelfItemPointerAttributeNumber:
- stadistinct = -1.0; /* unique */
+ stadistinct = -1.0; /* unique (and all non null) */
break;
case TableOidAttributeNumber:
stadistinct = 1.0; /* only 1 value */
* If there is a unique index or DISTINCT clause for the variable, assume
* it is unique no matter what pg_statistic says; the statistics could be
* out of date, or we might have found a partial unique index that proves
- * the var is unique for this query.
+ * the var is unique for this query. However, we'd better still believe
+ * the null-fraction statistic.
*/
if (vardata->isunique)
- stadistinct = -1.0;
+ stadistinct = -1.0 * (1.0 - stanullfrac);
/*
* If we had an absolute estimate, use that.
* > 0 actual number of distinct values
* < 0 negative of multiplier for number of rows
* The special negative case allows us to cope with columns that are
- * unique (stadistinct = -1) or nearly so (for example, a column in
- * which values appear about twice on the average could be represented
- * by stadistinct = -0.5). Because the number-of-rows statistic in
- * pg_class may be updated more frequently than pg_statistic is, it's
- * important to be able to describe such situations as a multiple of
- * the number of rows, rather than a fixed number of distinct values.
- * But in other cases a fixed number is correct (eg, a boolean column).
+ * unique (stadistinct = -1) or nearly so (for example, a column in which
+ * non-null values appear about twice on the average could be represented
+ * by stadistinct = -0.5 if there are no nulls, or -0.4 if 20% of the
+ * column is nulls). Because the number-of-rows statistic in pg_class may
+ * be updated more frequently than pg_statistic is, it's important to be
+ * able to describe such situations as a multiple of the number of rows,
+ * rather than a fixed number of distinct values. But in other cases a
+ * fixed number is correct (eg, a boolean column).
* ----------------
*/
float4 stadistinct;