diff --git a/src/backend/optimizer/plan/subselect.c b/src/backend/optimizer/plan/subselect.c index 555c91f61e3..921ebfb5edd 100644 --- a/src/backend/optimizer/plan/subselect.c +++ b/src/backend/optimizer/plan/subselect.c @@ -85,6 +85,8 @@ static bool testexpr_is_hashable(Node *testexpr); static bool hash_ok_operator(OpExpr *expr); static bool contain_dml(Node *node); static bool contain_dml_walker(Node *node, void *context); +static bool contain_outer_selfref(Node *node); +static bool contain_outer_selfref_walker(Node *node, Index *depth); static void inline_cte(PlannerInfo *root, CommonTableExpr *cte); static bool inline_cte_walker(Node *node, inline_cte_walker_context *context); static bool simplify_EXISTS_query(PlannerInfo *root, Query *query); @@ -867,6 +869,10 @@ SS_process_ctes(PlannerInfo *root) * SELECT, or containing volatile functions. Inlining might change * the side-effects, which would be bad. * + * 4. The CTE is multiply-referenced and contains a self-reference to + * a recursive CTE outside itself. Inlining would result in multiple + * recursive self-references, which we don't support. + * * Otherwise, we have an option whether to inline or not. That should * always be a win if there's just a single reference, but if the CTE * is multiply-referenced then it's unclear: inlining adds duplicate @@ -876,6 +882,9 @@ SS_process_ctes(PlannerInfo *root) * the user express a preference. Our default behavior is to inline * only singly-referenced CTEs, but a CTE marked CTEMaterializeNever * will be inlined even if multiply referenced. + * + * Note: we check for volatile functions last, because that's more + * expensive than the other tests needed. */ if ((cte->ctematerialized == CTEMaterializeNever || (cte->ctematerialized == CTEMaterializeDefault && @@ -883,6 +892,8 @@ SS_process_ctes(PlannerInfo *root) !cte->cterecursive && cmdType == CMD_SELECT && !contain_dml(cte->ctequery) && + (cte->cterefcount <= 1 || + !contain_outer_selfref(cte->ctequery)) && !contain_volatile_functions(cte->ctequery)) { inline_cte(root, cte); @@ -1016,6 +1027,61 @@ contain_dml_walker(Node *node, void *context) return expression_tree_walker(node, contain_dml_walker, context); } +/* + * contain_outer_selfref: is there an external recursive self-reference? + */ +static bool +contain_outer_selfref(Node *node) +{ + Index depth = 0; + + /* + * We should be starting with a Query, so that depth will be 1 while + * examining its immediate contents. + */ + Assert(IsA(node, Query)); + + return contain_outer_selfref_walker(node, &depth); +} + +static bool +contain_outer_selfref_walker(Node *node, Index *depth) +{ + if (node == NULL) + return false; + if (IsA(node, RangeTblEntry)) + { + RangeTblEntry *rte = (RangeTblEntry *) node; + + /* + * Check for a self-reference to a CTE that's above the Query that our + * search started at. + */ + if (rte->rtekind == RTE_CTE && + rte->self_reference && + rte->ctelevelsup >= *depth) + return true; + return false; /* allow range_table_walker to continue */ + } + if (IsA(node, Query)) + { + /* Recurse into subquery, tracking nesting depth properly */ + Query *query = (Query *) node; + bool result; + + (*depth)++; + + result = query_tree_walker(query, contain_outer_selfref_walker, + (void *) depth, QTW_EXAMINE_RTES_BEFORE); + + (*depth)--; + + return result; + } + return expression_tree_walker(node, contain_outer_selfref_walker, + (void *) depth); +} + /* * inline_cte: convert RTE_CTE references to given CTE into RTE_SUBQUERYs */ diff --git a/src/test/regress/expected/subselect.out b/src/test/regress/expected/subselect.out index 4a541041822..2d1963d12ae 100644 --- a/src/test/regress/expected/subselect.out +++ b/src/test/regress/expected/subselect.out @@ -1299,6 +1299,106 @@ select * from x, x x2 where x.n = x2.n; Output: subselect_tbl_1.f1 (11 rows) +-- Multiply-referenced CTEs can't be inlined if they contain outer self-refs +explain (verbose, costs off) +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z1.a as a from z cross join z as z1 + where length(z.a || z1.a) < 5)) +select * from x; + QUERY PLAN +---------------------------------------------------------- + CTE Scan on x + Output: x.a + CTE x + -> Recursive Union + -> Values Scan on "*VALUES*" + Output: "*VALUES*".column1 + -> Nested Loop + Output: (z.a || z1.a) + Join Filter: (length((z.a || z1.a)) < 5) + CTE z + -> WorkTable Scan on x x_1 + Output: x_1.a + -> CTE Scan on z + Output: z.a + -> CTE Scan on z z1 + Output: z1.a +(16 rows) + +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z1.a as a from z cross join z as z1 + where length(z.a || z1.a) < 5)) +select * from x; + a +------ + a + b + aa + ab + ba + bb + aaaa + aaab + aaba + aabb + abaa + abab + abba + abbb + baaa + baab + baba + babb + bbaa + bbab + bbba + bbbb +(22 rows) + +explain (verbose, costs off) +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z.a as a from z + where length(z.a || z.a) < 5)) +select * from x; + QUERY PLAN +-------------------------------------------------------- + CTE Scan on x + Output: x.a + CTE x + -> Recursive Union + -> Values Scan on "*VALUES*" + Output: "*VALUES*".column1 + -> WorkTable Scan on x x_1 + Output: (x_1.a || x_1.a) + Filter: (length((x_1.a || x_1.a)) < 5) +(9 rows) + +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z.a as a from z + where length(z.a || z.a) < 5)) +select * from x; + a +------ + a + b + aa + bb + aaaa + bbbb +(6 rows) + -- Check handling of outer references explain (verbose, costs off) with x as (select * from int4_tbl) diff --git a/src/test/regress/sql/subselect.sql b/src/test/regress/sql/subselect.sql index 856bbff7328..99ca69791e3 100644 --- a/src/test/regress/sql/subselect.sql +++ b/src/test/regress/sql/subselect.sql @@ -690,6 +690,41 @@ explain (verbose, costs off) with x as not materialized (select * from (select f1, now() as n from subselect_tbl) ss) select * from x, x x2 where x.n = x2.n; +-- Multiply-referenced CTEs can't be inlined if they contain outer self-refs +explain (verbose, costs off) +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z1.a as a from z cross join z as z1 + where length(z.a || z1.a) < 5)) +select * from x; + +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z1.a as a from z cross join z as z1 + where length(z.a || z1.a) < 5)) +select * from x; + +explain (verbose, costs off) +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z.a as a from z + where length(z.a || z.a) < 5)) +select * from x; + +with recursive x(a) as + ((values ('a'), ('b')) + union all + (with z as not materialized (select * from x) + select z.a || z.a as a from z + where length(z.a || z.a) < 5)) +select * from x; + -- Check handling of outer references explain (verbose, costs off) with x as (select * from int4_tbl)