mirror of
https://github.com/postgres/postgres.git
synced 2025-05-31 00:01:57 -04:00
Modify UPDATE/DELETE WHERE CURRENT OF to use the FOR UPDATE infrastructure to
locate the target row, if the cursor was declared with FOR UPDATE or FOR SHARE. This approach is more flexible and reliable than digging through the plan tree; for instance it can cope with join cursors. But we still provide the old code for use with non-FOR-UPDATE cursors. Per gripe from Robert Haas.
This commit is contained in:
parent
30f272a79b
commit
18004101ac
@ -1,4 +1,4 @@
|
|||||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.135 2008/10/28 22:02:05 tgl Exp $ -->
|
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.136 2008/11/16 17:34:28 tgl Exp $ -->
|
||||||
|
|
||||||
<chapter id="plpgsql">
|
<chapter id="plpgsql">
|
||||||
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
||||||
@ -2674,9 +2674,10 @@ DELETE FROM <replaceable>table</replaceable> WHERE CURRENT OF <replaceable>curso
|
|||||||
|
|
||||||
<para>
|
<para>
|
||||||
When a cursor is positioned on a table row, that row can be updated
|
When a cursor is positioned on a table row, that row can be updated
|
||||||
or deleted using the cursor to identify the row. Note that this
|
or deleted using the cursor to identify the row. There are
|
||||||
only works for simple (non-join, non-grouping) cursor queries.
|
restrictions on what the cursor's query can be (in particular,
|
||||||
For additional information see the
|
no grouping) and it's best to use <literal>FOR UPDATE</> in the
|
||||||
|
cursor. For additional information see the
|
||||||
<xref linkend="sql-declare" endterm="sql-declare-title">
|
<xref linkend="sql-declare" endterm="sql-declare-title">
|
||||||
reference page.
|
reference page.
|
||||||
</para>
|
</para>
|
||||||
|
@ -1,5 +1,5 @@
|
|||||||
<!--
|
<!--
|
||||||
$PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.44 2008/11/14 10:22:46 petere Exp $
|
$PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.45 2008/11/16 17:34:28 tgl Exp $
|
||||||
PostgreSQL documentation
|
PostgreSQL documentation
|
||||||
-->
|
-->
|
||||||
|
|
||||||
@ -213,6 +213,12 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
|
|||||||
specified, then backward fetches are disallowed in any case.
|
specified, then backward fetches are disallowed in any case.
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
Backward fetches are also disallowed when the query
|
||||||
|
includes <literal>FOR UPDATE</> or <literal>FOR SHARE</>; therefore
|
||||||
|
<literal>SCROLL</literal> may not be specified in this case.
|
||||||
|
</para>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
If the cursor's query includes <literal>FOR UPDATE</> or <literal>FOR
|
If the cursor's query includes <literal>FOR UPDATE</> or <literal>FOR
|
||||||
SHARE</>, then returned rows are locked at the time they are first
|
SHARE</>, then returned rows are locked at the time they are first
|
||||||
@ -221,20 +227,41 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
|
|||||||
these options.
|
these options.
|
||||||
In addition, the returned rows will be the most up-to-date versions;
|
In addition, the returned rows will be the most up-to-date versions;
|
||||||
therefore these options provide the equivalent of what the SQL standard
|
therefore these options provide the equivalent of what the SQL standard
|
||||||
calls a <quote>sensitive cursor</>. It is often wise to use <literal>FOR
|
calls a <quote>sensitive cursor</>. (Specifying <literal>INSENSITIVE</>
|
||||||
UPDATE</> if the cursor is intended to be used with <command>UPDATE
|
together with <literal>FOR UPDATE</> or <literal>FOR SHARE</> is an error.)
|
||||||
... WHERE CURRENT OF</> or <command>DELETE ... WHERE CURRENT OF</>,
|
</para>
|
||||||
since this will prevent other sessions from changing the rows between
|
|
||||||
the time they are fetched and the time they are updated. Without
|
<caution>
|
||||||
<literal>FOR UPDATE</>, a subsequent <literal>WHERE CURRENT OF</> command
|
<para>
|
||||||
will have no effect if the row was changed meanwhile.
|
It is generally recommended to use <literal>FOR UPDATE</> if the cursor
|
||||||
|
is intended to be used with <command>UPDATE ... WHERE CURRENT OF</> or
|
||||||
|
<command>DELETE ... WHERE CURRENT OF</>. Using <literal>FOR UPDATE</>
|
||||||
|
prevents other sessions from changing the rows between the time they are
|
||||||
|
fetched and the time they are updated. Without <literal>FOR UPDATE</>,
|
||||||
|
a subsequent <literal>WHERE CURRENT OF</> command will have no effect if
|
||||||
|
the row was changed since the cursor was created.
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
<literal>SCROLL</literal> may not be specified when the query
|
Another reason to use <literal>FOR UPDATE</> is that without it, a
|
||||||
includes <literal>FOR UPDATE</> or <literal>FOR SHARE</>.
|
subsequent <literal>WHERE CURRENT OF</> might fail if the cursor query
|
||||||
|
does not meet the SQL standard's rules for being <quote>simply
|
||||||
|
updatable</> (in particular, the cursor must reference just one table
|
||||||
|
and not use grouping or <literal>ORDER BY</>). Cursors
|
||||||
|
that are not simply updatable might work, or might not, depending on plan
|
||||||
|
choice details; so in the worst case, an application might work in testing
|
||||||
|
and then fail in production.
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
The main reason not to use <literal>FOR UPDATE</> with <literal>WHERE
|
||||||
|
CURRENT OF</> is if you need the cursor to be scrollable, or to be
|
||||||
|
insensitive to the subsequent updates (that is, continue to show the old
|
||||||
|
data). If this is a requirement, pay close heed to the caveats shown
|
||||||
|
above.
|
||||||
|
</para>
|
||||||
|
</caution>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
The SQL standard only makes provisions for cursors in embedded
|
The SQL standard only makes provisions for cursors in embedded
|
||||||
<acronym>SQL</acronym>. The <productname>PostgreSQL</productname>
|
<acronym>SQL</acronym>. The <productname>PostgreSQL</productname>
|
||||||
|
@ -1,5 +1,5 @@
|
|||||||
<!--
|
<!--
|
||||||
$PostgreSQL: pgsql/doc/src/sgml/ref/delete.sgml,v 1.34 2008/11/14 10:22:46 petere Exp $
|
$PostgreSQL: pgsql/doc/src/sgml/ref/delete.sgml,v 1.35 2008/11/16 17:34:28 tgl Exp $
|
||||||
PostgreSQL documentation
|
PostgreSQL documentation
|
||||||
-->
|
-->
|
||||||
|
|
||||||
@ -148,10 +148,13 @@ DELETE FROM [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ [ AS ]
|
|||||||
<para>
|
<para>
|
||||||
The name of the cursor to use in a <literal>WHERE CURRENT OF</>
|
The name of the cursor to use in a <literal>WHERE CURRENT OF</>
|
||||||
condition. The row to be deleted is the one most recently fetched
|
condition. The row to be deleted is the one most recently fetched
|
||||||
from this cursor. The cursor must be a simple (non-join, non-aggregate)
|
from this cursor. The cursor must be a non-grouping
|
||||||
query on the <command>DELETE</>'s target table.
|
query on the <command>DELETE</>'s target table.
|
||||||
Note that <literal>WHERE CURRENT OF</> cannot be
|
Note that <literal>WHERE CURRENT OF</> cannot be
|
||||||
specified together with a Boolean condition.
|
specified together with a Boolean condition. See
|
||||||
|
<xref linkend="sql-declare" endterm="sql-declare-title">
|
||||||
|
for more information about using cursors with
|
||||||
|
<literal>WHERE CURRENT OF</>.
|
||||||
</para>
|
</para>
|
||||||
</listitem>
|
</listitem>
|
||||||
</varlistentry>
|
</varlistentry>
|
||||||
|
@ -1,5 +1,5 @@
|
|||||||
<!--
|
<!--
|
||||||
$PostgreSQL: pgsql/doc/src/sgml/ref/update.sgml,v 1.47 2008/11/14 10:22:47 petere Exp $
|
$PostgreSQL: pgsql/doc/src/sgml/ref/update.sgml,v 1.48 2008/11/16 17:34:28 tgl Exp $
|
||||||
PostgreSQL documentation
|
PostgreSQL documentation
|
||||||
-->
|
-->
|
||||||
|
|
||||||
@ -167,10 +167,13 @@ UPDATE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ [ AS ] <rep
|
|||||||
<para>
|
<para>
|
||||||
The name of the cursor to use in a <literal>WHERE CURRENT OF</>
|
The name of the cursor to use in a <literal>WHERE CURRENT OF</>
|
||||||
condition. The row to be updated is the one most recently fetched
|
condition. The row to be updated is the one most recently fetched
|
||||||
from this cursor. The cursor must be a simple (non-join, non-aggregate)
|
from this cursor. The cursor must be a non-grouping
|
||||||
query on the <command>UPDATE</>'s target table.
|
query on the <command>UPDATE</>'s target table.
|
||||||
Note that <literal>WHERE CURRENT OF</> cannot be
|
Note that <literal>WHERE CURRENT OF</> cannot be
|
||||||
specified together with a Boolean condition.
|
specified together with a Boolean condition. See
|
||||||
|
<xref linkend="sql-declare" endterm="sql-declare-title">
|
||||||
|
for more information about using cursors with
|
||||||
|
<literal>WHERE CURRENT OF</>.
|
||||||
</para>
|
</para>
|
||||||
</listitem>
|
</listitem>
|
||||||
</varlistentry>
|
</varlistentry>
|
||||||
|
@ -6,7 +6,7 @@
|
|||||||
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
|
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
|
||||||
* Portions Copyright (c) 1994, Regents of the University of California
|
* Portions Copyright (c) 1994, Regents of the University of California
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/backend/executor/execCurrent.c,v 1.7 2008/05/12 00:00:48 alvherre Exp $
|
* $PostgreSQL: pgsql/src/backend/executor/execCurrent.c,v 1.8 2008/11/16 17:34:28 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -46,10 +46,6 @@ execCurrentOf(CurrentOfExpr *cexpr,
|
|||||||
char *table_name;
|
char *table_name;
|
||||||
Portal portal;
|
Portal portal;
|
||||||
QueryDesc *queryDesc;
|
QueryDesc *queryDesc;
|
||||||
ScanState *scanstate;
|
|
||||||
bool lisnull;
|
|
||||||
Oid tuple_tableoid;
|
|
||||||
ItemPointer tuple_tid;
|
|
||||||
|
|
||||||
/* Get the cursor name --- may have to look up a parameter reference */
|
/* Get the cursor name --- may have to look up a parameter reference */
|
||||||
if (cexpr->cursor_name)
|
if (cexpr->cursor_name)
|
||||||
@ -79,15 +75,85 @@ execCurrentOf(CurrentOfExpr *cexpr,
|
|||||||
errmsg("cursor \"%s\" is not a SELECT query",
|
errmsg("cursor \"%s\" is not a SELECT query",
|
||||||
cursor_name)));
|
cursor_name)));
|
||||||
queryDesc = PortalGetQueryDesc(portal);
|
queryDesc = PortalGetQueryDesc(portal);
|
||||||
if (queryDesc == NULL)
|
if (queryDesc == NULL || queryDesc->estate == NULL)
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
(errcode(ERRCODE_INVALID_CURSOR_STATE),
|
(errcode(ERRCODE_INVALID_CURSOR_STATE),
|
||||||
errmsg("cursor \"%s\" is held from a previous transaction",
|
errmsg("cursor \"%s\" is held from a previous transaction",
|
||||||
cursor_name)));
|
cursor_name)));
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Dig through the cursor's plan to find the scan node. Fail if it's not
|
* We have two different strategies depending on whether the cursor uses
|
||||||
* there or buried underneath aggregation.
|
* FOR UPDATE/SHARE or not. The reason for supporting both is that the
|
||||||
|
* FOR UPDATE code is able to identify a target table in many cases where
|
||||||
|
* the other code can't, while the non-FOR-UPDATE case allows use of WHERE
|
||||||
|
* CURRENT OF with an insensitive cursor.
|
||||||
|
*/
|
||||||
|
if (queryDesc->estate->es_rowMarks)
|
||||||
|
{
|
||||||
|
ExecRowMark *erm;
|
||||||
|
ListCell *lc;
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Here, the query must have exactly one FOR UPDATE/SHARE reference to
|
||||||
|
* the target table, and we dig the ctid info out of that.
|
||||||
|
*/
|
||||||
|
erm = NULL;
|
||||||
|
foreach(lc, queryDesc->estate->es_rowMarks)
|
||||||
|
{
|
||||||
|
ExecRowMark *thiserm = (ExecRowMark *) lfirst(lc);
|
||||||
|
|
||||||
|
if (RelationGetRelid(thiserm->relation) == table_oid)
|
||||||
|
{
|
||||||
|
if (erm)
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_INVALID_CURSOR_STATE),
|
||||||
|
errmsg("cursor \"%s\" has multiple FOR UPDATE/SHARE references to table \"%s\"",
|
||||||
|
cursor_name, table_name)));
|
||||||
|
erm = thiserm;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
if (erm == NULL)
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_INVALID_CURSOR_STATE),
|
||||||
|
errmsg("cursor \"%s\" does not have a FOR UPDATE/SHARE reference to table \"%s\"",
|
||||||
|
cursor_name, table_name)));
|
||||||
|
|
||||||
|
/*
|
||||||
|
* The cursor must have a current result row: per the SQL spec, it's
|
||||||
|
* an error if not.
|
||||||
|
*/
|
||||||
|
if (portal->atStart || portal->atEnd)
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_INVALID_CURSOR_STATE),
|
||||||
|
errmsg("cursor \"%s\" is not positioned on a row",
|
||||||
|
cursor_name)));
|
||||||
|
|
||||||
|
/* Return the currently scanned TID, if there is one */
|
||||||
|
if (ItemPointerIsValid(&(erm->curCtid)))
|
||||||
|
{
|
||||||
|
*current_tid = erm->curCtid;
|
||||||
|
return true;
|
||||||
|
}
|
||||||
|
|
||||||
|
/*
|
||||||
|
* This table didn't produce the cursor's current row; some other
|
||||||
|
* inheritance child of the same parent must have. Signal caller
|
||||||
|
* to do nothing on this table.
|
||||||
|
*/
|
||||||
|
return false;
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
ScanState *scanstate;
|
||||||
|
bool lisnull;
|
||||||
|
Oid tuple_tableoid;
|
||||||
|
ItemPointer tuple_tid;
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Without FOR UPDATE, we dig through the cursor's plan to find the
|
||||||
|
* scan node. Fail if it's not there or buried underneath
|
||||||
|
* aggregation.
|
||||||
*/
|
*/
|
||||||
scanstate = search_plan_tree(ExecGetActivePlanTree(queryDesc),
|
scanstate = search_plan_tree(ExecGetActivePlanTree(queryDesc),
|
||||||
table_oid);
|
table_oid);
|
||||||
@ -98,11 +164,11 @@ execCurrentOf(CurrentOfExpr *cexpr,
|
|||||||
cursor_name, table_name)));
|
cursor_name, table_name)));
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* The cursor must have a current result row: per the SQL spec, it's an
|
* The cursor must have a current result row: per the SQL spec, it's
|
||||||
* error if not. We test this at the top level, rather than at the scan
|
* an error if not. We test this at the top level, rather than at the
|
||||||
* node level, because in inheritance cases any one table scan could
|
* scan node level, because in inheritance cases any one table scan
|
||||||
* easily not be on a row. We want to return false, not raise error, if
|
* could easily not be on a row. We want to return false, not raise
|
||||||
* the passed-in table OID is for one of the inactive scans.
|
* error, if the passed-in table OID is for one of the inactive scans.
|
||||||
*/
|
*/
|
||||||
if (portal->atStart || portal->atEnd)
|
if (portal->atStart || portal->atEnd)
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
@ -115,7 +181,8 @@ execCurrentOf(CurrentOfExpr *cexpr,
|
|||||||
return false;
|
return false;
|
||||||
|
|
||||||
/* Use slot_getattr to catch any possible mistakes */
|
/* Use slot_getattr to catch any possible mistakes */
|
||||||
tuple_tableoid = DatumGetObjectId(slot_getattr(scanstate->ss_ScanTupleSlot,
|
tuple_tableoid =
|
||||||
|
DatumGetObjectId(slot_getattr(scanstate->ss_ScanTupleSlot,
|
||||||
TableOidAttributeNumber,
|
TableOidAttributeNumber,
|
||||||
&lisnull));
|
&lisnull));
|
||||||
Assert(!lisnull);
|
Assert(!lisnull);
|
||||||
@ -130,6 +197,7 @@ execCurrentOf(CurrentOfExpr *cexpr,
|
|||||||
*current_tid = *tuple_tid;
|
*current_tid = *tuple_tid;
|
||||||
|
|
||||||
return true;
|
return true;
|
||||||
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
/*
|
/*
|
||||||
|
@ -26,7 +26,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/backend/executor/execMain.c,v 1.316 2008/11/15 19:43:45 tgl Exp $
|
* $PostgreSQL: pgsql/src/backend/executor/execMain.c,v 1.317 2008/11/16 17:34:28 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -609,6 +609,7 @@ InitPlan(QueryDesc *queryDesc, int eflags)
|
|||||||
/* We'll locate the junk attrs below */
|
/* We'll locate the junk attrs below */
|
||||||
erm->ctidAttNo = InvalidAttrNumber;
|
erm->ctidAttNo = InvalidAttrNumber;
|
||||||
erm->toidAttNo = InvalidAttrNumber;
|
erm->toidAttNo = InvalidAttrNumber;
|
||||||
|
ItemPointerSetInvalid(&(erm->curCtid));
|
||||||
estate->es_rowMarks = lappend(estate->es_rowMarks, erm);
|
estate->es_rowMarks = lappend(estate->es_rowMarks, erm);
|
||||||
}
|
}
|
||||||
|
|
||||||
@ -1418,6 +1419,7 @@ lnext: ;
|
|||||||
if (tableoid != RelationGetRelid(erm->relation))
|
if (tableoid != RelationGetRelid(erm->relation))
|
||||||
{
|
{
|
||||||
/* this child is inactive right now */
|
/* this child is inactive right now */
|
||||||
|
ItemPointerSetInvalid(&(erm->curCtid));
|
||||||
continue;
|
continue;
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
@ -1481,6 +1483,9 @@ lnext: ;
|
|||||||
elog(ERROR, "unrecognized heap_lock_tuple status: %u",
|
elog(ERROR, "unrecognized heap_lock_tuple status: %u",
|
||||||
test);
|
test);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/* Remember tuple TID for WHERE CURRENT OF */
|
||||||
|
erm->curCtid = tuple.t_self;
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
@ -7,7 +7,7 @@
|
|||||||
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
|
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
|
||||||
* Portions Copyright (c) 1994, Regents of the University of California
|
* Portions Copyright (c) 1994, Regents of the University of California
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.195 2008/11/15 19:43:46 tgl Exp $
|
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.196 2008/11/16 17:34:28 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -381,6 +381,7 @@ typedef struct ExecRowMark
|
|||||||
bool noWait; /* NOWAIT option */
|
bool noWait; /* NOWAIT option */
|
||||||
AttrNumber ctidAttNo; /* resno of its ctid junk attribute */
|
AttrNumber ctidAttNo; /* resno of its ctid junk attribute */
|
||||||
AttrNumber toidAttNo; /* resno of tableoid junk attribute, if any */
|
AttrNumber toidAttNo; /* resno of tableoid junk attribute, if any */
|
||||||
|
ItemPointerData curCtid; /* ctid of currently locked tuple, if any */
|
||||||
} ExecRowMark;
|
} ExecRowMark;
|
||||||
|
|
||||||
|
|
||||||
|
@ -1154,6 +1154,47 @@ SELECT * FROM uctest;
|
|||||||
110 | hundred
|
110 | hundred
|
||||||
(3 rows)
|
(3 rows)
|
||||||
|
|
||||||
|
-- Can update from a self-join, but only if FOR UPDATE says which to use
|
||||||
|
BEGIN;
|
||||||
|
DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5;
|
||||||
|
FETCH 1 FROM c1;
|
||||||
|
f1 | f2 | f1 | f2
|
||||||
|
----+-----+----+-------
|
||||||
|
18 | one | 13 | three
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- fail
|
||||||
|
ERROR: cursor "c1" is not a simply updatable scan of table "uctest"
|
||||||
|
ROLLBACK;
|
||||||
|
BEGIN;
|
||||||
|
DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5 FOR UPDATE;
|
||||||
|
FETCH 1 FROM c1;
|
||||||
|
f1 | f2 | f1 | f2
|
||||||
|
----+-----+----+-------
|
||||||
|
18 | one | 13 | three
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- fail
|
||||||
|
ERROR: cursor "c1" has multiple FOR UPDATE/SHARE references to table "uctest"
|
||||||
|
ROLLBACK;
|
||||||
|
BEGIN;
|
||||||
|
DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5 FOR SHARE OF a;
|
||||||
|
FETCH 1 FROM c1;
|
||||||
|
f1 | f2 | f1 | f2
|
||||||
|
----+-----+----+-------
|
||||||
|
18 | one | 13 | three
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1;
|
||||||
|
SELECT * FROM uctest;
|
||||||
|
f1 | f2
|
||||||
|
-----+---------
|
||||||
|
13 | three
|
||||||
|
28 | one
|
||||||
|
110 | hundred
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
|
ROLLBACK;
|
||||||
-- Check various error cases
|
-- Check various error cases
|
||||||
DELETE FROM uctest WHERE CURRENT OF c1; -- fail, no such cursor
|
DELETE FROM uctest WHERE CURRENT OF c1; -- fail, no such cursor
|
||||||
ERROR: cursor "c1" does not exist
|
ERROR: cursor "c1" does not exist
|
||||||
@ -1166,6 +1207,11 @@ DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table
|
|||||||
ERROR: cursor "c" is not a simply updatable scan of table "uctest"
|
ERROR: cursor "c" is not a simply updatable scan of table "uctest"
|
||||||
ROLLBACK;
|
ROLLBACK;
|
||||||
BEGIN;
|
BEGIN;
|
||||||
|
DECLARE c CURSOR FOR SELECT * FROM tenk2 FOR SHARE;
|
||||||
|
DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table
|
||||||
|
ERROR: cursor "c" does not have a FOR UPDATE/SHARE reference to table "uctest"
|
||||||
|
ROLLBACK;
|
||||||
|
BEGIN;
|
||||||
DECLARE c CURSOR FOR SELECT * FROM tenk1 JOIN tenk2 USING (unique1);
|
DECLARE c CURSOR FOR SELECT * FROM tenk1 JOIN tenk2 USING (unique1);
|
||||||
DELETE FROM tenk1 WHERE CURRENT OF c; -- fail, cursor is on a join
|
DELETE FROM tenk1 WHERE CURRENT OF c; -- fail, cursor is on a join
|
||||||
ERROR: cursor "c" is not a simply updatable scan of table "tenk1"
|
ERROR: cursor "c" is not a simply updatable scan of table "tenk1"
|
||||||
|
@ -404,6 +404,24 @@ FETCH 1 FROM c1;
|
|||||||
COMMIT;
|
COMMIT;
|
||||||
SELECT * FROM uctest;
|
SELECT * FROM uctest;
|
||||||
|
|
||||||
|
-- Can update from a self-join, but only if FOR UPDATE says which to use
|
||||||
|
BEGIN;
|
||||||
|
DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5;
|
||||||
|
FETCH 1 FROM c1;
|
||||||
|
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- fail
|
||||||
|
ROLLBACK;
|
||||||
|
BEGIN;
|
||||||
|
DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5 FOR UPDATE;
|
||||||
|
FETCH 1 FROM c1;
|
||||||
|
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- fail
|
||||||
|
ROLLBACK;
|
||||||
|
BEGIN;
|
||||||
|
DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5 FOR SHARE OF a;
|
||||||
|
FETCH 1 FROM c1;
|
||||||
|
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1;
|
||||||
|
SELECT * FROM uctest;
|
||||||
|
ROLLBACK;
|
||||||
|
|
||||||
-- Check various error cases
|
-- Check various error cases
|
||||||
|
|
||||||
DELETE FROM uctest WHERE CURRENT OF c1; -- fail, no such cursor
|
DELETE FROM uctest WHERE CURRENT OF c1; -- fail, no such cursor
|
||||||
@ -414,6 +432,10 @@ DECLARE c CURSOR FOR SELECT * FROM tenk2;
|
|||||||
DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table
|
DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table
|
||||||
ROLLBACK;
|
ROLLBACK;
|
||||||
BEGIN;
|
BEGIN;
|
||||||
|
DECLARE c CURSOR FOR SELECT * FROM tenk2 FOR SHARE;
|
||||||
|
DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table
|
||||||
|
ROLLBACK;
|
||||||
|
BEGIN;
|
||||||
DECLARE c CURSOR FOR SELECT * FROM tenk1 JOIN tenk2 USING (unique1);
|
DECLARE c CURSOR FOR SELECT * FROM tenk1 JOIN tenk2 USING (unique1);
|
||||||
DELETE FROM tenk1 WHERE CURRENT OF c; -- fail, cursor is on a join
|
DELETE FROM tenk1 WHERE CURRENT OF c; -- fail, cursor is on a join
|
||||||
ROLLBACK;
|
ROLLBACK;
|
||||||
|
Loading…
x
Reference in New Issue
Block a user