Add support for deparsing semi-joins to contrib/postgres_fdw

SEMI-JOIN is deparsed as the EXISTS subquery. It references outer and inner
relations, so it should be evaluated as the condition in the upper-level WHERE
clause. The signatures of deparseFromExprForRel() and deparseRangeTblRef() are
revised so that they can add conditions to the upper level.

PgFdwRelationInfo now has a hidden_subquery_rels field, referencing the relids
used in the inner parts of semi-join.  They can't be referred to from upper
relations and should be used internally for equivalence member searches.

The planner can create semi-join, which refers to inner rel vars in its target
list. However, we deparse semi-join as an exists() subquery. So we skip the
case when the target list references to inner rel of semi-join.

Author: Alexander Pyhalov
Reviewed-by: Ashutosh Bapat, Ian Lawrence Barwick, Yuuki Fujii, Tomas Vondra
Discussion: https://postgr.es/m/c9e2a757cf3ac2333714eaf83a9cc184@postgrespro.ru
This commit is contained in:
Alexander Korotkov 2023-12-05 22:53:12 +02:00
parent 278eb13c48
commit 824dbea3e4
5 changed files with 699 additions and 83 deletions

View File

@ -180,11 +180,15 @@ static void appendConditions(List *exprs, deparse_expr_cxt *context);
static void deparseFromExprForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, bool use_alias,
Index ignore_rel, List **ignore_conds,
List **additional_conds,
List **params_list);
static void appendWhereClause(List *exprs, List *additional_conds,
deparse_expr_cxt *context);
static void deparseFromExpr(List *quals, deparse_expr_cxt *context);
static void deparseRangeTblRef(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, bool make_subquery,
Index ignore_rel, List **ignore_conds, List **params_list);
Index ignore_rel, List **ignore_conds,
List **additional_conds, List **params_list);
static void deparseAggref(Aggref *node, deparse_expr_cxt *context);
static void appendGroupByClause(List *tlist, deparse_expr_cxt *context);
static void appendOrderBySuffix(Oid sortop, Oid sortcoltype, bool nulls_first,
@ -1370,6 +1374,7 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
RelOptInfo *scanrel = context->scanrel;
List *additional_conds = NIL;
/* For upper relations, scanrel must be either a joinrel or a baserel */
Assert(!IS_UPPER_REL(context->foreignrel) ||
@ -1379,14 +1384,11 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
appendStringInfoString(buf, " FROM ");
deparseFromExprForRel(buf, context->root, scanrel,
(bms_membership(scanrel->relids) == BMS_MULTIPLE),
(Index) 0, NULL, context->params_list);
/* Construct WHERE clause */
if (quals != NIL)
{
appendStringInfoString(buf, " WHERE ");
appendConditions(quals, context);
}
(Index) 0, NULL, &additional_conds,
context->params_list);
appendWhereClause(quals, additional_conds, context);
if (additional_conds != NIL)
list_free_deep(additional_conds);
}
/*
@ -1598,6 +1600,42 @@ appendConditions(List *exprs, deparse_expr_cxt *context)
reset_transmission_modes(nestlevel);
}
/*
* Append WHERE clause, containing conditions from exprs and additional_conds,
* to context->buf.
*/
static void
appendWhereClause(List *exprs, List *additional_conds, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
bool need_and = false;
ListCell *lc;
if (exprs != NIL || additional_conds != NIL)
appendStringInfoString(buf, " WHERE ");
/*
* If there are some filters, append them.
*/
if (exprs != NIL)
{
appendConditions(exprs, context);
need_and = true;
}
/*
* If there are some EXISTS conditions, coming from SEMI-JOINS, append
* them.
*/
foreach(lc, additional_conds)
{
if (need_and)
appendStringInfoString(buf, " AND ");
appendStringInfoString(buf, (char *) lfirst(lc));
need_and = true;
}
}
/* Output join name for given join type */
const char *
get_jointype_name(JoinType jointype)
@ -1616,6 +1654,9 @@ get_jointype_name(JoinType jointype)
case JOIN_FULL:
return "FULL";
case JOIN_SEMI:
return "SEMI";
default:
/* Shouldn't come here, but protect from buggy code. */
elog(ERROR, "unsupported join type %d", jointype);
@ -1712,11 +1753,14 @@ deparseSubqueryTargetList(deparse_expr_cxt *context)
* of DELETE; it deparses the join relation as if the relation never contained
* the target relation, and creates a List of conditions to be deparsed into
* the top-level WHERE clause, which is returned to *ignore_conds.
*
* 'additional_conds' is a pointer to a list of strings to be appended to
* the WHERE clause, coming from lower-level SEMI-JOINs.
*/
static void
deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
bool use_alias, Index ignore_rel, List **ignore_conds,
List **params_list)
List **additional_conds, List **params_list)
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
@ -1728,6 +1772,8 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
RelOptInfo *innerrel = fpinfo->innerrel;
bool outerrel_is_target = false;
bool innerrel_is_target = false;
List *additional_conds_i = NIL;
List *additional_conds_o = NIL;
if (ignore_rel > 0 && bms_is_member(ignore_rel, foreignrel->relids))
{
@ -1764,7 +1810,8 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
initStringInfo(&join_sql_o);
deparseRangeTblRef(&join_sql_o, root, outerrel,
fpinfo->make_outerrel_subquery,
ignore_rel, ignore_conds, params_list);
ignore_rel, ignore_conds, &additional_conds_o,
params_list);
/*
* If inner relation is the target relation, skip deparsing it.
@ -1780,6 +1827,12 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
Assert(fpinfo->jointype == JOIN_INNER);
Assert(fpinfo->joinclauses == NIL);
appendBinaryStringInfo(buf, join_sql_o.data, join_sql_o.len);
/* Pass EXISTS conditions to upper level */
if (additional_conds_o != NIL)
{
Assert(*additional_conds == NIL);
*additional_conds = additional_conds_o;
}
return;
}
}
@ -1790,7 +1843,54 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
initStringInfo(&join_sql_i);
deparseRangeTblRef(&join_sql_i, root, innerrel,
fpinfo->make_innerrel_subquery,
ignore_rel, ignore_conds, params_list);
ignore_rel, ignore_conds, &additional_conds_i,
params_list);
/*
* SEMI-JOIN is deparsed as the EXISTS subquery. It references
* outer and inner relations, so it should be evaluated as the
* condition in the upper-level WHERE clause. We deparse the
* condition and pass it to upper level callers as an
* additional_conds list. Upper level callers are responsible for
* inserting conditions from the list where appropriate.
*/
if (fpinfo->jointype == JOIN_SEMI)
{
deparse_expr_cxt context;
StringInfoData str;
/* Construct deparsed condition from this SEMI-JOIN */
initStringInfo(&str);
appendStringInfo(&str, "EXISTS (SELECT NULL FROM %s",
join_sql_i.data);
context.buf = &str;
context.foreignrel = foreignrel;
context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
/*
* Append SEMI-JOIN clauses and EXISTS conditions from lower
* levels to the current EXISTS subquery
*/
appendWhereClause(fpinfo->joinclauses, additional_conds_i, &context);
/*
* EXISTS conditions, coming from lower join levels, have just
* been processed.
*/
if (additional_conds_i != NIL)
{
list_free_deep(additional_conds_i);
additional_conds_i = NIL;
}
/* Close parentheses for EXISTS subquery */
appendStringInfo(&str, ")");
*additional_conds = lappend(*additional_conds, str.data);
}
/*
* If outer relation is the target relation, skip deparsing it.
@ -1801,6 +1901,12 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
Assert(fpinfo->jointype == JOIN_INNER);
Assert(fpinfo->joinclauses == NIL);
appendBinaryStringInfo(buf, join_sql_i.data, join_sql_i.len);
/* Pass EXISTS conditions to the upper call */
if (additional_conds_i != NIL)
{
Assert(*additional_conds == NIL);
*additional_conds = additional_conds_i;
}
return;
}
}
@ -1809,33 +1915,65 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
Assert(!outerrel_is_target && !innerrel_is_target);
/*
* For a join relation FROM clause entry is deparsed as
*
* ((outer relation) <join type> (inner relation) ON (joinclauses))
* For semijoin FROM clause is deparsed as an outer relation. An inner
* relation and join clauses are converted to EXISTS condition and
* passed to the upper level.
*/
appendStringInfo(buf, "(%s %s JOIN %s ON ", join_sql_o.data,
get_jointype_name(fpinfo->jointype), join_sql_i.data);
/* Append join clause; (TRUE) if no join clause */
if (fpinfo->joinclauses)
if (fpinfo->jointype == JOIN_SEMI)
{
deparse_expr_cxt context;
context.buf = buf;
context.foreignrel = foreignrel;
context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
appendStringInfoChar(buf, '(');
appendConditions(fpinfo->joinclauses, &context);
appendStringInfoChar(buf, ')');
appendStringInfo(buf, "%s", join_sql_o.data);
}
else
appendStringInfoString(buf, "(TRUE)");
{
/*
* For a join relation FROM clause, entry is deparsed as
*
* ((outer relation) <join type> (inner relation) ON
* (joinclauses))
*/
appendStringInfo(buf, "(%s %s JOIN %s ON ", join_sql_o.data,
get_jointype_name(fpinfo->jointype), join_sql_i.data);
/* End the FROM clause entry. */
appendStringInfoChar(buf, ')');
/* Append join clause; (TRUE) if no join clause */
if (fpinfo->joinclauses)
{
deparse_expr_cxt context;
context.buf = buf;
context.foreignrel = foreignrel;
context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
appendStringInfoChar(buf, '(');
appendConditions(fpinfo->joinclauses, &context);
appendStringInfoChar(buf, ')');
}
else
appendStringInfoString(buf, "(TRUE)");
/* End the FROM clause entry. */
appendStringInfoChar(buf, ')');
}
/*
* Construct additional_conds to be passed to the upper caller from
* current level additional_conds and additional_conds, coming from
* inner and outer rels.
*/
if (additional_conds_o != NIL)
{
*additional_conds = list_concat(*additional_conds,
additional_conds_o);
list_free(additional_conds_o);
}
if (additional_conds_i != NIL)
{
*additional_conds = list_concat(*additional_conds,
additional_conds_i);
list_free(additional_conds_i);
}
}
else
{
@ -1863,11 +2001,13 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
/*
* Append FROM clause entry for the given relation into buf.
* Conditions from lower-level SEMI-JOINs are appended to additional_conds
* and should be added to upper level WHERE clause.
*/
static void
deparseRangeTblRef(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
bool make_subquery, Index ignore_rel, List **ignore_conds,
List **params_list)
List **additional_conds, List **params_list)
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
@ -1925,7 +2065,8 @@ deparseRangeTblRef(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
}
else
deparseFromExprForRel(buf, root, foreignrel, true, ignore_rel,
ignore_conds, params_list);
ignore_conds, additional_conds,
params_list);
}
/*
@ -2148,6 +2289,7 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
RangeTblEntry *rte = planner_rt_fetch(rtindex, root);
ListCell *lc,
*lc2;
List *additional_conds = NIL;
/* Set up context struct for recursion */
context.root = root;
@ -2189,17 +2331,17 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
{
List *ignore_conds = NIL;
appendStringInfoString(buf, " FROM ");
deparseFromExprForRel(buf, root, foreignrel, true, rtindex,
&ignore_conds, params_list);
&ignore_conds, &additional_conds, params_list);
remote_conds = list_concat(remote_conds, ignore_conds);
}
if (remote_conds)
{
appendStringInfoString(buf, " WHERE ");
appendConditions(remote_conds, &context);
}
appendWhereClause(remote_conds, additional_conds, &context);
if (additional_conds != NIL)
list_free_deep(additional_conds);
if (foreignrel->reloptkind == RELOPT_JOINREL)
deparseExplicitTargetList(returningList, true, retrieved_attrs,
@ -2255,6 +2397,7 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
List **retrieved_attrs)
{
deparse_expr_cxt context;
List *additional_conds = NIL;
/* Set up context struct for recursion */
context.root = root;
@ -2274,15 +2417,14 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
appendStringInfoString(buf, " USING ");
deparseFromExprForRel(buf, root, foreignrel, true, rtindex,
&ignore_conds, params_list);
&ignore_conds, &additional_conds, params_list);
remote_conds = list_concat(remote_conds, ignore_conds);
}
if (remote_conds)
{
appendStringInfoString(buf, " WHERE ");
appendConditions(remote_conds, &context);
}
appendWhereClause(remote_conds, additional_conds, &context);
if (additional_conds != NIL)
list_free_deep(additional_conds);
if (foreignrel->reloptkind == RELOPT_JOINREL)
deparseExplicitTargetList(returningList, true, retrieved_attrs,

View File

@ -2001,23 +2001,16 @@ SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER B
Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
(4 rows)
-- SEMI JOIN, not pushed down
-- SEMI JOIN
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
QUERY PLAN
---------------------------------------------------------------------------------------
Limit
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: t1.c1
-> Merge Semi Join
Output: t1.c1
Merge Cond: (t1.c1 = t2.c1)
-> Foreign Scan on public.ft1 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
-> Foreign Scan on public.ft2 t2
Output: t2.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
(11 rows)
Relations: (public.ft1 t1) SEMI JOIN (public.ft2 t2)
Remote SQL: SELECT r1."C 1" FROM "S 1"."T 1" r1 WHERE EXISTS (SELECT NULL FROM "S 1"."T 1" r2 WHERE ((r2."C 1" = r1."C 1"))) ORDER BY r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
(4 rows)
SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
c1
@ -4056,23 +4049,13 @@ RESET enable_sort;
-- subquery using immutable function (can be sent to remote)
PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------
Sort
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
Sort Key: t1.c1
-> Nested Loop Semi Join
Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
Join Filter: (t2.c3 = t1.c3)
-> Foreign Scan on public.ft1 t1
Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
-> Materialize
Output: t2.c3
-> Foreign Scan on public.ft2 t2
Output: t2.c3
Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
(14 rows)
Relations: (public.ft1 t1) SEMI JOIN (public.ft2 t2)
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8 FROM "S 1"."T 1" r1 WHERE ((r1."C 1" < 20)) AND EXISTS (SELECT NULL FROM "S 1"."T 1" r3 WHERE ((r3."C 1" > 10)) AND ((date(r3.c5) = '1970-01-17'::date)) AND ((r3.c3 = r1.c3))) ORDER BY r1."C 1" ASC NULLS LAST
(4 rows)
EXECUTE st3(10, 20);
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
@ -4616,6 +4599,283 @@ explain (verbose, costs off) select * from ft3 f, loct3 l
Index Cond: (l.f1 = 'foo'::text)
(12 rows)
-- ===================================================================
-- test SEMI-JOIN pushdown
-- ===================================================================
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN ft4 ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
AND EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)
ORDER BY ft2.c1;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3
Relations: ((public.ft2) INNER JOIN (public.ft4)) SEMI JOIN (public.ft5)
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, r2.c1, r2.c2, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 900)))) WHERE EXISTS (SELECT NULL FROM "S 1"."T 4" r4 WHERE ((r1.c2 = r4.c1))) ORDER BY r1."C 1" ASC NULLS LAST
(4 rows)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN ft4 ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
AND EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)
ORDER BY ft2.c1;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3
-----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
(10 rows)
-- The same query, different join order
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3
Relations: ((public.ft2) INNER JOIN (public.ft4)) SEMI JOIN (public.ft5)
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, r4.c1, r4.c2, r4.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r4 ON (((r1.c2 = r4.c1)) AND ((r1."C 1" > 900)))) WHERE EXISTS (SELECT NULL FROM "S 1"."T 4" r5 WHERE ((r4.c1 = r5.c1))) ORDER BY r1."C 1" ASC NULLS LAST
(4 rows)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3
-----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
(10 rows)
-- Left join
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 LEFT JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3
Relations: (public.ft2) LEFT JOIN ((public.ft4) SEMI JOIN (public.ft5))
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, s6.c1, s6.c2, s6.c3 FROM ("S 1"."T 1" r1 LEFT JOIN (SELECT r4.c1, r4.c2, r4.c3 FROM "S 1"."T 3" r4 WHERE EXISTS (SELECT NULL FROM "S 1"."T 4" r5 WHERE ((r4.c1 = r5.c1)))) s6(c1, c2, c3) ON (((r1.c2 = s6.c1)))) WHERE ((r1."C 1" > 900)) ORDER BY r1."C 1" ASC NULLS LAST LIMIT 10::bigint
(4 rows)
SELECT ft2.*, ft4.* FROM ft2 LEFT JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3
-----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------
901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo | | |
902 | 2 | 00902 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo | | |
903 | 3 | 00903 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo | | |
904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo | | |
905 | 5 | 00905 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo | | |
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
907 | 7 | 00907 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo | | |
908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo | | |
909 | 9 | 00909 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo | | |
910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo | | |
(10 rows)
-- Several semi-joins per upper level join
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN (SELECT * FROM ft5 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft5.c1)) ft5
ON ft2.c2 <= ft5.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3
Relations: ((((public.ft2) INNER JOIN (public.ft4)) SEMI JOIN (public.ft5)) INNER JOIN (public.ft5 ft5_1)) SEMI JOIN (public.ft4 ft4_1)
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, r6.c1, r6.c2, r6.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r6 ON (((r1.c2 = r6.c1)) AND ((r1."C 1" > 900)))) INNER JOIN "S 1"."T 4" r8 ON (((r1.c2 <= r8.c1)))) WHERE EXISTS (SELECT NULL FROM "S 1"."T 3" r9 WHERE ((r8.c1 = r9.c1))) AND EXISTS (SELECT NULL FROM "S 1"."T 4" r7 WHERE ((r6.c1 = r7.c1))) ORDER BY r1."C 1" ASC NULLS LAST LIMIT 10::bigint
(4 rows)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN (SELECT * FROM ft5 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft5.c1)) ft5
ON ft2.c2 <= ft5.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3
-----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006
(10 rows)
-- Semi-join below Semi-join
EXPLAIN (verbose, costs off)
SELECT ft2.* FROM ft2 WHERE
c1 = ANY (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2))
AND ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8
Relations: (public.ft2) SEMI JOIN ((public.ft2 ft2_1) SEMI JOIN (public.ft4))
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8 FROM "S 1"."T 1" r1 WHERE ((r1."C 1" > 900)) AND EXISTS (SELECT NULL FROM "S 1"."T 1" r3 WHERE ((r1."C 1" = r3."C 1")) AND EXISTS (SELECT NULL FROM "S 1"."T 3" r4 WHERE ((r3.c2 = r4.c2)))) ORDER BY r1."C 1" ASC NULLS LAST LIMIT 10::bigint
(4 rows)
SELECT ft2.* FROM ft2 WHERE
c1 = ANY (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2))
AND ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
-----+----+-------+------------------------------+--------------------------+----+------------+-----
903 | 3 | 00903 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
905 | 5 | 00905 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
907 | 7 | 00907 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
909 | 9 | 00909 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
913 | 3 | 00913 | Wed Jan 14 00:00:00 1970 PST | Wed Jan 14 00:00:00 1970 | 3 | 3 | foo
915 | 5 | 00915 | Fri Jan 16 00:00:00 1970 PST | Fri Jan 16 00:00:00 1970 | 5 | 5 | foo
917 | 7 | 00917 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
919 | 9 | 00919 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | 9 | foo
923 | 3 | 00923 | Sat Jan 24 00:00:00 1970 PST | Sat Jan 24 00:00:00 1970 | 3 | 3 | foo
925 | 5 | 00925 | Mon Jan 26 00:00:00 1970 PST | Mon Jan 26 00:00:00 1970 | 5 | 5 | foo
(10 rows)
-- Upper level relations shouldn't refer EXISTS() subqueries
EXPLAIN (verbose, costs off)
SELECT * FROM ft2 ftupper WHERE
EXISTS (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2) AND c1 = ftupper.c1 )
AND ftupper.c1 > 900
ORDER BY ftupper.c1 LIMIT 10;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ftupper.c1, ftupper.c2, ftupper.c3, ftupper.c4, ftupper.c5, ftupper.c6, ftupper.c7, ftupper.c8
Relations: (public.ft2 ftupper) SEMI JOIN ((public.ft2) SEMI JOIN (public.ft4))
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8 FROM "S 1"."T 1" r1 WHERE ((r1."C 1" > 900)) AND EXISTS (SELECT NULL FROM "S 1"."T 1" r2 WHERE ((r1."C 1" = r2."C 1")) AND EXISTS (SELECT NULL FROM "S 1"."T 3" r3 WHERE ((r2.c2 = r3.c2)))) ORDER BY r1."C 1" ASC NULLS LAST LIMIT 10::bigint
(4 rows)
SELECT * FROM ft2 ftupper WHERE
EXISTS (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2) AND c1 = ftupper.c1 )
AND ftupper.c1 > 900
ORDER BY ftupper.c1 LIMIT 10;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
-----+----+-------+------------------------------+--------------------------+----+------------+-----
903 | 3 | 00903 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
905 | 5 | 00905 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
907 | 7 | 00907 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
909 | 9 | 00909 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
913 | 3 | 00913 | Wed Jan 14 00:00:00 1970 PST | Wed Jan 14 00:00:00 1970 | 3 | 3 | foo
915 | 5 | 00915 | Fri Jan 16 00:00:00 1970 PST | Fri Jan 16 00:00:00 1970 | 5 | 5 | foo
917 | 7 | 00917 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
919 | 9 | 00919 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | 9 | foo
923 | 3 | 00923 | Sat Jan 24 00:00:00 1970 PST | Sat Jan 24 00:00:00 1970 | 3 | 3 | foo
925 | 5 | 00925 | Mon Jan 26 00:00:00 1970 PST | Mon Jan 26 00:00:00 1970 | 5 | 5 | foo
(10 rows)
-- EXISTS should be propogated to the highest upper inner join
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE EXISTS (
SELECT 1 FROM ft2 WHERE ft2.c2 = ft4.c2)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN
(SELECT * FROM ft2 WHERE EXISTS (
SELECT 1 FROM ft4 WHERE ft2.c2 = ft4.c2)) ft21
ON ft2.c2 = ft21.c2
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3
Relations: ((((public.ft2) INNER JOIN (public.ft4)) SEMI JOIN (public.ft2 ft2_1)) INNER JOIN (public.ft2 ft2_2)) SEMI JOIN (public.ft4 ft4_1)
Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, r6.c1, r6.c2, r6.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r6 ON (((r1.c2 = r6.c1)) AND ((r1."C 1" > 900)))) INNER JOIN "S 1"."T 1" r8 ON (((r1.c2 = r8.c2)))) WHERE EXISTS (SELECT NULL FROM "S 1"."T 3" r9 WHERE ((r1.c2 = r9.c2))) AND EXISTS (SELECT NULL FROM "S 1"."T 1" r7 WHERE ((r7.c2 = r6.c2))) ORDER BY r1."C 1" ASC NULLS LAST LIMIT 10::bigint
(4 rows)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE EXISTS (
SELECT 1 FROM ft2 WHERE ft2.c2 = ft4.c2)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN
(SELECT * FROM ft2 WHERE EXISTS (
SELECT 1 FROM ft4 WHERE ft2.c2 = ft4.c2)) ft21
ON ft2.c2 = ft21.c2
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3
----+----+----+----+----+----+----+----+----+----+----
(0 rows)
-- Can't push down semi-join with inner rel vars in targetlist
EXPLAIN (verbose, costs off)
SELECT ft1.c1 FROM ft1 JOIN ft2 on ft1.c1 = ft2.c1 WHERE
ft1.c1 IN (
SELECT ft2.c1 FROM ft2 JOIN ft4 ON ft2.c1 = ft4.c1)
ORDER BY ft1.c1 LIMIT 5;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit
Output: ft1.c1
-> Merge Semi Join
Output: ft1.c1
Merge Cond: (ft1.c1 = ft2_1.c1)
-> Foreign Scan
Output: ft1.c1, ft2.c1
Relations: (public.ft1) INNER JOIN (public.ft2)
Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1."C 1" ASC NULLS LAST
-> Foreign Scan
Output: ft2_1.c1, ft4.c1
Relations: (public.ft2 ft2_1) INNER JOIN (public.ft4)
Remote SQL: SELECT r5."C 1", r6.c1 FROM ("S 1"."T 1" r5 INNER JOIN "S 1"."T 3" r6 ON (((r5."C 1" = r6.c1)))) ORDER BY r5."C 1" ASC NULLS LAST
(13 rows)
-- ===================================================================
-- test writable foreign table stuff
-- ===================================================================

