postgres_fdw: Check PlaceHolderVars before pushing down a join.
As discovered by Andreas Seltenreich via sqlsmith, it's possible for a remote join to need to generate a target list which contains a PlaceHolderVar which would need to be evaluated on the remote server. This happens when we try to push down a join tree which contains outer joins and the nullable side of the join contains a subquery which evauates some expression which can go to NULL above the level of the join. Since the deparsing logic can't build a remote query that involves subqueries, it fails while trying to produce an SQL query that can be sent to the remote side. Detect such cases and don't try to push down the join at all. It's actually fine to push down the join if the PlaceHolderVar needs to be evaluated at the current join level. This patch makes a small change to build_tlist_to_deparse so that this case will work. Amit Langote, Ashutosh Bapat, and me.
This commit is contained in:
parent
5484c0a980
commit
131c7e70b4
4 changed files with 96 additions and 12 deletions
|
@ -731,7 +731,9 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
|
|||
* We require columns specified in foreignrel->reltarget->exprs and those
|
||||
* required for evaluating the local conditions.
|
||||
*/
|
||||
tlist = add_to_flat_tlist(tlist, foreignrel->reltarget->exprs);
|
||||
tlist = add_to_flat_tlist(tlist,
|
||||
pull_var_clause((Node *) foreignrel->reltarget->exprs,
|
||||
PVC_RECURSE_PLACEHOLDERS));
|
||||
tlist = add_to_flat_tlist(tlist,
|
||||
pull_var_clause((Node *) fpinfo->local_conds,
|
||||
PVC_RECURSE_PLACEHOLDERS));
|
||||
|
|
|
@ -2202,6 +2202,64 @@ SELECT t1.c1, t2.c1 FROM (ft5 t1 JOIN v_ft5 t2 ON (t1.c1 = t2.c1)) left join (ft
|
|||
Remote SQL: SELECT c1 FROM "S 1"."T 4"
|
||||
(27 rows)
|
||||
|
||||
-- non-Var items in targelist of the nullable rel of a join preventing
|
||||
-- push-down in some cases
|
||||
-- unable to push {ft1, ft2}
|
||||
EXPLAIN (COSTS false, VERBOSE)
|
||||
SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
|
||||
QUERY PLAN
|
||||
---------------------------------------------------------------------------------------------------------------------------
|
||||
Nested Loop Left Join
|
||||
Output: (13), ft2.c1
|
||||
Join Filter: (13 = ft2.c1)
|
||||
-> Foreign Scan on public.ft2
|
||||
Output: ft2.c1
|
||||
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
|
||||
-> Materialize
|
||||
Output: (13)
|
||||
-> Foreign Scan on public.ft1
|
||||
Output: 13
|
||||
Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
|
||||
(11 rows)
|
||||
|
||||
SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
|
||||
a | c1
|
||||
----+----
|
||||
| 10
|
||||
| 11
|
||||
| 12
|
||||
13 | 13
|
||||
| 14
|
||||
| 15
|
||||
(6 rows)
|
||||
|
||||
-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
|
||||
EXPLAIN (COSTS false, VERBOSE)
|
||||
SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
Nested Loop Left Join
|
||||
Output: ft4.c1, (13), ft1.c1, ft2.c1
|
||||
Join Filter: (ft4.c1 = ft1.c1)
|
||||
-> Foreign Scan on public.ft4
|
||||
Output: ft4.c1, ft4.c2, ft4.c3
|
||||
Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
|
||||
-> Materialize
|
||||
Output: ft1.c1, ft2.c1, (13)
|
||||
-> Foreign Scan
|
||||
Output: ft1.c1, ft2.c1, 13
|
||||
Relations: (public.ft1) INNER JOIN (public.ft2)
|
||||
Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
|
||||
(12 rows)
|
||||
|
||||
SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
|
||||
c1 | a | b | c
|
||||
----+----+----+----
|
||||
10 | | |
|
||||
12 | 13 | 12 | 12
|
||||
14 | | |
|
||||
(3 rows)
|
||||
|
||||
-- recreate the dropped user mapping for further tests
|
||||
CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
|
||||
DROP USER MAPPING FOR PUBLIC SERVER loopback;
|
||||
|
|
|
@ -3952,14 +3952,6 @@ postgresImportForeignSchema(ImportForeignSchemaStmt *stmt, Oid serverOid)
|
|||
* Assess whether the join between inner and outer relations can be pushed down
|
||||
* to the foreign server. As a side effect, save information we obtain in this
|
||||
* function to PgFdwRelationInfo passed in.
|
||||
*
|
||||
* Joins that satisfy conditions below are safe to push down.
|
||||
*
|
||||
* 1) Join type is INNER or OUTER (one of LEFT/RIGHT/FULL)
|
||||
* 2) Both outer and inner portions are safe to push-down
|
||||
* 3) All join conditions are safe to push down
|
||||
* 4) No relation has local filter (this can be relaxed for INNER JOIN, if we
|
||||
* can move unpushable clauses upwards in the join tree).
|
||||
*/
|
||||
static bool
|
||||
foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
|
||||
|
@ -4036,6 +4028,26 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
|
|||
return false;
|
||||
}
|
||||
|
||||
/*
|
||||
* deparseExplicitTargetList() isn't smart enough to handle anything other
|
||||
* than a Var. In particular, if there's some PlaceHolderVar that would
|
||||
* need to be evaluated within this join tree (because there's an upper
|
||||
* reference to a quantity that may go to NULL as a result of an outer
|
||||
* join), then we can't try to push the join down because we'll fail when
|
||||
* we get to deparseExplicitTargetList(). However, a PlaceHolderVar that
|
||||
* needs to be evaluated *at the top* of this join tree is OK, because we
|
||||
* can do that locally after fetching the results from the remote side.
|
||||
*/
|
||||
foreach(lc, root->placeholder_list)
|
||||
{
|
||||
PlaceHolderInfo *phinfo = lfirst(lc);
|
||||
Relids relids = joinrel->relids;
|
||||
|
||||
if (bms_is_subset(phinfo->ph_eval_at, relids) &&
|
||||
bms_nonempty_difference(relids, phinfo->ph_eval_at))
|
||||
return false;
|
||||
}
|
||||
|
||||
/* Save the join clauses, for later use. */
|
||||
fpinfo->joinclauses = joinclauses;
|
||||
|
||||
|
@ -4116,9 +4128,9 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
|
|||
}
|
||||
|
||||
/*
|
||||
* For an inner join, as explained above all restrictions can be treated
|
||||
* alike. Treating the pushed down conditions as join conditions allows a
|
||||
* top level full outer join to be deparsed without requiring subqueries.
|
||||
* For an inner join, all restrictions can be treated alike. Treating the
|
||||
* pushed down conditions as join conditions allows a top level full outer
|
||||
* join to be deparsed without requiring subqueries.
|
||||
*/
|
||||
if (jointype == JOIN_INNER)
|
||||
{
|
||||
|
|
|
@ -527,6 +527,18 @@ EXECUTE join_stmt;
|
|||
EXPLAIN (COSTS false, VERBOSE)
|
||||
SELECT t1.c1, t2.c1 FROM (ft5 t1 JOIN v_ft5 t2 ON (t1.c1 = t2.c1)) left join (ft5 t3 JOIN v_ft5 t4 ON (t3.c1 = t4.c1)) ON (t1.c1 = t3.c1);
|
||||
|
||||
-- non-Var items in targelist of the nullable rel of a join preventing
|
||||
-- push-down in some cases
|
||||
-- unable to push {ft1, ft2}
|
||||
EXPLAIN (COSTS false, VERBOSE)
|
||||
SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
|
||||
SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
|
||||
|
||||
-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
|
||||
EXPLAIN (COSTS false, VERBOSE)
|
||||
SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
|
||||
SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
|
||||
|
||||
-- recreate the dropped user mapping for further tests
|
||||
CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
|
||||
DROP USER MAPPING FOR PUBLIC SERVER loopback;
|
||||
|
|
Loading…
Reference in a new issue