Avoid regressions in foreign-key-based selectivity estimates.

David Rowley found that the "use the smallest per-column selectivity"
heuristic applied in some cases by get_foreign_key_join_selectivity()
was badly off if the FK columns are independent, producing estimates
much worse than we got before that code was added in 9.6.

One case where that heuristic was used was for LEFT and FULL outer joins
with the referenced rel on the outside of the join.  But we should not
really need to special-case those here.  eqjoinsel() never has had such a
special case; the correction is applied by calc_joinrel_size_estimate()
instead.  Let's just estimate such cases like inner joins and rely on that
later adjustment.  (I think there was something of a thinko here, in that
the comments seem to be thinking about the selectivity as defined for
semi/anti joins; but that shouldn't apply to left/full joins.)  Add a
regression test exercising such a case to show that this is sane in
at least some cases.

The other case where we used that heuristic was for SEMI/ANTI outer joins,
either if the referenced rel was on the outside, or if it was on the inside
but was part of a join within the RHS.  In either case, the FK doesn't give
us a lot of traction towards estimating the selectivity.  To ensure that
we don't have regressions from what happened before 9.6, let's punt by
ignoring the FK in such cases and applying the traditional selectivity
calculation.  (We might be able to improve on that later, but for now
I just want to be sure it's not worse than 9.5.)

Report and patch by David Rowley, simplified a bit by me.  Back-patch
to 9.6 where this code was added.

Discussion: https://postgr.es/m/CAKJS1f8NO8oCDcxrteohG6O72uU1saEVT9qX=R8pENr5QWerXw@mail.gmail.com
This commit is contained in:
Tom Lane 2017-06-19 15:33:41 -04:00
parent bd61d5a194
commit d8e6b84bd2
3 changed files with 93 additions and 67 deletions

View File

@ -4318,7 +4318,6 @@ get_foreign_key_join_selectivity(PlannerInfo *root,
{
ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
bool ref_is_outer;
bool use_smallest_selectivity = false;
List *removedlist;
ListCell *cell;
ListCell *prev;
@ -4337,6 +4336,22 @@ get_foreign_key_join_selectivity(PlannerInfo *root,
else
continue;
/*
* If we're dealing with a semi/anti join, and the FK's referenced
* relation is on the outside, then knowledge of the FK doesn't help
* us figure out what we need to know (which is the fraction of outer
* rows that have matches). On the other hand, if the referenced rel
* is on the inside, then all outer rows must have matches in the
* referenced table (ignoring nulls). But any restriction or join
* clauses that filter that table will reduce the fraction of matches.
* We can account for restriction clauses, but it's too hard to guess
* how many table rows would get through a join that's inside the RHS.
* Hence, if either case applies, punt and ignore the FK.
*/
if ((jointype == JOIN_SEMI || jointype == JOIN_ANTI) &&
(ref_is_outer || bms_membership(inner_relids) != BMS_SINGLETON))
continue;
/*
* Modify the restrictlist by removing clauses that match the FK (and
* putting them into removedlist instead). It seems unsafe to modify
@ -4437,10 +4452,7 @@ get_foreign_key_join_selectivity(PlannerInfo *root,
* However (1) if there are any strict restriction clauses for the
* referencing column(s) elsewhere in the query, derating here would
* be double-counting the null fraction, and (2) it's not very clear
* how to combine null fractions for multiple referencing columns.
*
* In the use_smallest_selectivity code below, null derating is done
* implicitly by relying on clause_selectivity(); in the other cases,
* how to combine null fractions for multiple referencing columns. So
* we do nothing for now about correcting for nulls.
*
* XXX another point here is that if either side of an FK constraint
@ -4453,52 +4465,23 @@ get_foreign_key_join_selectivity(PlannerInfo *root,
* work, it is uncommon in practice to have an FK referencing a parent
* table. So, at least for now, disregard inheritance here.
*/
if (ref_is_outer && jointype != JOIN_INNER)
if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
{
/*
* When the referenced table is on the outer side of a non-inner
* join, knowing that each inner row has exactly one match is not
* as useful as one could wish, since we really need to know the
* fraction of outer rows with a match. Still, we can avoid the
* folly of multiplying the per-column estimates together. Take
* the smallest per-column selectivity, instead. (This should
* correspond to the FK column with the most nulls.)
* For JOIN_SEMI and JOIN_ANTI, we only get here when the FK's
* referenced table is exactly the inside of the join. The join
* selectivity is defined as the fraction of LHS rows that have
* matches. The FK implies that every LHS row has a match *in the
* referenced table*; but any restriction clauses on it will
* reduce the number of matches. Hence we take the join
* selectivity as equal to the selectivity of the table's
* restriction clauses, which is rows / tuples; but we must guard
* against tuples == 0.
*/
use_smallest_selectivity = true;
}
else if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
{
/*
* For JOIN_SEMI and JOIN_ANTI, the selectivity is defined as the
* fraction of LHS rows that have matches. The referenced table
* is on the inner side (we already handled the other case above),
* so the FK implies that every LHS row has a match *in the
* referenced table*. But any restriction or join clauses below
* here will reduce the number of matches.
*/
if (bms_membership(inner_relids) == BMS_SINGLETON)
{
/*
* When the inner side of the semi/anti join is just the
* referenced table, we may take the FK selectivity as equal
* to the selectivity of the table's restriction clauses.
*/
RelOptInfo *ref_rel = find_base_rel(root, fkinfo->ref_relid);
double ref_tuples = Max(ref_rel->tuples, 1.0);
RelOptInfo *ref_rel = find_base_rel(root, fkinfo->ref_relid);
double ref_tuples = Max(ref_rel->tuples, 1.0);
fkselec *= ref_rel->rows / ref_tuples;
}
else
{
/*
* When the inner side of the semi/anti join is itself a join,
* it's hard to guess what fraction of the referenced table
* will get through the join. But we still don't want to
* multiply per-column estimates together. Take the smallest
* per-column selectivity, instead.
*/
use_smallest_selectivity = true;
}
fkselec *= ref_rel->rows / ref_tuples;
}
else
{
@ -4512,26 +4495,6 @@ get_foreign_key_join_selectivity(PlannerInfo *root,
fkselec *= 1.0 / ref_tuples;
}
/*
* Common code for cases where we should use the smallest selectivity
* that would be computed for any one of the FK's clauses.
*/
if (use_smallest_selectivity)
{
Selectivity thisfksel = 1.0;
foreach(cell, removedlist)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(cell);
Selectivity csel;
csel = clause_selectivity(root, (Node *) rinfo,
0, jointype, sjinfo);
thisfksel = Min(thisfksel, csel);
}
fkselec *= thisfksel;
}
}
*restrictlist = worklist;

View File

@ -5328,6 +5328,41 @@ LINE 1: ...xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
^
HINT: There is an entry for table "xx1", but it cannot be referenced from this part of the query.
--
-- test that foreign key join estimation performs sanely for outer joins
--
begin;
create table fkest (a int, b int, c int unique, primary key(a,b));
create table fkest1 (a int, b int, primary key(a,b));
insert into fkest select x/10, x%10, x from generate_series(1,1000) x;
insert into fkest1 select x/10, x%10 from generate_series(1,1000) x;
alter table fkest1
add constraint fkest1_a_b_fkey foreign key (a,b) references fkest;
analyze fkest;
analyze fkest1;
explain (costs off)
select *
from fkest f
left join fkest1 f1 on f.a = f1.a and f.b = f1.b
left join fkest1 f2 on f.a = f2.a and f.b = f2.b
left join fkest1 f3 on f.a = f3.a and f.b = f3.b
where f.c = 1;
QUERY PLAN
------------------------------------------------------------------
Nested Loop Left Join
-> Nested Loop Left Join
-> Nested Loop Left Join
-> Index Scan using fkest_c_key on fkest f
Index Cond: (c = 1)
-> Index Only Scan using fkest1_pkey on fkest1 f1
Index Cond: ((a = f.a) AND (b = f.b))
-> Index Only Scan using fkest1_pkey on fkest1 f2
Index Cond: ((a = f.a) AND (b = f.b))
-> Index Only Scan using fkest1_pkey on fkest1 f3
Index Cond: ((a = f.a) AND (b = f.b))
(11 rows)
rollback;
--
-- test planner's ability to mark joins as unique
--
create table j1 (id int primary key);

View File

@ -1733,6 +1733,34 @@ delete from xx1 using (select * from int4_tbl where f1 = x1) ss;
delete from xx1 using (select * from int4_tbl where f1 = xx1.x1) ss;
delete from xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
--
-- test that foreign key join estimation performs sanely for outer joins
--
begin;
create table fkest (a int, b int, c int unique, primary key(a,b));
create table fkest1 (a int, b int, primary key(a,b));
insert into fkest select x/10, x%10, x from generate_series(1,1000) x;
insert into fkest1 select x/10, x%10 from generate_series(1,1000) x;
alter table fkest1
add constraint fkest1_a_b_fkey foreign key (a,b) references fkest;
analyze fkest;
analyze fkest1;
explain (costs off)
select *
from fkest f
left join fkest1 f1 on f.a = f1.a and f.b = f1.b
left join fkest1 f2 on f.a = f2.a and f.b = f2.b
left join fkest1 f3 on f.a = f3.a and f.b = f3.b
where f.c = 1;
rollback;
--
-- test planner's ability to mark joins as unique
--