PATCH: use foreign keys to improve join estimates v1
Hi,
attached is a first version of a patch that aims to improve cardinality
estimates of joins by matching foreign keys between the tables (which
was ignored by the planner until now).
This significantly improves estimates when joining two tables using
multi-column conditions, matching a foreign key between the tables.
Consider for example this simple case
CREATE TABLE dim (a int, b int, primary key (a,b));
CREATE TABLE fact (a int, b int, foreign key (a,b) references dim(a,b));
INSERT INTO dim SELECT i,i FROM generate_series(1,1000000) s(i);
INSERT INTO fact SELECT i,i FROM generate_series(1,1000000) s(i);
ANALYZE dim;
ANALYZE fact;
EXPLAIN SELECT * FROM fact f JOIN dim d USING (a,b);
QUERY PLAN
---------------------------------------------------------------------------
Hash Join (cost=29425.00..51350.01 rows=1 width=16)
Hash Cond: ((f.a = d.a) AND (f.b = d.b))
-> Seq Scan on fact f (cost=0.00..14425.00 rows=1000000 width=8)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on dim d (cost=0.00..14425.00 rows=1000000 width=8)
(5 rows)
which is of course completely off, because the query produces 1M rows.
In practice, underestimates like this often cause much more serious
issues in the subsequent steps - for example the next join would
probably be executed as nested loop, which makes sense with a single row
but is an awful choice with 1M rows.
With the patch, the planner realizes there is a matching foreign key,
and tweaks the selectivities in calc_joinrel_size_estimate().
QUERY PLAN
-------------------------------------------------------------------------
Hash Join (cost=29426.25..250323877.62 rows=1000050 width=8)
Hash Cond: ((fact.a = dim.a) AND (fact.b = dim.b))
-> Seq Scan on fact (cost=0.00..14425.50 rows=1000050 width=8)
-> Hash (cost=14425.50..14425.50 rows=1000050 width=8)
-> Seq Scan on dim (cost=0.00..14425.50 rows=1000050 width=8)
(5 rows)
There are a few unsolved questions/issues:
(1) The current patch only does the trick when the FK matches the
conditions perfectly - when there are no missing columns (present
in the FK, not covered by a condition).
I believe this might be relaxed in both directions. When the
conditions don't cover all the FK columns, we know there's at least
one matching row (and we can estimate the number of matches). In
the other direction, we can estimate just the 'extra' conditions.
(2) Adding further conditions may further break the estimates, for
example after adding "WHERE d.a = d.b" this happens
QUERY PLAN
------------------------------------------------------------------------
Hash Join (cost=16987.50..33931.50 rows=25 width=8)
Hash Cond: (f.a = d.a)
-> Seq Scan on fact f (cost=0.00..16925.00 rows=5000 width=8)
Filter: (a = b)
-> Hash (cost=16925.00..16925.00 rows=5000 width=8)
-> Seq Scan on dim d (cost=0.00..16925.00 rows=5000 width=8)
Filter: (a = b)
(7 rows)
One issue is that "a=b" condition is poorly estimated due to
correlation (which might be improved by multi-variate stats). It
however removes one of the conditions from the join restrict list,
so it only contains "f.a = d.a" and thus only covers one of the FK
columns, and thus the patch fails to detect the FK :-(
Not sure how to fix this - one way might be performing the check
sooner, before the second join clause is removed (not sure where
that happens). Another option is reconstructing clauses somehow.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Attachments:
0001-estimation-with-fkeys-v1.patchtext/x-patch; name=0001-estimation-with-fkeys-v1.patchDownload
>From 5450be4c3af455ddae37b8949b293f8c01fc5bdd Mon Sep 17 00:00:00 2001
From: Tomas Vondra <tv@fuzzy.cz>
Date: Wed, 1 Apr 2015 22:26:46 +0200
Subject: [PATCH] improve cardinality estimation of joins on foreign keys
When estimating joins with multi-column join clauses, matching
FK constraints, the cardinality estimate is incorrect because
it multiplies selectivities of the clauses.
This may be significant issue for example with models involving
junction tables with multi-column primary keys, or other models
using multi-column primary keys.
CREATE TABLE dimension (a INT, b INT, PRIMARY KEY (a,b));
CREATE TABLE fact (a INT, b INT, FOREIGN KEY (a,b)
REFERENCES dimension (a,b));
INSERT INTO dimension SELECT i,i
FROM generate_series(1,1000) s(i);
INSERT INTO fact SELECT mod(i,1000)+1, mod(i,1000)+1
FROM generate_series(1,1000000) s(i);
ANALYZE;
EXPLAIN SELECT * FROM fact JOIN dimension USING (a,b);
This should estimate the join cardinality as 1.000.000, but it
the actual estimate is 1.000 (because of the multiplication).
The patch fixes this by matching the join clauses and foreign
key constraints in calc_joinrel_size_estimate().
---
src/backend/nodes/outfuncs.c | 13 ++
src/backend/optimizer/path/costsize.c | 14 ++
src/backend/optimizer/plan/analyzejoins.c | 249 ++++++++++++++++++++++++++++++
src/backend/optimizer/util/plancat.c | 80 ++++++++++
src/backend/utils/cache/relcache.c | 69 +++++++++
src/include/nodes/nodes.h | 1 +
src/include/nodes/relation.h | 15 ++
src/include/optimizer/paths.h | 2 +
src/include/optimizer/planmain.h | 3 +
src/include/utils/rel.h | 4 +
src/include/utils/relcache.h | 1 +
11 files changed, 451 insertions(+)
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 385b289..2fec460 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1837,6 +1837,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3178,6 +3188,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 1a0d358..f4c353a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3647,6 +3647,7 @@ calc_joinrel_size_estimate(PlannerInfo *root,
Selectivity jselec;
Selectivity pselec;
double nrows;
+ int fkey_join;
/*
* Compute joinclause selectivity. Note that we are only considering
@@ -3688,12 +3689,17 @@ calc_joinrel_size_estimate(PlannerInfo *root,
jointype,
sjinfo);
+ /* we only need join quals to determine this */
+ fkey_join = join_matches_fkey(root, sjinfo, joinquals);
+
/* Avoid leaking a lot of ListCells */
list_free(joinquals);
list_free(pushedquals);
}
else
{
+ fkey_join = join_matches_fkey(root, sjinfo, restrictlist);
+
jselec = clauselist_selectivity(root,
restrictlist,
0,
@@ -3703,6 +3709,14 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/*
+ * If it's a join on foreign key, tweak the selectivity accordingly. If there's
+ * outer table references inner (PK on inner), use 1/inner_rows, otherwise use
+ * 1/outer_rows.
+ */
+ if (fkey_join)
+ jselec = (fkey_join == 1) ? (1.0 / inner_rows) : (1.0 / outer_rows);
+
+ /*
* Basically, we multiply size of Cartesian product by selectivity.
*
* If we are doing an outer join, take that into account: the joinqual
diff --git a/src/backend/optimizer/plan/analyzejoins.c b/src/backend/optimizer/plan/analyzejoins.c
index 11d3933..3f601cc 100644
--- a/src/backend/optimizer/plan/analyzejoins.c
+++ b/src/backend/optimizer/plan/analyzejoins.c
@@ -564,6 +564,31 @@ remove_rel_from_joinlist(List *joinlist, int relid, int *nremoved)
return result;
}
+/*
+ * rel_has_unique_index
+ * Returns true if rel has at least one unique index.
+ *
+ * Fast pre-check for specialjoin_is_fk_join(), quickly eliminating joins that
+ * can't be FK joins.
+ */
+bool
+rel_has_unique_index(PlannerInfo *root, RelOptInfo *rel)
+{
+ ListCell *lc;
+
+ if (rel->rtekind != RTE_RELATION)
+ return false;
+
+ foreach (lc, rel->indexlist)
+ {
+ IndexOptInfo *iinfo = (IndexOptInfo *)lfirst(lc);
+
+ if (iinfo->unique)
+ return true;
+ }
+
+ return false;
+}
/*
* query_supports_distinctness - could the query possibly be proven distinct
@@ -749,3 +774,227 @@ distinct_col_search(int colno, List *colnos, List *opids)
}
return InvalidOid;
}
+
+bool
+has_matching_fkey(RelOptInfo *rel, Oid freloid, List *clauses,
+ bool reverse)
+{
+ ListCell *lc;
+ bool match = false;
+
+ foreach (lc, rel->fkeylist)
+ {
+ int i;
+ bool *matches;
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *)lfirst(lc);
+ int *conkey = fkinfo->conkeys,
+ *confkey = fkinfo->confkeys;
+ Oid *conpfeqop = fkinfo->conpfeqop;
+ ListCell *lc2;
+
+ if (fkinfo->confrelid != freloid)
+ continue;
+
+ /* one flag for each key of the foreign key constraint */
+ matches = (bool*)palloc0(fkinfo->nkeys);
+
+ foreach (lc2, clauses)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *)lfirst(lc2);
+ OpExpr *clause;
+ bool clause_match = false;
+
+ Var *outer_var, *inner_var;
+
+ /* FIXME should result in 'false' answer */
+ if (! IsA(rinfo, RestrictInfo))
+ break;
+
+ if (! IsA(rinfo->clause, OpExpr))
+ break;
+
+ clause = (OpExpr*)rinfo->clause;
+
+ if (list_length(clause->args) != 2)
+ break;
+
+ if ((rinfo->outer_is_left && (! reverse)) || (!rinfo->outer_is_left && reverse))
+ {
+ outer_var = list_nth(clause->args, 0);
+ inner_var = list_nth(clause->args, 1);
+ }
+ else
+ {
+ outer_var = list_nth(clause->args, 1);
+ inner_var = list_nth(clause->args, 0);
+ }
+
+ if ((! IsA(outer_var, Var)) || (! IsA(inner_var, Var)))
+ break;
+
+ for (i = 0; i < fkinfo->nkeys; i++)
+ {
+ if ((inner_var->varattno == confkey[i]) &&
+ (outer_var->varattno == conkey[i]) &&
+ (clause->opno == conpfeqop[i]))
+ {
+ clause_match = true;
+ matches[i] = true;
+ }
+ }
+
+ if (! clause_match)
+ {
+ /* reset the matches */
+ elog(WARNING, "clause does not match");
+ memset(matches, 0, fkinfo->nkeys);
+ break;
+ }
+ }
+
+ match = true;
+
+ for (i = 0; i < fkinfo->nkeys; i++)
+ match &= matches[i];
+
+ break;
+ }
+
+ return match;
+}
+
+
+/*
+ * join_is_on_fk
+ *
+ * blah blah blah
+ */
+bool
+join_matches_fkey(PlannerInfo *root, SpecialJoinInfo *sjinfo,
+ List * restrictlist)
+{
+ int innerrelid;
+ int outerrelid;
+ RelOptInfo *innerrel;
+ RelOptInfo *outerrel;
+ Relids joinrelids;
+
+ ListCell *lc;
+
+ bool inner_singleton;
+ bool outer_singleton;
+
+ Relids varnos = NULL;
+
+ /* if there's more than 1 inner relation involved then punt */
+ inner_singleton
+ = bms_get_singleton_member(sjinfo->min_righthand, &innerrelid);
+
+ outer_singleton
+ = bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid);
+
+ /* we need at least one singleton (otherwise we can't get PK) */
+ if ((! inner_singleton) && (! outer_singleton))
+ return false;
+
+ if ((! inner_singleton) || (! outer_singleton))
+ {
+ /* collect attnos from the clauses */
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = (RestrictInfo*)lfirst(lc);
+ OpExpr *clause;
+ ListCell *lc2;
+
+ Assert(IsA(rinfo, RestrictInfo));
+
+ /* get the clause, check that it has proper structure */
+ clause = (OpExpr*)rinfo->clause;
+
+ if (! IsA(clause, OpExpr))
+ return false;
+ else if (list_length(clause->args) != 2)
+ return false;
+
+ foreach (lc2, clause->args)
+ {
+ Var *var = (Var*)lfirst(lc2);
+ if (! IsA(var, Var))
+ return false;
+
+ varnos = bms_add_member(varnos, var->varno);
+ }
+ }
+
+ if (bms_num_members(varnos) != 2)
+ return false;
+
+ if (inner_singleton)
+ {
+ varnos = bms_del_member(varnos, innerrelid);
+ outerrelid = bms_singleton_member(varnos);
+ }
+
+ if (outer_singleton)
+ {
+ varnos = bms_del_member(varnos, outerrelid);
+ innerrelid = bms_singleton_member(varnos);
+ }
+ }
+
+ innerrel = find_base_rel(root, innerrelid);
+
+ if (innerrel->reloptkind != RELOPT_BASEREL)
+ return false;
+
+ outerrel = find_base_rel(root, outerrelid);
+
+ if (outerrel->reloptkind != RELOPT_BASEREL)
+ return false;
+
+ /*
+ * Before we go to the effort of pulling out the join condition's columns,
+ * make a quick check to eliminate cases in which we will surely be unable
+ * to prove the join is a FK joinuniqueness of the innerrel.
+ */
+ if ((! rel_has_unique_index(root, innerrel)) &&
+ (! rel_has_unique_index(root, outerrel)))
+ return false;
+
+ joinrelids = NULL;
+ joinrelids = bms_add_member(joinrelids, outerrelid);
+ joinrelids = bms_add_member(joinrelids, innerrelid);
+
+ /*
+ * Search for clauses that constrain the inner rel against either the
+ * outer rel.
+ */
+ foreach(lc, restrictlist)
+ {
+ RestrictInfo *restrictinfo = (RestrictInfo *) lfirst(lc);
+
+ /* needed to set the outer_is_left in the RestrictInfo */
+ clause_sides_match_join(restrictinfo,
+ outerrel->relids, innerrel->relids);
+ }
+
+ /*
+ * SELECT * FROM pg_constraint
+ * WHERE contype = 'f' AND conrelid = (outer) AND confrelid = (inner)
+ *
+ * conkey = confkey (using conpfeqop)
+ */
+
+ if (rel_has_unique_index(root, innerrel) &&
+ has_matching_fkey(root->simple_rel_array[outerrelid],
+ root->simple_rte_array[innerrelid]->relid,
+ restrictlist, false))
+ return 1;
+ else if (rel_has_unique_index(root, outerrel) &&
+ has_matching_fkey(root->simple_rel_array[innerrelid],
+ root->simple_rte_array[outerrelid]->relid,
+ restrictlist, true))
+ return 2;
+
+ return 0;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 8abed2a..fd31274 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -25,6 +25,7 @@
#include "access/transam.h"
#include "access/xlog.h"
#include "catalog/catalog.h"
+#include "catalog/pg_constraint.h"
#include "catalog/heap.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
@@ -39,6 +40,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -89,6 +91,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
/*
* We need not lock the relation since it was already locked, either by
@@ -377,6 +380,83 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
rel->indexlist = indexinfos;
+ /* TODO Can we do something like (hasindex) here? Is it necessary? */
+ if (true)
+ {
+ List *fkoidlist;
+ ListCell *l;
+
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+ }
+
+ rel->fkeylist = fkinfos;
+
/* Grab the fdwroutine info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
rel->fdwroutine = GetFdwRoutineForRelation(relation, true);
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 4ea01d1..1149aab 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3907,6 +3907,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_index for entries having indrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4875,6 +4942,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 38469ef..696d043 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -215,6 +215,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 401a686..d7b6f1c 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -452,6 +452,7 @@ typedef struct RelOptInfo
Relids lateral_relids; /* minimum parameterization of rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -543,6 +544,20 @@ typedef struct IndexOptInfo
bool amhasgetbitmap; /* does AM have amgetbitmap interface? */
} IndexOptInfo;
+/* TODO add info*/
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid;
+ Oid confrelid;
+
+ int nkeys;
+ int *conkeys;
+ int *confkeys;
+ Oid *conpfeqop;
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 6cad92e..7aae736 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -64,6 +64,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, Oid freloid, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index fa72918..66d909a 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -123,6 +123,9 @@ extern RestrictInfo *build_implied_join_equality(Oid opno,
* prototypes for plan/analyzejoins.c
*/
extern List *remove_useless_joins(PlannerInfo *root, List *joinlist);
+extern bool rel_has_unique_index(PlannerInfo *root, RelOptInfo *rel);
+extern bool join_matches_fkey(PlannerInfo *root, SpecialJoinInfo *sjinfo,
+ List *restrictlist);
extern bool query_supports_distinctness(Query *query);
extern bool query_is_distinct_for(Query *query, List *colnos, List *opids);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 9e17d87..d58bfa6 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -80,6 +80,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -113,6 +114,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 6953281..8878478 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
--
1.9.3
On 7 April 2015 at 13:41, Tomas Vondra <tomas.vondra@2ndquadrant.com> wrote:
(1) The current patch only does the trick when the FK matches the
conditions perfectly - when there are no missing columns (present
in the FK, not covered by a condition).
Hi Tomas,
I did glance at this patch a while back, but just thinking on it again.
I think if you find any quals that are a part of *any* foreign key between
the 2 join tables, then you should be never assume these quals to reduce
the number of rows. I believe this should be the case even if you don't
fully match all columns of the foreign key.
If we modify your example a little, let's say your foreign key between fact
and dim is made from 3 columns (a,b,c)
If we do:
EXPLAIN SELECT * FROM fact f JOIN dim d USING (a,b);
Then we should always (under normal circumstances) find at least one
matching row, although in this case since the join qual for c is missing,
we could find more than 1 matching row.
Without digging too deep here, I'd say that the best way to do this would
be to either have calc_joinrel_size_estimate() build a list of restrictinfo
items of all quals that are NOT part of any foreign key and pass that
trimmed list down to clauselist_selectivity() for selectivity estimates. Or
perhaps a better way would be just to teach clauselist_selectivity() about
foreign keys. Likely clauselist_selectivity() would just have to skip over
RestrictInfo items that are part of a foreign key.
Regards
David Rowley
Hi David,
On 05/17/15 14:31, David Rowley wrote:
Hi Tomas,
I did glance at this patch a while back, but just thinking on it again.
I think if you find any quals that are a part of *any* foreign key
between the 2 join tables, then you should be never assume these quals
to reduce the number of rows. I believe this should be the case even if
you don't fully match all columns of the foreign key.If we modify your example a little, let's say your foreign key between
fact and dim is made from 3 columns (a,b,c)If we do:
EXPLAIN SELECT * FROM fact f JOIN dim d USING (a,b);
Then we should always (under normal circumstances) find at least one
matching row, although in this case since the join qual for c is
missing, we could find more than 1 matching row.Without digging too deep here, I'd say that the best way to do this
would be to either have calc_joinrel_size_estimate() build a list of
restrictinfo items of all quals that are NOT part of any foreign key and
pass that trimmed list down to clauselist_selectivity() for selectivity
estimates. Or perhaps a better way would be just to
teach clauselist_selectivity() about foreign keys. Likely
clauselist_selectivity() would just have to skip over RestrictInfo items
that are part of a foreign key.
I'm not particularly happy about the way the current patch tweaks the
selectivity, but I think simply removing the clauses is not going to
work, because that implies the (removed) conditions have selectivity 1.0
(so the estimate would match a cartesian product). So we really need to
estimate the selectivity, we can't just throw them away.
And that's essentially what the current patch does - it realizes the
clauses match a FK, and then computes the estimate as 1/N where N is the
cardinality of the table with PK.
Another thing is that there may be multiple "candidate" foreign keys,
and we can't just remove clauses matching at least one of them. Imagine
e.g. a (somewhat artificial) example:
CREATE TABLE parent (
a INT,
b INT,
c INT,
d INT,
PRIMARY KEY (a,b),
UNIQUE (c,d)
);
CREATE TABLE child (
a INT,
b INT,
c INT,
d INT,
FOREIGN KEY (a,b) REFERENCES parent (a,b),
FOREIGN KEY (c,d) REFERENCES parent (c,b)
);
and a join on (a,b,c,d). We can't just discard all the conditions,
because (a,b) and (c,d) may 'mismatch'. We know (a,b) and (c,d) matches
about 1/N of the 'parent' table, but we don't know selectivity for the
whole join condition.
And it may be more complex, e.g. there may be two overlapping FKeys,
e.b. (a,b) and (b,c) - how do you split that?
But this may be an overkill (multiple multi-column FK join), although if
we could handle that reasonably, then why not ... someone out there
certainly has schema like that ;-)
What I think is somewhat more realistic is conditions matching only a
subset of FK columns - for example with a FK on (a,b) the join may only
use (a), for example. Then again - we can't just discard that, we need
to estimate that (and use it to compute the actual selectivity).
I agree that if we want to do anything fancy with this, we will have to
teach clauselist_selectivity() about foreign keys.
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 19 May 2015 at 11:08, Tomas Vondra <tomas.vondra@2ndquadrant.com> wrote:
On 05/17/15 14:31, David Rowley wrote:
I think if you find any quals that are a part of *any* foreign key
between the 2 join tables, then you should be never assume these quals
to reduce the number of rows. I believe this should be the case even if
you don't fully match all columns of the foreign key.If we modify your example a little, let's say your foreign key between
fact and dim is made from 3 columns (a,b,c)If we do:
EXPLAIN SELECT * FROM fact f JOIN dim d USING (a,b);
Then we should always (under normal circumstances) find at least one
matching row, although in this case since the join qual for c is
missing, we could find more than 1 matching row.Without digging too deep here, I'd say that the best way to do this
would be to either have calc_joinrel_size_estimate() build a list of
restrictinfo items of all quals that are NOT part of any foreign key and
pass that trimmed list down to clauselist_selectivity() for selectivity
estimates. Or perhaps a better way would be just to
teach clauselist_selectivity() about foreign keys. Likely
clauselist_selectivity() would just have to skip over RestrictInfo items
that are part of a foreign key.I'm not particularly happy about the way the current patch tweaks the
selectivity, but I think simply removing the clauses is not going to work,
because that implies the (removed) conditions have selectivity 1.0 (so the
estimate would match a cartesian product). So we really need to estimate
the selectivity, we can't just throw them away.
Of course I should have said 1.0 / <estimated rows>
And that's essentially what the current patch does - it realizes the
clauses match a FK, and then computes the estimate as 1/N where N is the
cardinality of the table with PK.Another thing is that there may be multiple "candidate" foreign keys, and
we can't just remove clauses matching at least one of them. Imagine e.g. a
(somewhat artificial) example:CREATE TABLE parent (
a INT,
b INT,
c INT,
d INT,
PRIMARY KEY (a,b),
UNIQUE (c,d)
);CREATE TABLE child (
a INT,
b INT,
c INT,
d INT,
FOREIGN KEY (a,b) REFERENCES parent (a,b),
FOREIGN KEY (c,d) REFERENCES parent (c,b)
);and a join on (a,b,c,d). We can't just discard all the conditions, because
(a,b) and (c,d) may 'mismatch'. We know (a,b) and (c,d) matches about 1/N
of the 'parent' table, but we don't know selectivity for the whole join
condition.
Ok how about we ignore partial foreign key matches and just get things
working when additional quals exist that are not a part of the foreign key.
I think here it would just be a matter of just deciding on which foreign
key to use the quals for and which ones to estimate the old fashioned way.
How about we have a function:
List *
get_non_foreign_key_quals(PlannerInfo *root, List *restrictlist) /* XXX
think of a better name */
which will be called from within calc_joinrel_size_estimate()
This function will simply take the list that's currently being sent off
to clauselist_selectivity() and it would search for the biggest possible
subset of foreign key columns from within that list. The returned list
would be what we would pass to clauselist_selectivity(), so if nothing
matched we'd just do the normal thing.
Let's say we have a restrictlist like in the join you describe above...
I'll use p for parent, and c for the child table:
{p.a = c.a}, {p.b = c.b}, {p.c = c.c}, {p.d = c.d}
get_non_foreign_key_quals would parse that list looking for foreign keys
going in either direction from both of these relations. It would look for
the "longest chain" of quals that match a foreign key and return the quals
which couldn't be matched. This "couldn't match" list would be what would
be returned to clauselist_selectivity(), the return value from that
function would have to be multiplied with.... I think 1.0 / min(<est inner
rows>, <est outer rows>). Though I've not quite gotten my head around how
outer joins change that, but I think that's ok for inner... Perhaps the
divide depends on which relation the fk is on... I need to think a bit more
to get my head around that...
I think you could implement this by generating a List of Bitmapset, pseudo
code along the lines of:
List *
get_non_foreign_key_quals(PlannerInfo *root, List *restrictlist) /* XXX
think of a better name */
{
List *fkey_matches;
foreach (foreign key in list)
{
Bitmapset matches;
if (foreign key is not for this rel)
continue;
foreach (qual in fkey)
{
int which_qual = 1;
foreach (qual in restrict list)
{
if (fkey qual matches ri qual)
matches = bmp_add_member(matches, which_qual);
which_qual++;
}
}
fkey_matches = lappend(fkey_matches, matches);
}
int longest_match = -1
int longest_match_idx;
int idx = 0;
foreach (match in fkey_matches)
{
int nmembers = bms_num_members(match);
/* only change the match it beats a previous match
* as we want to take the first longest match */
if (nmembers > longest_match)
{
longest_match = nmembers;
longest_match_idx = idx;
}
idx++;
}
if (longest_match == list_length(restrictlist))
return NULL; /* everything matches a fkey */
else
{
List *non_fk_list;
int which_qual = 1;
foreach (qual in restrict_list)
{
if (!bms_is_member(longest_match, which_qual))
non_fk_list = lappend(non_fk_list, qual);
which_qual++;
}
return non_fk_list;
}
}
Now in your example there's two foreign keys both of which will match 2
different quals each, this means that we have two different equally long
chains. I don't propose we do anything more complex than take the first of
the equal length chains. Although perhaps we'll want something stable...
perhaps in order of constraint name or something, but for a first cut I
highly doubt this matters. (See qsort() at the bottom
of CheckConstraintFetch() for example of what I mean)
And it may be more complex, e.g. there may be two overlapping FKeys, e.b.
(a,b) and (b,c) - how do you split that?But this may be an overkill (multiple multi-column FK join), although if
we could handle that reasonably, then why not ... someone out there
certainly has schema like that ;-)What I think is somewhat more realistic is conditions matching only a
subset of FK columns - for example with a FK on (a,b) the join may only use
(a), for example. Then again - we can't just discard that, we need to
estimate that (and use it to compute the actual selectivity).I agree that if we want to do anything fancy with this, we will have to
teach clauselist_selectivity() about foreign keys.
A few other things:
+ /* TODO Can we do something like (hasindex) here? Is it necessary? */
+ if (true)
I wondered about this too in my join removals stuff. I ended up adding a
pg_class flag for this. This was Tom's response:
/messages/by-id/18703.1410450446@sss.pgh.pa.us
Note that the unsetting of relhaspkey is not so great. It only happens to
get unset if the primary key is dropped and no other indexes of any type
exist on the relation and the table is vacuumed. So I think I understand
why Tom didn't want more flags that can end up being wrongly set.
+bool
+rel_has_unique_index(PlannerInfo *root, RelOptInfo *rel)
root is not used by this function.
+ for (i = 0; i < fkinfo->nkeys; i++)
+ match &= matches[i];
+
+ break;
This looks wrong. Why use break? This seems to be broken if there's more
than 1 foreign key between the two relations, as if the first of the two
does not match then it looks like you'll just return false... I've not
tested but that's the way the code seems to read.
Something like:
+ match = true;
+
+ for (i = 0; i < fkinfo->nkeys; i++)
+ {
+ if (!matches[i])
+ {
+ matched = false;
+ break;
+ }
+ }
+
+ /* each fkey column has been matched to the correct index column */
+ if (matched)
+ return true;
+ } /* foreach (lc, rel->fkeylist) */
+
+ return false; /* no matching fkey found */
With this we'll try the next fkey in the list if we didn't find a match.
Also I'm pretty sure it's just your temporary workings... but
in join_matches_fkey() you're returning 0, 1, or 2 from a bool function.
perhaps this won't be required anymore if my get_non_foreign_key_quals()
idea works out.
Thoughts?
Regards
David Rowley
Hi,
attached is a significantly reworked patch for using the foreign keys in
selectivity estimation. The previous patch only really worked if the
clauses matched the foreign key perfectly (i.e. no additional join
clauses) - this patch attempts to relax those restrictions a bit.
This patch also significantly improves the comments - the best place to
start reading is clauselist_join_selectivity().
In general, the patch works by looking for foreign keys between the
inner and outer side of the join, but only for keys that:
(a) have more than 2 keys (as this only really helps with multi-
column foreign keys)
(b) are 'fully matched' by the join clauses, i.e. there's a clause
exactly matching each part of the foreign key
Once we have matched foreign keys (for each join), we can estimate each
of them using 1/cardinality of the referenced table and estimate the
remaining clauses (not used to match any foreign key) the old way.
example with 3 tables
---------------------
create table a (a1 int, a2 int, primary key (a1, a2));
create table b (b1 int, b2 int, primary key (b1, b2));
create table f (f1 int, f2 int, f3 int, f4 int,
foreign key (f1,f2) references a(a1,a2),
foreign key (f3,f4) references b(b1,b2));
insert into a select i, i from generate_series(1,10000) s(i);
insert into b select i, i from generate_series(1,10000) s(i);
-- 10x
insert into f select i, i, i, i from generate_series(1,10000) s(i);
analyze;
Then on current master, I get these estimates (showing just rows,
because that's what matter):
while with the patch I get this:
select * from f join a on (f1 = a1 and f2 = a2);
QUERY PLAN
------------------------------------------------------------------------
Hash Join (rows=100000) (actual rows=100000)
Hash Cond: ((f.f1 = a.a1) AND (f.f2 = a.a2))
-> Seq Scan on f (rows=100000) (actual rows=100000)
-> Hash (rows=10000) (actual rows=10000)
Buckets: 16384 Batches: 1 Memory Usage: 519kB
-> Seq Scan on a (rows=10000) (actual rows=10000)
select * from f join a on (f1 = a1 and f2 = a2)
join b on (f3 = b1 and f4 = b2);
QUERY PLAN
------------------------------------------------------------------------
Hash Join (rows=100000) (actual rows=100000)
Hash Cond: ((f.f3 = b.b1) AND (f.f4 = b.b2))
-> Hash Join (rows=100000) (actual rows=100000)
Hash Cond: ((f.f1 = a.a1) AND (f.f2 = a.a2))
-> Seq Scan on f (rows=100000) (actual rows=100000)
-> Hash (rows=10000) (actual rows=10000)
Buckets: 16384 Batches: 1 Memory Usage: 519kB
-> Seq Scan on a (rows=10000) (actual rows=10000)
-> Hash (rows=10000) (actual rows=10000)
Buckets: 16384 Batches: 1 Memory Usage: 519kB
-> Seq Scan on b (rows=10000) (actual rows=10000)
So, that's pretty good.
I believe it might be possible to use even foreign keys matched only
partially (e.g. foreign key on 3 columns, but only 2 of those matched by
clauses), but I think that's a bit too much for now.
The examples above are rather trivial, and sadly it's not difficult to
break them. For example by adding a single additional join clause to the
first query does this:
select * from f join a on (f1 = a1 and f2 = a2 and f1 = a2);
QUERY PLAN
------------------------------------------------------------------------
Hash Join (rows=2) (actual rows=100000)
Hash Cond: (f.f1 = a.a1)
-> Seq Scan on f (rows=500) (actual rows=100000)
Filter: (f1 = f2)
-> Hash (rows=50) (rows=10000)
Buckets: 16384 (originally 1024) Batches: 1 (originally 1) ...
-> Seq Scan on a (rows=50) (actual rows=10000)
Filter: (a1 = a2)
This of course happens "thanks to" equality classes because the planner
is smart enough to realize that (f1=f2=a1=a2) thanks to the new clause.
I'm not sure how to fix this, and maybe this particular case would be
easier to fix using the multivariate stats (once it can estimate clauses
like a1=a2).
Similarly, the equality classes may break other examples by deriving
completely new clauses - for example assume the "f" table is defined
like this (again, with 100k rows):
create table f (f1 int, f2 int,
foreign key (f1,f2) references a(a1,a2),
foreign key (f1,f2) references b(b1,b2));
then this query
select * from f join a on (f1 = a1 and f2 = a2)
join b on (f1 = b1 and f2 = b2);
may get planned like this:
QUERY PLAN
------------------------------------------------------------------------
Hash Join (rows=100000) (actual rows=100000)
Hash Cond: ((f.f1 = a.a1) AND (f.f2 = a.a2))
-> Seq Scan on f (rows=100000) (actual rows=100000)
-> Hash (rows=1) (actual rows=10000)
-> Hash Join (rows=1) (actual rows=10000)
Hash Cond: ((a.a1 = b.b1) AND (a.a2 = b.b2))
-> Seq Scan on a (rows=10000) (actual rows=10000)
-> Hash (rows=10000) (actual rows=10000)
-> Seq Scan on b (rows=10000) (actual rows=10000)
because the planner derived that (a1=b1 and a2=b2) by looking at both
join clauses, and joined 'a' and 'b' first. And of course, there are no
foreign keys between these two tables (effectively dimensions), so the
patch can do nothing about the selectivities.
I'm not sure how serious problem this really is in practice - those
examples are constructed to show the issue. I also can't find a good
place to address this - either by tweaking the estimates before the
equality classes are processed, or somehow after.
It however illustrates that with this patch the user would be able to
influence the planner - either intentionally or by accident. For example
what should happen if someone creates the same foreign key twice? Should
we detect it and only count it once into the selectivity, or what?
There's a bunch of similar cases mentioned in the comment before
clauselist_join_selectivity.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Attachments:
0001-estimation-with-fkeys-v2.patchtext/x-diff; name=0001-estimation-with-fkeys-v2.patchDownload
>From d5e966d91ff3e30c81b3de2d9c6e8949fcf1e527 Mon Sep 17 00:00:00 2001
From: Tomas Vondra <tomas@pgaddict.com>
Date: Tue, 18 Aug 2015 19:15:02 +0200
Subject: [PATCH] foreign key estimation patch
---
src/backend/nodes/outfuncs.c | 13 +
src/backend/optimizer/path/costsize.c | 629 +++++++++++++++++++++++++++++-
src/backend/optimizer/plan/analyzejoins.c | 1 -
src/backend/optimizer/util/plancat.c | 85 ++++
src/backend/utils/cache/relcache.c | 69 ++++
src/include/nodes/nodes.h | 1 +
src/include/nodes/relation.h | 15 +
src/include/optimizer/paths.h | 2 +
src/include/utils/rel.h | 4 +
src/include/utils/relcache.h | 1 +
10 files changed, 809 insertions(+), 11 deletions(-)
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index a878498..fb9fe24 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1904,6 +1904,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3293,6 +3303,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 7069f60..633792d 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3732,6 +3732,614 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * clause_is_fk_compatible
+ * Verify that the clause may be compatible with foreign keys (i.e. it's
+ * a simple operator clause with two Vars, referencing two different
+ * relations).
+ *
+ * This only checks form of the clause (and returns 'true' if it may match
+ * a foreign key), but does not cross-check the clause against existing foreign
+ * keys for example.
+ *
+ * It also extracts data from the clause - rangetable indexes and attnums for
+ * each Var (if the function returns 'false' then those values are undefined
+ * and may contain garbage).
+ */
+static bool
+clause_is_fk_compatible(RestrictInfo *rinfo,
+ Index *varnoa, AttrNumber *attnoa,
+ Index *varnob, AttrNumber *attnob,
+ Oid *opno)
+{
+ OpExpr *clause;
+ Var *var0, *var1;
+
+ /* We only expect restriction clauses here, with operator expression. */
+
+ if (! IsA(rinfo, RestrictInfo))
+ return false;
+
+ if (! IsA(rinfo->clause, OpExpr))
+ return false;
+
+ clause = (OpExpr*)rinfo->clause;
+
+ /* The clause has to use exactly two simple variables. */
+
+ if (list_length(clause->args) != 2)
+ return false;
+
+ var0 = list_nth(clause->args, 0);
+ var1 = list_nth(clause->args, 1);
+
+ if (! (IsA(var0, Var) && IsA(var1, Var)))
+ return false;
+
+ /* The variables has to reference two different rangetable entries. */
+
+ if (var0->varno == var1->varno)
+ return false;
+
+ /*
+ * At this point we know the clause has the right structure, so extract
+ * the interesting info we'll need outside. We don't really track which
+ * relation is inner/outer, so we'll check both directions.
+ */
+
+ *varnoa = var0->varno;
+ *attnoa = var0->varattno;
+
+ *varnob = var1->varno;
+ *attnob = var1->varattno;
+
+ *opno = clause->opno;
+
+ return true;
+}
+
+
+/*
+ * fkey_is_matched_by_clauses
+ * Check whether the foreign key is "fully" matched by the clauses.
+ *
+ * This checks whether the foreign key is fully matched by clauses, i.e. if
+ * there's a clause matching perfectly all the parts of the foreign key.
+ */
+static bool
+fkey_is_matched_by_clauses(PlannerInfo *root, ForeignKeyOptInfo *fkinfo,
+ List *clauses, int relid, int frelid)
+{
+ int i;
+ ListCell *lc;
+ bool r;
+ bool *matched;
+
+ /* we should only get multi-column foreign keys here */
+ Assert(fkinfo->nkeys > 1);
+
+ /* flags for each part of the foreign key */
+ matched = palloc0(fkinfo->nkeys);
+
+ foreach (lc, clauses)
+ {
+ RestrictInfo *rinfo = (RestrictInfo*)lfirst(lc);
+
+ /* info extracted from the clause (opno, varnos and varattnos) */
+ Oid opno;
+ Index relida, relidb;
+ AttrNumber attnoa, attnob;
+
+ /* we'll look this up in the simple_rte_array table */
+ Oid oida, oidb;
+
+ /*
+ * If the clause has structure incompatible with foreign keys (not an
+ * operator clause with two Var nodes), just skip it.
+ */
+ if (! clause_is_fk_compatible(rinfo, &relida, &attnoa,
+ &relidb, &attnob, &opno))
+ continue;
+
+ /* lookup range table entries for the indexes */
+ oida = root->simple_rte_array[relida]->relid;
+ oidb = root->simple_rte_array[relidb]->relid;
+
+ /*
+ * Check if the clause matches any part of the foreign key.
+ */
+ for (i = 0; i < fkinfo->nkeys; i++)
+ {
+ /* if the operator does not match, try next key */
+ if (! fkinfo->conpfeqop[i] == opno)
+ continue;
+
+ /*
+ * We don't know in what order the clause lists the Vars, so we'll check
+ * the foreign key in both directions (it does not really matter).
+ */
+ if ((oida == fkinfo->conrelid) && (oidb == fkinfo->confrelid))
+ {
+ if ((fkinfo->confkeys[i] == attnob) &&
+ (fkinfo->conkeys[i] == attnoa))
+ matched[i] = true;
+ }
+
+ if ((oida == fkinfo->confrelid) && (oidb == fkinfo->conrelid))
+ {
+ if ((fkinfo->confkeys[i] == attnoa) &&
+ (fkinfo->conkeys[i] == attnob))
+ matched[i] = true;
+ }
+ }
+ }
+
+ /* return 'true' if all the parts of the foreign key were matched */
+ r = true;
+ for (i = 0; i < fkinfo->nkeys; i++)
+ r &= matched[i];
+
+ pfree(matched);
+
+ return r;
+}
+
+/*
+ * find_satisfied_fkeys
+ * Searches for all foreign keys fully-satisfied by the join clauses.
+ *
+ * A join is fully-satisfied if all the parts are matched by at least one
+ * join condition (same operator and attnos).
+ *
+ * This returns a list of foreign keys of identified foreign keys (or NIL),
+ * and also selectivity for all the (matched) foreign keys.
+ */
+static List *
+find_satisfied_fkeys(PlannerInfo *root, SpecialJoinInfo *sjinfo, List *joinquals,
+ Selectivity *sel)
+{
+ int inner, outer;
+ List *fkeys = NIL;
+
+ /*
+ * We'll take all combinations of inner/outer relations, and check if
+ * there are foreign keys between them. If we found a foreign key for
+ * the pair of base relations, we'll try matching it to clauses.
+ *
+ * We don't know in which direction the foreign keys are created, so
+ * we'll check both directions (it's allways between inner and outer
+ * side of the join).
+ */
+
+ inner = -1;
+ while ((inner = bms_next_member(sjinfo->min_righthand, inner)) >= 0)
+ {
+ RelOptInfo *rel_inner = find_base_rel(root, inner);
+ RangeTblEntry *rt_inner = planner_rt_fetch(inner, root);
+
+ Assert(rel_inner->reloptkind == RELOPT_BASEREL);
+
+ outer = -1;
+ while ((outer = bms_next_member(sjinfo->min_lefthand, outer)) >= 0)
+ {
+ ListCell *lc;
+ RelOptInfo *rel_outer = find_base_rel(root, outer);
+ RangeTblEntry *rt_outer = planner_rt_fetch(outer, root);
+
+ Assert(rel_outer->reloptkind == RELOPT_BASEREL);
+
+ /*
+ * Walk through foreign keys defined on the inner side, referencing
+ * relation on the outer side.
+ */
+ foreach (lc, rel_inner->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *)lfirst(lc);
+
+ /* We only care about keys referencing the current outer relation */
+ if (fkinfo->confrelid != rt_outer->relid)
+ continue;
+
+ /*
+ * And we don't care about foreign keys with less than two columns
+ * (those clauses will be handled by the regular estimation, unless
+ * matched by some other key).
+ *
+ * XXX Maybe we should estimate even the single-column keys here,
+ * as it's really cheap. But it can't do any cross-table check
+ * of MCV lists or whatever clauselist_selectivity() does.
+ */
+ if (fkinfo->nkeys < 2)
+ continue;
+
+ /*
+ * Finally check if the foreign key is full matched by clauses,
+ * and update the selectivity (simply use 1/cardinality of the
+ * table referenced by the foreign key).
+ *
+ * XXX Notice we're using 'rel->tuples' here and not 'rows',
+ * because we need the cardinality (before applying clauses).
+ */
+ if (fkey_is_matched_by_clauses(root, fkinfo, joinquals, inner, outer))
+ {
+ fkeys = lappend(fkeys, fkinfo);
+ *sel *= (1.0 / rel_outer->tuples);
+ }
+
+ }
+
+ /*
+ * And now check foreign keys in the other direction (defined on
+ * outer relation, referencing inner).
+ *
+ * XXX This does exactly the same thing as the previous loop, so no
+ * comments.
+ *
+ * TODO Merge those two blocks into a single utility function to
+ * reduce the code duplication.
+ */
+ foreach (lc, rel_outer->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *)lfirst(lc);
+
+ if (fkinfo->confrelid != rt_inner->relid)
+ continue;
+
+ if (fkinfo->nkeys < 2)
+ continue;
+
+ if (fkey_is_matched_by_clauses(root, fkinfo, joinquals, outer, inner))
+ {
+ fkeys = lappend(fkeys, fkinfo);
+ *sel *= (1.0 / rel_inner->tuples);
+ }
+
+ }
+
+ }
+ }
+
+ return fkeys;
+}
+
+/*
+ * filter_fk_join_clauses
+ * Remove the clauses that were used to match foreign keys (and will be
+ * estimated using the selectivity from keys).
+ *
+ * Once we identify the foreign keys matched by clauses, we need to remove the
+ * clauses so that we don't include them into the estimate twice. This method
+ * performs that - cross-checks the foreign keys and clauses and removes all
+ * clauses matching any of the foreign keys.
+ *
+ * If there are no foreign keys, this simply returns the original list of
+ * clauses. Otherwise it builds a new list (without modifying the source one).
+ */
+static List *
+filter_fk_join_clauses(PlannerInfo *root, SpecialJoinInfo *sjinfo, List *fkeys,
+ List *joinquals)
+{
+ ListCell *lc,
+ *lc2;
+ List *clauses = NIL;
+
+ /* if there are no foreign keys, return the original list */
+ if (list_length(fkeys) == 0)
+ return joinquals;
+
+ foreach (lc, joinquals)
+ {
+ Oid opno;
+ Index relida, relidb;
+ AttrNumber attnoa, attnob;
+ Oid oida, oidb;
+
+ /* was the clause matched by at least one key? */
+ bool matched = false;
+
+ RestrictInfo *rinfo = (RestrictInfo*)lfirst(lc);
+
+ /* if the clause is not compatible with foreign keys, just add it */
+ if (! clause_is_fk_compatible(rinfo, &relida, &attnoa,
+ &relidb, &attnob, &opno))
+ {
+ clauses = lappend(clauses, rinfo);
+ continue;
+ }
+
+ oida = root->simple_rte_array[relida]->relid;
+ oidb = root->simple_rte_array[relidb]->relid;
+
+ /*
+ * Walk through the matched foreign keys, and try to match the clause
+ * against each one. We don't know in what order are the Vars listed
+ * in the clause, so try both ways.
+ */
+ foreach (lc2, fkeys)
+ {
+ int i;
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo*)lfirst(lc2);
+
+ /* now check the keys - we can stop after finding the first match */
+ for (i = 0; i < fkinfo->nkeys; i++)
+ {
+ /* check the operator first */
+ if (fkinfo->conpfeqop[i] != opno)
+ continue;
+
+ /* now check the attnums */
+ if ((fkinfo->conrelid == oida) && (fkinfo->confrelid == oidb))
+ {
+ if ((fkinfo->confkeys[i] == attnob) &&
+ (fkinfo->conkeys[i] == attnoa))
+ {
+ matched = true;
+ break;
+ }
+ }
+ else if ((fkinfo->conrelid == oidb) && (fkinfo->confrelid == oida))
+ {
+ if ((fkinfo->confkeys[i] == attnoa) &&
+ (fkinfo->conkeys[i] == attnob))
+ {
+ matched = true;
+ break;
+ }
+ }
+ }
+
+ /* no need to try more keys, single match is enough */
+ if (matched)
+ break;
+ }
+
+ /* if a clause was not matched by any foreign key, continue */
+ if (! matched)
+ clauses = lappend(clauses, rinfo);
+
+ }
+
+ return clauses;
+}
+
+
+
+/*
+ * Estimate selectivity of join clauses - either by using foreign key info or
+ * by using the regular clauselist_selectivity().
+ *
+ * If there are multiple join clauses, we check whether the clauses match
+ * a foreign key between the tables - in that case we can use this information
+ * to derive a better estimate (otherwise we'd multiply the selectivities for
+ * each clause, which often causes significant underestimates).
+ *
+ * We only need to care about multi-clause join conditions and simply defer
+ * simple clauses to clauselist_selectivity().
+ *
+ * Let's see a few examples of foreign-key joins, illustrating the estimation
+ * ideas here.
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * a3 INT,
+ * a4 INT,
+ * PRIMARY KEY (a1, a2, a3)
+ * );
+ *
+ * CREATE TABLE b (
+ * b1 INT,
+ * b2 INT,
+ * b3 INT,
+ * b4 INT,
+ * FOREIGN KEY (b1, b2, b3) REFERENCES (a1, a2, a3)
+ * );
+ *
+ * clauses exactly match a foreign key
+ * -----------------------------------
+ *
+ * SELECT * FROM a JOIN b ON (a1=b1 AND a2=b2 AND a3=b3);
+ *
+ * - trivial, just use 1/card(a)
+ *
+ * clauses match a foreign key, with additional conditions exist
+ * -------------------------------------------------------------
+ *
+ * SELECT * FROM a JOIN b ON (a1=b1 AND a2=b2 AND a3=b3 AND a4=b4);
+ *
+ * - trivial, just use 1/card(a) * selectivity(remaining_clauses)
+ *
+ * incomplete foreign key match
+ * ----------------------------
+ *
+ * SELECT * FROM a JOIN b ON (a1=b1 AND a2=b2);
+ *
+ * - not sure, we'd need to compensate for the "missing part" somehow (we know
+ * the row exists, but we don't know much many rows - it's likely more than
+ * unique)
+ *
+ * - one way would be to assume each clause is responsible for (1/card(a))^(1/n)
+ * where 'n' is number of clauses - this way 'multiplying the FK clauses' would
+ * gets us the 1/card(a) selectivity if we had all the clauses
+ *
+ * - another thing is we might use 1/card(a) as a lower boundary - we can't
+ * possibly get lower selectivity, we know the rows exist (also this is not
+ * based on assumptions like the previous idea)
+ *
+ * multiple distinct foreign keys matching
+ * ---------------------------------------
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * a3 INT,
+ * a4 INT,
+ * PRIMARY KEY (a1, a2),
+ * UNIQUE (a3, a4)
+ * );
+ *
+ * CREATE TABLE b (
+ * b1 INT,
+ * b2 INT,
+ * b3 INT,
+ * b4 INT,
+ * FOREIGN KEY (b1, b2) REFERENCES (a1, a2),
+ * FOREIGN KEY (b3, b4) REFERENCES (a3, a4)
+ * );
+ *
+ * - simply just use 1/card(a) for each foreign key (assumes independence of the
+ * foreign keys, but well - we're assuming attribute independence so this is
+ * an improvement)
+ *
+ * multiple overlapping foreign keys matching
+ * ------------------------------------------
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * a3 INT,
+ * PRIMARY KEY (a1, a2),
+ * UNIQUE (a2, a3)
+ * );
+ *
+ * CREATE TABLE b (
+ * b1 INT,
+ * b2 INT,
+ * b3 INT,
+ * b4 INT,
+ * FOREIGN KEY (b1, b2) REFERENCES (a1, a2),
+ * FOREIGN KEY (b3, b4) REFERENCES (a2, a3)
+ * );
+ *
+ * - probably just use 1/card(a) for each foreign key, as in the previous
+ * example (assumes independence of the foreign keys, but well - we're
+ * assuming attribute independence so this is an improvement)
+ *
+ * There are strange cases with multiple foreign keys, where one FK implies
+ * the other FK. For example consider this:
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * a3 INT,
+ * UNIQUE (a1, a2, a3),
+ * UNIQUE (a1, a2)
+ * );
+ *
+ * CREATE TABLE b (
+ * b1 INT,
+ * b2 INT,
+ * b3 INT,
+ * FOREIGN KEY (b1, b2, b3) REFERENCES a (a1, a2, a3),
+ * FOREIGN KEY (b1, b2) REFERENCES a (a1, a2)
+ * );
+ *
+ * Clearly the (b1,b2) is implied by (b1,b2,b3) - if the latter exists, then
+ * the former exists too. Not sure how to handle this (or if it's actually
+ * needed).
+ *
+ * Another slightly strange case is FK constraints in both directions (these
+ * statements don't work - the foreign keys need to be established using
+ * ALTER, but for illustration it's sufficient).
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * UNIQUE (a1, a2),
+ * FOREIGN KEY (a1, a2) REFERENCES a (b1, b2)
+ * );
+ *
+ * CREATE TABLE b (
+ * b1 INT,
+ * b2 INT,
+ * UNIQUE (b1, b2),
+ * FOREIGN KEY (b1, b2) REFERENCES a (a1, a2)
+ * );
+ *
+ * which effectively establishes 1:1 relationship, or with distinct groups of
+ * columns for each direction
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * a3 INT,
+ * a4 INT,
+ * UNIQUE (a1, a2),
+ * FOREIGN KEY (a3, a4) REFERENCES a (b1, b2)
+ * );
+ *
+ * CREATE TABLE b (
+ * b1 INT,
+ * b2 INT,
+ * b3 INT,
+ * b4 INT,
+ * UNIQUE (b1, b2),
+ * FOREIGN KEY (b3, b4) REFERENCES a (a1, a2)
+ * );
+ *
+ * which creates a cycle of foreign keys.
+ *
+ * In the first case the foreign keys should be counted only once into the
+ * selectivity, because it's effectively a 1:1 relationship - each row has
+ * to have one matching row in the other table (not matched by other) rows.
+ *
+ * In the other case, it's probably right to factor in both foreign keys.
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals, int varno,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ Selectivity sel = 1.0;
+
+ List *fkeys; /* list of satisfied foreign keys */
+ List *unmatched; /* clauses remaining after removing FK clauses */
+
+ Assert(list_length(joinquals) >= 0);
+
+ /*
+ * If we only have a single clause, we don't need to mess with the foreign
+ * keys - that's only useful with multi-column clauses anyway. Just use the
+ * simple clauselist_selectivity.
+ */
+ if (list_length(joinquals) <= 1)
+ return clauselist_selectivity(root,
+ joinquals,
+ 0,
+ jointype,
+ sjinfo);
+
+ /*
+ * First we'll identify foreign keys that are fully matched by the join
+ * clauses, and we'll update the selectivity accordingly while doing so.
+ */
+ fkeys = find_satisfied_fkeys(root, sjinfo, joinquals, &sel);
+
+ /*
+ * Now that we have the foreign keys, we can get rid of the clauses
+ * matching any of them, and only keep the remaining clauses, so that
+ * we can estimate them using the regular selectivity estimation.
+ */
+ unmatched = filter_fk_join_clauses(root, sjinfo, fkeys, joinquals);
+
+ /*
+ * Estimate the remaining clauses (not matching any FK), if still have any.
+ */
+ if (list_length(unmatched) > 0)
+ {
+ sel *= clauselist_selectivity(root,
+ unmatched,
+ 0,
+ jointype,
+ sjinfo);
+
+ /* Only free the list if we actually found any foreign keys. */
+ if (list_length(fkeys) > 0)
+ list_free(unmatched);
+ }
+
+ return sel;
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3777,11 +4385,12 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ 0,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3794,11 +4403,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ 0,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/optimizer/plan/analyzejoins.c b/src/backend/optimizer/plan/analyzejoins.c
index 7912b15..05c8698 100644
--- a/src/backend/optimizer/plan/analyzejoins.c
+++ b/src/backend/optimizer/plan/analyzejoins.c
@@ -562,7 +562,6 @@ remove_rel_from_joinlist(List *joinlist, int relid, int *nremoved)
return result;
}
-
/*
* query_supports_distinctness - could the query possibly be proven distinct
* on some set of output columns?
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 9442e5f..fbc5579 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -40,6 +41,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -93,6 +95,7 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
/*
* We need not lock the relation since it was already locked, either by
@@ -380,6 +383,88 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
rel->indexlist = indexinfos;
+
+ /*
+ * TODO Can we do something like (hasindex) here? Is it necessary? The
+ * trouble with that is that we don't have a good place to reset that
+ * flag (relhasindex is reset by vacuum, but is has nothing to do with
+ * foreign keys at this point).
+ */
+ if (true)
+ {
+ List *fkoidlist;
+ ListCell *l;
+
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+ }
+
+ rel->fkeylist = fkinfos;
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 44e9509..a599ca5 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3896,6 +3896,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4864,6 +4931,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 748e434..31b40af 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -221,6 +221,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 5dc23d9..b887949 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -468,6 +468,7 @@ typedef struct RelOptInfo
Relids lateral_relids; /* minimum parameterization of rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -562,6 +563,20 @@ typedef struct IndexOptInfo
bool amhasgetbitmap; /* does AM have amgetbitmap interface? */
} IndexOptInfo;
+/* TODO add info*/
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid;
+ Oid confrelid;
+
+ int nkeys;
+ int *conkeys;
+ int *confkeys;
+ Oid *conpfeqop;
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 87123a5..da1fd58 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -73,6 +73,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8a55a09..c56cf8a 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -79,6 +79,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -112,6 +113,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 6953281..8878478 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
--
1.9.3
On 08/20/2015 03:49 AM, Tomas Vondra wrote:
Then on current master, I get these estimates (showing just rows,
because that's what matter):while with the patch I get this:
And of course I forgot to include the plans from master, so here we go:
select * from f join a on (f1 = a1 and f2 = a2);
QUERY PLAN
------------------------------------------------------------------------
Hash Join (rows=10) (actual rows=100000)
Hash Cond: ((f.f1 = a.a1) AND (f.f2 = a.a2))
-> Seq Scan on f (rows=100000) (actual rows=100000)
-> Hash (rows=10000) (actual rows=10000)
Buckets: 16384 Batches: 1 Memory Usage: 519kB
-> Seq Scan on a (rows=10000) (actual rows=10000)
select * from f join a on (f1 = a1 and f2 = a2)
join b on (f3 = b1 and f4 = b2);
QUERY PLAN
------------------------------------------------------------------------
Nested Loop (rows=1) (actual rows=100000)
-> Hash Join (rows=10) (actual rows=100000)
Hash Cond: ((f.f1 = a.a1) AND (f.f2 = a.a2))
-> Seq Scan on f (rows=100000) (actual rows=100000)
-> Hash (rows=10000) (actual rows=10000)
Buckets: 16384 Batches: 1 Memory Usage: 519kB
-> Seq Scan on a (rows=10000) (actual rows=10000)
-> Index Only Scan using b_pkey on b (rows=1) (actual rows=1)
Index Cond: ((b1 = f.f3) AND (b2 = f.f4))
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Thu, Aug 20, 2015 at 11:25 AM, Tomas Vondra
<tomas.vondra@2ndquadrant.com> wrote:
On 08/20/2015 03:49 AM, Tomas Vondra wrote:
Then on current master, I get these estimates (showing just rows,
because that's what matter):[...]
Moved to next CF 2015-09.
--
Michael
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 20 August 2015 at 13:49, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
attached is a significantly reworked patch for using the foreign keys in
selectivity estimation.
Thanks for working a new patch, I'm starting to look at it again now:
Here's my thoughts so far:
+ /*
+ * TODO Can we do something like (hasindex) here? Is it necessary? The
+ * trouble with that is that we don't have a good place to reset that
+ * flag (relhasindex is reset by vacuum, but is has nothing to do with
+ * foreign keys at this point).
+ */
+ if (true)
You don't seem to have addressed this part yet.
I mentioned previously that I had attempted this already. Here was the
response
/messages/by-id/18703.1410450446@sss.pgh.pa.us
Please just remove the comment and if (true). By today's
standards relhasindex would never be added.
Does it not just serve as an optimization only when the rel is not cached
anyway?
--- a/src/backend/optimizer/plan/analyzejoins.c
+++ b/src/backend/optimizer/plan/analyzejoins.c
@@ -562,7 +562,6 @@ remove_rel_from_joinlist(List *joinlist, int relid, int
*nremoved)
return result;
}
-
/*
Accidental change, please remove.
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals, int varno,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
varno is not used.
+ /*
+ * First we'll identify foreign keys that are fully matched by the join
+ * clauses, and we'll update the selectivity accordingly while doing so.
+ */
+ fkeys = find_satisfied_fkeys(root, sjinfo, joinquals, &sel);
+
+ /*
+ * Now that we have the foreign keys, we can get rid of the clauses
+ * matching any of them, and only keep the remaining clauses, so that
+ * we can estimate them using the regular selectivity estimation.
+ */
+ unmatched = filter_fk_join_clauses(root, sjinfo, fkeys, joinquals);
This seems a bit convoluted and inefficient.
Why not just return a bitmask of the matched items indexed by the list
position?
Doing it this way you're having to match the expressions twice. Once seems
fine.
Did you read my review about looking for the longest matches by counting
the bits in the mask?
+ * Another slightly strange case is FK constraints in both directions
(these
+ * statements don't work - the foreign keys need to be established using
+ * ALTER, but for illustration it's sufficient).
+ *
+ * CREATE TABLE a (
+ * a1 INT,
+ * a2 INT,
+ * UNIQUE (a1, a2),
+ * FOREIGN KEY (a1, a2) REFERENCES a (b1, b2)
+ * );
Did you perhaps mean b? i.e. REFERENCES b (b1, b2) ?
Same is duplicated further down.
+ *sel *= (1.0 / rel_outer->tuples);
I think this needs to be :
+ *sel *= (1.0 / Max(rel_outer->tuples, 1.0));
As the following causes a divide by zero.
See attached divide_by_zero.sql
Basically causes this: Hash Join (cost=8.29..-1.#J rows=1 width=40)
+ * XXX This does exactly the same thing as the previous loop, so no
+ * comments.
It would be better if we could do something more how make_join_rel() does
things like:
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_INNER, sjinfo,
restrictlist);
add_paths_to_joinrel(root, joinrel, rel2, rel1,
JOIN_INNER, sjinfo,
restrictlist);
Where the inputs to the function are just swapped.
+ outer = -1;
+ while ((outer = bms_next_member(sjinfo->min_lefthand, outer)) >= 0)
Why did you change this from ensuring we get a singleton member?
I'd imagine if more than 2 relations are required to make the join, then we
can't use foreign keys, as the other join may duplicate or eliminate tuples.
Perhaps you've thought of this more than I have. Would you be able to
explain?
+ * XXX Maybe we should estimate even the single-column keys here,
+ * as it's really cheap. But it can't do any cross-table check
+ * of MCV lists or whatever clauselist_selectivity() does.
+ */
+ if (fkinfo->nkeys < 2)
+ continue;
This should be removed. I see no reason at all to pass up likely perfect
estimates for histogram lookup estimates.
Overall, I really feel that you should just take the longest matching
foreign key. i.e the one that matches the most clauses in the joinquals,
and completely ignore any shorter matches, or partial matches. Just that
alone is probably 99.9999% of the use cases that will benefit from this. No
use adding weird code that's only right half the time for the other 0.0001%
of use cases.
I imagine clauselist_join_selectivity should be more like:
int outerrelid, innerrelid;
if (bms_get_singleton_member(sjinfo->min_righthand, &innerrelid) &&
bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid))
{
Bitmapset fkclauses1, fkclauses2;
List *unmatched;
Selectivity sel;
RelOptInfo *innerrel = find_base_rel(root, innerrelid);
RelOptInfo *outerrel = find_base_rel(root, outerrelid);
fkclauses1 = find_foreign_key_clauses(root, outerrel, innerrel,
joinquals);
fkclauses2 = find_foreign_key_clauses(root, innerrel, outerrel,
joinquals);
if (fkclauses1 || fkclauses2)
{
if (bms_num_members(fkclauses1) <
bms_num_members(fkclauses2))
{
bms_free(fkclauses1);
fkclauses1 = fkclauses2;
sel = 1.0 / Max(innerrel->tuples, 1.0);
}
else
{
bms_free(fkclauses2);
sel = 1.0 / Max(outerrel->tuples, 1.0);
}
}
if (fkclauses1)
{
ListCell *lc;
int lst_idx = 0;
unmatched = NIL;
foreach (lc, joinquals)
{
Node *clause = (Node *) lfirst(lc);
if (bms_is_member(fkclauses1, clause))
unmatched = lappend(unmatched, clause);
}
return sel * clauselist_selectivity(root, unmatched, 0,
jointype, sjinfo);
}
}
else
return clauselist_selectivity(root, unmatched, 0, jointype, sjinfo);
Of course, I'm not used to typing code in my email client. So likely it'll
need many fixups.
find_foreign_key_clauses() should look for the longest match and return a
Bitmap set of the list indexes to the caller.
It might be possible to fool the longest match logic by duplicating
clauses, e.g. a1 = b1 AND a1 = b1 and a1 = b1 AND a2 = b2 AND a3 = b3, but
I can't imagine that matters, but if it did, we could code it to be smart
enough to see through that.
One thing I've not thought of yet is the jointype, and also NULL values
references by the foreign key. Perhaps NULLs don't matter as they won't be
matched by the join condition anyway.
There's a few other things, but it makes sense to get the structure right
before going into finer details.
Let me know your thoughts.
Regards
David Rowley
--
David Rowley http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Training & Services
Attachments:
On 23 September 2015 at 17:11, David Rowley <david.rowley@2ndquadrant.com>
wrote:
find_foreign_key_clauses() should look for the longest match and return a
Bitmap set of the list indexes to the caller.
It might be possible to fool the longest match logic by duplicating
clauses, e.g. a1 = b1 AND a1 = b1 and a1 = b1 AND a2 = b2 AND a3 = b3, but
I can't imagine that matters, but if it did, we could code it to be smart
enough to see through that.
I took a bash at implementing what I described, and I've ended up with the
attached.
git diff -stat gives me:
src/backend/optimizer/path/costsize.c | 717
++++++++----------------------
src/backend/optimizer/plan/analyzejoins.c | 1 +
src/backend/optimizer/util/plancat.c | 112 +++--
3 files changed, 228 insertions(+), 602 deletions(-)
So it's removed quite a bit of code. I also discovered that: 1.0 /
Max(rel->tuples,1.0) is no good for SEMI and ANTI joins. I've coded around
this in the attached, but I'm not certain it's the best way of doing things.
I thought that it might be possible to add some regression test around
this, if we simply just find a plan the uses a nested loop due to
underestimation of matching rows, and then make sure that it no longer uses
a nested loop when the foreign key is added. I've not yet done this in the
attached.
Patched attached in delta form and complete form.
I still need to perform more analysis on the plancat.c changes.
Have I made any changes that you disagree with?
Regards
David Rowley
--
David Rowley http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Training & Services
Attachments:
estimation-with-fkeys-v2_david.patchapplication/octet-stream; name=estimation-with-fkeys-v2_david.patchDownload
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e1b49d5..8dbfeba 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1907,6 +1907,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3297,6 +3307,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index d107d76..d30d715 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3732,6 +3732,251 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * find_best_match_foreign_key
+ * Returns a Bitmapset with bits set for each 0 based index of 'joinquals'
+ * which to a foreign key which is defined on fkrel.
+ *
+ * Note: in the event that there's more than 1 foreign key between these two
+ * relations, the largest match, i.e. the bitmask for the one with the most
+ * matching 'joinquals' items, is returned.
+ *
+ * XXX it's possible to trick this code when the joinquals contain duplicate
+ * quals. Is this worth fixing?
+ */
+static Bitmapset *
+find_best_match_foreign_key(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals)
+{
+ Bitmapset *bestmatch;
+ Bitmapset *usefulquals;
+ ListCell *lc;
+ int lstidx;
+ Oid frelid;
+
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ return NULL;
+
+ bestmatch = NULL;
+ lstidx = -1;
+ usefulquals = NULL;
+
+ /*
+ * First build a bitmapset with all possibly useful quals. This will save
+ * from having to do this for each foreign key later. The only quals that
+ * are useful to us are in the form "var op var", so here we'll ignore
+ * things like "function(var1, var2)".
+ */
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+ OpExpr *clause;
+ Var *leftvar, *rightvar;
+
+ /*
+ * Increment this at the start of the loop to save doing it before each
+ * continue statement.
+ */
+ lstidx++;
+
+ if (!IsA(rinfo, RestrictInfo))
+ continue;
+
+ if (!IsA(rinfo->clause, OpExpr))
+ continue;
+
+ clause = (OpExpr *) rinfo->clause;
+
+ if (list_length(clause->args) != 2)
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ usefulquals = bms_add_member(usefulquals, lstidx);
+ }
+
+ frelid = root->simple_rte_array[foreignrel->relid]->relid;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *matches;
+ int i;
+
+ /* skip any foreign keys which don't reference frelid */
+ if (fkinfo->confrelid != frelid)
+ continue;
+
+ matches = NULL;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to match as many as possible.
+ */
+ for (i = 0; i < fkinfo->nkeys; i++)
+ {
+ ListCell *lc2;
+
+ lstidx = -1;
+ foreach(lc2, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
+
+ lstidx++;
+
+ /* skip anything we didn't mark as useful above. */
+ if (!bms_is_member(lstidx, usefulquals))
+ continue;
+
+ /*
+ * Here we can safely assume that we have an OpExpr, in the
+ * from of "var op var"
+ */
+ rinfo = (RestrictInfo *) lfirst(lc2);
+ clause = (OpExpr *) rinfo->clause;
+
+ /* skip if the operator does not match */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /*
+ * Check if the OpExpr matches the foreign key. Remember that
+ * this could be written with the Vars in either order, so we
+ * test both permutations of the expression.
+ */
+ if (fkinfo->confkeys[i] == leftvar->varattno &&
+ fkinfo->conkeys[i] == rightvar->varattno)
+ matches = bms_add_member(matches, lstidx);
+
+ else if (fkinfo->confkeys[i] == rightvar->varattno &&
+ fkinfo->conkeys[i] == leftvar->varattno)
+ matches = bms_add_member(matches, lstidx);
+ }
+ }
+
+ /* Is this match better than the current best match? */
+ if (bms_num_members(matches) > bms_num_members(bestmatch))
+ {
+ bms_free(bestmatch);
+ bestmatch = matches;
+ }
+ }
+
+ return bestmatch;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ *
+ * XXX is it worth adding code to do something smart when we only get a partial
+ * foreign key match?
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerrelid;
+ int innerrelid;
+
+ /*
+ * Since foreign keys can only references a single relation, and each
+ * foreign key belongs to at most a single relation, we require that only
+ * a single relation be at either side of the join condition. We'll fall
+ * back on clauselist_selectivity() if this is not the case.
+ */
+ if (bms_get_singleton_member(sjinfo->min_righthand, &innerrelid) &&
+ bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid))
+ {
+ Bitmapset *outer2inner, *inner2outer;
+ RelOptInfo *innerrel = find_base_rel(root, innerrelid);
+ RelOptInfo *outerrel = find_base_rel(root, outerrelid);
+
+ /* check which quals are matched by a foreign key referencing the innerrel */
+ outer2inner = find_best_match_foreign_key(root, outerrel, innerrel, joinquals);
+
+ /* do the same again, but with relations swapped */
+ inner2outer = find_best_match_foreign_key(root, innerrel, outerrel, joinquals);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outer2inner || inner2outer)
+ {
+ Selectivity sel;
+ ListCell *lc;
+ int lstidx;
+ List *nonfkeyclauses;
+
+ /* either could be NULL, but bms_num_members will handle that */
+ if (bms_num_members(outer2inner) < bms_num_members(inner2outer))
+ {
+ /*
+ * We can now disgard the lesser of the two and save the best
+ * match into one of the bitmaps. Let's just use outer2inner
+ */
+ bms_free(outer2inner);
+ outer2inner = inner2outer;
+
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = 1.0;
+ else
+ sel = 1.0 / Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ bms_free(inner2outer);
+
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = 1.0;
+ else
+ sel = 1.0 / Max(innerrel->tuples, 1.0);
+ }
+
+ /*
+ * build a list of all non-fkey joinquals, we'll need to enlist
+ * clauselist_selectivity() to estimate these
+ */
+ lstidx = 0;
+ nonfkeyclauses = NIL;
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, outer2inner))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ return sel * clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+ }
+
+ /* perform normal estimation without the help of foreign keys */
+ return clauselist_selectivity(root, joinquals, 0, jointype, sjinfo);
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3777,11 +4022,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3794,11 +4039,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 9442e5f..dbe6038 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -40,6 +41,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -93,6 +95,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -140,7 +145,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -380,6 +384,77 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
rel->indexlist = indexinfos;
+
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+
+ rel->fkeylist = fkinfos;
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 9c3d096..3ae9022 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3923,6 +3923,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4891,6 +4958,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 274480e..5c40b83 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -221,6 +221,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 79bed33..8ce35e7 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -472,6 +472,7 @@ typedef struct RelOptInfo
Relids lateral_relids; /* minimum parameterization of rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -566,6 +567,20 @@ typedef struct IndexOptInfo
bool amhasgetbitmap; /* does AM have amgetbitmap interface? */
} IndexOptInfo;
+/* TODO add info*/
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid;
+ Oid confrelid;
+
+ int nkeys;
+ int *conkeys;
+ int *confkeys;
+ Oid *conpfeqop;
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 87123a5..da1fd58 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -73,6 +73,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8a55a09..c56cf8a 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -79,6 +79,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -112,6 +113,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 6953281..8878478 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
estimation-with-fkeys-v2_david_delta.patchapplication/octet-stream; name=estimation-with-fkeys-v2_david_delta.patchDownload
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index c00fa30..d30d715 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3732,611 +3732,248 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
- * clause_is_fk_compatible
- * Verify that the clause may be compatible with foreign keys (i.e. it's
- * a simple operator clause with two Vars, referencing two different
- * relations).
+ * find_best_match_foreign_key
+ * Returns a Bitmapset with bits set for each 0 based index of 'joinquals'
+ * which to a foreign key which is defined on fkrel.
*
- * This only checks form of the clause (and returns 'true' if it may match
- * a foreign key), but does not cross-check the clause against existing foreign
- * keys for example.
+ * Note: in the event that there's more than 1 foreign key between these two
+ * relations, the largest match, i.e. the bitmask for the one with the most
+ * matching 'joinquals' items, is returned.
*
- * It also extracts data from the clause - rangetable indexes and attnums for
- * each Var (if the function returns 'false' then those values are undefined
- * and may contain garbage).
+ * XXX it's possible to trick this code when the joinquals contain duplicate
+ * quals. Is this worth fixing?
*/
-static bool
-clause_is_fk_compatible(RestrictInfo *rinfo,
- Index *varnoa, AttrNumber *attnoa,
- Index *varnob, AttrNumber *attnob,
- Oid *opno)
+static Bitmapset *
+find_best_match_foreign_key(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals)
{
- OpExpr *clause;
- Var *var0, *var1;
-
- /* We only expect restriction clauses here, with operator expression. */
-
- if (! IsA(rinfo, RestrictInfo))
- return false;
-
- if (! IsA(rinfo->clause, OpExpr))
- return false;
+ Bitmapset *bestmatch;
+ Bitmapset *usefulquals;
+ ListCell *lc;
+ int lstidx;
+ Oid frelid;
- clause = (OpExpr*)rinfo->clause;
-
- /* The clause has to use exactly two simple variables. */
-
- if (list_length(clause->args) != 2)
- return false;
-
- var0 = list_nth(clause->args, 0);
- var1 = list_nth(clause->args, 1);
-
- if (! (IsA(var0, Var) && IsA(var1, Var)))
- return false;
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ return NULL;
- /* The variables has to reference two different rangetable entries. */
-
- if (var0->varno == var1->varno)
- return false;
+ bestmatch = NULL;
+ lstidx = -1;
+ usefulquals = NULL;
/*
- * At this point we know the clause has the right structure, so extract
- * the interesting info we'll need outside. We don't really track which
- * relation is inner/outer, so we'll check both directions.
+ * First build a bitmapset with all possibly useful quals. This will save
+ * from having to do this for each foreign key later. The only quals that
+ * are useful to us are in the form "var op var", so here we'll ignore
+ * things like "function(var1, var2)".
*/
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+ OpExpr *clause;
+ Var *leftvar, *rightvar;
- *varnoa = var0->varno;
- *attnoa = var0->varattno;
-
- *varnob = var1->varno;
- *attnob = var1->varattno;
+ /*
+ * Increment this at the start of the loop to save doing it before each
+ * continue statement.
+ */
+ lstidx++;
- *opno = clause->opno;
+ if (!IsA(rinfo, RestrictInfo))
+ continue;
- return true;
-}
+ if (!IsA(rinfo->clause, OpExpr))
+ continue;
+ clause = (OpExpr *) rinfo->clause;
-/*
- * fkey_is_matched_by_clauses
- * Check whether the foreign key is "fully" matched by the clauses.
- *
- * This checks whether the foreign key is fully matched by clauses, i.e. if
- * there's a clause matching perfectly all the parts of the foreign key.
- */
-static bool
-fkey_is_matched_by_clauses(PlannerInfo *root, ForeignKeyOptInfo *fkinfo,
- List *clauses, int relid, int frelid)
-{
- int i;
- ListCell *lc;
- bool r;
- bool *matched;
+ if (list_length(clause->args) != 2)
+ continue;
- /* we should only get multi-column foreign keys here */
- Assert(fkinfo->nkeys > 1);
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
- /* flags for each part of the foreign key */
- matched = palloc0(fkinfo->nkeys);
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
- foreach (lc, clauses)
- {
- RestrictInfo *rinfo = (RestrictInfo*)lfirst(lc);
+ usefulquals = bms_add_member(usefulquals, lstidx);
+ }
- /* info extracted from the clause (opno, varnos and varattnos) */
- Oid opno;
- Index relida, relidb;
- AttrNumber attnoa, attnob;
+ frelid = root->simple_rte_array[foreignrel->relid]->relid;
- /* we'll look this up in the simple_rte_array table */
- Oid oida, oidb;
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *matches;
+ int i;
- /*
- * If the clause has structure incompatible with foreign keys (not an
- * operator clause with two Var nodes), just skip it.
- */
- if (! clause_is_fk_compatible(rinfo, &relida, &attnoa,
- &relidb, &attnob, &opno))
+ /* skip any foreign keys which don't reference frelid */
+ if (fkinfo->confrelid != frelid)
continue;
- /* lookup range table entries for the indexes */
- oida = root->simple_rte_array[relida]->relid;
- oidb = root->simple_rte_array[relidb]->relid;
+ matches = NULL;
/*
- * Check if the clause matches any part of the foreign key.
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to match as many as possible.
*/
for (i = 0; i < fkinfo->nkeys; i++)
{
- /* if the operator does not match, try next key */
- if (! fkinfo->conpfeqop[i] == opno)
- continue;
-
- /*
- * We don't know in what order the clause lists the Vars, so we'll check
- * the foreign key in both directions (it does not really matter).
- */
- if ((oida == fkinfo->conrelid) && (oidb == fkinfo->confrelid))
- {
- if ((fkinfo->confkeys[i] == attnob) &&
- (fkinfo->conkeys[i] == attnoa))
- matched[i] = true;
- }
-
- if ((oida == fkinfo->confrelid) && (oidb == fkinfo->conrelid))
- {
- if ((fkinfo->confkeys[i] == attnoa) &&
- (fkinfo->conkeys[i] == attnob))
- matched[i] = true;
- }
- }
- }
-
- /* return 'true' if all the parts of the foreign key were matched */
- r = true;
- for (i = 0; i < fkinfo->nkeys; i++)
- r &= matched[i];
-
- pfree(matched);
-
- return r;
-}
-
-/*
- * find_satisfied_fkeys
- * Searches for all foreign keys fully-satisfied by the join clauses.
- *
- * A join is fully-satisfied if all the parts are matched by at least one
- * join condition (same operator and attnos).
- *
- * This returns a list of foreign keys of identified foreign keys (or NIL),
- * and also selectivity for all the (matched) foreign keys.
- */
-static List *
-find_satisfied_fkeys(PlannerInfo *root, SpecialJoinInfo *sjinfo, List *joinquals,
- Selectivity *sel)
-{
- int inner, outer;
- List *fkeys = NIL;
-
- /*
- * We'll take all combinations of inner/outer relations, and check if
- * there are foreign keys between them. If we found a foreign key for
- * the pair of base relations, we'll try matching it to clauses.
- *
- * We don't know in which direction the foreign keys are created, so
- * we'll check both directions (it's allways between inner and outer
- * side of the join).
- */
-
- inner = -1;
- while ((inner = bms_next_member(sjinfo->min_righthand, inner)) >= 0)
- {
- RelOptInfo *rel_inner = find_base_rel(root, inner);
- RangeTblEntry *rt_inner = planner_rt_fetch(inner, root);
-
- Assert(rel_inner->reloptkind == RELOPT_BASEREL);
-
- outer = -1;
- while ((outer = bms_next_member(sjinfo->min_lefthand, outer)) >= 0)
- {
- ListCell *lc;
- RelOptInfo *rel_outer = find_base_rel(root, outer);
- RangeTblEntry *rt_outer = planner_rt_fetch(outer, root);
-
- Assert(rel_outer->reloptkind == RELOPT_BASEREL);
+ ListCell *lc2;
- /*
- * Walk through foreign keys defined on the inner side, referencing
- * relation on the outer side.
- */
- foreach (lc, rel_inner->fkeylist)
+ lstidx = -1;
+ foreach(lc2, joinquals)
{
- ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *)lfirst(lc);
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
- /* We only care about keys referencing the current outer relation */
- if (fkinfo->confrelid != rt_outer->relid)
- continue;
+ lstidx++;
- /*
- * And we don't care about foreign keys with less than two columns
- * (those clauses will be handled by the regular estimation, unless
- * matched by some other key).
- *
- * XXX Maybe we should estimate even the single-column keys here,
- * as it's really cheap. But it can't do any cross-table check
- * of MCV lists or whatever clauselist_selectivity() does.
- */
- if (fkinfo->nkeys < 2)
+ /* skip anything we didn't mark as useful above. */
+ if (!bms_is_member(lstidx, usefulquals))
continue;
/*
- * Finally check if the foreign key is full matched by clauses,
- * and update the selectivity (simply use 1/cardinality of the
- * table referenced by the foreign key).
- *
- * XXX Notice we're using 'rel->tuples' here and not 'rows',
- * because we need the cardinality (before applying clauses).
+ * Here we can safely assume that we have an OpExpr, in the
+ * from of "var op var"
*/
- if (fkey_is_matched_by_clauses(root, fkinfo, joinquals, inner, outer))
- {
- fkeys = lappend(fkeys, fkinfo);
- *sel *= (1.0 / rel_outer->tuples);
- }
-
- }
-
- /*
- * And now check foreign keys in the other direction (defined on
- * outer relation, referencing inner).
- *
- * XXX This does exactly the same thing as the previous loop, so no
- * comments.
- *
- * TODO Merge those two blocks into a single utility function to
- * reduce the code duplication.
- */
- foreach (lc, rel_outer->fkeylist)
- {
- ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *)lfirst(lc);
+ rinfo = (RestrictInfo *) lfirst(lc2);
+ clause = (OpExpr *) rinfo->clause;
- if (fkinfo->confrelid != rt_inner->relid)
+ /* skip if the operator does not match */
+ if (clause->opno != fkinfo->conpfeqop[i])
continue;
- if (fkinfo->nkeys < 2)
- continue;
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
- if (fkey_is_matched_by_clauses(root, fkinfo, joinquals, outer, inner))
- {
- fkeys = lappend(fkeys, fkinfo);
- *sel *= (1.0 / rel_inner->tuples);
- }
+ /*
+ * Check if the OpExpr matches the foreign key. Remember that
+ * this could be written with the Vars in either order, so we
+ * test both permutations of the expression.
+ */
+ if (fkinfo->confkeys[i] == leftvar->varattno &&
+ fkinfo->conkeys[i] == rightvar->varattno)
+ matches = bms_add_member(matches, lstidx);
+ else if (fkinfo->confkeys[i] == rightvar->varattno &&
+ fkinfo->conkeys[i] == leftvar->varattno)
+ matches = bms_add_member(matches, lstidx);
}
+ }
+ /* Is this match better than the current best match? */
+ if (bms_num_members(matches) > bms_num_members(bestmatch))
+ {
+ bms_free(bestmatch);
+ bestmatch = matches;
}
}
- return fkeys;
+ return bestmatch;
}
/*
- * filter_fk_join_clauses
- * Remove the clauses that were used to match foreign keys (and will be
- * estimated using the selectivity from keys).
- *
- * Once we identify the foreign keys matched by clauses, we need to remove the
- * clauses so that we don't include them into the estimate twice. This method
- * performs that - cross-checks the foreign keys and clauses and removes all
- * clauses matching any of the foreign keys.
- *
- * If there are no foreign keys, this simply returns the original list of
- * clauses. Otherwise it builds a new list (without modifying the source one).
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ *
+ * XXX is it worth adding code to do something smart when we only get a partial
+ * foreign key match?
*/
-static List *
-filter_fk_join_clauses(PlannerInfo *root, SpecialJoinInfo *sjinfo, List *fkeys,
- List *joinquals)
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
{
- ListCell *lc,
- *lc2;
- List *clauses = NIL;
-
- /* if there are no foreign keys, return the original list */
- if (list_length(fkeys) == 0)
- return joinquals;
+ int outerrelid;
+ int innerrelid;
- foreach (lc, joinquals)
+ /*
+ * Since foreign keys can only references a single relation, and each
+ * foreign key belongs to at most a single relation, we require that only
+ * a single relation be at either side of the join condition. We'll fall
+ * back on clauselist_selectivity() if this is not the case.
+ */
+ if (bms_get_singleton_member(sjinfo->min_righthand, &innerrelid) &&
+ bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid))
{
- Oid opno;
- Index relida, relidb;
- AttrNumber attnoa, attnob;
- Oid oida, oidb;
-
- /* was the clause matched by at least one key? */
- bool matched = false;
-
- RestrictInfo *rinfo = (RestrictInfo*)lfirst(lc);
+ Bitmapset *outer2inner, *inner2outer;
+ RelOptInfo *innerrel = find_base_rel(root, innerrelid);
+ RelOptInfo *outerrel = find_base_rel(root, outerrelid);
- /* if the clause is not compatible with foreign keys, just add it */
- if (! clause_is_fk_compatible(rinfo, &relida, &attnoa,
- &relidb, &attnob, &opno))
- {
- clauses = lappend(clauses, rinfo);
- continue;
- }
+ /* check which quals are matched by a foreign key referencing the innerrel */
+ outer2inner = find_best_match_foreign_key(root, outerrel, innerrel, joinquals);
- oida = root->simple_rte_array[relida]->relid;
- oidb = root->simple_rte_array[relidb]->relid;
+ /* do the same again, but with relations swapped */
+ inner2outer = find_best_match_foreign_key(root, innerrel, outerrel, joinquals);
/*
- * Walk through the matched foreign keys, and try to match the clause
- * against each one. We don't know in what order are the Vars listed
- * in the clause, so try both ways.
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
*/
- foreach (lc2, fkeys)
+ if (outer2inner || inner2outer)
{
- int i;
- ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo*)lfirst(lc2);
+ Selectivity sel;
+ ListCell *lc;
+ int lstidx;
+ List *nonfkeyclauses;
- /* now check the keys - we can stop after finding the first match */
- for (i = 0; i < fkinfo->nkeys; i++)
+ /* either could be NULL, but bms_num_members will handle that */
+ if (bms_num_members(outer2inner) < bms_num_members(inner2outer))
{
- /* check the operator first */
- if (fkinfo->conpfeqop[i] != opno)
- continue;
+ /*
+ * We can now disgard the lesser of the two and save the best
+ * match into one of the bitmaps. Let's just use outer2inner
+ */
+ bms_free(outer2inner);
+ outer2inner = inner2outer;
- /* now check the attnums */
- if ((fkinfo->conrelid == oida) && (fkinfo->confrelid == oidb))
- {
- if ((fkinfo->confkeys[i] == attnob) &&
- (fkinfo->conkeys[i] == attnoa))
- {
- matched = true;
- break;
- }
- }
- else if ((fkinfo->conrelid == oidb) && (fkinfo->confrelid == oida))
- {
- if ((fkinfo->confkeys[i] == attnoa) &&
- (fkinfo->conkeys[i] == attnob))
- {
- matched = true;
- break;
- }
- }
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = 1.0;
+ else
+ sel = 1.0 / Max(outerrel->tuples, 1.0);
}
+ else
+ {
+ bms_free(inner2outer);
- /* no need to try more keys, single match is enough */
- if (matched)
- break;
- }
-
- /* if a clause was not matched by any foreign key, continue */
- if (! matched)
- clauses = lappend(clauses, rinfo);
-
- }
-
- return clauses;
-}
-
-
-
-/*
- * Estimate selectivity of join clauses - either by using foreign key info or
- * by using the regular clauselist_selectivity().
- *
- * If there are multiple join clauses, we check whether the clauses match
- * a foreign key between the tables - in that case we can use this information
- * to derive a better estimate (otherwise we'd multiply the selectivities for
- * each clause, which often causes significant underestimates).
- *
- * We only need to care about multi-clause join conditions and simply defer
- * simple clauses to clauselist_selectivity().
- *
- * Let's see a few examples of foreign-key joins, illustrating the estimation
- * ideas here.
- *
- * CREATE TABLE a (
- * a1 INT,
- * a2 INT,
- * a3 INT,
- * a4 INT,
- * PRIMARY KEY (a1, a2, a3)
- * );
- *
- * CREATE TABLE b (
- * b1 INT,
- * b2 INT,
- * b3 INT,
- * b4 INT,
- * FOREIGN KEY (b1, b2, b3) REFERENCES (a1, a2, a3)
- * );
- *
- * clauses exactly match a foreign key
- * -----------------------------------
- *
- * SELECT * FROM a JOIN b ON (a1=b1 AND a2=b2 AND a3=b3);
- *
- * - trivial, just use 1/card(a)
- *
- * clauses match a foreign key, with additional conditions exist
- * -------------------------------------------------------------
- *
- * SELECT * FROM a JOIN b ON (a1=b1 AND a2=b2 AND a3=b3 AND a4=b4);
- *
- * - trivial, just use 1/card(a) * selectivity(remaining_clauses)
- *
- * incomplete foreign key match
- * ----------------------------
- *
- * SELECT * FROM a JOIN b ON (a1=b1 AND a2=b2);
- *
- * - not sure, we'd need to compensate for the "missing part" somehow (we know
- * the row exists, but we don't know much many rows - it's likely more than
- * unique)
- *
- * - one way would be to assume each clause is responsible for (1/card(a))^(1/n)
- * where 'n' is number of clauses - this way 'multiplying the FK clauses' would
- * gets us the 1/card(a) selectivity if we had all the clauses
- *
- * - another thing is we might use 1/card(a) as a lower boundary - we can't
- * possibly get lower selectivity, we know the rows exist (also this is not
- * based on assumptions like the previous idea)
- *
- * multiple distinct foreign keys matching
- * ---------------------------------------
- *
- * CREATE TABLE a (
- * a1 INT,
- * a2 INT,
- * a3 INT,
- * a4 INT,
- * PRIMARY KEY (a1, a2),
- * UNIQUE (a3, a4)
- * );
- *
- * CREATE TABLE b (
- * b1 INT,
- * b2 INT,
- * b3 INT,
- * b4 INT,
- * FOREIGN KEY (b1, b2) REFERENCES (a1, a2),
- * FOREIGN KEY (b3, b4) REFERENCES (a3, a4)
- * );
- *
- * - simply just use 1/card(a) for each foreign key (assumes independence of the
- * foreign keys, but well - we're assuming attribute independence so this is
- * an improvement)
- *
- * multiple overlapping foreign keys matching
- * ------------------------------------------
- *
- * CREATE TABLE a (
- * a1 INT,
- * a2 INT,
- * a3 INT,
- * PRIMARY KEY (a1, a2),
- * UNIQUE (a2, a3)
- * );
- *
- * CREATE TABLE b (
- * b1 INT,
- * b2 INT,
- * b3 INT,
- * b4 INT,
- * FOREIGN KEY (b1, b2) REFERENCES (a1, a2),
- * FOREIGN KEY (b3, b4) REFERENCES (a2, a3)
- * );
- *
- * - probably just use 1/card(a) for each foreign key, as in the previous
- * example (assumes independence of the foreign keys, but well - we're
- * assuming attribute independence so this is an improvement)
- *
- * There are strange cases with multiple foreign keys, where one FK implies
- * the other FK. For example consider this:
- *
- * CREATE TABLE a (
- * a1 INT,
- * a2 INT,
- * a3 INT,
- * UNIQUE (a1, a2, a3),
- * UNIQUE (a1, a2)
- * );
- *
- * CREATE TABLE b (
- * b1 INT,
- * b2 INT,
- * b3 INT,
- * FOREIGN KEY (b1, b2, b3) REFERENCES a (a1, a2, a3),
- * FOREIGN KEY (b1, b2) REFERENCES a (a1, a2)
- * );
- *
- * Clearly the (b1,b2) is implied by (b1,b2,b3) - if the latter exists, then
- * the former exists too. Not sure how to handle this (or if it's actually
- * needed).
- *
- * Another slightly strange case is FK constraints in both directions (these
- * statements don't work - the foreign keys need to be established using
- * ALTER, but for illustration it's sufficient).
- *
- * CREATE TABLE a (
- * a1 INT,
- * a2 INT,
- * UNIQUE (a1, a2),
- * FOREIGN KEY (a1, a2) REFERENCES a (b1, b2)
- * );
- *
- * CREATE TABLE b (
- * b1 INT,
- * b2 INT,
- * UNIQUE (b1, b2),
- * FOREIGN KEY (b1, b2) REFERENCES a (a1, a2)
- * );
- *
- * which effectively establishes 1:1 relationship, or with distinct groups of
- * columns for each direction
- *
- * CREATE TABLE a (
- * a1 INT,
- * a2 INT,
- * a3 INT,
- * a4 INT,
- * UNIQUE (a1, a2),
- * FOREIGN KEY (a3, a4) REFERENCES a (b1, b2)
- * );
- *
- * CREATE TABLE b (
- * b1 INT,
- * b2 INT,
- * b3 INT,
- * b4 INT,
- * UNIQUE (b1, b2),
- * FOREIGN KEY (b3, b4) REFERENCES a (a1, a2)
- * );
- *
- * which creates a cycle of foreign keys.
- *
- * In the first case the foreign keys should be counted only once into the
- * selectivity, because it's effectively a 1:1 relationship - each row has
- * to have one matching row in the other table (not matched by other) rows.
- *
- * In the other case, it's probably right to factor in both foreign keys.
- */
-static Selectivity
-clauselist_join_selectivity(PlannerInfo *root, List *joinquals, int varno,
- JoinType jointype, SpecialJoinInfo *sjinfo)
-{
- Selectivity sel = 1.0;
-
- List *fkeys; /* list of satisfied foreign keys */
- List *unmatched; /* clauses remaining after removing FK clauses */
-
- Assert(list_length(joinquals) >= 0);
-
- /*
- * If we only have a single clause, we don't need to mess with the foreign
- * keys - that's only useful with multi-column clauses anyway. Just use the
- * simple clauselist_selectivity.
- */
- if (list_length(joinquals) <= 1)
- return clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
-
- /*
- * First we'll identify foreign keys that are fully matched by the join
- * clauses, and we'll update the selectivity accordingly while doing so.
- */
- fkeys = find_satisfied_fkeys(root, sjinfo, joinquals, &sel);
-
- /*
- * Now that we have the foreign keys, we can get rid of the clauses
- * matching any of them, and only keep the remaining clauses, so that
- * we can estimate them using the regular selectivity estimation.
- */
- unmatched = filter_fk_join_clauses(root, sjinfo, fkeys, joinquals);
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = 1.0;
+ else
+ sel = 1.0 / Max(innerrel->tuples, 1.0);
+ }
- /*
- * Estimate the remaining clauses (not matching any FK), if still have any.
- */
- if (list_length(unmatched) > 0)
- {
- sel *= clauselist_selectivity(root,
- unmatched,
- 0,
- jointype,
- sjinfo);
-
- /* Only free the list if we actually found any foreign keys. */
- if (list_length(fkeys) > 0)
- list_free(unmatched);
+ /*
+ * build a list of all non-fkey joinquals, we'll need to enlist
+ * clauselist_selectivity() to estimate these
+ */
+ lstidx = 0;
+ nonfkeyclauses = NIL;
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, outer2inner))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ return sel * clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
}
- return sel;
+ /* perform normal estimation without the help of foreign keys */
+ return clauselist_selectivity(root, joinquals, 0, jointype, sjinfo);
}
/*
@@ -4387,7 +4024,6 @@ calc_joinrel_size_estimate(PlannerInfo *root,
/* Get the separate selectivities */
jselec = clauselist_join_selectivity(root,
joinquals,
- 0,
jointype,
sjinfo);
@@ -4405,7 +4041,6 @@ calc_joinrel_size_estimate(PlannerInfo *root,
{
jselec = clauselist_join_selectivity(root,
restrictlist,
- 0,
jointype,
sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
diff --git a/src/backend/optimizer/plan/analyzejoins.c b/src/backend/optimizer/plan/analyzejoins.c
index 05c8698..7912b15 100644
--- a/src/backend/optimizer/plan/analyzejoins.c
+++ b/src/backend/optimizer/plan/analyzejoins.c
@@ -562,6 +562,7 @@ remove_rel_from_joinlist(List *joinlist, int relid, int *nremoved)
return result;
}
+
/*
* query_supports_distinctness - could the query possibly be proven distinct
* on some set of output columns?
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index fbc5579..dbe6038 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -96,6 +96,8 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
bool hasindex;
List *indexinfos = NIL;
List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -143,7 +145,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -384,86 +385,75 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
rel->indexlist = indexinfos;
- /*
- * TODO Can we do something like (hasindex) here? Is it necessary? The
- * trouble with that is that we don't have a good place to reset that
- * flag (relhasindex is reset by vacuum, but is has nothing to do with
- * foreign keys at this point).
- */
- if (true)
- {
- List *fkoidlist;
- ListCell *l;
-
- fkoidlist = RelationGetFKeyList(relation);
-
- foreach(l, fkoidlist)
- {
- int i;
- ArrayType *arr;
- Datum adatum;
- bool isnull;
- int numkeys;
- Oid fkoid = lfirst_oid(l);
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
- HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
- Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
- ForeignKeyOptInfo *info;
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
- Assert(constraint->contype == CONSTRAINT_FOREIGN);
+ ForeignKeyOptInfo *info;
- info = makeNode(ForeignKeyOptInfo);
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
- info->conrelid = constraint->conrelid;
- info->confrelid = constraint->confrelid;
+ info = makeNode(ForeignKeyOptInfo);
- /* conkey */
- adatum = SysCacheGetAttr(CONSTROID, htup,
- Anum_pg_constraint_conkey, &isnull);
- Assert(!isnull);
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
- arr = DatumGetArrayTypeP(adatum);
- numkeys = ARR_DIMS(arr)[0];
- info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
- for (i = 0; i < numkeys; i++)
- info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
- /* confkey */
- adatum = SysCacheGetAttr(CONSTROID, htup,
- Anum_pg_constraint_confkey, &isnull);
- Assert(!isnull);
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
- arr = DatumGetArrayTypeP(adatum);
- numkeys = ARR_DIMS(arr)[0];
- info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
- for (i = 0; i < numkeys; i++)
- info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
- /* conpfeqop */
- adatum = SysCacheGetAttr(CONSTROID, htup,
- Anum_pg_constraint_conpfeqop, &isnull);
- Assert(!isnull);
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
- arr = DatumGetArrayTypeP(adatum);
- numkeys = ARR_DIMS(arr)[0];
- info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
- for (i = 0; i < numkeys; i++)
- info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
- info->nkeys = numkeys;
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
- ReleaseSysCache(htup);
+ info->nkeys = numkeys;
- fkinfos = lcons(info, fkinfos);
- }
+ ReleaseSysCache(htup);
- list_free(fkoidlist);
+ fkinfos = lcons(info, fkinfos);
}
+ list_free(fkoidlist);
+
rel->fkeylist = fkinfos;
/* Grab foreign-table info using the relcache, while we have it */
Hi,
Thanks for the review and time spent on reworking the patch!
On 09/24/2015 07:41 AM, David Rowley wrote:
On 23 September 2015 at 17:11, David Rowley
<david.rowley@2ndquadrant.com <mailto:david.rowley@2ndquadrant.com>> wrote:find_foreign_key_clauses() should look for the longest match and
return a Bitmap set of the list indexes to the caller.
It might be possible to fool the longest match logic by duplicating
clauses, e.g. a1 = b1 AND a1 = b1 and a1 = b1 AND a2 = b2 AND a3 =
b3, but I can't imagine that matters, but if it did, we could code
it to be smart enough to see through that.I took a bash at implementing what I described, and I've ended up with
the attached.git diff -stat gives me:
src/backend/optimizer/path/costsize.c | 717
++++++++----------------------
src/backend/optimizer/plan/analyzejoins.c | 1 +
src/backend/optimizer/util/plancat.c | 112 +++--
3 files changed, 228 insertions(+), 602 deletions(-)So it's removed quite a bit of code. I also discovered that: 1.0 /
Max(rel->tuples,1.0) is no good for SEMI and ANTI joins. I've coded
around this in the attached, but I'm not certain it's the best way of
doing things.I thought that it might be possible to add some regression test around
this, if we simply just find a plan the uses a nested loop due to
underestimation of matching rows, and then make sure that it no longer
uses a nested loop when the foreign key is added. I've not yet done this
in the attached.Patched attached in delta form and complete form.
I still need to perform more analysis on the plancat.c changes.
Have I made any changes that you disagree with?
I think the changes in general are a step in the right direction, but
I've noticed some differences in behavior - some of them may be actually
desirable, other are bugs I believe.
1) (rel)hasindex
----------------
I'm perfectly fine with getting rid of hasindex, it was mostly
cargo-cult programming anyway.
2) find_best_match_foreign_key
------------------------------
I think the comment before the function needs rephrasing (seems a bit
broken to me). I do like the approach in general, although it changes
the semantics a bit. The original code only considered "fully matching"
fkeys, while the new code simply takes the longest match.
Let me illustrate on a somewhat artificial example (fkjoin1.sql):
create table t1 (a int, b int, c int, d int,
unique(a,b), unique(a,b,c,d));
create table t2 (a int, b int, c int, d int,
foreign key (a,b) references t1(a,b),
foreign key (a,b,c,d) references t2(a,b,c,d));
insert into t1 select i, i, i, i from generate_series(1,1000000) s(i);
insert into t2 select i, i, i, i from generate_series(1,1000000) s(i);
Now, let's say a query joining the tables on (a,b,c). The original code
did this
explain select * from t1 join t2 using (a,b,c);
QUERY PLAN
-------------------------------------------------------------------------
Hash Join (cost=37789.00..79094.01 rows=1 width=20)
Hash Cond: ((t1.a = t2.a) AND (t1.b = t2.b) AND (t1.c = t2.c))
-> Seq Scan on t1 (cost=0.00..15406.00 rows=1000000 width=16)
-> Hash (cost=15406.00..15406.00 rows=1000000 width=16)
-> Seq Scan on t2 (cost=0.00..15406.00 rows=1000000 width=16)
while the new code does this:
QUERY PLAN
-------------------------------------------------------------------------
Hash Join (cost=37789.00..79094.01 rows=1000000 width=20)
Hash Cond: ((t1.a = t2.a) AND (t1.b = t2.b) AND (t1.c = t2.c))
-> Seq Scan on t1 (cost=0.00..15406.00 rows=1000000 width=16)
-> Hash (cost=15406.00..15406.00 rows=1000000 width=16)
-> Seq Scan on t2 (cost=0.00..15406.00 rows=1000000 width=16)
This happens (I believe) because the new code only looks for the longest
match, without the "full match" restriction. So while the old code finds
(a,b)+c, the new code finds (a,b,c,d).
I'm not saying the new code is wrong - the "full match" restriction was
there just to simplify v1 of the patch, because dealing with partial
matches is a bit more complicated. So it's desirable to relax this
condition.
It's also true that the new code works better in some cases, e.g. this
explain select * from t1 join t2 using (a,b,c,d);
QUERY PLAN
-----------------------------------------------------------------------
Hash Join (cost=40289.00..85344.01 rows=1000000 width=16)
Hash Cond: ((t1.a = t2.a) AND (t1.b = t2.b) AND (t1.c = t2.c)
AND (t1.d = t2.d))
-> Seq Scan on t1 (cost=0.00..15406.00 rows=1000000 width=16)
-> Hash (cost=15406.00..15406.00 rows=1000000 width=16)
-> Seq Scan on t2 (cost=0.00..15406.00 rows=1000000 width=16)
was originally estimated like this
QUERY PLAN
------------------------------------------------------------------------
Hash Join (cost=40289.00..85344.01 rows=1 width=16)
Hash Cond: ((t1.a = t2.a) AND (t1.b = t2.b) AND (t1.c = t2.c)
AND (t1.d = t2.d))
-> Seq Scan on t1 (cost=0.00..15406.00 rows=1000000 width=16)
-> Hash (cost=15406.00..15406.00 rows=1000000 width=16)
-> Seq Scan on t2 (cost=0.00..15406.00 rows=1000000 width=16)
because apparently it found (a,b) and then multiplied it with c and d.
Those examples are of course a bit artificial - I'd guess tables with
multiple multi-column fkeys (and matching multiple of those fkeys in a
single query) are rather rare. But if we're willing to handle multiple
foreign keys (as searching for the "best" match suggests we are), we
should probably try to handle these cases better.
Relaxing the "full match" restriction seems valuable on it's own, I
guess - we can't really assume the partial match still has 1/nrows
selectivity, though. We need to increase the selectivity as the
condition may match multiple tuples on the PK end.
I was thinking about two ways to address this:
(a) Assuming each condition contributes equally to the selectivity,
so if the foreign key is on k columns, it's actually
1/nrows = selectivity^k
so for example if the FK is on 2 columns, and there are 1.000.000
rows on the PK side, each column contributes ~1/1000. If there
are 3 columns, it's ~1/100 per column, so matching only 2 columns
on a 3-column key would have selectivity 1/1e4 and not 1/1e6.
(b) The previous approach of course assumes that each column
contributes equally to the selectivity, but that may not really
be true in practice - the cardinality of the columns may be very
different. So I was thinking about somehow using ndistinct for the
columns in this, but I don't have a clear idea on how to do that.
What's your opinion on this?
The comment before the function mentions it's possible to confuse the
code with duplicate quals. Can you give an example?
3) clauselist_join_selectivity
------------------------------
I think this is actually broken, i.e. it does not handle the cases it
was handling before - namely the cases where more than 3 tables are
joined (fkjoin2.sql).
Imagine a "fact" table referencing two dimensions, using 2-column fkeys:
create table a (a1 int, a2 int, unique (a1,a2));
create table b (b1 int, b2 int, unique (b1,b2));
create table f (a1 int, a2 int, b1 int, b2 int);
insert into a select i,i from generate_series(0,999999) s(i);
insert into b select i,i from generate_series(0,999999) s(i);
insert into f select i/10,i/10,i/10,i/10
from generate_series(0,9999999) s(i);
alter table f add foreign key (a1,a2) references a(a1,a2);
alter table f add foreign key (b1,b2) references b(b1,b2);
Each dimension has 1M rows, fact has 10M rows (and references each row
in dimensions 10x).
Now, let's see this simple star join:
explain select * from f join a using (a1,a2)
join b using (b1,b2);
This should return all 10M rows, and originally this was estimated like
this:
QUERY PLAN
-----------------------------------------------------------------------
Hash Join (cost=66664.00..573853.57 rows=10000175 width=16)
Hash Cond: ((f.b1 = b.b1) AND (f.b2 = b.b2))
-> Hash Join (cost=33332.00..363955.16 rows=10000175 width=16)
Hash Cond: ((f.a1 = a.a1) AND (f.a2 = a.a2))
-> Seq Scan on f (cost=0.00..154056.75 rows=10000175 width=16)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on a (cost=0.00..14425.00 rows=1000000 width=8)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on b (cost=0.00..14425.00 rows=1000000 width=8)
so pretty much perfectly accurate, while the new code does this:
QUERY PLAN
----------------------------------------------------------------------
Hash Join (cost=66664.00..573853.57 rows=10 width=16)
Hash Cond: ((f.b1 = b.b1) AND (f.b2 = b.b2))
-> Hash Join (cost=33332.00..363955.16 rows=10000175 width=16)
Hash Cond: ((f.a1 = a.a1) AND (f.a2 = a.a2))
-> Seq Scan on f (cost=0.00..154056.75 rows=10000175 width=16)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on a (cost=0.00..14425.00 rows=1000000 width=8)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on b (cost=0.00..14425.00 rows=1000000 width=8)
I think this is due to this check in clauselist_join_selectivity:
if (bms_get_singleton_member(sjinfo->min_righthand, &innerrelid) &&
bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid))
which pretty much says "only work with joins on two base relations". So
as long as you have a joinrel, (e.g. a fact + one of the dimensions),
it's game over.
I think the restriction is unnecessary, because when estimating joins,
we effectively take cardinality of a cartesian product of all the base
relations, and then apply selectivities for all the join quals (in a
pairwise manner).
So for the three tables we take
card(join) = card(f) * card(a) * card(b) * sel(f,a) * sel(f,b)
and we can consider the foreign keys in the pairwise selectivities.
At least that's my understanding ...
regards
Tomas
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On 24 September 2015 at 23:57, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
2) find_best_match_foreign_key
------------------------------I think the comment before the function needs rephrasing (seems a bit
broken to me). I do like the approach in general, although it changes the
semantics a bit. The original code only considered "fully matching" fkeys,
while the new code simply takes the longest match.
Oops, I did not code this at all the way I had originally pictured it. I
guess the evidence of that is in the function comment, which I wrote before
coding the function.
I of course intended to only allow full matches.
A full patch which fixes this is attached. This also should fix the clause
duplication trick that I talked about.
The comment before the function mentions it's possible to confuse the code
with duplicate quals. Can you give an example?
Something like: SELECT * FROM a LEFT JOIN b ON a.id=b.id and a.id=b.id AND
a.id=b.id AND a.id2 = b.id2 AND a.id3 = b.id3;
Note a.id = b.id repeated 3 times.
Where a foreign key exists on (a.id) ref (b.id), and also (a.id2, a.id3)
ref (b.id2, b.id3). In this case we match 3 quals for the FK with 1 key,
and 2 quals with the FK with 2 keys. But this is now fixed in the attached.
I used an outer join here as they won't be transformed into eclass members
and back to quals again. INNER JOIN wouldn't allow the duplicates to
materialise again.
3) clauselist_join_selectivity
------------------------------I think this is actually broken, i.e. it does not handle the cases it was
handling before - namely the cases where more than 3 tables are joined
(fkjoin2.sql).Imagine a "fact" table referencing two dimensions, using 2-column fkeys:
create table a (a1 int, a2 int, unique (a1,a2));
create table b (b1 int, b2 int, unique (b1,b2));
create table f (a1 int, a2 int, b1 int, b2 int);insert into a select i,i from generate_series(0,999999) s(i);
insert into b select i,i from generate_series(0,999999) s(i);
insert into f select i/10,i/10,i/10,i/10
from generate_series(0,9999999) s(i);alter table f add foreign key (a1,a2) references a(a1,a2);
alter table f add foreign key (b1,b2) references b(b1,b2);Each dimension has 1M rows, fact has 10M rows (and references each row in
dimensions 10x).Now, let's see this simple star join:
explain select * from f join a using (a1,a2)
join b using (b1,b2);This should return all 10M rows, and originally this was estimated like
this:QUERY PLAN
-----------------------------------------------------------------------
Hash Join (cost=66664.00..573853.57 rows=10000175 width=16)
Hash Cond: ((f.b1 = b.b1) AND (f.b2 = b.b2))
-> Hash Join (cost=33332.00..363955.16 rows=10000175 width=16)
Hash Cond: ((f.a1 = a.a1) AND (f.a2 = a.a2))
-> Seq Scan on f (cost=0.00..154056.75 rows=10000175 width=16)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on a (cost=0.00..14425.00 rows=1000000 width=8)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on b (cost=0.00..14425.00 rows=1000000 width=8)so pretty much perfectly accurate, while the new code does this:
QUERY PLAN
----------------------------------------------------------------------
Hash Join (cost=66664.00..573853.57 rows=10 width=16)
Hash Cond: ((f.b1 = b.b1) AND (f.b2 = b.b2))
-> Hash Join (cost=33332.00..363955.16 rows=10000175 width=16)
Hash Cond: ((f.a1 = a.a1) AND (f.a2 = a.a2))
-> Seq Scan on f (cost=0.00..154056.75 rows=10000175 width=16)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on a (cost=0.00..14425.00 rows=1000000 width=8)
-> Hash (cost=14425.00..14425.00 rows=1000000 width=8)
-> Seq Scan on b (cost=0.00..14425.00 rows=1000000 width=8)I think this is due to this check in clauselist_join_selectivity:
if (bms_get_singleton_member(sjinfo->min_righthand, &innerrelid) &&
bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid))which pretty much says "only work with joins on two base relations". So as
long as you have a joinrel, (e.g. a fact + one of the dimensions), it's
game over.I think the restriction is unnecessary, because when estimating joins, we
effectively take cardinality of a cartesian product of all the base
relations, and then apply selectivities for all the join quals (in a
pairwise manner).So for the three tables we take
card(join) = card(f) * card(a) * card(b) * sel(f,a) * sel(f,b)
and we can consider the foreign keys in the pairwise selectivities.
I looked at this again, and I'm not all that sure it's possible to assume
that 1.0 / <tuples> is valid when there's more than one relation at either
side of the join.
My reasoning for this is that the whole basis for the patch is that a if we
find a foreign key match, then we can be sure enough, as far as row
estimations go, that exactly 1 tuple will exist matching that condition.
This assumption of the 1 tuple no longer holds when 2 relations have
already been joined, as this can either cause tuple duplication, or
elimination.
It's a little hard force the join order so that it happens this way, but
say the join order in the following example was, from left to right:
a CROSS JOIN b JOIN c on a.id=c.id
Of course, the planner would perform the cross join last in reality, but
it's possible to trick it too not.
Let's say a foreign key exists on c (id) references a(id). If we assume
that a.id = c.id produces 1 tuple in the (a,b) rel, then we'd be very
wrong, as it's not 1, it's the number of rows in b! Which could be millions.
I've attempted to create a test case to demo this against your v2 patch,
and it does fall for it, only it does happen to actually give better
estimates than without the patch, but I'm sure there must be some case to
be found where it does not.
create table a (id1 int, id2 int, c_id1 int not null, c_id2 int not null,
primary key(id1, id2));
create table b (id int primary key, a_id1 int not null, a_id2 int not null);
create table c (id1 int, id2 int);
alter table b add constraint b_a_id1_a_id2_fkey foreign key (a_id1, a_id2)
references a;
insert into a select x,x,x,x from generate_series(1,100) s(x);
insert into b select id1,id2,id1 from a;
insert into c select c_id1,c_id2 from a, generate_series(1,100);
analyze a;
analyze b;
analyze c;
explain analyze select * from a inner join b on a.id1=b.a_id1 and a.id2 =
b.a_id2 join c on c.id1%2 = a.c_id1%2 and c.id2%2 = a.c_id2%2;
I'm not saying that my version of the patch does any better... I've
actually not tested, but I think we could only use the FK to test this if
we happened to back that up with something like UNIQUE join detection. My
unique join patch aims to add some of the infrastructure which might be
required to make that possible.
Perhaps the patch cannot work well without this, as since we are trying to
fix a row underestimation, then we might just succeed in having the planner
switch the join order to some order that is not backed up by foreign keys,
because the row estimates look more favourable that way. Although perhaps
that could be fixed by changing the 1.0 / <tuples> to <something else> /
<tuples>
Regards
David Rowley
--
David Rowley http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Training & Services
Attachments:
estimation-with-fkeys-v2_davidv2.patchapplication/octet-stream; name=estimation-with-fkeys-v2_davidv2.patchDownload
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e1b49d5..8dbfeba 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1907,6 +1907,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3297,6 +3307,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index d107d76..d9083b2 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3732,6 +3732,253 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * find_best_match_foreign_key
+ * Returns a Bitmapset with bits set for each 0 based index of 'joinquals'
+ * which to a foreign key which is defined on fkrel.
+ *
+ * Note: in the event that there's more than 1 foreign key between these two
+ * relations, the largest match, i.e. the bitmask which was generated from the
+ * foreign key with the highest number of keys is returned.
+ */
+static Bitmapset *
+find_best_match_foreign_key(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals)
+{
+ Bitmapset *qualbestmatch;
+ Bitmapset *usefulquals;
+ ListCell *lc;
+ int quallstidx;
+ int bestmatchnkeys;
+ Oid frelid;
+
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ return NULL;
+
+ qualbestmatch = NULL;
+ quallstidx = -1;
+ usefulquals = NULL;
+ bestmatchnkeys = 0;
+
+ /*
+ * First build a bitmapset with all possibly useful quals. This will save
+ * from having to do this for each foreign key later. The only quals that
+ * are useful to us are in the form "var op var", so here we'll ignore
+ * things like "function(var1, var2)".
+ */
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+ OpExpr *clause;
+ Var *leftvar, *rightvar;
+
+ /*
+ * Increment this at the start of the loop to save doing it before each
+ * continue statement.
+ */
+ quallstidx++;
+
+ if (!IsA(rinfo, RestrictInfo))
+ continue;
+
+ if (!IsA(rinfo->clause, OpExpr))
+ continue;
+
+ clause = (OpExpr *) rinfo->clause;
+
+ if (list_length(clause->args) != 2)
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ usefulquals = bms_add_member(usefulquals, quallstidx);
+ }
+
+ frelid = root->simple_rte_array[foreignrel->relid]->relid;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualmatches;
+ Bitmapset *fkmatches;
+ int i;
+ int nkeys;
+
+ /* skip any foreign keys which don't reference frelid */
+ if (fkinfo->confrelid != frelid)
+ continue;
+
+ qualmatches = NULL;
+ fkmatches = NULL;
+ nkeys = fkinfo->nkeys;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to match as many as possible.
+ */
+ for (i = 0; i < nkeys; i++)
+ {
+ ListCell *lc2;
+
+ quallstidx = -1;
+ foreach(lc2, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
+
+ quallstidx++;
+
+ /* skip anything we didn't mark as useful above. */
+ if (!bms_is_member(quallstidx, usefulquals))
+ continue;
+
+ /*
+ * Here we can safely assume that we have an OpExpr, in the
+ * from of "var op var"
+ */
+ rinfo = (RestrictInfo *) lfirst(lc2);
+ clause = (OpExpr *) rinfo->clause;
+
+ /* skip if the operator does not match */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /*
+ * Check if the OpExpr matches the foreign key. Remember that
+ * this could be written with the Vars in either order, so we
+ * test both permutations of the expression.
+ */
+ if ((fkinfo->confkeys[i] == leftvar->varattno &&
+ fkinfo->conkeys[i] == rightvar->varattno) ||
+ (fkinfo->confkeys[i] == rightvar->varattno &&
+ fkinfo->conkeys[i] == leftvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ }
+ }
+
+ /* did we get a complete match to the foreign key? */
+ if (bms_num_members(fkmatches) == nkeys)
+ {
+ /* does this match match more keys than any previous match? */
+ if (nkeys > bestmatchnkeys)
+ {
+ bms_free(qualbestmatch);
+ qualbestmatch = qualmatches;
+ bestmatchnkeys = nkeys;
+ }
+ }
+
+ bms_free(fkmatches);
+ }
+
+ return qualbestmatch;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerrelid;
+ int innerrelid;
+
+ if (bms_get_singleton_member(sjinfo->min_righthand, &innerrelid) &&
+ bms_get_singleton_member(sjinfo->min_lefthand, &outerrelid))
+ {
+ Bitmapset *outer2inner, *inner2outer;
+ RelOptInfo *innerrel = find_base_rel(root, innerrelid);
+ RelOptInfo *outerrel = find_base_rel(root, outerrelid);
+
+ /* check which quals are matched by a foreign key referencing the innerrel */
+ outer2inner = find_best_match_foreign_key(root, outerrel, innerrel, joinquals);
+
+ /* do the same again, but with relations swapped */
+ inner2outer = find_best_match_foreign_key(root, innerrel, outerrel, joinquals);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outer2inner || inner2outer)
+ {
+ Selectivity sel;
+ ListCell *lc;
+ int lstidx;
+ List *nonfkeyclauses;
+
+ /* either could be NULL, but bms_num_members will handle that */
+ if (bms_num_members(outer2inner) < bms_num_members(inner2outer))
+ {
+ /*
+ * We can now disgard the lesser of the two and save the best
+ * match into one of the bitmaps. Let's just use outer2inner
+ */
+ bms_free(outer2inner);
+ outer2inner = inner2outer;
+
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = 1.0;
+ else
+ sel = 1.0 / Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ bms_free(inner2outer);
+
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = 1.0;
+ else
+ sel = 1.0 / Max(innerrel->tuples, 1.0);
+ }
+
+ /*
+ * build a list of all non-fkey joinquals, we'll need to enlist
+ * clauselist_selectivity() to estimate these
+ */
+ lstidx = 0;
+ nonfkeyclauses = NIL;
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, outer2inner))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ return sel * clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+ }
+
+ /* perform normal estimation without the help of foreign keys */
+ return clauselist_selectivity(root, joinquals, 0, jointype, sjinfo);
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3777,11 +4024,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3794,11 +4041,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 9442e5f..dbe6038 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -40,6 +41,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -93,6 +95,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -140,7 +145,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -380,6 +384,77 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
rel->indexlist = indexinfos;
+
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+
+ rel->fkeylist = fkinfos;
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 9c3d096..3ae9022 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3923,6 +3923,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4891,6 +4958,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 274480e..5c40b83 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -221,6 +221,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 79bed33..8ce35e7 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -472,6 +472,7 @@ typedef struct RelOptInfo
Relids lateral_relids; /* minimum parameterization of rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -566,6 +567,20 @@ typedef struct IndexOptInfo
bool amhasgetbitmap; /* does AM have amgetbitmap interface? */
} IndexOptInfo;
+/* TODO add info*/
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid;
+ Oid confrelid;
+
+ int nkeys;
+ int *conkeys;
+ int *confkeys;
+ Oid *conpfeqop;
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 87123a5..da1fd58 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -73,6 +73,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8a55a09..c56cf8a 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -79,6 +79,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -112,6 +113,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 6953281..8878478 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
Hi,
On 09/25/2015 03:39 AM, David Rowley wrote:
On 24 September 2015 at 23:57, Tomas Vondra
<tomas.vondra@2ndquadrant.com <mailto:tomas.vondra@2ndquadrant.com>> wrote:2) find_best_match_foreign_key
------------------------------I think the comment before the function needs rephrasing (seems a
bit broken to me). I do like the approach in general, although it
changes the semantics a bit. The original code only considered
"fully matching" fkeys, while the new code simply takes the longest
match.Oops, I did not code this at all the way I had originally pictured it. I
guess the evidence of that is in the function comment, which I wrote
before coding the function.
I of course intended to only allow full matches.
A full patch which fixes this is attached. This also should fix the
clause duplication trick that I talked about.
OK, thanks. Let's leave partial FK matches for the future.
The comment before the function mentions it's possible to confuse
the code with duplicate quals. Can you give an example? >Something like: SELECT * FROM a LEFT JOIN b ON a.id a.id=b.id b.id
and a.id a.id=b.id b.id AND a.id a.id=b.id b.id AND a.id2 = b.id2 AND
a.id3 = b.id3;Note a.id a.id = b.id b.id repeated 3 times.
Where a foreign key exists on (a.id a.id) ref (b.id b.id), and also
(a.id2, a.id3) ref (b.id2, b.id3). In this case we match 3 quals for
the FK with 1 key, and 2 quals with the FK with 2 keys. But this is
now fixed in the attached.I used an outer join here as they won't be transformed into eclass
members and back to quals again. INNER JOIN wouldn't allow the
duplicates to materialise again.
Ah, OK. Didn't think about outer joins.
...
I looked at this again, and I'm not all that sure it's possible to
assume that 1.0 / <tuples> is valid when there's more than one
relation at either side of the join.My reasoning for this is that the whole basis for the patch is that a
if we find a foreign key match, then we can be sure enough, as far as
row estimations go, that exactly 1 tuple will exist matching that
condition. This assumption of the 1 tuple no longer holds when 2
relations have already been joined, as this can either cause tuple
duplication, or elimination.
I don't see why that would be the case. Of course, you need to take the
right <tuples>, i.e. the "target" of the foreign key (the table with
UNIQUE constraint) so that the selectivity matches the fact that exactly
1 tuple (on the PK side) matches.
Let's say we have 3 tables
A (1000000 rows)
B (333333 rows)
D (222222 rows)
and let's assume A references the other two tables
A (b_id) REFERENCES B(id)
A (c_id) REFERENCES C(id)
Now, let's estimate the join
SELECT * FROM A JOIN B ON (a.b_id = b.id)
JOIN C ON (a.c_id = c.id)
Which will do this
card(join) = card(A) * card(B) * card(C) * sel(b_id=id) * sel(c_id=id)
where card(T) is a cardinality of a table, and sel(C) is selectivity of
the conditions. We do know that
card(A) = 1000
card(B) = 333
card(C) = 222
and we do know that selectivity of each condition is 1/card(T) of the
table with the UNIQUE constraint, referenced by the FK. So
sel(b_id=id) = 1/card(B) = 1/333
sel(c_id=id) = 1/card(C) = 1/222
The fact is that these selectivities perfectly eliminate the impact of
cardinality of the table. So
card(join) = 1000 * (333 * (1/333)) * (222 * (1/222))
so the expected cardinality is 1000.
Of course, this estimation effectively happens in steps, i.e. we first
join 2 tables - say A and B, then (A,B) and C. So in the first step we
do this:
card(A,B) = card(A) * card(B) * sel(b_id=id) = 1000
card((A,B),C) = card(A,B) * card(C) * sel(a_id=id) = 1000
The join order does not matter - we could easily join B,C first, and
then join A.
card(B,C) = card(B) * card(C) * sel(NULL) = 73926
and then
card((B,C),A) = card(B,C) * card(A) * sel(a_id=id) * sel(b_id=id)
= 1000
Notice that in this case, the singleton table (A) actually references
primary keys within the join relation - obviously the whole join
relation does not have unique keys or anything, but that does not matter.
The crucial part here is that selectivity of the condition needs to use
the number of tuples of the base relation, because that's the right
selectivity for the join clause.
It's a little hard force the join order so that it happens this way, but
say the join order in the following example was, from left to right:a CROSS JOIN b JOIN c on a.id a.id=c.id
Of course, the planner would perform the cross join last in reality, but
it's possible to trick it too not.Let's say a foreign key exists on c (id) references a(id). If we
assume that a.id a.id = c.id <c.id> produces 1 tuple in the (a,b)
rel, thenwe'd be very wrong, as it's not 1, it's the number of
rows in b! Which could be millions.
I think this is the part where you're wrong. What needs to happen in the
estimation is this:
card(A,B) = card(A) * card(B) /* cross join */
card((A,B),C) = card(A,B) * card(C) * sel(a.id=c.id)
= card(A,B) * card(C) * (1 / card(A))
= card(B) * card(C)
Which is what the v2 of the patch seems to be getting right. Let me
demonstrate - I'll try to replicate the example you're presenting:
create table a as select i as a_id1, i as a_id2
from generate_series(1,1000) s(i);
create table b as select i as b_id1, i as b_id2
from generate_series(0,332) s(i);
alter table b add unique (b_id1, b_id2);
create table c as select i/3 as c_id1, i/3 as c_id2
from generate_series(0,998) s(i);
alter table c add foreign key (c_id1, c_id2)
references b (b_id1, b_id2);
analyze;
Let's force the join order:
set join_collapse_limit = 1;
and run a bunch of queries joining the tables in different orders. I'll
only present the EXPLAIN output here, but the estimates are perfectly
accurate:
test=# explain select * from (a cross join b)
join c on (b_id1 = c_id1 AND b_id2 = c_id2);
QUERY PLAN
-----------------------------------------------------------------------------------------------
Merge Join (cost=64.91..5981.72 rows=999000 width=24)
Merge Cond: ((b.b_id1 = c.c_id1) AND (b.b_id2 = c.c_id2))
-> Nested Loop (cost=0.15..4199.45 rows=333000 width=16)
-> Index Only Scan using b_b_id1_b_id2_key on b
(cost=0.15..19.45 rows=333 width=8)
-> Materialize (cost=0.00..20.00 rows=1000 width=8)
-> Seq Scan on a (cost=0.00..15.00 rows=1000 width=8)
-> Sort (cost=64.76..67.26 rows=999 width=8)
Sort Key: c.c_id1, c.c_id2
-> Seq Scan on c (cost=0.00..14.99 rows=999 width=8)
(9 rows)
test=# explain select * from (a cross join c)
join b on (b_id1 = c_id1 and b_id2 = c_id2);
QUERY PLAN
----------------------------------------------------------------------
Hash Join (cost=10.32..20052.81 rows=999000 width=24)
Hash Cond: ((c.c_id1 = b.b_id1) AND (c.c_id2 = b.b_id2))
-> Nested Loop (cost=0.00..12519.99 rows=999000 width=16)
-> Seq Scan on a (cost=0.00..15.00 rows=1000 width=8)
-> Materialize (cost=0.00..19.98 rows=999 width=8)
-> Seq Scan on c (cost=0.00..14.99 rows=999 width=8)
-> Hash (cost=5.33..5.33 rows=333 width=8)
-> Seq Scan on b (cost=0.00..5.33 rows=333 width=8)
(8 rows)
test=# explain select * from (b join c on (b_id1=c_id1 and
b_id2=c_id2)) cross join a;
QUERY PLAN
---------------------------------------------------------------------------
Nested Loop (cost=10.32..12537.84 rows=999000 width=24)
-> Seq Scan on a (cost=0.00..15.00 rows=1000 width=8)
-> Materialize (cost=10.32..37.83 rows=999 width=16)
-> Hash Join (cost=10.32..32.84 rows=999 width=16)
Hash Cond: ((c.c_id1 = b.b_id1) AND (c.c_id2 = b.b_id2))
-> Seq Scan on c (cost=0.00..14.99 rows=999 width=8)
-> Hash (cost=5.33..5.33 rows=333 width=8)
-> Seq Scan on b (cost=0.00..5.33 rows=333 width=8)
(8 rows)
I've attempted to create a test case to demo this against your v2
patch, and it does fall for it, only it does happen to actually give
better estimates than without the patch, but I'm sure there must be
some case to be found where it does not.create table a (id1 int, id2 int, c_id1 int not null, c_id2 int not
null, primary key(id1, id2));
create table b (id int primary key, a_id1 int not null, a_id2 int not null);
create table c (id1 int, id2 int);alter table b add constraint b_a_id1_a_id2_fkey foreign key (a_id1,
a_id2) references a;insert into a select x,x,x,x from generate_series(1,100) s(x);
insert into b select id1,id2,id1 from a;
insert into c select c_id1,c_id2 from a, generate_series(1,100);analyze a;
analyze b;
analyze c;explain analyze select * from a inner join b on a.id1=b.a_id1 and a.id2
= b.a_id2 join c on c.id1%2 = a.c_id1%2 and c.id2%2 = a.c_id2%2;
No, I don't think it 'falls for it'. Table C is not connected to the
other two tables by a foreign key, and even if it was, the modulo
expression would make it impossible to detect the join a s FK join.
Which makes the example rather irrelevant for this patch, I think.
If you try to fix those issues, you should get basically the example
I've presented.
It's possible to confuse the patch - e.g. by creating foreign keys in
both directions, or 3-day join with each table referencing the other
two. But it should still give better estimates than the current
estimation that does not consider foreign keys at all.
I'm not saying that my version of the patch does any better... I've
actually not tested, but I think we could only use the FK to test
this if we happened to back that up with something like UNIQUE join
detection. My unique join patch aims to add some of the
infrastructure which might be required to make that possible.
I'm not sure where you see the problem in the current patch, so I can't
really say whether this is good or bad.
Perhaps the patch cannot work well without this, as since we are
trying to fix a row underestimation, then we might just succeed in
having the planner switch the join order to some order that is not
backed up by foreign keys, because the row estimates look more
favourable that way. Although perhaps that could be fixed by changing
the 1.0 / <tuples> to <something else> / <tuples>
I don't think the join order should matter (and I tried to demonstrate
that with the example above).
It might matter if we hit the issue with equivalence classes, because
then the planner comes up with new join clauses that may not be backed
by foreign keys. But even in that case we should not do worse that now.
regards
--
Tomas Vondra www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 26 September 2015 at 01:57, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
Hi,
On 09/25/2015 03:39 AM, David Rowley wrote:
I looked at this again, and I'm not all that sure it's possible to
assume that 1.0 / <tuples> is valid when there's more than one
relation at either side of the join.
My reasoning for this is that the whole basis for the patch is that a
if we find a foreign key match, then we can be sure enough, as far as
row estimations go, that exactly 1 tuple will exist matching that
condition. This assumption of the 1 tuple no longer holds when 2
relations have already been joined, as this can either cause tuple
duplication, or elimination.I don't see why that would be the case. Of course, you need to take the
right <tuples>, i.e. the "target" of the foreign key (the table with UNIQUE
constraint) so that the selectivity matches the fact that exactly 1 tuple
(on the PK side) matches.
hmm, ok. You're right. It appears I was a bit confused, but thanks for
explaining it again. I get it now.
I've been working on this again. I've put back the code that you wrote for
the looping over each combination of relations from either side of the join.
I've also added some code to get around the problem with eclass joins and
the RestrictInfo having some alternative Vars that don't belong to the
foreign key. Basically I'm just checking if the RestrictInfo has a
parent_ec, and if it does just loop over the members to try and find the
Vars that belong to the foreign key. I've tested it with the following, and
it seems to work:
create table a as select i as a_id1, i as a_id2, i as dummy1 from
generate_series(0,999) s(i);
alter table a add unique (a_id1, a_id2);
create table b as select i as b_id1, i as b_id2 from generate_series(0,332)
s(i);
analyze a;
analyze b;
alter table b add foreign key (b_id1, b_id2) references a (a_id1, a_id2);
explain analyze select * from a inner join b on a.dummy1 = b.b_id1 and
a.a_id2 = b.b_id2 where a.a_id1 = a.dummy1;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Hash Join (cost=18.57..26.41 rows=2 width=20) (actual time=0.775..1.046
rows=333 loops=1)
Hash Cond: ((b.b_id1 = a.dummy1) AND (b.b_id2 = a.a_id2))
-> Seq Scan on b (cost=0.00..5.33 rows=333 width=8) (actual
time=0.013..0.046 rows=333 loops=1)
-> Hash (cost=18.50..18.50 rows=5 width=12) (actual time=0.737..0.737
rows=1000 loops=1)
Buckets: 1024 Batches: 1 Memory Usage: 51kB
-> Seq Scan on a (cost=0.00..18.50 rows=5 width=12) (actual
time=0.014..0.389 rows=1000 loops=1)
Filter: (dummy1 = a_id1)
The non-patched version estimates 1 row. The patched estimates 2 rows, but
that's due to the bad estimate on dummy1 = a_id1.
The 2 comes from ceil(5 * 0.333).
Perhaps you have a better test case to for this?
Regards
David Rowley
--
David Rowley http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Training & Services
Attachments:
estimation-with-fkeys-v2_davidv3.patchapplication/octet-stream; name=estimation-with-fkeys-v2_davidv3.patchDownload
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e1b49d5..8dbfeba 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1907,6 +1907,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3297,6 +3307,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index d107d76..0a57bc9 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3732,6 +3732,322 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * find_best_foreign_key_quals
+ * Analyzes joinquals to determine if any quals match foreign keys defined
+ * on 'fkrel' which reference 'foreignrel'. We return the number of keys
+ * of the best matching foreign key. We assume the best matching foreign
+ * key is the one with the most keys, not the most quals matching quals,
+ * as quals could be duplicated. We also set 'joinqualsbitmap' bits to
+ * mark which quals in 'joinquals' were matched. Zero is returned if no
+ * match is found. In this case 'joinqualsbitmap' is set to NULL. Partial
+ * foreign key matches are currently ignored.
+ */
+static int
+find_best_foreign_key_quals(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals,
+ Bitmapset **joinqualsbitmap)
+{
+ Bitmapset *qualbestmatch;
+ Bitmapset *usefulquals;
+ ListCell *lc;
+ int quallstidx;
+ int bestmatchnkeys;
+ Oid frelid;
+
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ {
+ *joinqualsbitmap = NULL;
+ return 0;
+ }
+
+ qualbestmatch = NULL;
+ quallstidx = -1;
+ usefulquals = NULL;
+ bestmatchnkeys = 0;
+
+ /*
+ * First build a bitmapset with all possibly useful quals. This will save
+ * from having to do this for each foreign key later. The only quals that
+ * are useful to us are in the form "var op var", so here we'll ignore
+ * things like "function(var1, var2)".
+ */
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+ OpExpr *clause;
+ Var *leftvar, *rightvar;
+
+ /*
+ * Increment this at the start of the loop to save doing it before each
+ * continue statement.
+ */
+ quallstidx++;
+
+ if (!IsA(rinfo, RestrictInfo))
+ continue;
+
+ if (!IsA(rinfo->clause, OpExpr))
+ continue;
+
+ clause = (OpExpr *) rinfo->clause;
+
+ if (list_length(clause->args) != 2)
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ usefulquals = bms_add_member(usefulquals, quallstidx);
+ }
+
+ frelid = root->simple_rte_array[foreignrel->relid]->relid;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualmatches;
+ Bitmapset *fkmatches;
+ int i;
+ int nkeys;
+
+ /* skip any foreign keys which don't reference frelid */
+ if (fkinfo->confrelid != frelid)
+ continue;
+
+ qualmatches = NULL;
+ fkmatches = NULL;
+ nkeys = fkinfo->nkeys;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to match as many as possible.
+ */
+ for (i = 0; i < nkeys; i++)
+ {
+ ListCell *lc2;
+
+ quallstidx = -1;
+ foreach(lc2, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+
+ quallstidx++;
+
+ /* skip anything we didn't mark as useful above. */
+ if (!bms_is_member(quallstidx, usefulquals))
+ continue;
+
+ /*
+ * Here we can safely assume that we have an OpExpr, in the
+ * from of "var op var"
+ */
+ rinfo = (RestrictInfo *) lfirst(lc2);
+ clause = (OpExpr *) rinfo->clause;
+
+ /*
+ * if the operator does not match then there's little point in
+ * checking the operands
+ */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ /*
+ * For RestrictInfos built from an eclass we must consider
+ * each member of the eclass, as rinfo may not be using the
+ * foreign key Vars. For efficient tracking of which Vars we've
+ * found, since we're only tracking 2 Vars, we use a bitmask.
+ * We can safely finish searching when both of the least
+ * significant bits are set.
+ */
+ if (rinfo->parent_ec)
+ {
+ EquivalenceClass *ec = rinfo->parent_ec;
+ ListCell *lc3;
+ int foundvarmask = 0;
+
+ foreach(lc3, ec->ec_members)
+ {
+ EquivalenceMember *em = (EquivalenceMember *) lfirst(lc3);
+ Var *var = (Var *) em->em_expr;
+
+ if (!IsA(var, Var))
+ continue;
+
+ if (foreignrel->relid == var->varno &&
+ fkinfo->confkeys[i] == var->varattno)
+ foundvarmask |= 1;
+
+ else if (fkrel->relid == var->varno &&
+ fkinfo->conkeys[i] == var->varattno)
+ foundvarmask |= 2;
+
+ /*
+ * Check if we've found both matches. If found we add
+ * this qual to the matched list and mark this key as
+ * matched too.
+ */
+ if (foundvarmask == 3)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ break;
+ }
+ }
+ }
+ else
+ {
+ Var *leftvar = (Var *) get_leftop((Expr *) clause);
+ Var *rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /*
+ * In this non eclass RestrictInfo case we'll check if the
+ * left and right Vars match to this part of the foreign
+ * key. Remember that this could be written with the Vars
+ * in either order, so we test both permutations of the
+ * expression.
+ */
+ if (foreignrel->relid == leftvar->varno &&
+ fkrel->relid == rightvar->varno &&
+ fkinfo->confkeys[i] == leftvar->varattno &&
+ fkinfo->conkeys[i] == rightvar->varattno)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ else if (foreignrel->relid == rightvar->varno &&
+ fkrel->relid == leftvar->varno &&
+ fkinfo->confkeys[i] == rightvar->varattno &&
+ fkinfo->conkeys[i] == leftvar->varattno)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ }
+ }
+ }
+
+ /* did we get a complete match to the foreign key? */
+ if (bms_num_members(fkmatches) == nkeys)
+ {
+ /* does this match match more keys than any previous match? */
+ if (nkeys > bestmatchnkeys)
+ {
+ bms_free(qualbestmatch);
+ qualbestmatch = qualmatches;
+ bestmatchnkeys = nkeys;
+ }
+ }
+
+ bms_free(fkmatches);
+ }
+
+ *joinqualsbitmap = qualbestmatch;
+ return bestmatchnkeys;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerid;
+ int innerid;
+ Selectivity sel = 1.0;
+ Bitmapset *nonfkquals = NULL;
+
+ innerid = -1;
+ while ((innerid = bms_next_member(sjinfo->min_righthand, innerid)) >= 0)
+ {
+ RelOptInfo *innerrel = find_base_rel(root, innerid);
+
+ outerid = -1;
+ while ((outerid = bms_next_member(sjinfo->min_lefthand, outerid)) >= 0)
+ {
+ RelOptInfo *outerrel = find_base_rel(root, outerid);
+ Bitmapset *outer2inner;
+ Bitmapset *inner2outer;
+ int innermatches;
+ int outermatches;
+
+ /*
+ * check which quals are matched by a foreign key referencing the
+ * innerrel.
+ */
+ outermatches = find_best_foreign_key_quals(root, outerrel,
+ innerrel, joinquals, &outer2inner);
+
+ /* do the same, but with relations swapped */
+ innermatches = find_best_foreign_key_quals(root, innerrel,
+ outerrel, joinquals, &inner2outer);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outermatches != 0 || innermatches != 0)
+ {
+ /* either could be zero, but not both. */
+ if (outermatches < innermatches)
+ {
+ nonfkquals = bms_add_members(nonfkquals, inner2outer);
+
+ if (jointype != JOIN_SEMI && jointype != JOIN_ANTI)
+ sel *= 1.0 / Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ nonfkquals = bms_add_members(nonfkquals, outer2inner);
+
+ if (jointype != JOIN_SEMI && jointype != JOIN_ANTI)
+ sel *= 1.0 / Max(innerrel->tuples, 1.0);
+ }
+ }
+ }
+ }
+
+ /*
+ * If any non matched quals exist then we build a list of the non-matches
+ * and use clauselist_selectivity() to estimate the selectivity of these.
+ */
+ if (bms_num_members(nonfkquals) < list_length(joinquals))
+ {
+ ListCell *lc;
+ int lstidx = 0;
+ List *nonfkeyclauses = NIL;
+
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, nonfkquals))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ sel *= clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+
+ return sel;
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3777,11 +4093,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3794,11 +4110,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 9442e5f..dbe6038 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -40,6 +41,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -93,6 +95,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -140,7 +145,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -380,6 +384,77 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
rel->indexlist = indexinfos;
+
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+
+ rel->fkeylist = fkinfos;
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 9c3d096..3ae9022 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3923,6 +3923,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4891,6 +4958,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 274480e..5c40b83 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -221,6 +221,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 79bed33..8ce35e7 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -472,6 +472,7 @@ typedef struct RelOptInfo
Relids lateral_relids; /* minimum parameterization of rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -566,6 +567,20 @@ typedef struct IndexOptInfo
bool amhasgetbitmap; /* does AM have amgetbitmap interface? */
} IndexOptInfo;
+/* TODO add info*/
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid;
+ Oid confrelid;
+
+ int nkeys;
+ int *conkeys;
+ int *confkeys;
+ Oid *conpfeqop;
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 87123a5..da1fd58 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -73,6 +73,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8a55a09..c56cf8a 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -79,6 +79,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -112,6 +113,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 6953281..8878478 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
Hi,
On 09/27/2015 02:00 PM, David Rowley wrote:
I've been working on this again. I've put back the code that you wrote
for the looping over each combination of relations from either side of
the join.I've also added some code to get around the problem with eclass joins
and the RestrictInfo having some alternative Vars that don't belong to
the foreign key. Basically I'm just checking if the RestrictInfo has a
parent_ec, and if it does just loop over the members to try and find the
Vars that belong to the foreign key. I've tested it with the following,
and it seems to work:
I didn't have time to look into the code yet, but this seems like an
interesting idea.
create table a as select i as a_id1, i as a_id2, i as dummy1 from
generate_series(0,999) s(i);
alter table a add unique (a_id1, a_id2);
create table b as select i as b_id1, i as b_id2 from
generate_series(0,332) s(i);analyze a;
analyze b;alter table b add foreign key (b_id1, b_id2) references a (a_id1, a_id2);
explain analyze select * from a inner join b on a.dummy1 = b.b_id1 and
a.a_id2 = b.b_id2 where a.a_id1 = a.dummy1;QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Hash Join (cost=18.57..26.41 rows=2 width=20) (actual
time=0.775..1.046 rows=333 loops=1)
Hash Cond: ((b.b_id1 = a.dummy1) AND (b.b_id2 = a.a_id2))
-> Seq Scan on b (cost=0.00..5.33 rows=333 width=8) (actual
time=0.013..0.046 rows=333 loops=1)
-> Hash (cost=18.50..18.50 rows=5 width=12) (actual
time=0.737..0.737 rows=1000 loops=1)
Buckets: 1024 Batches: 1 Memory Usage: 51kB
-> Seq Scan on a (cost=0.00..18.50 rows=5 width=12) (actual
time=0.014..0.389 rows=1000 loops=1)
Filter: (dummy1 = a_id1)The non-patched version estimates 1 row. The patched estimates 2 rows,
but that's due to the bad estimate on dummy1 = a_id1.The 2 comes from ceil(5 * 0.333).
Perhaps you have a better test case to for this?
I think the additional WHERE clause is needlessly confusing. I've been
able to come up with an example - pretty much a normalized with a "main"
table and auxiliary tables (referencing the main one using FK) with
additional info. So not unlikely to happen in practice (except maybe for
the multi-column foreign key bit).
CREATE TABLE f (id1 INT, id2 INT, PRIMARY KEY (id1, id2));
CREATE TABLE d1 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));
CREATE TABLE d2 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));
INSERT INTO f SELECT i, i FROM generate_series(1,1000000) s(i);
INSERT INTO d1 SELECT i, i FROM generate_series(1,100000) s(i);
INSERT INTO d2 SELECT i, i FROM generate_series(1,300000) s(i);
now, both pair-wise joins (f JOIN d1) and (f JOIN d2) are estimated
perfectly accurately, but as soon as the query involves both of them,
this happens:
SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND f.id2 = d1.id2)
JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);
QUERY PLAN
-------------------------------------------------------------------------
Nested Loop (cost=3334.43..12647.57 rows=30000 width=24)
(actual time=221.086..1767.206 rows=100000 loops=1)
Join Filter: ((d1.id1 = f.id1) AND (d1.id2 = f.id2))
-> Hash Join (cost=3334.00..12647.01 rows=1 width=16)
(actual time=221.058..939.482 rows=100000 loops=1)
Hash Cond: ((d2.id1 = d1.id1) AND (d2.id2 = d1.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8)
(actual time=0.038..263.356 rows=300000 loops=1)
-> Hash (cost=1443.00..1443.00 rows=100000 width=8)
(actual time=220.721..220.721 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 2982kB
-> Seq Scan on d1 (cost=0.00..1443.00 rows=100000 ...)
(actual time=0.033..101.547 rows=100000 loops=1)
-> Index Only Scan using f_pkey on f (cost=0.42..0.54 rows=1 ...)
(actual time=0.004..0.004 rows=1 loops=100000)
Index Cond: ((id1 = d2.id1) AND (id2 = d2.id2))
Heap Fetches: 100000
Clearly, the inner join (d1 JOIN d2) is poorly estimated (1 vs. 100000).
I assume that's only because we find FK only on the second join with f.
So it seems like s a clear improvement, both compared to master and the
previous versions of the patch.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 29 September 2015 at 01:59, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
CREATE TABLE f (id1 INT, id2 INT, PRIMARY KEY (id1, id2));
CREATE TABLE d1 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));
CREATE TABLE d2 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));INSERT INTO f SELECT i, i FROM generate_series(1,1000000) s(i);
INSERT INTO d1 SELECT i, i FROM generate_series(1,100000) s(i);
INSERT INTO d2 SELECT i, i FROM generate_series(1,300000) s(i);now, both pair-wise joins (f JOIN d1) and (f JOIN d2) are estimated
perfectly accurately, but as soon as the query involves both of them, this
happens:SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND f.id2 = d1.id2)
JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);
This is a near perfect example of what I was trying to explain about being
unable to have guarantees about there being 1.0 matching tuples in the
referenced relation.
If we run the above with join_collapse_limit = 1, then we'll first join f
to d1, which will give us 100000 tuples. (With IDs ranging from 1 to 100000)
If we now perform estimates to join d2 to (f, d1), we don't have all of the
referenced tuples in (f, d1), so how do we estimate that? Remember that d2
has IDs 100001 to 300000 that won't be found in the "referenced" relation.
What if we had populated d1 with:
INSERT INTO d1 SELECT i, i FROM generate_series(900001,1000000) s(i);
The join will find exactly 0 tuples between the join of (f, d1) -> d2.
Is my logic here wrong somehow?
--
David Rowley http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Training & Services
On 29 September 2015 at 01:59, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
Hi,
On 09/27/2015 02:00 PM, David Rowley wrote:
I've been working on this again. I've put back the code that you wrote
for the looping over each combination of relations from either side of
the join.I've also added some code to get around the problem with eclass joins
and the RestrictInfo having some alternative Vars that don't belong to
the foreign key. Basically I'm just checking if the RestrictInfo has a
parent_ec, and if it does just loop over the members to try and find the
Vars that belong to the foreign key. I've tested it with the following,
and it seems to work:I didn't have time to look into the code yet, but this seems like an
interesting idea.create table a as select i as a_id1, i as a_id2, i as dummy1 from
generate_series(0,999) s(i);
alter table a add unique (a_id1, a_id2);
create table b as select i as b_id1, i as b_id2 from
generate_series(0,332) s(i);analyze a;
analyze b;alter table b add foreign key (b_id1, b_id2) references a (a_id1, a_id2);
explain analyze select * from a inner join b on a.dummy1 = b.b_id1 and
a.a_id2 = b.b_id2 where a.a_id1 = a.dummy1;QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Hash Join (cost=18.57..26.41 rows=2 width=20) (actual
time=0.775..1.046 rows=333 loops=1)
Hash Cond: ((b.b_id1 = a.dummy1) AND (b.b_id2 = a.a_id2))
-> Seq Scan on b (cost=0.00..5.33 rows=333 width=8) (actual
time=0.013..0.046 rows=333 loops=1)
-> Hash (cost=18.50..18.50 rows=5 width=12) (actual
time=0.737..0.737 rows=1000 loops=1)
Buckets: 1024 Batches: 1 Memory Usage: 51kB
-> Seq Scan on a (cost=0.00..18.50 rows=5 width=12) (actual
time=0.014..0.389 rows=1000 loops=1)
Filter: (dummy1 = a_id1)The non-patched version estimates 1 row. The patched estimates 2 rows,
but that's due to the bad estimate on dummy1 = a_id1.The 2 comes from ceil(5 * 0.333).
Perhaps you have a better test case to for this?
I think the additional WHERE clause is needlessly confusing. I've been
able to come up with an example - pretty much a normalized with a "main"
table and auxiliary tables (referencing the main one using FK) with
additional info. So not unlikely to happen in practice (except maybe for
the multi-column foreign key bit).CREATE TABLE f (id1 INT, id2 INT, PRIMARY KEY (id1, id2));
CREATE TABLE d1 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));
CREATE TABLE d2 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));INSERT INTO f SELECT i, i FROM generate_series(1,1000000) s(i);
INSERT INTO d1 SELECT i, i FROM generate_series(1,100000) s(i);
INSERT INTO d2 SELECT i, i FROM generate_series(1,300000) s(i);now, both pair-wise joins (f JOIN d1) and (f JOIN d2) are estimated
perfectly accurately, but as soon as the query involves both of them, this
happens:SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND f.id2 = d1.id2)
JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);QUERY PLAN
-------------------------------------------------------------------------
Nested Loop (cost=3334.43..12647.57 rows=30000 width=24)
(actual time=221.086..1767.206 rows=100000 loops=1)
Join Filter: ((d1.id1 = f.id1) AND (d1.id2 = f.id2))
-> Hash Join (cost=3334.00..12647.01 rows=1 width=16)
(actual time=221.058..939.482 rows=100000 loops=1)
Hash Cond: ((d2.id1 = d1.id1) AND (d2.id2 = d1.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8)
(actual time=0.038..263.356 rows=300000 loops=1)
-> Hash (cost=1443.00..1443.00 rows=100000 width=8)
(actual time=220.721..220.721 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 2982kB
-> Seq Scan on d1 (cost=0.00..1443.00 rows=100000 ...)
(actual time=0.033..101.547 rows=100000 loops=1)
-> Index Only Scan using f_pkey on f (cost=0.42..0.54 rows=1 ...)
(actual time=0.004..0.004 rows=1 loops=100000)
Index Cond: ((id1 = d2.id1) AND (id2 = d2.id2))
Heap Fetches: 100000Clearly, the inner join (d1 JOIN d2) is poorly estimated (1 vs. 100000). I
assume that's only because we find FK only on the second join with f.So it seems like s a clear improvement, both compared to master and the
previous versions of the patch.
I've been experimenting with this example. Of course, the reason why we get
the 1 row estimate on the join between d1 and d2 is that there's no foreign
key between those two relations.
The attached patch changes things so that the foreign key matching code is
better able to see foreign keys "hidden" behind eclasses. So it does now in
fact detect a foreign key on d2 referencing d1, by looking for Vars foreign
keys which have Vars in the same eclasses as the joinquals are built from.
This has improved the result
postgres=# EXPLAIN ANALYZE SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND
f.id2 = d1.id2) JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);
QUERY
PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
Hash Join (cost=16655.94..26066.95 rows=30000 width=24) (actual
time=267.322..468.383 rows=100000 loops=1)
Hash Cond: ((d2.id1 = f.id1) AND (d2.id2 = f.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8) (actual
time=0.019..31.396 rows=300000 loops=1)
-> Hash (cost=14666.94..14666.94 rows=100000 width=16) (actual
time=266.263..266.263 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 3373kB
-> Merge Join (cost=9748.32..14666.94 rows=100000 width=16)
(actual time=104.494..224.908 rows=100000 loops=1)
Merge Cond: ((f.id1 = d1.id1) AND (f.id2 = d1.id2))
-> Index Only Scan using f_pkey on f (cost=0.42..36214.93
rows=1000000 width=8) (actual time=0.045..35.758 rows=100001 loops=1)
Heap Fetches: 100001
-> Sort (cost=9747.82..9997.82 rows=100000 width=8)
(actual time=104.440..122.401 rows=100000 loops=1)
Sort Key: d1.id1, d1.id2
Sort Method: external sort Disk: 2152kB
-> Seq Scan on d1 (cost=0.00..1443.00 rows=100000
width=8) (actual time=0.019..9.443 rows=100000 loops=1)
The problem is that the code I added is sometimes a bit too optimistic at
finding a suitable foreign key. When performing estimates for the join
between (f,d1) <-> (d2), since the code loops over each relation making up
the set of relations at either side of the join, we find a foreign key on
'f' which references d2, this one actually exists. It then goes on and also
finds a foreign key for (d1) references (d2), of course this one does not
exists and it's only could due to the eclasses. The problem here is, which
one do we use? If we multiply the selectivity for each of these foreign
keys then we'd end up with a selectivty = (1.0 / 1000000) * (1.0 / 300000),
which is a massive underestimation. Perhaps doing this would be perfectly
valid if the actual foreign key being around was not the same one as the
last one, but this seems wrong when we match to the same foreign key in
both instances.
I've gone though a few variations on ways to handle this and I'm a bit
stuck on what's the best way.
In the attached I've coded it to take the Min() selectivity for when the
same quals are matched more than once. I know this is not correct, but
since it seems impossible to obtain an exact estimate in this case, we'd
need to decide on some logic which does well in the average case.
--
David Rowley http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Training & Services
Attachments:
estimation-with-fkeys-v2_davidv4.patchapplication/octet-stream; name=estimation-with-fkeys-v2_davidv4.patchDownload
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index c91273c..cc1cb78 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1909,6 +1909,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3299,6 +3309,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index d107d76..50828f2 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3732,6 +3732,405 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * quals_match_foreign_key
+ * Determines if 'joinquals' contains quals which match up to the foreign
+ * key 'fkinfo'. If a complete match is made to the foreign key, then a
+ * bitmap is returned with bits set for each of the 'joinquals' 0 based
+ * list position of each match. If 'joinquals' only partially matches the
+ * foreign key, then NULL is returned.
+ */
+static Bitmapset *
+quals_match_foreign_key(PlannerInfo *root, ForeignKeyOptInfo *fkinfo,
+ RelOptInfo *fkrel, RelOptInfo *foreignrel,
+ List *joinquals)
+{
+ int i;
+ int nkeys = fkinfo->nkeys;
+ Bitmapset *qualmatches = NULL;
+ Bitmapset *fkmatches = NULL;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to generate a bitmap index which has bits set for
+ * every matching join qual.
+ */
+ for (i = 0; i < nkeys; i++)
+ {
+ ListCell *lc;
+ int quallstidx = -1;
+
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
+
+ quallstidx++;
+
+ /*
+ * Technically we don't need to, but here we skip this qual if
+ * we've matched it to part of the foreign key already. This
+ * should prove to be a useful optimization when the quals appear
+ * in the same order as the foreign key's keys. We need only bother
+ * doing this when the foreign key is made up of more than 1 set
+ * of columns, and we're not testing the first column.
+ */
+ if (i > 0 && bms_is_member(quallstidx, qualmatches))
+ continue;
+
+ /*
+ * Here since 'usefulquals' only contains bitmap indexes for quals
+ * of type "var op var" we can safely skip checking this.
+ */
+ rinfo = (RestrictInfo *) lfirst(lc);
+ clause = (OpExpr *) rinfo->clause;
+
+ /*
+ * If the operator does not match then there's little point in
+ * checking the operands
+ */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ /*
+ * For RestrictInfos built from an eclass we must consider each
+ * member of the eclass as rinfo's operands may not belong to the
+ * foreign key. For efficient tracking of which Vars we've found,
+ * since we're only tracking 2 Vars, we use a bitmask. We can
+ * safely finish searching when both of the least significant bits
+ * are set.
+ */
+ if (rinfo->parent_ec)
+ {
+ EquivalenceClass *ec = rinfo->parent_ec;
+ ListCell *lc2;
+ int foundvarmask = 0;
+
+ foreach(lc2, ec->ec_members)
+ {
+ EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
+ Var *var = (Var *) em->em_expr;
+
+ if (!IsA(var, Var))
+ continue;
+
+ if (foreignrel->relid == var->varno &&
+ fkinfo->confkeys[i] == var->varattno)
+ foundvarmask |= 1;
+
+ else if (fkrel->relid == var->varno &&
+ fkinfo->conkeys[i] == var->varattno)
+ foundvarmask |= 2;
+
+ /*
+ * Check if we've found both matches. If found we add
+ * this qual to the matched list and mark this key as
+ * matched too.
+ */
+ if (foundvarmask == 3)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ break;
+ }
+ }
+ }
+ else
+ {
+ /*
+ * In this non eclass RestrictInfo case we'll check if the left
+ * and right Vars match to this part of the foreign key.
+ * Remember that this could be written with the Vars in either
+ * order, so we test both permutations of the expression.
+ */
+ if (foreignrel->relid == leftvar->varno &&
+ fkrel->relid == rightvar->varno &&
+ fkinfo->confkeys[i] == leftvar->varattno &&
+ fkinfo->conkeys[i] == rightvar->varattno)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ else if (foreignrel->relid == rightvar->varno &&
+ fkrel->relid == leftvar->varno &&
+ fkinfo->confkeys[i] == rightvar->varattno &&
+ fkinfo->conkeys[i] == leftvar->varattno)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ }
+ }
+ }
+
+ /*
+ * We only return the matches if we found a match for every column in
+ * the foreign key.
+ */
+ if (bms_num_members(fkmatches) == nkeys)
+ {
+ bms_free(fkmatches);
+ return qualmatches;
+ }
+
+ bms_free(fkmatches);
+ return NULL;
+}
+
+/*
+ * find_best_foreign_key_quals
+ * Analyzes joinquals to determine if any quals match foreign keys defined
+ * on 'fkrel' which reference 'foreignrel'. We return the number of keys
+ * of the best matching foreign key. We assume the best matching foreign
+ * key is the one with the most keys, not the most quals matching quals,
+ * as quals could be duplicated. We also set 'joinqualsbitmap' bits to
+ * mark which quals in 'joinquals' were matched. Zero is returned if no
+ * match is found. In this case the value of 'joinqualsbitmap' will be set
+ * to NULL. Partial foreign key matches are currently ignored.
+ */
+static int
+find_best_foreign_key_quals(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals,
+ Bitmapset **joinqualsbitmap)
+{
+ Bitmapset *qualbestmatch;
+ ListCell *lc;
+ int bestmatchnkeys;
+
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ {
+ *joinqualsbitmap = NULL;
+ return 0;
+ }
+
+ qualbestmatch = NULL;
+ bestmatchnkeys = 0;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualsmatched;
+
+ /*
+ * We make no attempt in checking that this foreign key actually
+ * references 'foreignrel', the reasoning here is that we may be able
+ * to match the foreign key to an eclass member Var of a RestrictInfo
+ * that's in qualslist, this Var may belong to some other relation.
+ */
+ qualsmatched = quals_match_foreign_key(root, fkinfo, fkrel, foreignrel,
+ joinquals);
+
+ /* Did we get a match? And is that match better than a previous one? */
+ if (qualsmatched != NULL && fkinfo->nkeys > bestmatchnkeys)
+ {
+ /* save the new best match */
+ bms_free(qualbestmatch);
+ qualbestmatch = qualsmatched;
+ bestmatchnkeys = fkinfo->nkeys;
+ }
+ }
+
+ /*
+ * If no match was found, then make one last ditch attempt to find a match
+ * by looking at foreign keys for other rels that we may exist in one of
+ * the eclasses which the joinquals were built from.
+ *
+ * XXX Perhaps we should actually be looking for a better match using this
+ * method, even if the code above already found a match.
+ */
+ if (bestmatchnkeys == 0)
+ {
+ int fkrelid;
+ Bitmapset *otherfkrels = NULL;
+
+ /*
+ * First build a list of all rels seen in eclasses that joinquals were
+ * build from.
+ */
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+ if (rinfo->parent_ec)
+ otherfkrels = bms_add_members(otherfkrels, rinfo->parent_ec->ec_relids);
+ }
+
+ /*
+ * Remove both 'fkrel' and 'foreignrel' from the bitmap so that we're
+ * left with only the extra rels that were seen.
+ */
+ otherfkrels = bms_del_member(otherfkrels, fkrel->relid);
+ otherfkrels = bms_del_member(otherfkrels, foreignrel->relid);
+
+ if (bms_is_empty(otherfkrels))
+ return 0;
+
+ fkrelid = -1;
+ while ((fkrelid = bms_next_member(otherfkrels, fkrelid)) >= 0)
+ {
+ fkrel = find_base_rel(root, fkrelid);
+
+ /* The eclass may have some dead rels. We'll skip these. */
+ if (fkrel->reloptkind != RELOPT_BASEREL)
+ continue;
+
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualsmatched;
+
+ /*
+ * We make no attempt in checking that this foreign key
+ * actually references 'foreignrel', the reasoning here is
+ * that we may be able to match the foreign key to an eclass
+ * member Var of a RestrictInfo that's in qualslist, this Var
+ * may belong to some other relation.
+ */
+ qualsmatched = quals_match_foreign_key(root, fkinfo, fkrel,
+ foreignrel, joinquals);
+
+ /* does this match match more keys than any previous match? */
+ if (qualsmatched != NULL && fkinfo->nkeys > bestmatchnkeys)
+ {
+ bms_free(qualbestmatch);
+ qualbestmatch = qualsmatched;
+ bestmatchnkeys = fkinfo->nkeys;
+ }
+ }
+ }
+ }
+
+ *joinqualsbitmap = qualbestmatch;
+ return bestmatchnkeys;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerid;
+ int innerid;
+ Selectivity sel = 1.0;
+ Bitmapset *foundfkquals = NULL;
+
+ innerid = -1;
+ while ((innerid = bms_next_member(sjinfo->min_righthand, innerid)) >= 0)
+ {
+ RelOptInfo *innerrel = find_base_rel(root, innerid);
+
+ outerid = -1;
+ while ((outerid = bms_next_member(sjinfo->min_lefthand, outerid)) >= 0)
+ {
+ RelOptInfo *outerrel = find_base_rel(root, outerid);
+ Bitmapset *outer2inner;
+ Bitmapset *inner2outer;
+ int innermatches;
+ int outermatches;
+
+ /*
+ * check which quals are matched by a foreign key referencing the
+ * innerrel.
+ */
+ outermatches = find_best_foreign_key_quals(root, outerrel,
+ innerrel, joinquals, &outer2inner);
+
+ /* do the same, but with relations swapped */
+ innermatches = find_best_foreign_key_quals(root, innerrel,
+ outerrel, joinquals, &inner2outer);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outermatches != 0 || innermatches != 0)
+ {
+ double referenced_tuples;
+ bool overlap;
+
+ /* either could be zero, but not both. */
+ if (outermatches < innermatches)
+ {
+ overlap = bms_overlap(foundfkquals, inner2outer);
+
+ foundfkquals = bms_add_members(foundfkquals, inner2outer);
+ referenced_tuples = Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ overlap = bms_overlap(foundfkquals, outer2inner);
+
+ foundfkquals = bms_add_members(foundfkquals, outer2inner);
+ referenced_tuples = Max(innerrel->tuples, 1.0);
+ }
+
+ /*
+ * XXX should we ignore these overlapping matches?
+ * Or perhaps take the Max() or Min()?
+ */
+ if (overlap)
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = Min(sel,Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0));
+ else
+ sel = Min(sel, 1.0 / referenced_tuples);
+ }
+ else
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel *= Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0);
+ else
+ sel *= 1.0 / referenced_tuples;
+ }
+ }
+ }
+ }
+
+ /*
+ * If any non matched quals exist then we build a list of the non-matches
+ * and use clauselist_selectivity() to estimate the selectivity of these.
+ */
+ if (bms_num_members(foundfkquals) < list_length(joinquals))
+ {
+ ListCell *lc;
+ int lstidx = 0;
+ List *nonfkeyclauses = NIL;
+
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, foundfkquals))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ sel *= clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+
+ return sel;
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3777,11 +4176,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3794,11 +4193,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 9442e5f..dbe6038 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -40,6 +41,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -93,6 +95,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -140,7 +145,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -380,6 +384,77 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
rel->indexlist = indexinfos;
+
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+
+ rel->fkeylist = fkinfos;
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 9c3d096..3ae9022 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3923,6 +3923,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4891,6 +4958,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 274480e..5c40b83 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -221,6 +221,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 79bed33..8ce35e7 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -472,6 +472,7 @@ typedef struct RelOptInfo
Relids lateral_relids; /* minimum parameterization of rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -566,6 +567,20 @@ typedef struct IndexOptInfo
bool amhasgetbitmap; /* does AM have amgetbitmap interface? */
} IndexOptInfo;
+/* TODO add info*/
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid;
+ Oid confrelid;
+
+ int nkeys;
+ int *conkeys;
+ int *confkeys;
+ Oid *conpfeqop;
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 87123a5..da1fd58 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -73,6 +73,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8a55a09..c56cf8a 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -79,6 +79,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -112,6 +113,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 6953281..8878478 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
On Wed, Sep 30, 2015 at 10:12 AM, David Rowley
<david.rowley@2ndquadrant.com> wrote:
On 29 September 2015 at 01:59, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:Hi,
On 09/27/2015 02:00 PM, David Rowley wrote:
I've been working on this again. I've put back the code that you wrote
for the looping over each combination of relations from either side of
the join.I've also added some code to get around the problem with eclass joins
and the RestrictInfo having some alternative Vars that don't belong to
the foreign key. Basically I'm just checking if the RestrictInfo has a
parent_ec, and if it does just loop over the members to try and find the
Vars that belong to the foreign key. I've tested it with the following,
and it seems to work:I didn't have time to look into the code yet, but this seems like an
interesting idea.create table a as select i as a_id1, i as a_id2, i as dummy1 from
generate_series(0,999) s(i);
alter table a add unique (a_id1, a_id2);
create table b as select i as b_id1, i as b_id2 from
generate_series(0,332) s(i);analyze a;
analyze b;alter table b add foreign key (b_id1, b_id2) references a (a_id1, a_id2);
explain analyze select * from a inner join b on a.dummy1 = b.b_id1 and
a.a_id2 = b.b_id2 where a.a_id1 = a.dummy1;QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Hash Join (cost=18.57..26.41 rows=2 width=20) (actual
time=0.775..1.046 rows=333 loops=1)
Hash Cond: ((b.b_id1 = a.dummy1) AND (b.b_id2 = a.a_id2))
-> Seq Scan on b (cost=0.00..5.33 rows=333 width=8) (actual
time=0.013..0.046 rows=333 loops=1)
-> Hash (cost=18.50..18.50 rows=5 width=12) (actual
time=0.737..0.737 rows=1000 loops=1)
Buckets: 1024 Batches: 1 Memory Usage: 51kB
-> Seq Scan on a (cost=0.00..18.50 rows=5 width=12) (actual
time=0.014..0.389 rows=1000 loops=1)
Filter: (dummy1 = a_id1)The non-patched version estimates 1 row. The patched estimates 2 rows,
but that's due to the bad estimate on dummy1 = a_id1.The 2 comes from ceil(5 * 0.333).
Perhaps you have a better test case to for this?
I think the additional WHERE clause is needlessly confusing. I've been
able to come up with an example - pretty much a normalized with a "main"
table and auxiliary tables (referencing the main one using FK) with
additional info. So not unlikely to happen in practice (except maybe for the
multi-column foreign key bit).CREATE TABLE f (id1 INT, id2 INT, PRIMARY KEY (id1, id2));
CREATE TABLE d1 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));
CREATE TABLE d2 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));INSERT INTO f SELECT i, i FROM generate_series(1,1000000) s(i);
INSERT INTO d1 SELECT i, i FROM generate_series(1,100000) s(i);
INSERT INTO d2 SELECT i, i FROM generate_series(1,300000) s(i);now, both pair-wise joins (f JOIN d1) and (f JOIN d2) are estimated
perfectly accurately, but as soon as the query involves both of them, this
happens:SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND f.id2 = d1.id2)
JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);QUERY PLAN
-------------------------------------------------------------------------
Nested Loop (cost=3334.43..12647.57 rows=30000 width=24)
(actual time=221.086..1767.206 rows=100000 loops=1)
Join Filter: ((d1.id1 = f.id1) AND (d1.id2 = f.id2))
-> Hash Join (cost=3334.00..12647.01 rows=1 width=16)
(actual time=221.058..939.482 rows=100000 loops=1)
Hash Cond: ((d2.id1 = d1.id1) AND (d2.id2 = d1.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8)
(actual time=0.038..263.356 rows=300000 loops=1)
-> Hash (cost=1443.00..1443.00 rows=100000 width=8)
(actual time=220.721..220.721 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 2982kB
-> Seq Scan on d1 (cost=0.00..1443.00 rows=100000 ...)
(actual time=0.033..101.547 rows=100000 loops=1)
-> Index Only Scan using f_pkey on f (cost=0.42..0.54 rows=1 ...)
(actual time=0.004..0.004 rows=1 loops=100000)
Index Cond: ((id1 = d2.id1) AND (id2 = d2.id2))
Heap Fetches: 100000Clearly, the inner join (d1 JOIN d2) is poorly estimated (1 vs. 100000). I
assume that's only because we find FK only on the second join with f.So it seems like s a clear improvement, both compared to master and the
previous versions of the patch.I've been experimenting with this example. Of course, the reason why we get
the 1 row estimate on the join between d1 and d2 is that there's no foreign
key between those two relations.The attached patch changes things so that the foreign key matching code is
better able to see foreign keys "hidden" behind eclasses. So it does now in
fact detect a foreign key on d2 referencing d1, by looking for Vars foreign
keys which have Vars in the same eclasses as the joinquals are built from.
This has improved the resultpostgres=# EXPLAIN ANALYZE SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND
f.id2 = d1.id2) JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);
QUERY
PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
Hash Join (cost=16655.94..26066.95 rows=30000 width=24) (actual
time=267.322..468.383 rows=100000 loops=1)
Hash Cond: ((d2.id1 = f.id1) AND (d2.id2 = f.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8) (actual
time=0.019..31.396 rows=300000 loops=1)
-> Hash (cost=14666.94..14666.94 rows=100000 width=16) (actual
time=266.263..266.263 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 3373kB
-> Merge Join (cost=9748.32..14666.94 rows=100000 width=16)
(actual time=104.494..224.908 rows=100000 loops=1)
Merge Cond: ((f.id1 = d1.id1) AND (f.id2 = d1.id2))
-> Index Only Scan using f_pkey on f (cost=0.42..36214.93
rows=1000000 width=8) (actual time=0.045..35.758 rows=100001 loops=1)
Heap Fetches: 100001
-> Sort (cost=9747.82..9997.82 rows=100000 width=8) (actual
time=104.440..122.401 rows=100000 loops=1)
Sort Key: d1.id1, d1.id2
Sort Method: external sort Disk: 2152kB
-> Seq Scan on d1 (cost=0.00..1443.00 rows=100000
width=8) (actual time=0.019..9.443 rows=100000 loops=1)The problem is that the code I added is sometimes a bit too optimistic at
finding a suitable foreign key. When performing estimates for the join
between (f,d1) <-> (d2), since the code loops over each relation making up
the set of relations at either side of the join, we find a foreign key on
'f' which references d2, this one actually exists. It then goes on and also
finds a foreign key for (d1) references (d2), of course this one does not
exists and it's only could due to the eclasses. The problem here is, which
one do we use? If we multiply the selectivity for each of these foreign keys
then we'd end up with a selectivty = (1.0 / 1000000) * (1.0 / 300000), which
is a massive underestimation. Perhaps doing this would be perfectly valid if
the actual foreign key being around was not the same one as the last one,
but this seems wrong when we match to the same foreign key in both
instances.I've gone though a few variations on ways to handle this and I'm a bit stuck
on what's the best way.In the attached I've coded it to take the Min() selectivity for when the
same quals are matched more than once. I know this is not correct, but since
it seems impossible to obtain an exact estimate in this case, we'd need to
decide on some logic which does well in the average case.
Is there still an interest for this patch? The last message of this
thread has added a new version of the patch but the patch was still in
"Waiting on author" state for a couple of months. Just guessing that
the status was incorrect, I have moved it to next CF.
--
Michael
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 12/24/2015 03:45 AM, Michael Paquier wrote:
On Wed, Sep 30, 2015 at 10:12 AM, David Rowley
...
In the attached I've coded it to take the Min() selectivity for when the
same quals are matched more than once. I know this is not correct, but since
it seems impossible to obtain an exact estimate in this case, we'd need to
decide on some logic which does well in the average case.Is there still an interest for this patch? The last message of this
thread has added a new version of the patch but the patch was still in
"Waiting on author" state for a couple of months. Just guessing that
the status was incorrect, I have moved it to next CF.
Yes, I still think the patch is useful. Thanks for moving it to the next
commitfest and sorry for not updating the status.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 24 December 2015 at 16:32, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
On 12/24/2015 03:45 AM, Michael Paquier wrote:
On Wed, Sep 30, 2015 at 10:12 AM, David Rowley
...
In the attached I've coded it to take the Min() selectivity for when the
same quals are matched more than once. I know this is not correct, but
since
it seems impossible to obtain an exact estimate in this case, we'd need
to
decide on some logic which does well in the average case.Is there still an interest for this patch? The last message of this
thread has added a new version of the patch but the patch was still in
"Waiting on author" state for a couple of months. Just guessing that
the status was incorrect, I have moved it to next CF.Yes, I still think the patch is useful. Thanks for moving it to the next
commitfest and sorry for not updating the status.
Hi,
I'm not sure that I agree with this being set to "Needs review". The last
progress that I see made on this was me hacking at the patch to remove some
equivalence class limitations. I think the logical next step would be for
you to look at these changes and either accept or reject them. So does that
not suit "Waiting on author" better than "Needs review" ?
--
David Rowley http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Training & Services
David Rowley wrote:
I'm not sure that I agree with this being set to "Needs review". The last
progress that I see made on this was me hacking at the patch to remove some
equivalence class limitations. I think the logical next step would be for
you to look at these changes and either accept or reject them. So does that
not suit "Waiting on author" better than "Needs review" ?
Tomas, I think we need you need to submit a new version of this patch,
please. Closing it for now.
--
�lvaro Herrera http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Hi,
On 09/30/2015 03:12 AM, David Rowley wrote:
...
CREATE TABLE f (id1 INT, id2 INT, PRIMARY KEY (id1, id2));
CREATE TABLE d1 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));
CREATE TABLE d2 (id1 INT, id2 INT, FOREIGN KEY (id1, id2) REFERENCES
f(id1, id2));INSERT INTO f SELECT i, i FROM generate_series(1,1000000) s(i);
INSERT INTO d1 SELECT i, i FROM generate_series(1,100000) s(i);
INSERT INTO d2 SELECT i, i FROM generate_series(1,300000) s(i);now, both pair-wise joins (f JOIN d1) and (f JOIN d2) are estimated
perfectly accurately, but as soon as the query involves both of
them, this happens:SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND f.id2 = d1.id2)
JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);QUERY PLAN
-------------------------------------------------------------------------
Nested Loop (cost=3334.43..12647.57 rows=30000 width=24)
(actual time=221.086..1767.206 rows=100000 loops=1)
Join Filter: ((d1.id1 = f.id1) AND (d1.id2 = f.id2))
-> Hash Join (cost=3334.00..12647.01 rows=1 width=16)
(actual time=221.058..939.482 rows=100000 loops=1)
Hash Cond: ((d2.id1 = d1.id1) AND (d2.id2 = d1.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8)
(actual time=0.038..263.356 rows=300000 loops=1)
-> Hash (cost=1443.00..1443.00 rows=100000 width=8)
(actual time=220.721..220.721 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 2982kB
-> Seq Scan on d1 (cost=0.00..1443.00 rows=100000 ...)
(actual time=0.033..101.547 rows=100000 loops=1)
-> Index Only Scan using f_pkey on f (cost=0.42..0.54 rows=1 ...)
(actual time=0.004..0.004 rows=1 loops=100000)
Index Cond: ((id1 = d2.id1) AND (id2 = d2.id2))
Heap Fetches: 100000Clearly, the inner join (d1 JOIN d2) is poorly estimated (1 vs.
100000). I assume that's only because we find FK only on the second
join with f.So it seems like s a clear improvement, both compared to master and
the previous versions of the patch.I've been experimenting with this example. Of course, the reason why we
get the 1 row estimate on the join between d1 and d2 is that there's no
foreign key between those two relations.The attached patch changes things so that the foreign key matching code
is better able to see foreign keys "hidden" behind eclasses. So it does
now in fact detect a foreign key on d2 referencing d1, by looking for
Vars foreign keys which have Vars in the same eclasses as the joinquals
are built from. This has improved the resultpostgres=# EXPLAIN ANALYZE SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1
AND f.id2 = d1.id2) JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
Hash Join (cost=16655.94..26066.95 rows=30000 width=24) (actual
time=267.322..468.383 rows=100000 loops=1)
Hash Cond: ((d2.id1 = f.id1) AND (d2.id2 = f.id2))
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8) (actual
time=0.019..31.396 rows=300000 loops=1)
-> Hash (cost=14666.94..14666.94 rows=100000 width=16) (actual
time=266.263..266.263 rows=100000 loops=1)
Buckets: 131072 Batches: 2 Memory Usage: 3373kB
-> Merge Join (cost=9748.32..14666.94 rows=100000 width=16)
(actual time=104.494..224.908 rows=100000 loops=1)
Merge Cond: ((f.id1 = d1.id1) AND (f.id2 = d1.id2))
-> Index Only Scan using f_pkey on f
(cost=0.42..36214.93 rows=1000000 width=8) (actual time=0.045..35.758
rows=100001 loops=1)
Heap Fetches: 100001
-> Sort (cost=9747.82..9997.82 rows=100000 width=8)
(actual time=104.440..122.401 rows=100000 loops=1)
Sort Key: d1.id1, d1.id2
Sort Method: external sort Disk: 2152kB
-> Seq Scan on d1 (cost=0.00..1443.00
rows=100000 width=8) (actual time=0.019..9.443 rows=100000 loops=1)The problem is that the code I added is sometimes a bit too optimistic
at finding a suitable foreign key. When performing estimates for the
join between (f,d1) <-> (d2), since the code loops over each relation
making up the set of relations at either side of the join, we find a
foreign key on 'f' which references d2, this one actually exists. It
then goes on and also finds a foreign key for (d1) references (d2), of
course this one does not exists and it's only could due to the eclasses.
The problem here is, which one do we use? If we multiply the selectivity
for each of these foreign keys then we'd end up with a selectivty = (1.0
/ 1000000) * (1.0 / 300000), which is a massive underestimation. Perhaps
doing this would be perfectly valid if the actual foreign key being
around was not the same one as the last one, but this seems wrong when
we match to the same foreign key in both instances.I've gone though a few variations on ways to handle this and I'm a bit
stuck on what's the best way.In the attached I've coded it to take the Min() selectivity for when the
same quals are matched more than once. I know this is not correct, but
since it seems impossible to obtain an exact estimate in this case, we'd
need to decide on some logic which does well in the average case.
I don't think we should derive foreign keys like this. The basis for
using foreign keys to improve estimates is that the foreign keys are
supposed to provide guarantees of existence, but that's clearly not the
case here - there's no foreign key between the two tables that get
joined first, and the FK you derive this way guarantees nothing.
For example the tables might refer different subsets of the "f" table,
e.g. d1 might reference odd rows while d2 even rows. That kinda breaks
the assumption of containment, but well - that's exactly what FK
constraints are supposed to guarantee (and what we use to improve the
estimates).
The problem with estimating cardinality of the d1:d2 join is purely in
our inability to estimate the cardinality of the pair of columns used in
the join condition. The planner sees the conditions independently,
estimates the selectivity as 1/ndistinct for the column and then
multiplies that together. Sadly, in this case ndistinct is equal to
cardinality of each of the tables, thus we get extreme under-estimate.
Consider a simplified example:
CREATE TABLE d1 (id1 INT, id2 INT);
CREATE TABLE d2 (id1 INT, id2 INT);
INSERT INTO d1 SELECT i/100, i%100 FROM generate_series(0,9999) s(i);
INSERT INTO d2 SELECT i/548, i%548 FROM generate_series(0,299999) s(i);
In this case the data are constructed in a way that the product of
column cardinalities is equal to table cardinality.
d1: 100 x 100 = 10.000
d2: 548 x 548 = 300.000 (about)
QUERY PLAN
------------------------------------------------------------------------
Hash Join (cost=10000.00..30046.69 rows=9969 width=8)
(actual time=278.989..306.935 rows=10000 loops=1)
Hash Cond: ((d1.id1 = d2.id1) AND (d1.id2 = d2.id2))
-> Seq Scan on d1 (cost=0.00..145.00 rows=10000 width=8)
(actual time=0.031..4.202 rows=10000 loops=1)
-> Hash (cost=4328.00..4328.00 rows=300000 width=8)
(actual time=278.717..278.717 rows=300000 loops=1)
Buckets: 131072 Batches: 4 Memory Usage: 3947kB
-> Seq Scan on d2 (cost=0.00..4328.00 rows=300000 width=8)
(actual time=0.020..129.025 rows=300000 loops=1)
Planning time: 0.556 ms
Execution time: 311.037 ms
(8 rows)
So fixing the cardinality estimate for (id1,id2) actually fixes the
estimate, but that's a task for the multivariate stats patch, not for
this one.
The FK improves the ndistinct estimate implicitly as it guarantees the
cardinality of one side is exactly the cardinality of the table (thanks
to referencing a primary key). Maybe we could use the existence of
unique constraints in other cases.
Overall, I still believe the FK patch is a clear improvement of the
current status - while it's true it does not improve all possible cases
and there's a room for additional improvements (like handling multiple
candidate FK constraints), it should not make existing estimates worse.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Hi Thomas,
On 2/24/16 11:21 AM, Tomas Vondra wrote:
Overall, I still believe the FK patch is a clear improvement of the
current status - while it's true it does not improve all possible cases
and there's a room for additional improvements (like handling multiple
candidate FK constraints), it should not make existing estimates worse.
The latest version of this patch does not apply:
$ git apply ../other/0001-estimation-with-fkeys-v2.patch
../other/0001-estimation-with-fkeys-v2.patch:748: trailing whitespace.
error: patch failed: src/backend/optimizer/util/plancat.c:27
error: src/backend/optimizer/util/plancat.c: patch does not apply
error: patch failed: src/include/nodes/relation.h:468
error: src/include/nodes/relation.h: patch does not apply
David's most recent version also does not apply:
$ git apply ../other/estimation-with-fkeys-v2_davidv4.patch
../other/estimation-with-fkeys-v2_davidv4.patch:517: trailing whitespace.
error: patch failed: src/backend/optimizer/util/plancat.c:27
error: src/backend/optimizer/util/plancat.c: patch does not apply
error: patch failed: src/include/nodes/relation.h:472
error: src/include/nodes/relation.h: patch does not apply
I don't think it would be clear to any reviewer which patch to apply
even if they were working. I'm marking this "waiting for author".
Thanks,
--
-David
david@pgmasters.net
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Hi,
On 03/14/2016 02:12 PM, David Steele wrote:
Hi Thomas,
...
I don't think it would be clear to any reviewer which patch to apply
even if they were working. I'm marking this "waiting for author".
Yeah. Rebasing the patches to current master was simple enough (there
was just a simple #include conflict), but figuring out which of the
patches is review-worthy was definitely difficult.
I do believe David's last patch is the best step forward, so I've
rebased it, and made some basic aesthetic fixes (adding or rewording
comments on a few places, etc.)
The one important code change is that I've removed the piece of code
from find_best_foreign_key_quals that tried to be a bit too smart about
equivalence classes.
My understanding is that it tried to handle cases like this example:
CREATE TABLE f (id1 INT, id2 INT, PRIMARY KEY (id1, id2));
CREATE TABLE d1 (id1 INT, id2 INT, FOREIGN KEY (id1, id2)
REFERENCES f(id1, id2));
CREATE TABLE d2 (id1 INT, id2 INT, FOREIGN KEY (id1, id2)
REFERENCES f(id1, id2));
SELECT * FROM f JOIN d1 ON (f.id1 = d1.id1 AND f.id2 = d1.id2)
JOIN d2 ON (f.id1 = d2.id1 AND f.id2 = d2.id2);
But it did so by also deriving foreign keys between d1 and d2, which I
believe is wrong as there really is no foreign key, and thus no
guarantee of existence of a matching row.
FWIW as I explained in a message from 24/2/2015, while this is
definitely an issue worth fixing, I believe it needs to be done in some
other way, not by foreign keys.
Attached is v3 of the patch, and also three SQL scripts demonstrating
the impact of the patch on simple examples.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Attachments:
estimation-with-fkeys-v3.patchtext/x-patch; name=estimation-with-fkeys-v3.patchDownload
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index eb0fc1e..3d38384 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -2153,6 +2153,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3603,6 +3613,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 5350329..4399a9f 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3870,6 +3870,347 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * quals_match_foreign_key
+ * Determines if the foreign key is matched by joinquals.
+ *
+ * Checks that there are conditions on all columns of the foreign key, matching
+ * the operator used by the foreign key etc. If such complete match is found,
+ * the function returns bitmap identifying the matching quals (0-based).
+ *
+ * Otherwise (no match at all or incomplete match), NULL is returned.
+ */
+static Bitmapset *
+quals_match_foreign_key(PlannerInfo *root, ForeignKeyOptInfo *fkinfo,
+ RelOptInfo *fkrel, RelOptInfo *foreignrel,
+ List *joinquals)
+{
+ int i;
+ int nkeys = fkinfo->nkeys;
+ Bitmapset *qualmatches = NULL;
+ Bitmapset *fkmatches = NULL;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to generate a bitmap index which has bits set for
+ * every matching join qual.
+ */
+ for (i = 0; i < nkeys; i++)
+ {
+ ListCell *lc;
+ int quallstidx = -1;
+
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
+
+ quallstidx++;
+
+ /*
+ * Technically we don't need to, but here we skip this qual if
+ * we've matched it to part of the foreign key already. This
+ * should prove to be a useful optimization when the quals appear
+ * in the same order as the foreign key's keys. We need only bother
+ * doing this when the foreign key is made up of more than 1 set
+ * of columns, and we're not testing the first column.
+ */
+ if (i > 0 && bms_is_member(quallstidx, qualmatches))
+ continue;
+
+ /*
+ * Here since 'usefulquals' only contains bitmap indexes for quals
+ * of type "var op var" we can safely skip checking this.
+ */
+ rinfo = (RestrictInfo *) lfirst(lc);
+ clause = (OpExpr *) rinfo->clause;
+
+ /*
+ * If the operator does not match then there's little point in
+ * checking the operands
+ */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ /*
+ * For RestrictInfos built from an eclass we must consider each
+ * member of the eclass as rinfo's operands may not belong to the
+ * foreign key. For efficient tracking of which Vars we've found,
+ * since we're only tracking 2 Vars, we use a bitmask. We can
+ * safely finish searching when both of the least significant bits
+ * are set.
+ */
+ if (rinfo->parent_ec)
+ {
+ EquivalenceClass *ec = rinfo->parent_ec;
+ ListCell *lc2;
+ int foundvarmask = 0;
+
+ foreach(lc2, ec->ec_members)
+ {
+ EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
+ Var *var = (Var *) em->em_expr;
+
+ if (!IsA(var, Var))
+ continue;
+
+ if (foreignrel->relid == var->varno &&
+ fkinfo->confkeys[i] == var->varattno)
+ foundvarmask |= 1;
+
+ else if (fkrel->relid == var->varno &&
+ fkinfo->conkeys[i] == var->varattno)
+ foundvarmask |= 2;
+
+ /*
+ * Check if we've found both matches. If found we add
+ * this qual to the matched list and mark this key as
+ * matched too.
+ */
+ if (foundvarmask == 3)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ break;
+ }
+ }
+ }
+ else
+ {
+ /*
+ * In this non eclass RestrictInfo case we'll check if the left
+ * and right Vars match to this part of the foreign key.
+ * Remember that this could be written with the Vars in either
+ * order, so we test both permutations of the expression.
+ */
+ if ((foreignrel->relid == leftvar->varno) &&
+ (fkrel->relid == rightvar->varno) &&
+ (fkinfo->confkeys[i] == leftvar->varattno) &&
+ (fkinfo->conkeys[i] == rightvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ else if ((foreignrel->relid == rightvar->varno) &&
+ (fkrel->relid == leftvar->varno) &&
+ (fkinfo->confkeys[i] == rightvar->varattno) &&
+ (fkinfo->conkeys[i] == leftvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ }
+ }
+ }
+
+ /* can't find more matches than columns in the foreign key */
+ Assert(bms_num_members(fkmatches) <= nkeys);
+
+ /* Only return the matches if we the foreign key is matched fully. */
+ if (bms_num_members(fkmatches) == nkeys)
+ {
+ bms_free(fkmatches);
+ return qualmatches;
+ }
+
+ bms_free(fkmatches);
+ bms_free(qualmatches);
+
+ return NULL;
+}
+
+/*
+ * find_best_foreign_key_quals
+ * Finds the foreign key best matching the joinquals.
+ *
+ * Analyzes joinquals to determine if any quals match foreign keys defined the
+ * two relations (fkrel referencing foreignrel). When multiple foreign keys
+ * match, we do choose the one with the most keys as the best one. We might
+ * also choose the one matching the most quals, however we assume the quals
+ * may be duplicated.
+ *
+ * We also track which joinquals match the current foreign key, so that we can
+ * easily skip then when computing the selectivity.
+ *
+ * When no matching foreign key is found we return 0, otherwise we return the
+ * number of keys in the foreign key.
+ *
+ * Foreign keys matched only partially ( are currently ignored.
+ */
+static int
+find_best_foreign_key_quals(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals,
+ Bitmapset **joinqualsbitmap)
+{
+ Bitmapset *qualbestmatch;
+ ListCell *lc;
+ int bestmatchnkeys;
+
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ {
+ *joinqualsbitmap = NULL;
+ return 0;
+ }
+
+ qualbestmatch = NULL;
+ bestmatchnkeys = 0;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualsmatched;
+
+ /*
+ * We make no attempt in checking that this foreign key actually
+ * references 'foreignrel', the reasoning here is that we may be able
+ * to match the foreign key to an eclass member Var of a RestrictInfo
+ * that's in qualslist, this Var may belong to some other relation.
+ */
+ qualsmatched = quals_match_foreign_key(root, fkinfo, fkrel, foreignrel,
+ joinquals);
+
+ /* Did we get a match? And is that match better than a previous one? */
+ if (qualsmatched != NULL && fkinfo->nkeys > bestmatchnkeys)
+ {
+ /* save the new best match */
+ bms_free(qualbestmatch);
+ qualbestmatch = qualsmatched;
+ bestmatchnkeys = fkinfo->nkeys;
+ }
+ }
+
+ *joinqualsbitmap = qualbestmatch;
+ return bestmatchnkeys;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerid;
+ int innerid;
+ Selectivity sel = 1.0;
+ Bitmapset *foundfkquals = NULL;
+
+ innerid = -1;
+ while ((innerid = bms_next_member(sjinfo->min_righthand, innerid)) >= 0)
+ {
+ RelOptInfo *innerrel = find_base_rel(root, innerid);
+
+ outerid = -1;
+ while ((outerid = bms_next_member(sjinfo->min_lefthand, outerid)) >= 0)
+ {
+ RelOptInfo *outerrel = find_base_rel(root, outerid);
+ Bitmapset *outer2inner;
+ Bitmapset *inner2outer;
+ int innermatches;
+ int outermatches;
+
+ /*
+ * check which quals are matched by a foreign key referencing the
+ * innerrel.
+ */
+ outermatches = find_best_foreign_key_quals(root, outerrel,
+ innerrel, joinquals, &outer2inner);
+
+ /* do the same, but with relations swapped */
+ innermatches = find_best_foreign_key_quals(root, innerrel,
+ outerrel, joinquals, &inner2outer);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outermatches != 0 || innermatches != 0)
+ {
+ double referenced_tuples;
+ bool overlap;
+
+ /* either could be zero, but not both. */
+ if (outermatches < innermatches)
+ {
+ overlap = bms_overlap(foundfkquals, inner2outer);
+
+ foundfkquals = bms_add_members(foundfkquals, inner2outer);
+ referenced_tuples = Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ overlap = bms_overlap(foundfkquals, outer2inner);
+
+ foundfkquals = bms_add_members(foundfkquals, outer2inner);
+ referenced_tuples = Max(innerrel->tuples, 1.0);
+ }
+
+ /*
+ * XXX should we ignore these overlapping matches?
+ * Or perhaps take the Max() or Min()?
+ */
+ if (overlap)
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = Min(sel,Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0));
+ else
+ sel = Min(sel, 1.0 / referenced_tuples);
+ }
+ else
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel *= Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0);
+ else
+ sel *= 1.0 / referenced_tuples;
+ }
+ }
+ }
+ }
+
+ /*
+ * If any non matched quals exist then we build a list of the non-matches
+ * and use clauselist_selectivity() to estimate the selectivity of these.
+ */
+ if (bms_num_members(foundfkquals) < list_length(joinquals))
+ {
+ ListCell *lc;
+ int lstidx = 0;
+ List *nonfkeyclauses = NIL;
+
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, foundfkquals))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ sel *= clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+
+ return sel;
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3915,11 +4256,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3932,11 +4273,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index ad715bb..481911e 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -28,6 +28,7 @@
#include "catalog/dependency.h"
#include "catalog/heap.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -41,6 +42,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -94,6 +96,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -141,7 +146,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -387,6 +391,77 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
rel->indexlist = indexinfos;
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+
+ rel->fkeylist = fkinfos;
+
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
{
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 130c06d..9390235 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -3957,6 +3957,73 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeyvalid)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ relation->rd_fkeyvalid = true;
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4920,6 +4987,8 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
+ rel->rd_fkeyvalid = false;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index fad9988..18f42b3 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -223,6 +223,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 641728b..e88e9a2 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -539,6 +539,7 @@ typedef struct RelOptInfo
List *lateral_vars; /* LATERAL Vars and PHVs referenced by rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -634,6 +635,27 @@ typedef struct IndexOptInfo
void (*amcostestimate) (); /* AM's cost estimator */
} IndexOptInfo;
+/*
+ * ForeignKeyOptInfo
+ * Per-foreign-key information for planning/optimization
+ *
+ * Only includes columns from pg_constraint related to foreign keys.
+ *
+ * conkeys[], confkeys[] and conpfeqop[] each have nkeys entries.
+ */
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid; /* relation constrained by the foreign key */
+ Oid confrelid; /* relation referenced by the foreign key */
+
+ int nkeys; /* number of columns in the foreign key */
+ int *conkeys; /* attnums of columns in the constrained table */
+ int *confkeys; /* attnums of columns in the referenced table */
+ Oid *conpfeqop; /* OIDs of equality operators used by the FK */
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 2fccc3a..f0840e5 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -76,6 +76,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index f2bebf2..f1fe4dc 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -61,6 +61,7 @@ typedef struct RelationData
bool rd_isvalid; /* relcache entry is valid */
char rd_indexvalid; /* state of rd_indexlist: 0 = not valid, 1 =
* valid, 2 = temporarily forced */
+ bool rd_fkeyvalid; /* state of rd_fkeylist: 0 = not valid, 1 = valid */
/*
* rd_createSubid is the ID of the highest subtransaction the rel has
@@ -94,6 +95,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 1b48304..7f07c26 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
Hi Simon,
On 3/14/16 3:42 PM, Tomas Vondra wrote:
Attached is v3 of the patch, and also three SQL scripts demonstrating
the impact of the patch on simple examples.
Do you know when you'll have a chance to review Tomas' latest patch?
Thanks,
--
-David
david@pgmasters.net
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 14 March 2016 at 19:42, Tomas Vondra <tomas.vondra@2ndquadrant.com>
wrote:
Hi,
On 03/14/2016 02:12 PM, David Steele wrote:
Hi Thomas,
...
I don't think it would be clear to any reviewer which patch to apply
even if they were working. I'm marking this "waiting for author".Yeah. Rebasing the patches to current master was simple enough (there was
just a simple #include conflict), but figuring out which of the patches is
review-worthy was definitely difficult.I do believe David's last patch is the best step forward, so I've rebased
it, and made some basic aesthetic fixes (adding or rewording comments on a
few places, etc.)
I'd like to split this into 2 patches
1) Add FK info to relcache
2) use FK info in planner
Would the credit for this be 1) Tomas, 2) Tomas + David ?
I'd be inclined to see a little more explanatory docs on this.
Have we done any tests on planning overhead for cases where multiple FKs
exist?
--
Simon Riggs http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On 04/03/2016 10:06 PM, Simon Riggs wrote:
On 14 March 2016 at 19:42, Tomas Vondra <tomas.vondra@2ndquadrant.com
<mailto:tomas.vondra@2ndquadrant.com>> wrote:
...
I'd like to split this into 2 patches
1) Add FK info to relcache
2) use FK info in plannerWould the credit for this be 1) Tomas, 2) Tomas + David ?
I could split the patch like that, but I don't quite see the point. The
two parts will not overlap at all, so not making reviews any simpler. So
the only reason for such split seems to be be different credits, but
would we actually commit the pieces independently? Not sure about that.
I'd be inclined to see a little more explanatory docs on this.
That's probably a good idea. Do you have any particular place for the
docs in mind?
Have we done any tests on planning overhead for cases where multiple
FKs exist?
I have done some benchmarks initially, and haven't measured any
noticeable impact. But the code changed since than, so I'll redo that
and post some results.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 3 April 2016 at 22:09, Tomas Vondra <tomas.vondra@2ndquadrant.com> wrote:
On 04/03/2016 10:06 PM, Simon Riggs wrote:
On 14 March 2016 at 19:42, Tomas Vondra <tomas.vondra@2ndquadrant.com
<mailto:tomas.vondra@2ndquadrant.com>> wrote:...
I'd like to split this into 2 patches
1) Add FK info to relcache
2) use FK info in plannerWould the credit for this be 1) Tomas, 2) Tomas + David ?
I could split the patch like that, but I don't quite see the point. The
two parts will not overlap at all, so not making reviews any simpler. So
the only reason for such split seems to be be different credits, but would
we actually commit the pieces independently? Not sure about that.
Oh sorry. Reason for split was because adding the FK info to relcache was a
very solid addition, whereas we might imagine some churn around the planner
aspects.
I'd be inclined to see a little more explanatory docs on this.
That's probably a good idea. Do you have any particular place for the docs
in mind?
Detailed comments in the planner part of the patch. The discussion around
this patch isn't reflected enough in the patch.
Have we done any tests on planning overhead for cases where multiple
FKs exist?
I have done some benchmarks initially, and haven't measured any noticeable
impact. But the code changed since than, so I'll redo that and post some
results.
Thanks
--
Simon Riggs http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On 3 April 2016 at 22:44, Simon Riggs <simon@2ndquadrant.com> wrote:
Detailed comments in the planner part of the patch. The discussion around
this patch isn't reflected enough in the patch.
I think we should record that the planner uses the constraint, even if the
constraint is not yet valid, per DDL.
The rel cache code you're adding uses a flag called "rd_fkeyvalid" which
indicates that the relcache is correctly filled. That is confusing, since
it has nothing to do with the concept of constraint validity. We should
rename that to rd_fkeycachefilled or similar.
ISTM that the FKey info added to the rel cache would be useful for many
optimizations, hence why I think we should commit that separately, whether
or not the specific optimization for the other half of the patch is
accepted or later modified or revoked. Objections?
--
Simon Riggs http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On 2016/04/04 17:25, Simon Riggs wrote:
The rel cache code you're adding uses a flag called "rd_fkeyvalid" which
indicates that the relcache is correctly filled. That is confusing, since
it has nothing to do with the concept of constraint validity. We should
rename that to rd_fkeycachefilled or similar.
Maybe I'm missing something, but is a separate bool required at all in
this case? Wouldn't simply doing the following suffice?
/* Quick exit if we already computed the list. */
if (relation->rd_fkeylist)
return list_copy(relation->rd_fkeylist);
ISTM, rd_fkeyvalid is modeled on rd_indexvalid, where the latter serves to
convey more info than simply whether the index list is valid or not, so
the extra field is justified.
Also, it seems the patch forgot to update RelationDestroyRelation().
Thanks,
Amit
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Hi,
attached is the patch split into two parts, as proposed by Simon. 0001
just adds the stuff to relcache, 0002 actually uses it for estimation.
On 04/04/2016 12:03 PM, Amit Langote wrote:
On 2016/04/04 17:25, Simon Riggs wrote:
The rel cache code you're adding uses a flag called "rd_fkeyvalid"
which indicates that the relcache is correctly filled. That is
confusing, since it has nothing to do with the concept of
constraint validity. We should rename that to rd_fkeycachefilled or
similar.Maybe I'm missing something, but is a separate bool required at all
in this case? Wouldn't simply doing the following suffice?/* Quick exit if we already computed the list. */
if (relation->rd_fkeylist)
return list_copy(relation->rd_fkeylist);ISTM, rd_fkeyvalid is modeled on rd_indexvalid, where the latter
serves to convey more info than simply whether the index list is
valid or not, so the extra field is justified.
I think you're right. I've copied the logic for indexes, but clearly for
foreign keys we don't need this flag. I've removed it.
Also, it seems the patch forgot to update RelationDestroyRelation().
Right. Fixed.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Attachments:
0001-add-foreign-key-info-into-relcache.patchbinary/octet-stream; name=0001-add-foreign-key-info-into-relcache.patchDownload
From bb07024646068a0bd82258495496ebac61f7e763 Mon Sep 17 00:00:00 2001
From: Tomas Vondra <tomas@pgaddict.com>
Date: Thu, 7 Apr 2016 00:57:44 +0200
Subject: [PATCH 1/2] add foreign key info into relcache
---
src/backend/nodes/outfuncs.c | 13 ++++++
src/backend/optimizer/util/plancat.c | 77 +++++++++++++++++++++++++++++++++++-
src/backend/utils/cache/relcache.c | 68 +++++++++++++++++++++++++++++++
src/include/nodes/nodes.h | 1 +
src/include/nodes/relation.h | 22 +++++++++++
src/include/utils/rel.h | 3 ++
src/include/utils/relcache.h | 1 +
7 files changed, 184 insertions(+), 1 deletion(-)
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e39c374..f783a49 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -2138,6 +2138,16 @@ _outIndexOptInfo(StringInfo str, const IndexOptInfo *node)
}
static void
+_outForeignKeyOptInfo(StringInfo str, const ForeignKeyOptInfo *node)
+{
+ WRITE_NODE_TYPE("FOREIGNKEYOPTINFO");
+
+ WRITE_OID_FIELD(conrelid);
+ WRITE_OID_FIELD(confrelid);
+ WRITE_INT_FIELD(nkeys);
+}
+
+static void
_outEquivalenceClass(StringInfo str, const EquivalenceClass *node)
{
/*
@@ -3607,6 +3617,9 @@ _outNode(StringInfo str, const void *obj)
case T_IndexOptInfo:
_outIndexOptInfo(str, obj);
break;
+ case T_ForeignKeyOptInfo:
+ _outForeignKeyOptInfo(str, obj);
+ break;
case T_EquivalenceClass:
_outEquivalenceClass(str, obj);
break;
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 5bdeac0..e5c5551 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -28,6 +28,7 @@
#include "catalog/dependency.h"
#include "catalog/heap.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_constraint.h"
#include "foreign/fdwapi.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
@@ -41,6 +42,7 @@
#include "rewrite/rewriteManip.h"
#include "storage/bufmgr.h"
#include "utils/lsyscache.h"
+#include "utils/syscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
@@ -94,6 +96,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
Relation relation;
bool hasindex;
List *indexinfos = NIL;
+ List *fkinfos = NIL;
+ List *fkoidlist;
+ ListCell *l;
/*
* We need not lock the relation since it was already locked, either by
@@ -141,7 +146,6 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
if (hasindex)
{
List *indexoidlist;
- ListCell *l;
LOCKMODE lmode;
indexoidlist = RelationGetIndexList(relation);
@@ -388,6 +392,77 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
rel->indexlist = indexinfos;
+ /* load foreign keys */
+ fkoidlist = RelationGetFKeyList(relation);
+
+ foreach(l, fkoidlist)
+ {
+ int i;
+ ArrayType *arr;
+ Datum adatum;
+ bool isnull;
+ int numkeys;
+ Oid fkoid = lfirst_oid(l);
+
+ HeapTuple htup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fkoid));
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ ForeignKeyOptInfo *info;
+
+ Assert(constraint->contype == CONSTRAINT_FOREIGN);
+
+ info = makeNode(ForeignKeyOptInfo);
+
+ info->conrelid = constraint->conrelid;
+ info->confrelid = constraint->confrelid;
+
+ /* conkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->conkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* confkey */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_confkey, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->confkeys = (int*)palloc0(numkeys * sizeof(int));
+
+ for (i = 0; i < numkeys; i++)
+ info->confkeys[i] = ((int16 *) ARR_DATA_PTR(arr))[i];
+
+ /* conpfeqop */
+ adatum = SysCacheGetAttr(CONSTROID, htup,
+ Anum_pg_constraint_conpfeqop, &isnull);
+ Assert(!isnull);
+
+ arr = DatumGetArrayTypeP(adatum);
+ numkeys = ARR_DIMS(arr)[0];
+ info->conpfeqop = (Oid*)palloc0(numkeys * sizeof(Oid));
+
+ for (i = 0; i < numkeys; i++)
+ info->conpfeqop[i] = ((Oid *) ARR_DATA_PTR(arr))[i];
+
+ info->nkeys = numkeys;
+
+ ReleaseSysCache(htup);
+
+ fkinfos = lcons(info, fkinfos);
+ }
+
+ list_free(fkoidlist);
+
+ rel->fkeylist = fkinfos;
+
/* Grab foreign-table info using the relcache, while we have it */
if (relation->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
{
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 130c06d..273d70e 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -2031,6 +2031,7 @@ RelationDestroyRelation(Relation relation, bool remember_tupdesc)
FreeTupleDesc(relation->rd_att);
}
list_free(relation->rd_indexlist);
+ list_free(relation->rd_fkeylist);
bms_free(relation->rd_indexattr);
bms_free(relation->rd_keyattr);
bms_free(relation->rd_idattr);
@@ -3957,6 +3958,72 @@ RelationGetIndexList(Relation relation)
}
/*
+ * RelationGetFKeyList -- get a list of foreign key oids
+ *
+ * TODO blah blah blah
+ */
+List *
+RelationGetFKeyList(Relation relation)
+{
+ Relation conrel;
+ SysScanDesc conscan;
+ ScanKeyData skey;
+ HeapTuple htup;
+ List *result;
+ List *oldlist;
+ MemoryContext oldcxt;
+
+ /* Quick exit if we already computed the list. */
+ if (relation->rd_fkeylist)
+ return list_copy(relation->rd_fkeylist);
+
+ /*
+ * We build the list we intend to return (in the caller's context) while
+ * doing the scan. After successfully completing the scan, we copy that
+ * list into the relcache entry. This avoids cache-context memory leakage
+ * if we get some sort of error partway through.
+ */
+ result = NIL;
+
+ /* Prepare to scan pg_constraint for entries having conrelid = this rel. */
+ ScanKeyInit(&skey,
+ Anum_pg_constraint_conrelid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+
+ conrel = heap_open(ConstraintRelationId, AccessShareLock);
+ conscan = systable_beginscan(conrel, ConstraintRelidIndexId, true,
+ NULL, 1, &skey);
+
+ while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+ {
+ Form_pg_constraint constraint = (Form_pg_constraint) GETSTRUCT(htup);
+
+ /* return only foreign keys */
+ if (constraint->contype != CONSTRAINT_FOREIGN)
+ continue;
+
+ /* Add index's OID to result list in the proper order */
+ result = insert_ordered_oid(result, HeapTupleGetOid(htup));
+ }
+
+ systable_endscan(conscan);
+
+ heap_close(conrel, AccessShareLock);
+
+ /* Now save a copy of the completed list in the relcache entry. */
+ oldcxt = MemoryContextSwitchTo(CacheMemoryContext);
+ oldlist = relation->rd_fkeylist;
+ relation->rd_fkeylist = list_copy(result);
+ MemoryContextSwitchTo(oldcxt);
+
+ /* Don't leak the old list, if there is one */
+ list_free(oldlist);
+
+ return result;
+}
+
+/*
* insert_ordered_oid
* Insert a new Oid into a sorted list of Oids, preserving ordering
*
@@ -4920,6 +4987,7 @@ load_relcache_init_file(bool shared)
rel->rd_indexattr = NULL;
rel->rd_keyattr = NULL;
rel->rd_idattr = NULL;
+ rel->rd_fkeylist = NIL;
rel->rd_createSubid = InvalidSubTransactionId;
rel->rd_newRelfilenodeSubid = InvalidSubTransactionId;
rel->rd_amcache = NULL;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 3f22bdb..84efa8e 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -223,6 +223,7 @@ typedef enum NodeTag
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
+ T_ForeignKeyOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 5264d3c..d430f6e 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -516,6 +516,7 @@ typedef struct RelOptInfo
List *lateral_vars; /* LATERAL Vars and PHVs referenced by rel */
Relids lateral_referencers; /* rels that reference me laterally */
List *indexlist; /* list of IndexOptInfo */
+ List *fkeylist; /* list of ForeignKeyOptInfo */
BlockNumber pages; /* size estimates derived from pg_class */
double tuples;
double allvisfrac;
@@ -621,6 +622,27 @@ typedef struct IndexOptInfo
void (*amcostestimate) (); /* AM's cost estimator */
} IndexOptInfo;
+/*
+ * ForeignKeyOptInfo
+ * Per-foreign-key information for planning/optimization
+ *
+ * Only includes columns from pg_constraint related to foreign keys.
+ *
+ * conkeys[], confkeys[] and conpfeqop[] each have nkeys entries.
+ */
+typedef struct ForeignKeyOptInfo
+{
+ NodeTag type;
+
+ Oid conrelid; /* relation constrained by the foreign key */
+ Oid confrelid; /* relation referenced by the foreign key */
+
+ int nkeys; /* number of columns in the foreign key */
+ int *conkeys; /* attnums of columns in the constrained table */
+ int *confkeys; /* attnums of columns in the referenced table */
+ Oid *conpfeqop; /* OIDs of equality operators used by the FK */
+
+} ForeignKeyOptInfo;
/*
* EquivalenceClasses
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index f2bebf2..51eb27a 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -94,6 +94,9 @@ typedef struct RelationData
Oid rd_oidindex; /* OID of unique index on OID, if any */
Oid rd_replidindex; /* OID of replica identity index, if any */
+ /* data managed by RelationGetFKList: */
+ List *rd_fkeylist; /* OIDs of foreign keys */
+
/* data managed by RelationGetIndexAttrBitmap: */
Bitmapset *rd_indexattr; /* identifies columns used in indexes */
Bitmapset *rd_keyattr; /* cols that can be ref'd by foreign keys */
diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h
index 1b48304..7f07c26 100644
--- a/src/include/utils/relcache.h
+++ b/src/include/utils/relcache.h
@@ -38,6 +38,7 @@ extern void RelationClose(Relation relation);
* Routines to compute/retrieve additional cached information
*/
extern List *RelationGetIndexList(Relation relation);
+extern List *RelationGetFKeyList(Relation relation);
extern Oid RelationGetOidIndex(Relation relation);
extern Oid RelationGetReplicaIndex(Relation relation);
extern List *RelationGetIndexExpressions(Relation relation);
--
2.5.5
0002-use-fkeys-in-join-estimation.patchbinary/octet-stream; name=0002-use-fkeys-in-join-estimation.patchDownload
From a662c85b18c126e67a07aa68c613a7555150ec02 Mon Sep 17 00:00:00 2001
From: Tomas Vondra <tomas@pgaddict.com>
Date: Thu, 7 Apr 2016 00:58:03 +0200
Subject: [PATCH 2/2] use fkeys in join estimation
---
src/backend/optimizer/path/costsize.c | 360 +++++++++++++++++++++++++++++++++-
src/include/optimizer/paths.h | 2 +
2 files changed, 352 insertions(+), 10 deletions(-)
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 70a4c27..b403558 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -3888,6 +3888,347 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * quals_match_foreign_key
+ * Determines if the foreign key is matched by joinquals.
+ *
+ * Checks that there are conditions on all columns of the foreign key, matching
+ * the operator used by the foreign key etc. If such complete match is found,
+ * the function returns bitmap identifying the matching quals (0-based).
+ *
+ * Otherwise (no match at all or incomplete match), NULL is returned.
+ */
+static Bitmapset *
+quals_match_foreign_key(PlannerInfo *root, ForeignKeyOptInfo *fkinfo,
+ RelOptInfo *fkrel, RelOptInfo *foreignrel,
+ List *joinquals)
+{
+ int i;
+ int nkeys = fkinfo->nkeys;
+ Bitmapset *qualmatches = NULL;
+ Bitmapset *fkmatches = NULL;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to generate a bitmap index which has bits set for
+ * every matching join qual.
+ */
+ for (i = 0; i < nkeys; i++)
+ {
+ ListCell *lc;
+ int quallstidx = -1;
+
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
+
+ quallstidx++;
+
+ /*
+ * Technically we don't need to, but here we skip this qual if
+ * we've matched it to part of the foreign key already. This
+ * should prove to be a useful optimization when the quals appear
+ * in the same order as the foreign key's keys. We need only bother
+ * doing this when the foreign key is made up of more than 1 set
+ * of columns, and we're not testing the first column.
+ */
+ if (i > 0 && bms_is_member(quallstidx, qualmatches))
+ continue;
+
+ /*
+ * Here since 'usefulquals' only contains bitmap indexes for quals
+ * of type "var op var" we can safely skip checking this.
+ */
+ rinfo = (RestrictInfo *) lfirst(lc);
+ clause = (OpExpr *) rinfo->clause;
+
+ /*
+ * If the operator does not match then there's little point in
+ * checking the operands
+ */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ /*
+ * For RestrictInfos built from an eclass we must consider each
+ * member of the eclass as rinfo's operands may not belong to the
+ * foreign key. For efficient tracking of which Vars we've found,
+ * since we're only tracking 2 Vars, we use a bitmask. We can
+ * safely finish searching when both of the least significant bits
+ * are set.
+ */
+ if (rinfo->parent_ec)
+ {
+ EquivalenceClass *ec = rinfo->parent_ec;
+ ListCell *lc2;
+ int foundvarmask = 0;
+
+ foreach(lc2, ec->ec_members)
+ {
+ EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
+ Var *var = (Var *) em->em_expr;
+
+ if (!IsA(var, Var))
+ continue;
+
+ if (foreignrel->relid == var->varno &&
+ fkinfo->confkeys[i] == var->varattno)
+ foundvarmask |= 1;
+
+ else if (fkrel->relid == var->varno &&
+ fkinfo->conkeys[i] == var->varattno)
+ foundvarmask |= 2;
+
+ /*
+ * Check if we've found both matches. If found we add
+ * this qual to the matched list and mark this key as
+ * matched too.
+ */
+ if (foundvarmask == 3)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ break;
+ }
+ }
+ }
+ else
+ {
+ /*
+ * In this non eclass RestrictInfo case we'll check if the left
+ * and right Vars match to this part of the foreign key.
+ * Remember that this could be written with the Vars in either
+ * order, so we test both permutations of the expression.
+ */
+ if ((foreignrel->relid == leftvar->varno) &&
+ (fkrel->relid == rightvar->varno) &&
+ (fkinfo->confkeys[i] == leftvar->varattno) &&
+ (fkinfo->conkeys[i] == rightvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ else if ((foreignrel->relid == rightvar->varno) &&
+ (fkrel->relid == leftvar->varno) &&
+ (fkinfo->confkeys[i] == rightvar->varattno) &&
+ (fkinfo->conkeys[i] == leftvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ }
+ }
+ }
+
+ /* can't find more matches than columns in the foreign key */
+ Assert(bms_num_members(fkmatches) <= nkeys);
+
+ /* Only return the matches if we the foreign key is matched fully. */
+ if (bms_num_members(fkmatches) == nkeys)
+ {
+ bms_free(fkmatches);
+ return qualmatches;
+ }
+
+ bms_free(fkmatches);
+ bms_free(qualmatches);
+
+ return NULL;
+}
+
+/*
+ * find_best_foreign_key_quals
+ * Finds the foreign key best matching the joinquals.
+ *
+ * Analyzes joinquals to determine if any quals match foreign keys defined the
+ * two relations (fkrel referencing foreignrel). When multiple foreign keys
+ * match, we do choose the one with the most keys as the best one. We might
+ * also choose the one matching the most quals, however we assume the quals
+ * may be duplicated.
+ *
+ * We also track which joinquals match the current foreign key, so that we can
+ * easily skip then when computing the selectivity.
+ *
+ * When no matching foreign key is found we return 0, otherwise we return the
+ * number of keys in the foreign key.
+ *
+ * Foreign keys matched only partially ( are currently ignored.
+ */
+static int
+find_best_foreign_key_quals(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals,
+ Bitmapset **joinqualsbitmap)
+{
+ Bitmapset *qualbestmatch;
+ ListCell *lc;
+ int bestmatchnkeys;
+
+ /* fast path out when there's no foreign keys on fkrel */
+ if (fkrel->fkeylist == NIL)
+ {
+ *joinqualsbitmap = NULL;
+ return 0;
+ }
+
+ qualbestmatch = NULL;
+ bestmatchnkeys = 0;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualsmatched;
+
+ /*
+ * We make no attempt in checking that this foreign key actually
+ * references 'foreignrel', the reasoning here is that we may be able
+ * to match the foreign key to an eclass member Var of a RestrictInfo
+ * that's in qualslist, this Var may belong to some other relation.
+ */
+ qualsmatched = quals_match_foreign_key(root, fkinfo, fkrel, foreignrel,
+ joinquals);
+
+ /* Did we get a match? And is that match better than a previous one? */
+ if (qualsmatched != NULL && fkinfo->nkeys > bestmatchnkeys)
+ {
+ /* save the new best match */
+ bms_free(qualbestmatch);
+ qualbestmatch = qualsmatched;
+ bestmatchnkeys = fkinfo->nkeys;
+ }
+ }
+
+ *joinqualsbitmap = qualbestmatch;
+ return bestmatchnkeys;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerid;
+ int innerid;
+ Selectivity sel = 1.0;
+ Bitmapset *foundfkquals = NULL;
+
+ innerid = -1;
+ while ((innerid = bms_next_member(sjinfo->min_righthand, innerid)) >= 0)
+ {
+ RelOptInfo *innerrel = find_base_rel(root, innerid);
+
+ outerid = -1;
+ while ((outerid = bms_next_member(sjinfo->min_lefthand, outerid)) >= 0)
+ {
+ RelOptInfo *outerrel = find_base_rel(root, outerid);
+ Bitmapset *outer2inner;
+ Bitmapset *inner2outer;
+ int innermatches;
+ int outermatches;
+
+ /*
+ * check which quals are matched by a foreign key referencing the
+ * innerrel.
+ */
+ outermatches = find_best_foreign_key_quals(root, outerrel,
+ innerrel, joinquals, &outer2inner);
+
+ /* do the same, but with relations swapped */
+ innermatches = find_best_foreign_key_quals(root, innerrel,
+ outerrel, joinquals, &inner2outer);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outermatches != 0 || innermatches != 0)
+ {
+ double referenced_tuples;
+ bool overlap;
+
+ /* either could be zero, but not both. */
+ if (outermatches < innermatches)
+ {
+ overlap = bms_overlap(foundfkquals, inner2outer);
+
+ foundfkquals = bms_add_members(foundfkquals, inner2outer);
+ referenced_tuples = Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ overlap = bms_overlap(foundfkquals, outer2inner);
+
+ foundfkquals = bms_add_members(foundfkquals, outer2inner);
+ referenced_tuples = Max(innerrel->tuples, 1.0);
+ }
+
+ /*
+ * XXX should we ignore these overlapping matches?
+ * Or perhaps take the Max() or Min()?
+ */
+ if (overlap)
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = Min(sel,Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0));
+ else
+ sel = Min(sel, 1.0 / referenced_tuples);
+ }
+ else
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel *= Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0);
+ else
+ sel *= 1.0 / referenced_tuples;
+ }
+ }
+ }
+ }
+
+ /*
+ * If any non matched quals exist then we build a list of the non-matches
+ * and use clauselist_selectivity() to estimate the selectivity of these.
+ */
+ if (bms_num_members(foundfkquals) < list_length(joinquals))
+ {
+ ListCell *lc;
+ int lstidx = 0;
+ List *nonfkeyclauses = NIL;
+
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, foundfkquals))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ sel *= clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+
+ return sel;
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3933,11 +4274,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3950,11 +4291,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 7ad4f02..d9a3c1f 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -76,6 +76,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
--
2.5.5
On 7 April 2016 at 00:15, Tomas Vondra <tomas.vondra@2ndquadrant.com> wrote:
Right. Fixed.
0001 committed. I added comments and a fastpath when no triggers are
present.
For 0002, I would be more comfortable adding
enable_fk_plans = on (true) | off
even if we decided to remove that parameter that before release.
--
Simon Riggs http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Hi,
On 04/07/2016 01:23 PM, Simon Riggs wrote:
On 7 April 2016 at 00:15, Tomas Vondra <tomas.vondra@2ndquadrant.com
<mailto:tomas.vondra@2ndquadrant.com>> wrote:Right. Fixed.
0001 committed. I added comments and a fastpath when no triggers are
present.For 0002, I would be more comfortable adding
enable_fk_plans = on (true) | offeven if we decided to remove that parameter that before release.
Attached is 0002 with the GUC added. I certainly believe we should think
twice before keeping the GUC in the final release - it's definitely
useful for testing etc. but I'm afraid it'd be just another tuning knob
for regular users.
regards
--
Tomas Vondra http://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Attachments:
0002-use-fkeys-in-join-estimation.patchbinary/octet-stream; name=0002-use-fkeys-in-join-estimation.patchDownload
From e7bee70ee85a8413f494719bb5f1acf8d24007c6 Mon Sep 17 00:00:00 2001
From: Tomas Vondra <tomas@pgaddict.com>
Date: Thu, 7 Apr 2016 00:58:03 +0200
Subject: [PATCH 2/2] use fkeys in join estimation
---
src/backend/optimizer/path/costsize.c | 364 +++++++++++++++++++++++++++++++++-
src/backend/utils/misc/guc.c | 9 +
src/include/optimizer/cost.h | 1 +
src/include/optimizer/paths.h | 2 +
4 files changed, 366 insertions(+), 10 deletions(-)
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 70a4c27..f1cd11b 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,7 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_fkey_estimates = true;
typedef struct
{
@@ -3888,6 +3889,350 @@ get_parameterized_joinrel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
+ * quals_match_foreign_key
+ * Determines if the foreign key is matched by joinquals.
+ *
+ * Checks that there are conditions on all columns of the foreign key, matching
+ * the operator used by the foreign key etc. If such complete match is found,
+ * the function returns bitmap identifying the matching quals (0-based).
+ *
+ * Otherwise (no match at all or incomplete match), NULL is returned.
+ */
+static Bitmapset *
+quals_match_foreign_key(PlannerInfo *root, ForeignKeyOptInfo *fkinfo,
+ RelOptInfo *fkrel, RelOptInfo *foreignrel,
+ List *joinquals)
+{
+ int i;
+ int nkeys = fkinfo->nkeys;
+ Bitmapset *qualmatches = NULL;
+ Bitmapset *fkmatches = NULL;
+
+ /*
+ * Loop over each column of the foreign key and build a bitmap index
+ * of each joinqual which matches. Note that we don't stop when we find
+ * the first match, as the expression could be duplicated in the
+ * joinquals, and we want to generate a bitmap index which has bits set for
+ * every matching join qual.
+ */
+ for (i = 0; i < nkeys; i++)
+ {
+ ListCell *lc;
+ int quallstidx = -1;
+
+ foreach(lc, joinquals)
+ {
+ RestrictInfo *rinfo;
+ OpExpr *clause;
+ Var *leftvar;
+ Var *rightvar;
+
+ quallstidx++;
+
+ /*
+ * Technically we don't need to, but here we skip this qual if
+ * we've matched it to part of the foreign key already. This
+ * should prove to be a useful optimization when the quals appear
+ * in the same order as the foreign key's keys. We need only bother
+ * doing this when the foreign key is made up of more than 1 set
+ * of columns, and we're not testing the first column.
+ */
+ if (i > 0 && bms_is_member(quallstidx, qualmatches))
+ continue;
+
+ /*
+ * Here since 'usefulquals' only contains bitmap indexes for quals
+ * of type "var op var" we can safely skip checking this.
+ */
+ rinfo = (RestrictInfo *) lfirst(lc);
+ clause = (OpExpr *) rinfo->clause;
+
+ /*
+ * If the operator does not match then there's little point in
+ * checking the operands
+ */
+ if (clause->opno != fkinfo->conpfeqop[i])
+ continue;
+
+ leftvar = (Var *) get_leftop((Expr *) clause);
+ rightvar = (Var *) get_rightop((Expr *) clause);
+
+ /* Foreign keys only support Vars, so ignore anything more complex */
+ if (!IsA(leftvar, Var) || !IsA(rightvar, Var))
+ continue;
+
+ /*
+ * For RestrictInfos built from an eclass we must consider each
+ * member of the eclass as rinfo's operands may not belong to the
+ * foreign key. For efficient tracking of which Vars we've found,
+ * since we're only tracking 2 Vars, we use a bitmask. We can
+ * safely finish searching when both of the least significant bits
+ * are set.
+ */
+ if (rinfo->parent_ec)
+ {
+ EquivalenceClass *ec = rinfo->parent_ec;
+ ListCell *lc2;
+ int foundvarmask = 0;
+
+ foreach(lc2, ec->ec_members)
+ {
+ EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
+ Var *var = (Var *) em->em_expr;
+
+ if (!IsA(var, Var))
+ continue;
+
+ if (foreignrel->relid == var->varno &&
+ fkinfo->confkeys[i] == var->varattno)
+ foundvarmask |= 1;
+
+ else if (fkrel->relid == var->varno &&
+ fkinfo->conkeys[i] == var->varattno)
+ foundvarmask |= 2;
+
+ /*
+ * Check if we've found both matches. If found we add
+ * this qual to the matched list and mark this key as
+ * matched too.
+ */
+ if (foundvarmask == 3)
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ break;
+ }
+ }
+ }
+ else
+ {
+ /*
+ * In this non eclass RestrictInfo case we'll check if the left
+ * and right Vars match to this part of the foreign key.
+ * Remember that this could be written with the Vars in either
+ * order, so we test both permutations of the expression.
+ */
+ if ((foreignrel->relid == leftvar->varno) &&
+ (fkrel->relid == rightvar->varno) &&
+ (fkinfo->confkeys[i] == leftvar->varattno) &&
+ (fkinfo->conkeys[i] == rightvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ else if ((foreignrel->relid == rightvar->varno) &&
+ (fkrel->relid == leftvar->varno) &&
+ (fkinfo->confkeys[i] == rightvar->varattno) &&
+ (fkinfo->conkeys[i] == leftvar->varattno))
+ {
+ qualmatches = bms_add_member(qualmatches, quallstidx);
+ fkmatches = bms_add_member(fkmatches, i);
+ }
+ }
+ }
+ }
+
+ /* can't find more matches than columns in the foreign key */
+ Assert(bms_num_members(fkmatches) <= nkeys);
+
+ /* Only return the matches if we the foreign key is matched fully. */
+ if (bms_num_members(fkmatches) == nkeys)
+ {
+ bms_free(fkmatches);
+ return qualmatches;
+ }
+
+ bms_free(fkmatches);
+ bms_free(qualmatches);
+
+ return NULL;
+}
+
+/*
+ * find_best_foreign_key_quals
+ * Finds the foreign key best matching the joinquals.
+ *
+ * Analyzes joinquals to determine if any quals match foreign keys defined the
+ * two relations (fkrel referencing foreignrel). When multiple foreign keys
+ * match, we do choose the one with the most keys as the best one. We might
+ * also choose the one matching the most quals, however we assume the quals
+ * may be duplicated.
+ *
+ * We also track which joinquals match the current foreign key, so that we can
+ * easily skip then when computing the selectivity.
+ *
+ * When no matching foreign key is found we return 0, otherwise we return the
+ * number of keys in the foreign key.
+ *
+ * Foreign keys matched only partially ( are currently ignored.
+ */
+static int
+find_best_foreign_key_quals(PlannerInfo *root, RelOptInfo *fkrel,
+ RelOptInfo *foreignrel, List *joinquals,
+ Bitmapset **joinqualsbitmap)
+{
+ Bitmapset *qualbestmatch;
+ ListCell *lc;
+ int bestmatchnkeys;
+
+ /*
+ * fast path out when there's no foreign keys on fkrel, or when use of
+ * foreign keys for estimation is disabled by GUC
+ */
+ if ((fkrel->fkeylist == NIL) || (!enable_fkey_estimates))
+ {
+ *joinqualsbitmap = NULL;
+ return 0;
+ }
+
+ qualbestmatch = NULL;
+ bestmatchnkeys = 0;
+
+ /* now check the matches for each foreign key defined on the fkrel */
+ foreach(lc, fkrel->fkeylist)
+ {
+ ForeignKeyOptInfo *fkinfo = (ForeignKeyOptInfo *) lfirst(lc);
+ Bitmapset *qualsmatched;
+
+ /*
+ * We make no attempt in checking that this foreign key actually
+ * references 'foreignrel', the reasoning here is that we may be able
+ * to match the foreign key to an eclass member Var of a RestrictInfo
+ * that's in qualslist, this Var may belong to some other relation.
+ */
+ qualsmatched = quals_match_foreign_key(root, fkinfo, fkrel, foreignrel,
+ joinquals);
+
+ /* Did we get a match? And is that match better than a previous one? */
+ if (qualsmatched != NULL && fkinfo->nkeys > bestmatchnkeys)
+ {
+ /* save the new best match */
+ bms_free(qualbestmatch);
+ qualbestmatch = qualsmatched;
+ bestmatchnkeys = fkinfo->nkeys;
+ }
+ }
+
+ *joinqualsbitmap = qualbestmatch;
+ return bestmatchnkeys;
+}
+
+/*
+ * clauselist_join_selectivity
+ * Estimate selectivity of join clauses either by using foreign key info
+ * or by using the regular clauselist_selectivity().
+ *
+ * Since selectivity estimates for each joinqual are multiplied together, this
+ * can cause significant underestimates on the number of join tuples in cases
+ * where there's more than 1 clause in the join condition. To help ease the
+ * pain here we make use of foreign keys, and we assume that 1 row will match
+ * when *all* of the foreign key columns are present in the join condition, any
+ * additional clauses are estimated using clauselist_selectivity().
+ */
+static Selectivity
+clauselist_join_selectivity(PlannerInfo *root, List *joinquals,
+ JoinType jointype, SpecialJoinInfo *sjinfo)
+{
+ int outerid;
+ int innerid;
+ Selectivity sel = 1.0;
+ Bitmapset *foundfkquals = NULL;
+
+ innerid = -1;
+ while ((innerid = bms_next_member(sjinfo->min_righthand, innerid)) >= 0)
+ {
+ RelOptInfo *innerrel = find_base_rel(root, innerid);
+
+ outerid = -1;
+ while ((outerid = bms_next_member(sjinfo->min_lefthand, outerid)) >= 0)
+ {
+ RelOptInfo *outerrel = find_base_rel(root, outerid);
+ Bitmapset *outer2inner;
+ Bitmapset *inner2outer;
+ int innermatches;
+ int outermatches;
+
+ /*
+ * check which quals are matched by a foreign key referencing the
+ * innerrel.
+ */
+ outermatches = find_best_foreign_key_quals(root, outerrel,
+ innerrel, joinquals, &outer2inner);
+
+ /* do the same, but with relations swapped */
+ innermatches = find_best_foreign_key_quals(root, innerrel,
+ outerrel, joinquals, &inner2outer);
+
+ /*
+ * did we find any matches at all? If so we need to see which one is
+ * the best/longest match
+ */
+ if (outermatches != 0 || innermatches != 0)
+ {
+ double referenced_tuples;
+ bool overlap;
+
+ /* either could be zero, but not both. */
+ if (outermatches < innermatches)
+ {
+ overlap = bms_overlap(foundfkquals, inner2outer);
+
+ foundfkquals = bms_add_members(foundfkquals, inner2outer);
+ referenced_tuples = Max(outerrel->tuples, 1.0);
+ }
+ else
+ {
+ overlap = bms_overlap(foundfkquals, outer2inner);
+
+ foundfkquals = bms_add_members(foundfkquals, outer2inner);
+ referenced_tuples = Max(innerrel->tuples, 1.0);
+ }
+
+ /*
+ * XXX should we ignore these overlapping matches?
+ * Or perhaps take the Max() or Min()?
+ */
+ if (overlap)
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel = Min(sel,Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0));
+ else
+ sel = Min(sel, 1.0 / referenced_tuples);
+ }
+ else
+ {
+ if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
+ sel *= Min(1.0 / (outerrel->tuples / Max(innerrel->tuples, 1.0)), 1.0);
+ else
+ sel *= 1.0 / referenced_tuples;
+ }
+ }
+ }
+ }
+
+ /*
+ * If any non matched quals exist then we build a list of the non-matches
+ * and use clauselist_selectivity() to estimate the selectivity of these.
+ */
+ if (bms_num_members(foundfkquals) < list_length(joinquals))
+ {
+ ListCell *lc;
+ int lstidx = 0;
+ List *nonfkeyclauses = NIL;
+
+ foreach (lc, joinquals)
+ {
+ if (!bms_is_member(lstidx, foundfkquals))
+ nonfkeyclauses = lappend(nonfkeyclauses, lfirst(lc));
+ lstidx++;
+ }
+ sel *= clauselist_selectivity(root, nonfkeyclauses, 0, jointype, sjinfo);
+ }
+
+ return sel;
+}
+
+/*
* calc_joinrel_size_estimate
* Workhorse for set_joinrel_size_estimates and
* get_parameterized_joinrel_size.
@@ -3933,11 +4278,11 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
/* Get the separate selectivities */
- jselec = clauselist_selectivity(root,
- joinquals,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ joinquals,
+ jointype,
+ sjinfo);
+
pselec = clauselist_selectivity(root,
pushedquals,
0,
@@ -3950,11 +4295,10 @@ calc_joinrel_size_estimate(PlannerInfo *root,
}
else
{
- jselec = clauselist_selectivity(root,
- restrictlist,
- 0,
- jointype,
- sjinfo);
+ jselec = clauselist_join_selectivity(root,
+ restrictlist,
+ jointype,
+ sjinfo);
pselec = 0.0; /* not used, keep compiler quiet */
}
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index b7afe6b..a070500 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -877,6 +877,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_fkey_estimates", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables use of foreign keys for estimating joins."),
+ NULL
+ },
+ &enable_fkey_estimates,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index d4adca6..58ac163 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -66,6 +66,7 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_fkey_estimates;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 7ad4f02..d9a3c1f 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -76,6 +76,8 @@ extern Expr *adjust_rowcompare_for_index(RowCompareExpr *clause,
int indexcol,
List **indexcolnos,
bool *var_on_left_p);
+extern bool has_matching_fkey(RelOptInfo *rel, RelOptInfo *frel, List *clauses,
+ bool reverse);
/*
* tidpath.h
--
2.5.5
On 7 April 2016 at 12:23, Simon Riggs <simon@2ndquadrant.com> wrote:
For 0002
For find_best_foreign_key_quals() how can this ever match 2 FKs with
different keys?
The fkrel references the foreignrel, which has a single PK. How can the FK
have a different number of columns to the PK?
Assuming that is possible/makes sense, I don't see why it matters whether
we take the FK with the most keys or the least keys and that isn't
documented.
This also affects your comments in clauselist_join_selectivity() about how
we handle overlapping matches from FKs in different directions. If we're
going to prove that there is a 1:1 match, why does that matter? That
section of code looks too much. I would be happy for now with dealing
correctly and simply with the common case where just one FK matches in
either direction.
Also, I see that the effects of this on outer joins are not documented.
Earlier you mention you hadn't thought of outer joins, so I need to check
whether outer joins are not handled at all, or whether we are assuming that
we can still use an estimate even if there is an outer join present.
Thoughts?
--
Simon Riggs http://www.2ndQuadrant.com/
<http://www.2ndquadrant.com/>
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services