View File

@ -779,6 +779,7 @@ postgresGetForeignRelSize(PlannerInfo *root,
fpinfo->make_outerrel_subquery = false;
fpinfo->make_innerrel_subquery = false;
fpinfo->lower_subquery_rels = NULL;
fpinfo->hidden_subquery_rels = NULL;
/* Set the relation index. */
fpinfo->relation_index = baserel->relid;
}
@ -5724,6 +5725,45 @@ postgresImportForeignSchema(ImportForeignSchemaStmt *stmt, Oid serverOid)
return commands;
}
/*
* Check if reltarget is safe enough to push down semi-join. Reltarget is not
* safe, if it contains references to inner rel relids, which do not belong to
* outer rel.
*/
static bool
semijoin_target_ok(PlannerInfo *root, RelOptInfo *joinrel, RelOptInfo *outerrel, RelOptInfo *innerrel)
{
List *vars;
ListCell *lc;
bool ok = true;
Assert(joinrel->reltarget);
vars = pull_var_clause((Node *) joinrel->reltarget->exprs, PVC_INCLUDE_PLACEHOLDERS);
foreach(lc, vars)
{
Var *var = (Var *) lfirst(lc);
if (!IsA(var, Var))
continue;
if (bms_is_member(var->varno, innerrel->relids) &&
!bms_is_member(var->varno, outerrel->relids))
{
/*
* The planner can create semi-join, which refers to inner rel
* vars in its target list. However, we deparse semi-join as an
* exists() subquery, so can't handle references to inner rel in
* the target list.
*/
ok = false;
break;
}
}
return ok;
}
/*
* 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
@ -5741,12 +5781,19 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
List *joinclauses;
/*
* We support pushing down INNER, LEFT, RIGHT and FULL OUTER joins.
* Constructing queries representing SEMI and ANTI joins is hard, hence
* not considered right now.
* We support pushing down INNER, LEFT, RIGHT, FULL OUTER and SEMI joins.
* Constructing queries representing ANTI joins is hard, hence not
* considered right now.
*/
if (jointype != JOIN_INNER && jointype != JOIN_LEFT &&
jointype != JOIN_RIGHT && jointype != JOIN_FULL)
jointype != JOIN_RIGHT && jointype != JOIN_FULL &&
jointype != JOIN_SEMI)
return false;
/*
* We can't push down semi-join if its reltarget is not safe
*/
if ((jointype == JOIN_SEMI) && !semijoin_target_ok(root, joinrel, outerrel, innerrel))
return false;
/*
@ -5858,6 +5905,8 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
Assert(bms_is_subset(fpinfo_i->lower_subquery_rels, innerrel->relids));
fpinfo->lower_subquery_rels = bms_union(fpinfo_o->lower_subquery_rels,
fpinfo_i->lower_subquery_rels);
fpinfo->hidden_subquery_rels = bms_union(fpinfo_o->hidden_subquery_rels,
fpinfo_i->hidden_subquery_rels);
/*
* Pull the other remote conditions from the joining relations into join
@ -5871,6 +5920,12 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
* the joinclauses, since they need to be evaluated while constructing the
* join.
*
* For SEMI-JOIN clauses from inner relation can not be added to
* remote_conds, but should be treated as join clauses (as they are
* deparsed to EXISTS subquery, where inner relation can be referred). A
* list of relation ids, which can't be referred to from higher levels, is
* preserved as a hidden_subquery_rels list.
*
* For a FULL OUTER JOIN, the other clauses from either relation can not
* be added to the joinclauses or remote_conds, since each relation acts
* as an outer relation for the other.
@ -5901,6 +5956,16 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
fpinfo_i->remote_conds);
break;
case JOIN_SEMI:
fpinfo->joinclauses = list_concat(fpinfo->joinclauses,
fpinfo_i->remote_conds);
fpinfo->joinclauses = list_concat(fpinfo->joinclauses,
fpinfo->remote_conds);
fpinfo->remote_conds = list_copy(fpinfo_o->remote_conds);
fpinfo->hidden_subquery_rels = bms_union(fpinfo->hidden_subquery_rels,
innerrel->relids);
break;
case JOIN_FULL:
/*
@ -5943,6 +6008,24 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
fpinfo->joinclauses = fpinfo->remote_conds;
fpinfo->remote_conds = NIL;
}
else if (jointype == JOIN_LEFT || jointype == JOIN_RIGHT || jointype == JOIN_FULL)
{
/*
* Conditions, generated from semi-joins, should be evaluated before
* LEFT/RIGHT/FULL join.
*/
if (!bms_is_empty(fpinfo_o->hidden_subquery_rels))
{
fpinfo->make_outerrel_subquery = true;
fpinfo->lower_subquery_rels = bms_add_members(fpinfo->lower_subquery_rels, outerrel->relids);
}
if (!bms_is_empty(fpinfo_i->hidden_subquery_rels))
{
fpinfo->make_innerrel_subquery = true;
fpinfo->lower_subquery_rels = bms_add_members(fpinfo->lower_subquery_rels, innerrel->relids);
}
}
/* Mark that this join can be pushed down safely */
fpinfo->pushdown_safe = true;
@ -7692,6 +7775,8 @@ find_em_for_rel(PlannerInfo *root, EquivalenceClass *ec, RelOptInfo *rel)
{
ListCell *lc;
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) rel->fdw_private;
foreach(lc, ec->ec_members)
{
EquivalenceMember *em = (EquivalenceMember *) lfirst(lc);
@ -7702,6 +7787,7 @@ find_em_for_rel(PlannerInfo *root, EquivalenceClass *ec, RelOptInfo *rel)
*/
if (bms_is_subset(em->em_relids, rel->relids) &&
!bms_is_empty(em->em_relids) &&
bms_is_empty(bms_intersect(em->em_relids, fpinfo->hidden_subquery_rels)) &&
is_foreign_expr(root, rel, em->em_expr))
return em;
}

