Re-allow duplicate aliases within aliased JOINs.

Although the SQL spec forbids duplicate table aliases, historically
we've allowed queries like
    SELECT ... FROM tab1 x CROSS JOIN (tab2 x CROSS JOIN tab3 y) z
on the grounds that the aliased join (z) hides the aliases within it,
therefore there is no conflict between the two RTEs named "x".  The
LATERAL patch broke this, on the misguided basis that "x" could be
ambiguous if tab3 were a LATERAL subquery.  To avoid breaking existing
queries, it's better to allow this situation and complain only if
tab3 actually does contain an ambiguous reference.  We need only remove
the check that was throwing an error, because the column lookup code
is already prepared to handle ambiguous references.  Per bug #8444.
This commit is contained in:
Tom Lane 2013-11-11 10:42:57 -05:00
parent 705556a631
commit 648bd05b13
4 changed files with 52 additions and 4 deletions

View File

@ -720,14 +720,15 @@ transformFromClauseItem(ParseState *pstate, Node *n,
* we always push them into the namespace, but mark them as not
* lateral_ok if the jointype is wrong.
*
* Notice that we don't require the merged namespace list to be
* conflict-free. See the comments for scanNameSpaceForRefname().
*
* NB: this coding relies on the fact that list_concat is not
* destructive to its second argument.
*/
lateral_ok = (j->jointype == JOIN_INNER || j->jointype == JOIN_LEFT);
setNamespaceLateralState(l_namespace, true, lateral_ok);
checkNameSpaceConflicts(pstate, pstate->p_namespace, l_namespace);
sv_namespace_length = list_length(pstate->p_namespace);
pstate->p_namespace = list_concat(pstate->p_namespace, l_namespace);

View File

@ -130,6 +130,18 @@ refnameRangeTblEntry(ParseState *pstate,
* Search the query's table namespace for an RTE matching the
* given unqualified refname. Return the RTE if a unique match, or NULL
* if no match. Raise error if multiple matches.
*
* Note: it might seem that we shouldn't have to worry about the possibility
* of multiple matches; after all, the SQL standard disallows duplicate table
* aliases within a given SELECT level. Historically, however, Postgres has
* been laxer than that. For example, we allow
* SELECT ... FROM tab1 x CROSS JOIN (tab2 x CROSS JOIN tab3 y) z
* on the grounds that the aliased join (z) hides the aliases within it,
* therefore there is no conflict between the two RTEs named "x". However,
* if tab3 is a LATERAL subquery, then from within the subquery both "x"es
* are visible. Rather than rejecting queries that used to work, we allow
* this situation, and complain only if there's actually an ambiguous
* reference to "x".
*/
static RangeTblEntry *
scanNameSpaceForRefname(ParseState *pstate, const char *refname, int location)
@ -174,8 +186,7 @@ scanNameSpaceForRefname(ParseState *pstate, const char *refname, int location)
/*
* Search the query's table namespace for a relation RTE matching the
* given relation OID. Return the RTE if a unique match, or NULL
* if no match. Raise error if multiple matches (which shouldn't
* happen if the namespace was checked correctly when it was created).
* if no match. Raise error if multiple matches.
*
* See the comments for refnameRangeTblEntry to understand why this
* acts the way it does.

View File

@ -3093,6 +3093,24 @@ SELECT * FROM
(5 rows)
rollback;
-- bug #8444: we've historically allowed duplicate aliases within aliased JOINs
select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y) j on q1 = f1; -- error
ERROR: column reference "f1" is ambiguous
LINE 2: ..._tbl x join (int4_tbl x cross join int4_tbl y) j on q1 = f1;
^
select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y) j on q1 = y.f1; -- error
ERROR: invalid reference to FROM-clause entry for table "y"
LINE 2: ...bl x join (int4_tbl x cross join int4_tbl y) j on q1 = y.f1;
^
HINT: There is an entry for table "y", but it cannot be referenced from this part of the query.
select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y(ff)) j on q1 = f1; -- ok
q1 | q2 | f1 | ff
----+----+----+----
(0 rows)
--
-- Test LATERAL
--
@ -3947,6 +3965,12 @@ ERROR: invalid reference to FROM-clause entry for table "a"
LINE 1: ...m int4_tbl a full join lateral generate_series(0, a.f1) g on...
^
DETAIL: The combining JOIN type must be INNER or LEFT for a LATERAL reference.
-- check we complain about ambiguous table references
select * from
int8_tbl x cross join (int4_tbl x cross join lateral (select x.f1) ss);
ERROR: table reference "x" is ambiguous
LINE 2: ...cross join (int4_tbl x cross join lateral (select x.f1) ss);
^
-- LATERAL can be used to put an aggregate into the FROM clause of its query
select 1 from tenk1 a, lateral (select max(a.unique1) from int4_tbl b) ss;
ERROR: aggregate functions are not allowed in FROM clause of their own query level

View File

@ -892,6 +892,15 @@ SELECT * FROM
rollback;
-- bug #8444: we've historically allowed duplicate aliases within aliased JOINs
select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y) j on q1 = f1; -- error
select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y) j on q1 = y.f1; -- error
select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y(ff)) j on q1 = f1; -- ok
--
-- Test LATERAL
--
@ -1079,5 +1088,8 @@ 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;
-- check we complain about ambiguous table references
select * from
int8_tbl x cross join (int4_tbl x cross join lateral (select x.f1) ss);
-- LATERAL can be used to put an aggregate into the FROM clause of its query
select 1 from tenk1 a, lateral (select max(a.unique1) from int4_tbl b) ss;