Commit 25a9e54d authored by Dean Rasheed's avatar Dean Rasheed

Improve estimation of OR clauses using extended statistics.

Formerly we only applied extended statistics to an OR clause as part
of the clauselist_selectivity() code path for an OR clause appearing
in an implicitly-ANDed list of clauses. This meant that it could only
use extended statistics if all sub-clauses of the OR clause were
covered by a single extended statistics object.

Instead, teach clause_selectivity() how to apply extended statistics
to an OR clause by handling its ORed list of sub-clauses in a similar
manner to an implicitly-ANDed list of sub-clauses, but with different
combination rules. This allows one or more extended statistics objects
to be used to estimate all or part of the list of sub-clauses. Any
remaining sub-clauses are then treated as if they are independent.

Additionally, to avoid double-application of extended statistics, this
introduces "extended" versions of clause_selectivity() and
clauselist_selectivity(), which include an option to ignore extended
statistics. This replaces the old clauselist_selectivity_simple()
function which failed to completely ignore extended statistics when
called from the extended statistics code.

A known limitation of the current infrastructure is that an AND clause
under an OR clause is not treated as compatible with extended
statistics (because we don't build RestrictInfos for such sub-AND
clauses). Thus, for example, "(a=1 AND b=1) OR (a=2 AND b=2)" will
currently be treated as two independent AND clauses (each of which may
be estimated using extended statistics), but extended statistics will
not currently be used to account for any possible overlap between
those clauses. Improving that is left as a task for the future.

Original patch by Tomas Vondra, with additional improvements by me.