View File

@ -118,6 +118,10 @@ typedef struct PgFdwRelationInfo
* subquery? */
Relids lower_subquery_rels; /* all relids appearing in lower
* subqueries */
Relids hidden_subquery_rels; /* relids, which can't be referred to
* from upper relations, used
* internally for equivalence member
* search */
/*
* Index of the relation. It is used to create an alias to a subquery

View File

@ -600,7 +600,7 @@ WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t
-- ctid with whole-row reference
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
-- SEMI JOIN, not pushed down
-- SEMI JOIN
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
@ -1305,6 +1305,130 @@ explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
explain (verbose, costs off) select * from ft3 f, loct3 l
where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
-- ===================================================================
-- test SEMI-JOIN pushdown
-- ===================================================================
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN ft4 ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
AND EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)
ORDER BY ft2.c1;
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN ft4 ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
AND EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)
ORDER BY ft2.c1;
-- The same query, different join order
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1;
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1;
-- Left join
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 LEFT JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
SELECT ft2.*, ft4.* FROM ft2 LEFT JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
-- Several semi-joins per upper level join
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN (SELECT * FROM ft5 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft5.c1)) ft5
ON ft2.c2 <= ft5.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE
EXISTS (SELECT 1 FROM ft5 WHERE ft4.c1 = ft5.c1)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN (SELECT * FROM ft5 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft5.c1)) ft5
ON ft2.c2 <= ft5.c1
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
-- Semi-join below Semi-join
EXPLAIN (verbose, costs off)
SELECT ft2.* FROM ft2 WHERE
c1 = ANY (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2))
AND ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
SELECT ft2.* FROM ft2 WHERE
c1 = ANY (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2))
AND ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
-- Upper level relations shouldn't refer EXISTS() subqueries
EXPLAIN (verbose, costs off)
SELECT * FROM ft2 ftupper WHERE
EXISTS (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2) AND c1 = ftupper.c1 )
AND ftupper.c1 > 900
ORDER BY ftupper.c1 LIMIT 10;
SELECT * FROM ft2 ftupper WHERE
EXISTS (
SELECT c1 FROM ft2 WHERE
EXISTS (SELECT 1 FROM ft4 WHERE ft4.c2 = ft2.c2) AND c1 = ftupper.c1 )
AND ftupper.c1 > 900
ORDER BY ftupper.c1 LIMIT 10;
-- EXISTS should be propogated to the highest upper inner join
EXPLAIN (verbose, costs off)
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE EXISTS (
SELECT 1 FROM ft2 WHERE ft2.c2 = ft4.c2)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN
(SELECT * FROM ft2 WHERE EXISTS (
SELECT 1 FROM ft4 WHERE ft2.c2 = ft4.c2)) ft21
ON ft2.c2 = ft21.c2
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
(SELECT * FROM ft4 WHERE EXISTS (
SELECT 1 FROM ft2 WHERE ft2.c2 = ft4.c2)) ft4
ON ft2.c2 = ft4.c1
INNER JOIN
(SELECT * FROM ft2 WHERE EXISTS (
SELECT 1 FROM ft4 WHERE ft2.c2 = ft4.c2)) ft21
ON ft2.c2 = ft21.c2
WHERE ft2.c1 > 900
ORDER BY ft2.c1 LIMIT 10;
-- Can't push down semi-join with inner rel vars in targetlist
EXPLAIN (verbose, costs off)
SELECT ft1.c1 FROM ft1 JOIN ft2 on ft1.c1 = ft2.c1 WHERE
ft1.c1 IN (
SELECT ft2.c1 FROM ft2 JOIN ft4 ON ft2.c1 = ft4.c1)
ORDER BY ft1.c1 LIMIT 5;
-- ===================================================================
-- test writable foreign table stuff
-- ===================================================================