Skip to content

Commit

Permalink
Disallow LATERAL references to the target table of an UPDATE/DELETE.
Browse files Browse the repository at this point in the history
On second thought, commit 0c051c9 was
over-hasty: rather than allowing this case, we ought to reject it for now.
That leaves the field clear for a future feature that allows the target
table to be re-specified in the FROM (or USING) clause, which will enable
left-joining the target table to something else.  We can then also allow
LATERAL references to such an explicitly re-specified target table.
But allowing them right now will create ambiguities or worse for such a
feature, and it isn't something we documented 9.3 as supporting.

While at it, add a convenience subroutine to avoid having several copies
of the ereport for disalllowed-LATERAL-reference cases.
  • Loading branch information
tglsfdc committed Jan 12, 2014
1 parent 910bac5 commit 158b7fa
Show file tree
Hide file tree
Showing 5 changed files with 72 additions and 66 deletions.
12 changes: 8 additions & 4 deletions src/backend/parser/analyze.c
Original file line number Diff line number Diff line change
Expand Up @@ -367,8 +367,9 @@ transformDeleteStmt(ParseState *pstate, DeleteStmt *stmt)
/* there's no DISTINCT in DELETE */
qry->distinctClause = NIL;

/* subqueries in USING can see the result relation only via LATERAL */
/* subqueries in USING cannot access the result relation */
nsitem->p_lateral_only = true;
nsitem->p_lateral_ok = false;

/*
* The USING clause is non-standard SQL syntax, and is equivalent in
Expand All @@ -378,8 +379,9 @@ transformDeleteStmt(ParseState *pstate, DeleteStmt *stmt)
*/
transformFromClause(pstate, stmt->usingClause);

/* remaining clauses can see the result relation normally */
/* remaining clauses can reference the result relation normally */
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;

qual = transformWhereClause(pstate, stmt->whereClause,
EXPR_KIND_WHERE, "WHERE");
Expand Down Expand Up @@ -1925,17 +1927,19 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt)
/* grab the namespace item made by setTargetTable */
nsitem = (ParseNamespaceItem *) llast(pstate->p_namespace);

/* subqueries in FROM can see the result relation only via LATERAL */
/* subqueries in FROM cannot access the result relation */
nsitem->p_lateral_only = true;
nsitem->p_lateral_ok = false;

/*
* the FROM clause is non-standard SQL syntax. We used to be able to do
* this with REPLACE in POSTQUEL so we keep the feature.
*/
transformFromClause(pstate, stmt->fromClause);

/* remaining clauses can see the result relation normally */
/* remaining clauses can reference the result relation normally */
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;

qry->targetList = transformTargetList(pstate, stmt->targetList,
EXPR_KIND_UPDATE_SOURCE);
Expand Down
62 changes: 37 additions & 25 deletions src/backend/parser/parse_relation.c
Original file line number Diff line number Diff line change
Expand Up @@ -37,6 +37,8 @@ static RangeTblEntry *scanNameSpaceForRefname(ParseState *pstate,
const char *refname, int location);
static RangeTblEntry *scanNameSpaceForRelid(ParseState *pstate, Oid relid,
int location);
static void check_lateral_ref_ok(ParseState *pstate, ParseNamespaceItem *nsitem,
int location);
static void markRTEForSelectPriv(ParseState *pstate, RangeTblEntry *rte,
int rtindex, AttrNumber col);
static void expandRelation(Oid relid, Alias *eref,
Expand Down Expand Up @@ -170,14 +172,7 @@ scanNameSpaceForRefname(ParseState *pstate, const char *refname, int location)
errmsg("table reference \"%s\" is ambiguous",
refname),
parser_errposition(pstate, location)));
/* SQL:2008 demands this be an error, not an invisible item */
if (nsitem->p_lateral_only && !nsitem->p_lateral_ok)
ereport(ERROR,
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
errmsg("invalid reference to FROM-clause entry for table \"%s\"",
refname),
errdetail("The combining JOIN type must be INNER or LEFT for a LATERAL reference."),
parser_errposition(pstate, location)));
check_lateral_ref_ok(pstate, nsitem, location);
result = rte;
}
}
Expand Down Expand Up @@ -221,14 +216,7 @@ scanNameSpaceForRelid(ParseState *pstate, Oid relid, int location)
errmsg("table reference %u is ambiguous",
relid),
parser_errposition(pstate, location)));
/* SQL:2008 demands this be an error, not an invisible item */
if (nsitem->p_lateral_only && !nsitem->p_lateral_ok)
ereport(ERROR,
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
errmsg("invalid reference to FROM-clause entry for table \"%s\"",
rte->eref->aliasname),
errdetail("The combining JOIN type must be INNER or LEFT for a LATERAL reference."),
parser_errposition(pstate, location)));
check_lateral_ref_ok(pstate, nsitem, location);
result = rte;
}
}
Expand Down Expand Up @@ -410,6 +398,37 @@ checkNameSpaceConflicts(ParseState *pstate, List *namespace1,
}
}

