postgres_fdw: Avoid pulling up restrict infos from subqueries
authorAlexander Korotkov <[email protected]>
Tue, 25 Mar 2025 03:49:47 +0000 (05:49 +0200)
committerAlexander Korotkov <[email protected]>
Tue, 25 Mar 2025 03:50:39 +0000 (05:50 +0200)
Semi-join joins below left/right join are deparsed as
subqueries.  Thus, we can't refer to subqueries vars from upper relations.
This commit avoids pulling conditions from them.

Reported-by: Robins Tharakan <[email protected]>
Bug: #18852
Discussion: https://postgr.es/m/CAEP4nAzryLd3gwcUpFBAG9MWyDfMRX8ZjuyY2XXjyC_C6k%2B_Zw%40mail.gmail.com
Author: Alexander Pyhalov <[email protected]>
Reviewed-by: Alexander Korotkov <[email protected]>
Backpatch-through: 17

contrib/postgres_fdw/expected/postgres_fdw.out
contrib/postgres_fdw/postgres_fdw.c
contrib/postgres_fdw/sql/postgres_fdw.sql

index 9f75fed3f5d30c96f732984a25209751a40e1cdc..602067c4e474f4a729d4e3749c6c470f5fd75304 100644 (file)
@@ -4926,6 +4926,44 @@ SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
 ----+----+----+----+----+----+----+----+----+----+----
 (0 rows)
 
+-- Semi-join conditions shouldn't pop up as left/right join clauses.
+SET enable_material TO off;
+EXPLAIN (verbose, costs off)
+SELECT x1.c1 FROM
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x1
+   RIGHT JOIN
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x2
+   ON (x1.c1 = x2.c1)
+ORDER BY x1.c1 LIMIT 10;
+                                                                                                                                                                                 QUERY PLAN                                                                                                                                                                                 
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+   Output: ft2.c1
+   Relations: ((public.ft2 ft2_1) LEFT JOIN ((public.ft2) SEMI JOIN (public.ft4))) SEMI JOIN (public.ft4 ft4_1)
+   Remote SQL: SELECT s9.c1 FROM ("S 1"."T 1" r6 LEFT JOIN (SELECT r4."C 1" FROM "S 1"."T 1" r4 WHERE ((r4.c2 < 10)) AND EXISTS (SELECT NULL FROM "S 1"."T 3" r5 WHERE ((r4."C 1" = r5.c1)))) s9(c1) ON (((s9.c1 = r6."C 1")))) WHERE ((r6.c2 < 10)) AND EXISTS (SELECT NULL FROM "S 1"."T 3" r7 WHERE ((r6."C 1" = r7.c1))) ORDER BY s9.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT x1.c1 FROM
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x1
+   RIGHT JOIN
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x2
+   ON (x1.c1 = x2.c1)
+ORDER BY x1.c1 LIMIT 10;
+ c1 
+----
+  2
+  4
+  6
+  8
+ 10
+ 12
+ 14
+ 16
+ 18
+ 20
+(10 rows)
+
+RESET enable_material;
 -- 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
index fc65d81e2177ada3671a1fd1296280cd64a5e046..6f030e4f31b48a5d5bedd5301fbb645a4b43cce0 100644 (file)
@@ -5953,17 +5953,33 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
            break;
 
        case JOIN_LEFT:
-           fpinfo->joinclauses = list_concat(fpinfo->joinclauses,
-                                             fpinfo_i->remote_conds);
-           fpinfo->remote_conds = list_concat(fpinfo->remote_conds,
-                                              fpinfo_o->remote_conds);
+
+           /*
+            * When semi-join is involved in the inner or outer part of the
+            * left join, it's deparsed as a subquery, and we can't refer to
+            * its vars on the upper level.
+            */
+           if (bms_is_empty(fpinfo_i->hidden_subquery_rels))
+               fpinfo->joinclauses = list_concat(fpinfo->joinclauses,
+                                                 fpinfo_i->remote_conds);
+           if (bms_is_empty(fpinfo_o->hidden_subquery_rels))
+               fpinfo->remote_conds = list_concat(fpinfo->remote_conds,
+                                                  fpinfo_o->remote_conds);
            break;
 
        case JOIN_RIGHT:
-           fpinfo->joinclauses = list_concat(fpinfo->joinclauses,
-                                             fpinfo_o->remote_conds);
-           fpinfo->remote_conds = list_concat(fpinfo->remote_conds,
-                                              fpinfo_i->remote_conds);
+
+           /*
+            * When semi-join is involved in the inner or outer part of the
+            * right join, it's deparsed as a subquery, and we can't refer to
+            * its vars on the upper level.
+            */
+           if (bms_is_empty(fpinfo_o->hidden_subquery_rels))
+               fpinfo->joinclauses = list_concat(fpinfo->joinclauses,
+                                                 fpinfo_o->remote_conds);
+           if (bms_is_empty(fpinfo_i->hidden_subquery_rels))
+               fpinfo->remote_conds = list_concat(fpinfo->remote_conds,
+                                                  fpinfo_i->remote_conds);
            break;
 
        case JOIN_SEMI:
index db69434188581a60d2beffc72953ff6abfc34320..8acfb78f471cb010f49cd6dc7c29f4d2c504caaa 100644 (file)
@@ -1455,6 +1455,23 @@ SELECT ft2.*, ft4.* FROM ft2 INNER JOIN
    WHERE ft2.c1 > 900
    ORDER BY ft2.c1 LIMIT 10;
 
+-- Semi-join conditions shouldn't pop up as left/right join clauses.
+SET enable_material TO off;
+EXPLAIN (verbose, costs off)
+SELECT x1.c1 FROM
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x1
+   RIGHT JOIN
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x2
+   ON (x1.c1 = x2.c1)
+ORDER BY x1.c1 LIMIT 10;
+SELECT x1.c1 FROM
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x1
+   RIGHT JOIN
+       (SELECT * FROM ft2 WHERE EXISTS (SELECT 1 FROM ft4 WHERE ft4.c1 = ft2.c1 AND ft2.c2 < 10)) x2
+   ON (x1.c1 = x2.c1)
+ORDER BY x1.c1 LIMIT 10;
+RESET enable_material;
+
 -- 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