Discussion: https://postgr.es/m/20200113230008.g67iyk4cs3xbnjju@development
parent b5913f61
This diff is collapsed.
......@@ -1073,8 +1073,8 @@ clauselist_apply_dependencies(PlannerInfo *root, List *clauses,
}
}
simple_sel = clauselist_selectivity_simple(root, attr_clauses, varRelid,
jointype, sjinfo, NULL);
simple_sel = clauselist_selectivity_ext(root, attr_clauses, varRelid,
jointype, sjinfo, false);
attr_sel[attidx++] = simple_sel;
}
......
This diff is collapsed.
......@@ -32,6 +32,7 @@
#include "utils/fmgroids.h"
#include "utils/fmgrprotos.h"
#include "utils/lsyscache.h"
#include "utils/selfuncs.h"
#include "utils/syscache.h"
#include "utils/typcache.h"
......@@ -1888,16 +1889,80 @@ mcv_get_match_bitmap(PlannerInfo *root, List *clauses,
}
/*
* mcv_combine_selectivities
* Combine per-column and multi-column MCV selectivity estimates.
*
* simple_sel is a "simple" selectivity estimate (produced without using any
* extended statistics, essentially assuming independence of columns/clauses).
*
* mcv_sel and mcv_basesel are sums of the frequencies and base frequencies of
* all matching MCV items. The difference (mcv_sel - mcv_basesel) is then
* essentially interpreted as a correction to be added to simple_sel, as
* described below.
*
* mcv_totalsel is the sum of the frequencies of all MCV items (not just the
* matching ones). This is used as an upper bound on the portion of the
* selectivity estimates not covered by the MCV statistics.
*
* Note: While simple and base selectivities are defined in a quite similar
* way, the values are computed differently and are not therefore equal. The
* simple selectivity is computed as a product of per-clause estimates, while
* the base selectivity is computed by adding up base frequencies of matching
* items of the multi-column MCV list. So the values may differ for two main
* reasons - (a) the MCV list may not cover 100% of the data and (b) some of
* the MCV items did not match the estimated clauses.
*
* As both (a) and (b) reduce the base selectivity value, it generally holds
* that (simple_sel >= mcv_basesel). If the MCV list covers all the data, the
* values may be equal.
*
* So, other_sel = (simple_sel - mcv_basesel) is an estimate for the part not
* covered by the MCV list, and (mcv_sel - mcv_basesel) may be seen as a
* correction for the part covered by the MCV list. Those two statements are
* actually equivalent.
*/
Selectivity
mcv_combine_selectivities(Selectivity simple_sel,
Selectivity mcv_sel,
Selectivity mcv_basesel,
Selectivity mcv_totalsel)
{
Selectivity other_sel;
Selectivity sel;
/* estimated selectivity of values not covered by MCV matches */
other_sel = simple_sel - mcv_basesel;
CLAMP_PROBABILITY(other_sel);
/* this non-MCV selectivity cannot exceed 1 - mcv_totalsel */
if (other_sel > 1.0 - mcv_totalsel)
other_sel = 1.0 - mcv_totalsel;
/* overall selectivity is the sum of the MCV and non-MCV parts */
sel = mcv_sel + other_sel;
CLAMP_PROBABILITY(sel);
return sel;
}
/*
* mcv_clauselist_selectivity
* Return the selectivity estimate computed using an MCV list.
* Use MCV statistics to estimate the selectivity of an implicitly-ANDed
* list of clauses.
*
* First builds a bitmap of MCV items matching the clauses, and then sums
* the frequencies of matching items.
* This determines which MCV items match every clause in the list and returns
* the sum of the frequencies of those items.
*
* It also produces two additional interesting selectivities - total
* selectivity of all the MCV items (not just the matching ones), and the
* base frequency computed on the assumption of independence.
* In addition, it returns the sum of the base frequencies of each of those
* items (that is the sum of the selectivities that each item would have if
* the columns were independent of one another), and the total selectivity of
* all the MCV items (not just the matching ones). These are expected to be
* used together with a "simple" selectivity estimate (one based only on
* per-column statistics) to produce an overall selectivity estimate that
* makes use of both per-column and multi-column statistics --- see
* mcv_combine_selectivities().
*/
Selectivity
mcv_clauselist_selectivity(PlannerInfo *root, StatisticExtInfo *stat,
......@@ -1928,7 +1993,6 @@ mcv_clauselist_selectivity(PlannerInfo *root, StatisticExtInfo *stat,
if (matches[i] != false)
{
/* XXX Shouldn't the basesel be outside the if condition? */
*basesel += mcv->items[i].base_frequency;
s += mcv->items[i].frequency;
}
......@@ -1936,3 +2000,94 @@ mcv_clauselist_selectivity(PlannerInfo *root, StatisticExtInfo *stat,
return s;
}
/*
* mcv_clause_selectivity_or
* Use MCV statistics to estimate the selectivity of a clause that
* appears in an ORed list of clauses.
*
* As with mcv_clauselist_selectivity() this determines which MCV items match
* the clause and returns both the sum of the frequencies and the sum of the
* base frequencies of those items, as well as the sum of the frequencies of
* all MCV items (not just the matching ones) so that this information can be
* used by mcv_combine_selectivities() to produce a selectivity estimate that
* makes use of both per-column and multi-column statistics.
*
* Additionally, we return information to help compute the overall selectivity
* of the ORed list of clauses assumed to contain this clause. This function
* is intended to be called for each clause in the ORed list of clauses,
* allowing the overall selectivity to be computed using the following
* algorithm:
*
* Suppose P[n] = P(C[1] OR C[2] OR ... OR C[n]) is the combined selectivity
* of the first n clauses in the list. Then the combined selectivity taking
* into account the next clause C[n+1] can be written as
*
* P[n+1] = P[n] + P(C[n+1]) - P((C[1] OR ... OR C[n]) AND C[n+1])
*
* The final term above represents the overlap between the clauses examined so
* far and the (n+1)'th clause. To estimate its selectivity, we track the
* match bitmap for the ORed list of clauses examined so far and examine its
* intersection with the match bitmap for the (n+1)'th clause.
*
* We then also return the sums of the MCV item frequencies and base
* frequencies for the match bitmap intersection corresponding to the overlap
* term above, so that they can be combined with a simple selectivity estimate
* for that term.
*
* The parameter "or_matches" is an in/out parameter tracking the match bitmap
* for the clauses examined so far. The caller is expected to set it to NULL
* the first time it calls this function.
*/
Selectivity
mcv_clause_selectivity_or(PlannerInfo *root, StatisticExtInfo *stat,
MCVList *mcv, Node *clause, bool **or_matches,
Selectivity *basesel, Selectivity *overlap_mcvsel,
Selectivity *overlap_basesel, Selectivity *totalsel)
{
Selectivity s = 0.0;
bool *new_matches;
int i;
/* build the OR-matches bitmap, if not built already */
if (*or_matches == NULL)
*or_matches = palloc0(sizeof(bool) * mcv->nitems);
/* build the match bitmap for the new clause */
new_matches = mcv_get_match_bitmap(root, list_make1(clause), stat->keys,
mcv, false);
/*
* Sum the frequencies for all the MCV items matching this clause and also
* those matching the overlap between this clause and any of the preceding
* clauses as described above.
*/
*basesel = 0.0;
*overlap_mcvsel = 0.0;
*overlap_basesel = 0.0;
*totalsel = 0.0;
for (i = 0; i < mcv->nitems; i++)
{
*totalsel += mcv->items[i].frequency;
if (new_matches[i])
{
s += mcv->items[i].frequency;
*basesel += mcv->items[i].base_frequency;
if ((*or_matches)[i])
{
*overlap_mcvsel += mcv->items[i].frequency;
*overlap_basesel += mcv->items[i].base_frequency;
}
}
/* update the OR-matches bitmap for the next clause */
(*or_matches)[i] = (*or_matches)[i] || new_matches[i];
}
pfree(new_matches);
return s;
}
......@@ -58,17 +58,23 @@ extern Selectivity clause_selectivity(PlannerInfo *root,
int varRelid,
JoinType jointype,
SpecialJoinInfo *sjinfo);
extern Selectivity clauselist_selectivity_simple(PlannerInfo *root,
List *clauses,
extern Selectivity clause_selectivity_ext(PlannerInfo *root,
Node *clause,
int varRelid,
JoinType jointype,
SpecialJoinInfo *sjinfo,
Bitmapset *estimatedclauses);
bool use_extended_stats);
extern Selectivity clauselist_selectivity(PlannerInfo *root,
List *clauses,
int varRelid,
JoinType jointype,
SpecialJoinInfo *sjinfo);
extern Selectivity clauselist_selectivity_ext(PlannerInfo *root,
List *clauses,
int varRelid,
JoinType jointype,
SpecialJoinInfo *sjinfo,
bool use_extended_stats);
/* in path/costsize.c: */
......
......@@ -99,6 +99,11 @@ extern SortItem *build_sorted_items(int numrows, int *nitems, HeapTuple *rows,
extern bool examine_clause_args(List *args, Var **varp,
Const **cstp, bool *varonleftp);
extern Selectivity mcv_combine_selectivities(Selectivity simple_sel,
Selectivity mcv_sel,
Selectivity mcv_basesel,
Selectivity mcv_totalsel);
extern Selectivity mcv_clauselist_selectivity(PlannerInfo *root,
StatisticExtInfo *stat,
List *clauses,
......@@ -109,4 +114,14 @@ extern Selectivity mcv_clauselist_selectivity(PlannerInfo *root,
Selectivity *basesel,
Selectivity *totalsel);
extern Selectivity mcv_clause_selectivity_or(PlannerInfo *root,
StatisticExtInfo *stat,
MCVList *mcv,
Node *clause,
bool **or_matches,
Selectivity *basesel,
Selectivity *overlap_mcvsel,
Selectivity *overlap_basesel,
Selectivity *totalsel);
#endif /* EXTENDED_STATS_INTERNAL_H */
......@@ -116,7 +116,8 @@ extern Selectivity statext_clauselist_selectivity(PlannerInfo *root,
JoinType jointype,
SpecialJoinInfo *sjinfo,
RelOptInfo *rel,
Bitmapset **estimatedclauses);
Bitmapset **estimatedclauses,
bool is_or);
extern bool has_stats_of_kind(List *stats, char requiredkind);
extern StatisticExtInfo *choose_best_statistics(List *stats, char requiredkind,
Bitmapset **clause_attnums,
......
......@@ -1113,6 +1113,12 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a = 1 OR b = '
200 | 200
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a = 1 OR b = ''1'' OR c = 1 OR d IS NOT NULL');
estimated | actual
-----------+--------
200 | 200
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a IN (1, 2, 51, 52) AND b IN ( ''1'', ''2'')');
estimated | actual
-----------+--------
......@@ -1173,13 +1179,6 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a < ALL (ARRAY
100 | 100
(1 row)
-- we can't use the statistic for OR clauses that are not fully covered (missing 'd' attribute)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a = 1 OR b = ''1'' OR c = 1 OR d IS NOT NULL');
estimated | actual
-----------+--------
343 | 200
(1 row)
-- check change of unrelated column type does not reset the MCV statistics
ALTER TABLE mcv_lists ALTER COLUMN d TYPE VARCHAR(64);
SELECT d.stxdmcv IS NOT NULL
......@@ -1477,6 +1476,134 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_bool WHERE NOT a AND
1 | 0
(1 row)
-- mcv covering just a small fraction of data
CREATE TABLE mcv_lists_partial (
a INT,
b INT,
c INT
);
-- 10 frequent groups, each with 100 elements
INSERT INTO mcv_lists_partial (a, b, c)
SELECT
mod(i,10),
mod(i,10),
mod(i,10)
FROM generate_series(0,999) s(i);
-- 100 groups that will make it to the MCV list (includes the 10 frequent ones)
INSERT INTO mcv_lists_partial (a, b, c)
SELECT
i,
i,
i
FROM generate_series(0,99) s(i);
-- 4000 groups in total, most of which won't make it (just a single item)
INSERT INTO mcv_lists_partial (a, b, c)
SELECT
i,
i,
i
FROM generate_series(0,3999) s(i);
ANALYZE mcv_lists_partial;
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 0');
estimated | actual
-----------+--------
1 | 102
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 0');
estimated | actual
-----------+--------
300 | 102
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 AND b = 10 AND c = 10');
estimated | actual
-----------+--------
1 | 2
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 OR b = 10 OR c = 10');
estimated | actual
-----------+--------
6 | 2
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 10');
estimated | actual
-----------+--------
1 | 0
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 10');
estimated | actual
-----------+--------
204 | 104
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0 AND c = 0) OR (a = 1 AND b = 1 AND c = 1) OR (a = 2 AND b = 2 AND c = 2)');
estimated | actual
-----------+--------
1 | 306
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0) OR (a = 0 AND c = 0) OR (b = 0 AND c = 0)');
estimated | actual
-----------+--------
6 | 102
(1 row)
CREATE STATISTICS mcv_lists_partial_stats (mcv) ON a, b, c
FROM mcv_lists_partial;
ANALYZE mcv_lists_partial;
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 0');
estimated | actual
-----------+--------
102 | 102
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 0');
estimated | actual
-----------+--------
96 | 102
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 AND b = 10 AND c = 10');
estimated | actual
-----------+--------
2 | 2
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 OR b = 10 OR c = 10');
estimated | actual
-----------+--------
2 | 2
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 10');
estimated | actual
-----------+--------
1 | 0
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 10');
estimated | actual
-----------+--------
102 | 104
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0 AND c = 0) OR (a = 1 AND b = 1 AND c = 1) OR (a = 2 AND b = 2 AND c = 2)');
estimated | actual
-----------+--------
300 | 306
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0) OR (a = 0 AND c = 0) OR (b = 0 AND c = 0)');
estimated | actual
-----------+--------
306 | 102
(1 row)
DROP TABLE mcv_lists_partial;
-- check the ability to use multiple MCV lists
CREATE TABLE mcv_lists_multi (
a INTEGER,
......@@ -1506,12 +1633,36 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE c = 0 AN
102 | 714
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 AND c = 0');
estimated | actual
-----------+--------
143 | 142
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 OR c = 0');
estimated | actual
-----------+--------
1571 | 1572
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 AND b = 0 AND c = 0 AND d = 0');
estimated | actual
-----------+--------
4 | 142
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE (a = 0 AND b = 0) OR (c = 0 AND d = 0)');
estimated | actual
-----------+--------
298 | 1572
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 OR b = 0 OR c = 0 OR d = 0');
estimated | actual
-----------+--------
2649 | 1572
(1 row)
-- create separate MCV statistics
CREATE STATISTICS mcv_lists_multi_1 (mcv) ON a, b FROM mcv_lists_multi;
CREATE STATISTICS mcv_lists_multi_2 (mcv) ON c, d FROM mcv_lists_multi;
......@@ -1528,12 +1679,36 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE c = 0 AN
714 | 714
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 AND c = 0');
estimated | actual
-----------+--------
143 | 142
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 OR c = 0');
estimated | actual
-----------+--------
1571 | 1572
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 AND b = 0 AND c = 0 AND d = 0');
estimated | actual
-----------+--------
143 | 142
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE (a = 0 AND b = 0) OR (c = 0 AND d = 0)');
estimated | actual
-----------+--------
1571 | 1572
(1 row)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 OR b = 0 OR c = 0 OR d = 0');
estimated | actual
-----------+--------
1714 | 1572
(1 row)
DROP TABLE mcv_lists_multi;
-- Permission tests. Users should not be able to see specific data values in
-- the extended statistics, if they lack permission to see those values in
......
......@@ -561,6 +561,8 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE 4 >= a AND ''0
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a = 1 OR b = ''1'' OR c = 1');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a = 1 OR b = ''1'' OR c = 1 OR d IS NOT NULL');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a IN (1, 2, 51, 52) AND b IN ( ''1'', ''2'')');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a IN (1, 2, 51, 52, NULL) AND b IN ( ''1'', ''2'', NULL)');
......@@ -581,9 +583,6 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a < ALL (ARRAY
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a < ALL (ARRAY[4, 5]) AND b IN (''1'', ''2'', NULL, ''3'') AND c > ANY (ARRAY[1, 2, NULL, 3])');
-- we can't use the statistic for OR clauses that are not fully covered (missing 'd' attribute)
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists WHERE a = 1 OR b = ''1'' OR c = 1 OR d IS NOT NULL');
-- check change of unrelated column type does not reset the MCV statistics
ALTER TABLE mcv_lists ALTER COLUMN d TYPE VARCHAR(64);
......@@ -777,6 +776,78 @@ SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_bool WHERE NOT a AND
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_bool WHERE NOT a AND b AND NOT c');
-- mcv covering just a small fraction of data
CREATE TABLE mcv_lists_partial (
a INT,
b INT,
c INT
);
-- 10 frequent groups, each with 100 elements
INSERT INTO mcv_lists_partial (a, b, c)
SELECT
mod(i,10),
mod(i,10),
mod(i,10)
FROM generate_series(0,999) s(i);
-- 100 groups that will make it to the MCV list (includes the 10 frequent ones)
INSERT INTO mcv_lists_partial (a, b, c)
SELECT
i,
i,
i
FROM generate_series(0,99) s(i);
-- 4000 groups in total, most of which won't make it (just a single item)
INSERT INTO mcv_lists_partial (a, b, c)
SELECT
i,
i,
i
FROM generate_series(0,3999) s(i);
ANALYZE mcv_lists_partial;
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 AND b = 10 AND c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 OR b = 10 OR c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0 AND c = 0) OR (a = 1 AND b = 1 AND c = 1) OR (a = 2 AND b = 2 AND c = 2)');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0) OR (a = 0 AND c = 0) OR (b = 0 AND c = 0)');
CREATE STATISTICS mcv_lists_partial_stats (mcv) ON a, b, c
FROM mcv_lists_partial;
ANALYZE mcv_lists_partial;
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 AND b = 10 AND c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 10 OR b = 10 OR c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 AND b = 0 AND c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE a = 0 OR b = 0 OR c = 10');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0 AND c = 0) OR (a = 1 AND b = 1 AND c = 1) OR (a = 2 AND b = 2 AND c = 2)');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_partial WHERE (a = 0 AND b = 0) OR (a = 0 AND c = 0) OR (b = 0 AND c = 0)');
DROP TABLE mcv_lists_partial;
-- check the ability to use multiple MCV lists
CREATE TABLE mcv_lists_multi (
a INTEGER,
......@@ -799,7 +870,11 @@ ANALYZE mcv_lists_multi;
-- estimates without any mcv statistics
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 AND b = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE c = 0 AND d = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 AND c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 OR c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 AND b = 0 AND c = 0 AND d = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE (a = 0 AND b = 0) OR (c = 0 AND d = 0)');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 OR b = 0 OR c = 0 OR d = 0');
-- create separate MCV statistics
CREATE STATISTICS mcv_lists_multi_1 (mcv) ON a, b FROM mcv_lists_multi;
......@@ -809,7 +884,11 @@ ANALYZE mcv_lists_multi;
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 AND b = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE c = 0 AND d = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 AND c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE b = 0 OR c = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 AND b = 0 AND c = 0 AND d = 0');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE (a = 0 AND b = 0) OR (c = 0 AND d = 0)');
SELECT * FROM check_estimated_rows('SELECT * FROM mcv_lists_multi WHERE a = 0 OR b = 0 OR c = 0 OR d = 0');
DROP TABLE mcv_lists_multi;
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment