-
Notifications
You must be signed in to change notification settings - Fork 3.8k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
sql: evaluate correlated subqueries as routines
Previously, the optimizer would error in rare cases when it was unable to hoist correlated subqueries into apply-joins. Now, scalar, correlated subqueries that aren't hoisted are executed successfully. There is remaining work to apply the same method in this commit to `EXISTS` and `<op> ANY` subqueries. Hoisting correlated subqueries is not possible when a conditional expression, like a `CASE`, wraps a subquery that is not leak-proof. One of the effects of hoisting a subquery is that the subquery will be unconditionally evaluated. For leak-proof subqueries, the worst case is that unnecessary computation is performed. For non-leak-proof subqueries, errors could originate from the subquery when it should have never been evaluated because the corresponding conditional expression was never true. So, in order to support these cases, we must be able to execute a correlated subquery. A correlated subquery can be thought of as a relational expression with parameters that need to be filled in with constant value arguments for each invocation. It is essentially a user-defined function with a single statement in the function body. So, the `tree.RoutineExpr` machinery that powers UDFs is easily repurposed to facilitate evaluation of correlated subqueries. Fixes #71908 Fixes #73573 Fixes #80169 Release note (sql change): Some queries which previously resulted in the error "could not decorrelate subquery" now succeed.
- Loading branch information
Showing
11 changed files
with
606 additions
and
18 deletions.
There are no files selected for viewing
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,229 @@ | ||
# Tests for queries made by asyncpg. | ||
|
||
# Regression test for #71908 and #80169. | ||
query TTTTTTTTTTITTI rowsort | ||
---------------------------------------------------------------------------------------- | ||
WITH RECURSIVE | ||
typeinfo_tree | ||
( | ||
oid, ns, name, kind, basetype, elemtype, elemdelim, range_subtype, attrtypoids, attrnames, depth | ||
) | ||
AS ( | ||
SELECT | ||
ti.oid, | ||
ti.ns, | ||
ti.name, | ||
ti.kind, | ||
ti.basetype, | ||
ti.elemtype, | ||
ti.elemdelim, | ||
ti.range_subtype, | ||
ti.attrtypoids, | ||
ti.attrnames, | ||
0 | ||
FROM | ||
( | ||
SELECT | ||
t.oid AS oid, | ||
ns.nspname AS ns, | ||
t.typname AS name, | ||
t.typtype AS kind, | ||
CASE | ||
WHEN t.typtype = 'd' | ||
THEN ( | ||
WITH RECURSIVE | ||
typebases (oid, depth) | ||
AS ( | ||
SELECT | ||
t2.typbasetype AS oid, 0 AS depth | ||
FROM | ||
pg_type AS t2 | ||
WHERE | ||
t2.oid = t.oid | ||
UNION ALL | ||
SELECT | ||
t2.typbasetype AS oid, | ||
tb.depth + 1 AS depth | ||
FROM | ||
pg_type AS t2, typebases AS tb | ||
WHERE | ||
tb.oid = t2.oid AND t2.typbasetype != 0 | ||
) | ||
SELECT | ||
oid | ||
FROM | ||
typebases | ||
ORDER BY | ||
depth DESC | ||
LIMIT | ||
1 | ||
) | ||
ELSE NULL | ||
END | ||
AS basetype, | ||
t.typelem AS elemtype, | ||
elem_t.typdelim AS elemdelim, | ||
range_t.rngsubtype AS range_subtype, | ||
CASE | ||
WHEN t.typtype = 'c' | ||
THEN ( | ||
SELECT | ||
array_agg(ia.atttypid ORDER BY ia.attnum) | ||
FROM | ||
pg_attribute AS ia | ||
INNER JOIN pg_class AS c ON ia.attrelid = c.oid | ||
WHERE | ||
ia.attnum > 0 | ||
AND NOT ia.attisdropped | ||
AND c.reltype = t.oid | ||
) | ||
ELSE NULL | ||
END | ||
AS attrtypoids, | ||
CASE | ||
WHEN t.typtype = 'c' | ||
THEN ( | ||
SELECT | ||
array_agg(ia.attname::STRING ORDER BY ia.attnum) | ||
FROM | ||
pg_attribute AS ia | ||
INNER JOIN pg_class AS c ON ia.attrelid = c.oid | ||
WHERE | ||
ia.attnum > 0 | ||
AND NOT ia.attisdropped | ||
AND c.reltype = t.oid | ||
) | ||
ELSE NULL | ||
END | ||
AS attrnames | ||
FROM | ||
pg_catalog.pg_type AS t | ||
INNER JOIN pg_catalog.pg_namespace AS ns ON | ||
ns.oid = t.typnamespace | ||
LEFT JOIN pg_type AS elem_t ON | ||
t.typlen = -1 | ||
AND t.typelem != 0 | ||
AND t.typelem = elem_t.oid | ||
LEFT JOIN pg_range AS range_t ON t.oid = range_t.rngtypid | ||
) | ||
AS ti | ||
WHERE | ||
ti.oid = ANY ARRAY[21, 23]::OID[] | ||
UNION ALL | ||
SELECT | ||
ti.oid, | ||
ti.ns, | ||
ti.name, | ||
ti.kind, | ||
ti.basetype, | ||
ti.elemtype, | ||
ti.elemdelim, | ||
ti.range_subtype, | ||
ti.attrtypoids, | ||
ti.attrnames, | ||
tt.depth + 1 | ||
FROM | ||
( | ||
SELECT | ||
t.oid AS oid, | ||
ns.nspname AS ns, | ||
t.typname AS name, | ||
t.typtype AS kind, | ||
CASE | ||
WHEN t.typtype = 'd' | ||
THEN ( | ||
WITH RECURSIVE | ||
typebases (oid, depth) | ||
AS ( | ||
SELECT | ||
t2.typbasetype AS oid, 0 AS depth | ||
FROM | ||
pg_type AS t2 | ||
WHERE | ||
t2.oid = t.oid | ||
UNION ALL | ||
SELECT | ||
t2.typbasetype AS oid, | ||
tb.depth + 1 AS depth | ||
FROM | ||
pg_type AS t2, typebases AS tb | ||
WHERE | ||
tb.oid = t2.oid | ||
AND t2.typbasetype != 0 | ||
) | ||
SELECT | ||
oid | ||
FROM | ||
typebases | ||
ORDER BY | ||
depth DESC | ||
LIMIT | ||
1 | ||
) | ||
ELSE NULL | ||
END | ||
AS basetype, | ||
t.typelem AS elemtype, | ||
elem_t.typdelim AS elemdelim, | ||
range_t.rngsubtype AS range_subtype, | ||
CASE | ||
WHEN t.typtype = 'c' | ||
THEN ( | ||
SELECT | ||
array_agg(ia.atttypid ORDER BY ia.attnum) | ||
FROM | ||
pg_attribute AS ia | ||
INNER JOIN pg_class AS c ON ia.attrelid = c.oid | ||
WHERE | ||
ia.attnum > 0 | ||
AND NOT ia.attisdropped | ||
AND c.reltype = t.oid | ||
) | ||
ELSE NULL | ||
END | ||
AS attrtypoids, | ||
CASE | ||
WHEN t.typtype = 'c' | ||
THEN ( | ||
SELECT | ||
array_agg(ia.attname::STRING ORDER BY ia.attnum) | ||
FROM | ||
pg_attribute AS ia | ||
INNER JOIN pg_class AS c ON ia.attrelid = c.oid | ||
WHERE | ||
ia.attnum > 0 | ||
AND NOT ia.attisdropped | ||
AND c.reltype = t.oid | ||
) | ||
ELSE NULL | ||
END | ||
AS attrnames | ||
FROM | ||
pg_catalog.pg_type AS t | ||
INNER JOIN pg_catalog.pg_namespace AS ns ON | ||
ns.oid = t.typnamespace | ||
LEFT JOIN pg_type AS elem_t ON | ||
t.typlen = -1 | ||
AND t.typelem != 0 | ||
AND t.typelem = elem_t.oid | ||
LEFT JOIN pg_range AS range_t ON t.oid = range_t.rngtypid | ||
) | ||
AS ti, | ||
typeinfo_tree AS tt | ||
WHERE | ||
(tt.elemtype IS NOT NULL AND ti.oid = tt.elemtype) | ||
OR (tt.attrtypoids IS NOT NULL AND ti.oid = ANY tt.attrtypoids) | ||
OR (tt.range_subtype IS NOT NULL AND ti.oid = tt.range_subtype) | ||
) | ||
SELECT | ||
DISTINCT *, | ||
basetype::REGTYPE::STRING AS basetype_name, | ||
elemtype::REGTYPE::STRING AS elemtype_name, | ||
range_subtype::REGTYPE::STRING AS range_subtype_name | ||
FROM | ||
typeinfo_tree | ||
ORDER BY | ||
depth DESC | ||
---- | ||
21 pg_catalog int2 b NULL 0 NULL NULL NULL NULL 0 NULL - NULL | ||
23 pg_catalog int4 b NULL 0 NULL NULL NULL NULL 0 NULL - NULL |
Oops, something went wrong.