diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index bcee9468240..caa9f1b3389 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -717,14 +717,24 @@ SELECT * - Subqueries and table functions appearing in FROM can be + Subqueries appearing in FROM can be preceded by the key word LATERAL. This allows them to reference columns provided by preceding FROM items. - (Without LATERAL, each FROM item is + (Without LATERAL, each subquery is evaluated independently and so cannot cross-reference any other FROM item.) + + + + Table functions appearing in FROM can also be + preceded by the key word LATERAL, but for functions the + key word is optional; the function's arguments can contain references + to columns provided by preceding FROM items in any case. + + + A LATERAL item can appear at top level in the - FROM list, or within a JOIN tree; in the latter + FROM list, or within a JOIN tree. In the latter case it can also refer to any items that are on the left-hand side of a JOIN that it is on the right-hand side of. @@ -770,7 +780,9 @@ FROM polygons p1 CROSS JOIN LATERAL vertices(p1.poly) v1, polygons p2 CROSS JOIN LATERAL vertices(p2.poly) v2 WHERE (v1 <-> v2) < 10 AND p1.id != p2.id; - or in several other equivalent formulations. + or in several other equivalent formulations. (As already mentioned, + the LATERAL key word is unnecessary in this example, but + we use it for clarity.) diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index 26d511fad8c..0f9d52753d8 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -504,18 +504,28 @@ TABLE [ ONLY ] table_name [ * ] LATERAL - The LATERAL key word can precede a - sub-SELECT or function-call FROM - item. This allows the sub-SELECT or function - expression to refer to columns of FROM items that appear - before it in the FROM list. (Without - LATERAL, each FROM item is evaluated - independently and so cannot cross-reference any other - FROM item.) A LATERAL item can - appear at top level in the FROM list, or within a - JOIN tree; in the latter case it can also refer to any - items that are on the left-hand side of a JOIN that it is - on the right-hand side of. + + The LATERAL key word can precede a + sub-SELECT FROM item. This allows the + sub-SELECT to refer to columns of FROM + items that appear before it in the FROM list. (Without + LATERAL, each sub-SELECT is + evaluated independently and so cannot cross-reference any other + FROM item.) + + + + LATERAL can also precede a function-call + FROM item, but in this case it is a noise word, because + the function expression can refer to earlier FROM items + in any case. + + + + A LATERAL item can appear at top level in the + FROM list, or within a JOIN tree. In the + latter case it can also refer to any items that are on the left-hand + side of a JOIN that it is on the right-hand side of. @@ -1738,7 +1748,12 @@ SELECT distributors.* WHERE distributors.name = 'Westward'; sub-SELECT; that is, the syntax FROM func(...) alias is approximately equivalent to - FROM (SELECT func(...)) alias. + FROM LATERAL (SELECT func(...)) alias. + Note that LATERAL is considered to be implicit; this is + because the standard requires LATERAL semantics for an + UNNEST() item in FROM. + PostgreSQL treats UNNEST() the + same as other set-returning functions. diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c index dd78500aa93..b9655954cde 100644 --- a/src/backend/parser/parse_clause.c +++ b/src/backend/parser/parse_clause.c @@ -503,6 +503,7 @@ transformRangeFunction(ParseState *pstate, RangeFunction *r) { Node *funcexpr; char *funcname; + bool is_lateral; RangeTblEntry *rte; /* @@ -514,12 +515,16 @@ transformRangeFunction(ParseState *pstate, RangeFunction *r) funcname = FigureColname(r->funccallnode); /* - * If the function is LATERAL, make lateral_only names of this level - * visible to it. (LATERAL can't nest within a single pstate level, so we - * don't need save/restore logic here.) + * We make lateral_only names of this level visible, whether or not the + * function is explicitly marked LATERAL. This is needed for SQL spec + * compliance in the case of UNNEST(), and seems useful on convenience + * grounds for all functions in FROM. + * + * (LATERAL can't nest within a single pstate level, so we don't need + * save/restore logic here.) */ Assert(!pstate->p_lateral_active); - pstate->p_lateral_active = r->lateral; + pstate->p_lateral_active = true; /* * Transform the raw expression. @@ -533,11 +538,17 @@ transformRangeFunction(ParseState *pstate, RangeFunction *r) */ assign_expr_collations(pstate, funcexpr); + /* + * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if + * there are any lateral cross-references in it. + */ + is_lateral = r->lateral || contain_vars_of_level(funcexpr, 0); + /* * OK, build an RTE for the function. */ rte = addRangeTableEntryForFunction(pstate, funcname, funcexpr, - r, r->lateral, true); + r, is_lateral, true); /* * If a coldeflist was supplied, ensure it defines a legal set of names diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out index 22265d7a7c8..3421a559f25 100644 --- a/src/test/regress/expected/join.out +++ b/src/test/regress/expected/join.out @@ -3157,7 +3157,7 @@ select *, (select r from (select q1 as q2) x, lateral (select q2 as r) y) from i 4567890123456789 | -4567890123456789 | 4567890123456789 (5 rows) --- lateral SRF +-- lateral with function in FROM select count(*) from tenk1 a, lateral generate_series(1,two) g; count ------- @@ -3184,6 +3184,17 @@ explain (costs off) -> Function Scan on generate_series g (4 rows) +-- don't need the explicit LATERAL keyword for functions +explain (costs off) + select count(*) from tenk1 a, generate_series(1,two) g; + QUERY PLAN +------------------------------------------------ + Aggregate + -> Nested Loop + -> Seq Scan on tenk1 a + -> Function Scan on generate_series g +(4 rows) + -- lateral with UNION ALL subselect explain (costs off) select * from generate_series(100,200) g, @@ -3578,25 +3589,25 @@ select * from (26 rows) -- test some error cases where LATERAL should have been used but wasn't -select f1,g from int4_tbl a, generate_series(0, f1) g; +select f1,g from int4_tbl a, (select f1 as g) ss; ERROR: column "f1" does not exist -LINE 1: select f1,g from int4_tbl a, generate_series(0, f1) g; - ^ +LINE 1: select f1,g from int4_tbl a, (select f1 as g) ss; + ^ HINT: There is a column named "f1" in table "a", but it cannot be referenced from this part of the query. -select f1,g from int4_tbl a, generate_series(0, a.f1) g; +select f1,g from int4_tbl a, (select a.f1 as g) ss; ERROR: invalid reference to FROM-clause entry for table "a" -LINE 1: select f1,g from int4_tbl a, generate_series(0, a.f1) g; - ^ +LINE 1: select f1,g from int4_tbl a, (select a.f1 as g) ss; + ^ HINT: There is an entry for table "a", but it cannot be referenced from this part of the query. -select f1,g from int4_tbl a cross join generate_series(0, f1) g; +select f1,g from int4_tbl a cross join (select f1 as g) ss; ERROR: column "f1" does not exist -LINE 1: ...ct f1,g from int4_tbl a cross join generate_series(0, f1) g; - ^ +LINE 1: select f1,g from int4_tbl a cross join (select f1 as g) ss; + ^ HINT: There is a column named "f1" in table "a", but it cannot be referenced from this part of the query. -select f1,g from int4_tbl a cross join generate_series(0, a.f1) g; +select f1,g from int4_tbl a cross join (select a.f1 as g) ss; ERROR: invalid reference to FROM-clause entry for table "a" -LINE 1: ... f1,g from int4_tbl a cross join generate_series(0, a.f1) g; - ^ +LINE 1: select f1,g from int4_tbl a cross join (select a.f1 as g) ss... + ^ HINT: There is an entry for table "a", but it cannot be referenced from this part of the query. -- SQL:2008 says the left table is in scope but illegal to access here select f1,g from int4_tbl a right join lateral generate_series(0, a.f1) g on true; diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out index 0fe8ca4c4e9..16782776f45 100644 --- a/src/test/regress/expected/rangefuncs.out +++ b/src/test/regress/expected/rangefuncs.out @@ -19,12 +19,15 @@ INSERT INTO foo2 VALUES(1, 11); INSERT INTO foo2 VALUES(2, 22); INSERT INTO foo2 VALUES(1, 111); CREATE FUNCTION foot(int) returns setof foo2 as 'SELECT * FROM foo2 WHERE fooid = $1;' LANGUAGE SQL; --- supposed to fail with ERROR +-- function with implicit LATERAL select * from foo2, foot(foo2.fooid) z where foo2.f2 = z.f2; -ERROR: invalid reference to FROM-clause entry for table "foo2" -LINE 1: select * from foo2, foot(foo2.fooid) z where foo2.f2 = z.f2; - ^ -HINT: There is an entry for table "foo2", but it cannot be referenced from this part of the query. + fooid | f2 | fooid | f2 +-------+-----+-------+----- + 1 | 11 | 1 | 11 + 2 | 22 | 2 | 22 + 1 | 111 | 1 | 111 +(3 rows) + -- function in subselect select * from foo2 where f2 in (select f2 from foot(foo2.fooid) z where z.fooid = foo2.fooid) ORDER BY 1,2; fooid | f2 diff --git a/src/test/regress/sql/join.sql b/src/test/regress/sql/join.sql index 6c1e3394adc..6f51b853276 100644 --- a/src/test/regress/sql/join.sql +++ b/src/test/regress/sql/join.sql @@ -901,12 +901,15 @@ explain (costs off) select *, (select r from (select q1 as q2) x, (select q2 as r) y) from int8_tbl; select *, (select r from (select q1 as q2) x, lateral (select q2 as r) y) from int8_tbl; --- lateral SRF +-- lateral with function in FROM select count(*) from tenk1 a, lateral generate_series(1,two) g; explain (costs off) select count(*) from tenk1 a, lateral generate_series(1,two) g; explain (costs off) select count(*) from tenk1 a cross join lateral generate_series(1,two) g; +-- don't need the explicit LATERAL keyword for functions +explain (costs off) + select count(*) from tenk1 a, generate_series(1,two) g; -- lateral with UNION ALL subselect explain (costs off) @@ -987,10 +990,10 @@ select * from lateral (select ss2.y) ss3; -- test some error cases where LATERAL should have been used but wasn't -select f1,g from int4_tbl a, generate_series(0, f1) g; -select f1,g from int4_tbl a, generate_series(0, a.f1) g; -select f1,g from int4_tbl a cross join generate_series(0, f1) g; -select f1,g from int4_tbl a cross join generate_series(0, a.f1) g; +select f1,g from int4_tbl a, (select f1 as g) ss; +select f1,g from int4_tbl a, (select a.f1 as g) ss; +select f1,g from int4_tbl a cross join (select f1 as g) ss; +select f1,g from int4_tbl a cross join (select a.f1 as g) ss; -- SQL:2008 says the left table is in scope but illegal to access here select f1,g from int4_tbl a right join lateral generate_series(0, a.f1) g on true; select f1,g from int4_tbl a full join lateral generate_series(0, a.f1) g on true; diff --git a/src/test/regress/sql/rangefuncs.sql b/src/test/regress/sql/rangefuncs.sql index 54cfc178c05..f1a405a5f7e 100644 --- a/src/test/regress/sql/rangefuncs.sql +++ b/src/test/regress/sql/rangefuncs.sql @@ -7,7 +7,7 @@ INSERT INTO foo2 VALUES(1, 111); CREATE FUNCTION foot(int) returns setof foo2 as 'SELECT * FROM foo2 WHERE fooid = $1;' LANGUAGE SQL; --- supposed to fail with ERROR +-- function with implicit LATERAL select * from foo2, foot(foo2.fooid) z where foo2.f2 = z.f2; -- function in subselect