mirror of
https://github.com/postgres/postgres.git
synced 2025-08-06 18:42:54 +03:00
Make LATERAL implicit for functions in FROM.
The SQL standard does not have general functions-in-FROM, but it does allow UNNEST() there (see the <collection derived table> production), and the semantics of that are defined to include lateral references. So spec compliance requires allowing lateral references within UNNEST() even without an explicit LATERAL keyword. Rather than making UNNEST() a special case, it seems best to extend this flexibility to any function-in-FROM. We'll still allow LATERAL to be written explicitly for clarity's sake, but it's now a noise word in this context. In theory this change could result in a change in behavior of existing queries, by allowing what had been an outer reference in a function-in-FROM to be captured by an earlier FROM-item at the same level. However, all pre-9.3 PG releases have a bug that causes them to match variable references to earlier FROM-items in preference to outer references (and then throw an error). So no previously-working query could contain the type of ambiguity that would risk a change of behavior. Per a suggestion from Andrew Gierth, though I didn't use his patch.
This commit is contained in:
@@ -717,14 +717,24 @@ SELECT *
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
Subqueries and table functions appearing in <literal>FROM</> can be
|
||||
Subqueries appearing in <literal>FROM</> can be
|
||||
preceded by the key word <literal>LATERAL</>. This allows them to
|
||||
reference columns provided by preceding <literal>FROM</> items.
|
||||
(Without <literal>LATERAL</literal>, each <literal>FROM</> item is
|
||||
(Without <literal>LATERAL</literal>, each subquery is
|
||||
evaluated independently and so cannot cross-reference any other
|
||||
<literal>FROM</> item.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Table functions appearing in <literal>FROM</> can also be
|
||||
preceded by the key word <literal>LATERAL</>, but for functions the
|
||||
key word is optional; the function's arguments can contain references
|
||||
to columns provided by preceding <literal>FROM</> items in any case.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A <literal>LATERAL</literal> item can appear at top level in the
|
||||
<literal>FROM</> list, or within a <literal>JOIN</> tree; in the latter
|
||||
<literal>FROM</> list, or within a <literal>JOIN</> tree. In the latter
|
||||
case it can also refer to any items that are on the left-hand side of a
|
||||
<literal>JOIN</> that it is on the right-hand side of.
|
||||
</para>
|
||||
@@ -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;
|
||||
</programlisting>
|
||||
or in several other equivalent formulations.
|
||||
or in several other equivalent formulations. (As already mentioned,
|
||||
the <literal>LATERAL</> key word is unnecessary in this example, but
|
||||
we use it for clarity.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
@@ -504,18 +504,28 @@ TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
|
||||
<varlistentry>
|
||||
<term><literal>LATERAL</literal></term>
|
||||
<listitem>
|
||||
<para>The <literal>LATERAL</literal> key word can precede a
|
||||
sub-<command>SELECT</command> or function-call <literal>FROM</>
|
||||
item. This allows the sub-<command>SELECT</command> or function
|
||||
expression to refer to columns of <literal>FROM</> items that appear
|
||||
before it in the <literal>FROM</> list. (Without
|
||||
<literal>LATERAL</literal>, each <literal>FROM</> item is evaluated
|
||||
independently and so cannot cross-reference any other
|
||||
<literal>FROM</> item.) A <literal>LATERAL</literal> item can
|
||||
appear at top level in the <literal>FROM</> list, or within a
|
||||
<literal>JOIN</> tree; in the latter case it can also refer to any
|
||||
items that are on the left-hand side of a <literal>JOIN</> that it is
|
||||
on the right-hand side of.
|
||||
<para>
|
||||
The <literal>LATERAL</literal> key word can precede a
|
||||
sub-<command>SELECT</command> <literal>FROM</> item. This allows the
|
||||
sub-<command>SELECT</command> to refer to columns of <literal>FROM</>
|
||||
items that appear before it in the <literal>FROM</> list. (Without
|
||||
<literal>LATERAL</literal>, each sub-<command>SELECT</command> is
|
||||
evaluated independently and so cannot cross-reference any other
|
||||
<literal>FROM</> item.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<literal>LATERAL</literal> can also precede a function-call
|
||||
<literal>FROM</> item, but in this case it is a noise word, because
|
||||
the function expression can refer to earlier <literal>FROM</> items
|
||||
in any case.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A <literal>LATERAL</literal> item can appear at top level in the
|
||||
<literal>FROM</> list, or within a <literal>JOIN</> tree. In the
|
||||
latter case it can also refer to any items that are on the left-hand
|
||||
side of a <literal>JOIN</> that it is on the right-hand side of.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@@ -1738,7 +1748,12 @@ SELECT distributors.* WHERE distributors.name = 'Westward';
|
||||
sub-<command>SELECT</command>; that is, the syntax
|
||||
<literal>FROM <replaceable>func</>(...) <replaceable>alias</></literal>
|
||||
is approximately equivalent to
|
||||
<literal>FROM (SELECT <replaceable>func</>(...)) <replaceable>alias</></literal>.
|
||||
<literal>FROM LATERAL (SELECT <replaceable>func</>(...)) <replaceable>alias</></literal>.
|
||||
Note that <literal>LATERAL</> is considered to be implicit; this is
|
||||
because the standard requires <literal>LATERAL</> semantics for an
|
||||
<literal>UNNEST()</> item in <literal>FROM</>.
|
||||
<productname>PostgreSQL</productname> treats <literal>UNNEST()</> the
|
||||
same as other set-returning functions.
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
|
Reference in New Issue
Block a user