As reported in bug #15613 from Srinivasan S A, file_fdw and postgres_fdw
neglected to mark plain baserel foreign paths as parameterized when the
relation has lateral_relids. Other FDWs have surely copied this mistake,
so rather than just patching those two modules, install a band-aid fix
in create_foreignscan_path to rectify the mistake centrally.
Although the band-aid is enough to fix the visible symptom, correct
the calls in file_fdw and postgres_fdw anyway, so that they are valid
examples for external FDWs.
Also, since the band-aid isn't enough to make this work for parameterized
foreign joins, throw an elog(ERROR) if such a case is passed to
create_foreignscan_path. This shouldn't pose much of a problem for
existing external FDWs, since it's likely they aren't trying to make such
paths anyway (though some of them may need a defense against joins with
lateral_relids, similar to the one this patch installs into postgres_fdw).
Add some assertions in relnode.c to catch future occurrences of the same
error --- in particular, as backstop against core-code mistakes like the
one fixed by commit
bdd9a99aa.
Discussion: https://postgr.es/m/15613-
092be1be9576c728@postgresql.org
* Create a ForeignPath node and add it as only possible path. We use the
* fdw_private list of the path to carry the convert_selectively option;
* it will be propagated into the fdw_private list of the Plan node.
+ *
+ * We don't support pushing join clauses into the quals of this path, but
+ * it could still have required parameterization due to LATERAL refs in
+ * its tlist.
*/
add_path(baserel, (Path *)
create_foreignscan_path(root, baserel,
startup_cost,
total_cost,
NIL, /* no pathkeys */
- NULL, /* no outer rel either */
+ baserel->lateral_relids,
NULL, /* no extra plan */
coptions));
1
(10 rows)
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'::text))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'::text))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
-- non-Var items in targetlist of the nullable rel of a join preventing
-- push-down in some cases
-- unable to push {ft1, ft2}
* baserestrict conditions we were able to send to remote, there might
* actually be an indexscan happening there). We already did all the work
* to estimate cost and size of this path.
+ *
+ * Although this path uses no join clauses, it could still have required
+ * parameterization due to LATERAL refs in its tlist.
*/
path = create_foreignscan_path(root, baserel,
NULL, /* default pathtarget */
fpinfo->startup_cost,
fpinfo->total_cost,
NIL, /* no pathkeys */
- NULL, /* no outer rel either */
+ baserel->lateral_relids,
NULL, /* no extra plan */
NIL); /* no fdw_private list */
add_path(baserel, (Path *) path);
startup_cost,
total_cost,
useful_pathkeys,
- NULL,
+ rel->lateral_relids,
sorted_epq_path,
NIL));
}
if (joinrel->fdw_private)
return;
+ /*
+ * This code does not work for joins with lateral references, since those
+ * must have parameterized paths, which we don't generate yet.
+ */
+ if (!bms_is_empty(joinrel->lateral_relids))
+ return;
+
/*
* Create unfinished PgFdwRelationInfo entry which is used to indicate
* that the join relation is already considered, so that we won't waste
startup_cost,
total_cost,
NIL, /* no pathkeys */
- NULL, /* no required_outer */
+ joinrel->lateral_relids,
epq_path,
NULL); /* no fdw_private */
SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+
-- non-Var items in targetlist of the nullable rel of a join preventing
-- push-down in some cases
-- unable to push {ft1, ft2}
{
ForeignPath *pathnode = makeNode(ForeignPath);
+ /*
+ * Since the path's required_outer should always include all the rel's
+ * lateral_relids, forcibly add those if necessary. This is a bit of a
+ * hack, but up till early 2019 the contrib FDWs failed to ensure that,
+ * and it's likely that the same error has propagated into many external
+ * FDWs. Don't risk modifying the passed-in relid set here.
+ */
+ if (rel->lateral_relids && !bms_is_subset(rel->lateral_relids,
+ required_outer))
+ required_outer = bms_union(required_outer, rel->lateral_relids);
+
+ /*
+ * Although this function is only designed to be used for scans of
+ * baserels, before v12 postgres_fdw abused it to make paths for join and
+ * upper rels. It will work for such cases as long as required_outer is
+ * empty (otherwise get_baserel_parampathinfo does the wrong thing), which
+ * fortunately is the expected case for now.
+ */
+ if (!bms_is_empty(required_outer) &&
+ !(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL))
+ elog(ERROR, "parameterized foreign joins are not supported yet");
+
pathnode->path.pathtype = T_ForeignScan;
pathnode->path.parent = rel;
pathnode->path.pathtarget = target ? target : rel->reltarget;
double rows;
ListCell *lc;
+ /* If rel has LATERAL refs, every path for it should account for them */
+ Assert(bms_is_subset(baserel->lateral_relids, required_outer));
+
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
return NULL;
double rows;
ListCell *lc;
+ /* If rel has LATERAL refs, every path for it should account for them */
+ Assert(bms_is_subset(joinrel->lateral_relids, required_outer));
+
/* Unparameterized paths have no ParamPathInfo or extra join clauses */
if (bms_is_empty(required_outer))
return NULL;
ParamPathInfo *ppi;
ListCell *lc;
+ /* If rel has LATERAL refs, every path for it should account for them */
+ Assert(bms_is_subset(appendrel->lateral_relids, required_outer));
+
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
return NULL;