/*
* Complain if a namespace item is currently disallowed as a LATERAL reference.
* This enforces both SQL:2008's rather odd idea of what to do with a LATERAL
* reference to the wrong side of an outer join, and our own prohibition on
* referencing the target table of an UPDATE or DELETE as a lateral reference
* in a FROM/USING clause.
*
* Convenience subroutine to avoid multiple copies of a rather ugly ereport.
*/
static void
check_lateral_ref_ok(ParseState *pstate, ParseNamespaceItem *nsitem,
int location)
{
if (nsitem->p_lateral_only && !nsitem->p_lateral_ok)
{
/* SQL:2008 demands this be an error, not an invisible item */
RangeTblEntry *rte = nsitem->p_rte;
char *refname = rte->eref->aliasname;

ereport(ERROR,
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
errmsg("invalid reference to FROM-clause entry for table \"%s\"",
refname),
(rte == pstate->p_target_rangetblentry) ?
errhint("There is an entry for table \"%s\", but it cannot be referenced from this part of the query.",
refname) :
errdetail("The combining JOIN type must be INNER or LEFT for a LATERAL reference."),
parser_errposition(pstate, location)));
}
}

/*
* given an RTE, return RT index (starting with 1) of the entry,
* and optionally get its nesting depth (0 = current). If sublevels_up
Expand Down Expand Up @@ -632,15 +651,8 @@ colNameToVar(ParseState *pstate, char *colname, bool localonly,
(errcode(ERRCODE_AMBIGUOUS_COLUMN),
errmsg("column reference \"%s\" is ambiguous",
colname),
parser_errposition(orig_pstate, location)));
/* SQL:2008 demands this be an error, not an invisible item */
if (nsitem->p_lateral_only && !nsitem->p_lateral_ok)
ereport(ERROR,
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
errmsg("invalid reference to FROM-clause entry for table \"%s\"",
rte->eref->aliasname),
errdetail("The combining JOIN type must be INNER or LEFT for a LATERAL reference."),
parser_errposition(orig_pstate, location)));
parser_errposition(pstate, location)));
check_lateral_ref_ok(pstate, nsitem, location);
result = newresult;
}
}
Expand Down
3 changes: 2 additions & 1 deletion src/include/parser/parse_node.h
Original file line number Diff line number Diff line change
Expand Up @@ -186,7 +186,8 @@ struct ParseState
* inside such a subexpression at the moment.) If p_lateral_ok is not set,
* it's an error to actually use such a namespace item. One might think it
* would be better to just exclude such items from visibility, but the wording
* of SQL:2008 requires us to do it this way.
* of SQL:2008 requires us to do it this way. We also use p_lateral_ok to
* forbid LATERAL references to an UPDATE/DELETE target table.
*
* At no time should a namespace list contain two entries that conflict
* according to the rules in checkNameSpaceConflicts; but note that those
Expand Down
48 changes: 19 additions & 29 deletions src/test/regress/expected/join.out
Original file line number Diff line number Diff line change
Expand Up @@ -4105,17 +4105,7 @@ LINE 1: select 1 from tenk1 a, lateral (select max(a.unique1) from i...
^
-- check behavior of LATERAL in UPDATE/DELETE
create temp table xx1 as select f1 as x1, -f1 as x2 from int4_tbl;
select * from xx1;
x1 | x2
-------------+-------------
0 | 0
123456 | -123456
-123456 | 123456
2147483647 | -2147483647
-2147483647 | 2147483647
(5 rows)

-- error, can't do this without LATERAL:
-- error, can't do this:
update xx1 set x2 = f1 from (select * from int4_tbl where f1 = x1) ss;
ERROR: column "x1" does not exist
LINE 1: ... set x2 = f1 from (select * from int4_tbl where f1 = x1) ss;
Expand All @@ -4126,28 +4116,28 @@ ERROR: invalid reference to FROM-clause entry for table "xx1"
LINE 1: ...t x2 = f1 from (select * from int4_tbl where f1 = xx1.x1) ss...
^
HINT: There is an entry for table "xx1", but it cannot be referenced from this part of the query.
-- OK:
-- can't do it even with LATERAL:
update xx1 set x2 = f1 from lateral (select * from int4_tbl where f1 = x1) ss;
select * from xx1;
x1 | x2
-------------+-------------
0 | 0
123456 | 123456
-123456 | -123456
2147483647 | 2147483647
-2147483647 | -2147483647
(5 rows)

-- error:
ERROR: invalid reference to FROM-clause entry for table "xx1"
LINE 1: ...= f1 from lateral (select * from int4_tbl where f1 = x1) ss;
^
HINT: There is an entry for table "xx1", but it cannot be referenced from this part of the query.
-- we might in future allow something like this, but for now it's an error:
update xx1 set x2 = f1 from xx1, lateral (select * from int4_tbl where f1 = x1) ss;
ERROR: table name "xx1" specified more than once
-- also errors:
delete from xx1 using (select * from int4_tbl where f1 = x1) ss;
ERROR: column "x1" does not exist
LINE 1: ...te from xx1 using (select * from int4_tbl where f1 = x1) ss;
^
HINT: There is a column named "x1" in table "xx1", but it cannot be referenced from this part of the query.
-- OK:
delete from xx1 using (select * from int4_tbl where f1 = xx1.x1) ss;
ERROR: invalid reference to FROM-clause entry for table "xx1"
LINE 1: ...from xx1 using (select * from int4_tbl where f1 = xx1.x1) ss...
^
HINT: There is an entry for table "xx1", but it cannot be referenced from this part of the query.
delete from xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
select * from xx1;
x1 | x2
----+----
(0 rows)

ERROR: invalid reference to FROM-clause entry for table "xx1"
LINE 1: ...xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
^
HINT: There is an entry for table "xx1", but it cannot be referenced from this part of the query.
13 changes: 6 additions & 7 deletions src/test/regress/sql/join.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1151,17 +1151,16 @@ select 1 from tenk1 a, lateral (select max(a.unique1) from int4_tbl b) ss;
-- check behavior of LATERAL in UPDATE/DELETE

create temp table xx1 as select f1 as x1, -f1 as x2 from int4_tbl;
select * from xx1;

-- error, can't do this without LATERAL:
-- error, can't do this:
update xx1 set x2 = f1 from (select * from int4_tbl where f1 = x1) ss;
update xx1 set x2 = f1 from (select * from int4_tbl where f1 = xx1.x1) ss;
-- OK:
-- can't do it even with LATERAL:
update xx1 set x2 = f1 from lateral (select * from int4_tbl where f1 = x1) ss;
select * from xx1;
-- we might in future allow something like this, but for now it's an error:
update xx1 set x2 = f1 from xx1, lateral (select * from int4_tbl where f1 = x1) ss;

-- error:
-- also errors:
delete from xx1 using (select * from int4_tbl where f1 = x1) ss;
-- OK:
delete from xx1 using (select * from int4_tbl where f1 = xx1.x1) ss;
delete from xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
select * from xx1;

0 comments on commit 158b7fa

Please sign in to comment.