Commit dd13ad9d authored by Peter Eisentraut's avatar Peter Eisentraut

Fix use of cursor sensitivity terminology

Documentation and comments in code and tests have been using the terms
sensitive/insensitive cursor incorrectly relative to the SQL standard.
(Cursor sensitivity is only relevant for changes made in the same
transaction as the cursor, not for concurrent changes in other
sessions.)  Moreover, some of the behavior of PostgreSQL is incorrect
according to the SQL standard, confusing the issue further.  (WHERE
CURRENT OF changes are not visible in insensitive cursors, but they
should be.)

This change corrects the terminology and removes the claim that
sensitive cursors are supported.  It also adds a test case that checks
the insensitive behavior in a "correct" way, using a change command
not using WHERE CURRENT OF.  Finally, it adds the ASENSITIVE cursor
option to select the default asensitive behavior, per SQL standard.

There are no changes to cursor behavior in this patch.

Discussion: https://www.postgresql.org/message-id/flat/96ee8b30-9889-9e1b-b053-90e10c050e85%40enterprisedb.com
parent 0b5e8245
......@@ -6792,8 +6792,8 @@ EXEC SQL DEALLOCATE DESCRIPTOR mydesc;
<refsynopsisdiv>
<synopsis>
DECLARE <replaceable class="parameter">cursor_name</replaceable> [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable class="parameter">prepared_name</replaceable>
DECLARE <replaceable class="parameter">cursor_name</replaceable> [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable class="parameter">query</replaceable>
DECLARE <replaceable class="parameter">cursor_name</replaceable> [ BINARY ] [ ASENSITIVE | INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable class="parameter">prepared_name</replaceable>
DECLARE <replaceable class="parameter">cursor_name</replaceable> [ BINARY ] [ ASENSITIVE | INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable class="parameter">query</replaceable>
</synopsis>
</refsynopsisdiv>
......
......@@ -26,7 +26,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ]
DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ ASENSITIVE | INSENSITIVE ] [ [ NO ] SCROLL ]
CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable class="parameter">query</replaceable>
</synopsis>
</refsynopsisdiv>
......@@ -75,14 +75,25 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
</varlistentry>
<varlistentry>
<term><literal>ASENSITIVE</literal></term>
<term><literal>INSENSITIVE</literal></term>
<listitem>
<para>
Indicates that data retrieved from the cursor should be
unaffected by updates to the table(s) underlying the cursor that occur
after the cursor is created. In <productname>PostgreSQL</productname>,
this is the default behavior; so this key word has no
effect and is only accepted for compatibility with the SQL standard.
Cursor sensitivity determines whether changes to the data underlying the
cursor, done in the same transaction, after the cursor has been
declared, are visible in the cursor. <literal>INSENSITIVE</literal>
means they are not visible, <literal>ASENSITIVE</literal> means the
behavior is implementation-dependent. A third behavior,
<literal>SENSITIVE</literal>, meaning that such changes are visible in
the cursor, is not available in <productname>PostgreSQL</productname>.
In <productname>PostgreSQL</productname>, all cursors are insensitive;
so these key words have no effect and are only accepted for
compatibility with the SQL standard.
</para>
<para>
Specifying <literal>INSENSITIVE</literal> together with <literal>FOR
UPDATE</literal> or <literal>FOR SHARE</literal> is an error.
</para>
</listitem>
</varlistentry>
......@@ -133,7 +144,7 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
</variablelist>
<para>
The key words <literal>BINARY</literal>,
The key words <literal>ASENSITIVE</literal>, <literal>BINARY</literal>,
<literal>INSENSITIVE</literal>, and <literal>SCROLL</literal> can
appear in any order.
</para>
......@@ -246,10 +257,7 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
fetched, in the same way as for a regular
<link linkend="sql-select"><command>SELECT</command></link> command with
these options.
In addition, the returned rows will be the most up-to-date versions;
therefore these options provide the equivalent of what the SQL standard
calls a <quote>sensitive cursor</quote>. (Specifying <literal>INSENSITIVE</literal>
together with <literal>FOR UPDATE</literal> or <literal>FOR SHARE</literal> is an error.)
In addition, the returned rows will be the most up-to-date versions.
</para>
<caution>
......@@ -278,7 +286,7 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
<para>
The main reason not to use <literal>FOR UPDATE</literal> with <literal>WHERE
CURRENT OF</literal> is if you need the cursor to be scrollable, or to be
insensitive to the subsequent updates (that is, continue to show the old
isolated from concurrent updates (that is, continue to show the old
data). If this is a requirement, pay close heed to the caveats shown
above.
</para>
......@@ -318,20 +326,21 @@ DECLARE liahona CURSOR FOR SELECT * FROM films;
<refsect1>
<title>Compatibility</title>
<para>
The SQL standard says that it is implementation-dependent whether cursors
are sensitive to concurrent updates of the underlying data by default. In
<productname>PostgreSQL</productname>, cursors are insensitive by default,
and can be made sensitive by specifying <literal>FOR UPDATE</literal>. Other
products may work differently.
</para>
<para>
The SQL standard allows cursors only in embedded
<acronym>SQL</acronym> and in modules. <productname>PostgreSQL</productname>
permits cursors to be used interactively.
</para>
<para>
According to the SQL standard, changes made to insensitive cursors by
<literal>UPDATE ... WHERE CURRENT OF</literal> and <literal>DELETE
... WHERE CURRENT OF</literal> statements are visibible in that same
cursor. <productname>PostgreSQL</productname> treats these statements like
all other data changing statements in that they are not visible in
insensitive cursors.
</para>
<para>
Binary cursors are a <productname>PostgreSQL</productname>
extension.
......
......@@ -452,7 +452,7 @@ T211 Basic trigger capability 07 TRIGGER privilege YES
T211 Basic trigger capability 08 Multiple triggers for the same event are executed in the order in which they were created in the catalog NO intentionally omitted
T212 Enhanced trigger capability YES
T213 INSTEAD OF triggers YES
T231 Sensitive cursors YES
T231 Sensitive cursors NO
T241 START TRANSACTION statement YES
T251 SET TRANSACTION statement: LOCAL option NO
T261 Chained transactions YES
......
......@@ -2681,14 +2681,21 @@ transformDeclareCursorStmt(ParseState *pstate, DeclareCursorStmt *stmt)
Query *result;
Query *query;
/*
* Don't allow both SCROLL and NO SCROLL to be specified
*/
if ((stmt->options & CURSOR_OPT_SCROLL) &&
(stmt->options & CURSOR_OPT_NO_SCROLL))
ereport(ERROR,
(errcode(ERRCODE_INVALID_CURSOR_DEFINITION),
errmsg("cannot specify both SCROLL and NO SCROLL")));
/* translator: %s is a SQL keyword */
errmsg("cannot specify both %s and %s",
"SCROLL", "NO SCROLL")));
if ((stmt->options & CURSOR_OPT_ASENSITIVE) &&
(stmt->options & CURSOR_OPT_INSENSITIVE))
ereport(ERROR,
(errcode(ERRCODE_INVALID_CURSOR_DEFINITION),
/* translator: %s is a SQL keyword */
errmsg("cannot specify both %s and %s",
"ASENSITIVE", "INSENSITIVE")));
/* Transform contained query, not allowing SELECT INTO */
query = transformStmt(pstate, stmt->query);
......@@ -2734,10 +2741,10 @@ transformDeclareCursorStmt(ParseState *pstate, DeclareCursorStmt *stmt)
/* FOR UPDATE and INSENSITIVE are not compatible */
if (query->rowMarks != NIL && (stmt->options & CURSOR_OPT_INSENSITIVE))
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
(errcode(ERRCODE_INVALID_CURSOR_DEFINITION),
/*------
translator: %s is a SQL row locking clause such as FOR UPDATE */
errmsg("DECLARE INSENSITIVE CURSOR ... %s is not supported",
errmsg("DECLARE INSENSITIVE CURSOR ... %s is not valid",
LCS_asString(((RowMarkClause *)
linitial(query->rowMarks))->strength)),
errdetail("Insensitive cursors must be READ ONLY.")));
......
......@@ -637,7 +637,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
/* ordinary key words in alphabetical order */
%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
ASSERTION ASSIGNMENT ASYMMETRIC AT ATTACH ATTRIBUTE AUTHORIZATION
ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC AT ATTACH ATTRIBUTE AUTHORIZATION
BACKWARD BEFORE BEGIN_P BETWEEN BIGINT BINARY BIT
BOOLEAN_P BOTH BREADTH BY
......@@ -11217,6 +11217,7 @@ cursor_options: /*EMPTY*/ { $$ = 0; }
| cursor_options NO SCROLL { $$ = $1 | CURSOR_OPT_NO_SCROLL; }
| cursor_options SCROLL { $$ = $1 | CURSOR_OPT_SCROLL; }
| cursor_options BINARY { $$ = $1 | CURSOR_OPT_BINARY; }
| cursor_options ASENSITIVE { $$ = $1 | CURSOR_OPT_ASENSITIVE; }
| cursor_options INSENSITIVE { $$ = $1 | CURSOR_OPT_INSENSITIVE; }
;
......@@ -15424,6 +15425,7 @@ unreserved_keyword:
| ALSO
| ALTER
| ALWAYS
| ASENSITIVE
| ASSERTION
| ASSIGNMENT
| AT
......@@ -15931,6 +15933,7 @@ bare_label_keyword:
| AND
| ANY
| ASC
| ASENSITIVE
| ASSERTION
| ASSIGNMENT
| ASYMMETRIC
......
......@@ -3052,7 +3052,7 @@ psql_completion(const char *text, int start, int end)
* SCROLL, and CURSOR.
*/
else if (Matches("DECLARE", MatchAny))
COMPLETE_WITH("BINARY", "INSENSITIVE", "SCROLL", "NO SCROLL",
COMPLETE_WITH("BINARY", "ASENSITIVE", "INSENSITIVE", "SCROLL", "NO SCROLL",
"CURSOR");
/*
......
......@@ -2774,7 +2774,8 @@ typedef struct SecLabelStmt
#define CURSOR_OPT_SCROLL 0x0002 /* SCROLL explicitly given */
#define CURSOR_OPT_NO_SCROLL 0x0004 /* NO SCROLL explicitly given */
#define CURSOR_OPT_INSENSITIVE 0x0008 /* INSENSITIVE */
#define CURSOR_OPT_HOLD 0x0010 /* WITH HOLD */
#define CURSOR_OPT_ASENSITIVE 0x0010 /* ASENSITIVE */
#define CURSOR_OPT_HOLD 0x0020 /* WITH HOLD */
/* these planner-control flags do not correspond to any SQL grammar: */
#define CURSOR_OPT_FAST_PLAN 0x0100 /* prefer fast-start plan */
#define CURSOR_OPT_GENERIC_PLAN 0x0200 /* force use of generic plan */
......
......@@ -44,6 +44,7 @@ PG_KEYWORD("any", ANY, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("array", ARRAY, RESERVED_KEYWORD, AS_LABEL)
PG_KEYWORD("as", AS, RESERVED_KEYWORD, AS_LABEL)
PG_KEYWORD("asc", ASC, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("asensitive", ASENSITIVE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("assertion", ASSERTION, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("assignment", ASSIGNMENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("asymmetric", ASYMMETRIC, RESERVED_KEYWORD, BARE_LABEL)
......
......@@ -1094,7 +1094,7 @@ SELECT * FROM uctest;
8 | one
(1 row)
--- sensitive cursors can't currently scroll back, so this is an error:
--- FOR UPDATE cursors can't currently scroll back, so this is an error:
FETCH RELATIVE 0 FROM c1;
ERROR: cursor can only scan forward
HINT: Declare it with SCROLL option to enable backward scan.
......@@ -1106,6 +1106,41 @@ SELECT * FROM uctest;
8 | one
(2 rows)
-- Check insensitive cursor with INSERT
-- (The above tests don't test the SQL notion of an insensitive cursor
-- correctly, because per SQL standard, changes from WHERE CURRENT OF
-- commands should be visible in the cursor. So here we make the
-- changes with a command that is independent of the cursor.)
BEGIN;
DECLARE c1 INSENSITIVE CURSOR FOR SELECT * FROM uctest;
INSERT INTO uctest VALUES (10, 'ten');
FETCH NEXT FROM c1;
f1 | f2
----+-------
3 | three
(1 row)
FETCH NEXT FROM c1;
f1 | f2
----+-----
8 | one
(1 row)
FETCH NEXT FROM c1; -- insert not visible
f1 | f2
----+----
(0 rows)
COMMIT;
SELECT * FROM uctest;
f1 | f2
----+-------
3 | three
8 | one
10 | ten
(3 rows)
DELETE FROM uctest WHERE f1 = 10; -- restore test table state
-- Check inheritance cases
CREATE TEMP TABLE ucchild () inherits (uctest);
INSERT INTO ucchild values(100, 'hundred');
......
......@@ -382,11 +382,26 @@ DELETE FROM uctest WHERE CURRENT OF c1; -- no-op
SELECT * FROM uctest;
UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- no-op
SELECT * FROM uctest;
--- sensitive cursors can't currently scroll back, so this is an error:
--- FOR UPDATE cursors can't currently scroll back, so this is an error:
FETCH RELATIVE 0 FROM c1;
ROLLBACK;
SELECT * FROM uctest;
-- Check insensitive cursor with INSERT
-- (The above tests don't test the SQL notion of an insensitive cursor
-- correctly, because per SQL standard, changes from WHERE CURRENT OF
-- commands should be visible in the cursor. So here we make the
-- changes with a command that is independent of the cursor.)
BEGIN;
DECLARE c1 INSENSITIVE CURSOR FOR SELECT * FROM uctest;
INSERT INTO uctest VALUES (10, 'ten');
FETCH NEXT FROM c1;
FETCH NEXT FROM c1;
FETCH NEXT FROM c1; -- insert not visible
COMMIT;
SELECT * FROM uctest;
DELETE FROM uctest WHERE f1 = 10; -- restore test table state
-- Check inheritance cases
CREATE TEMP TABLE ucchild () inherits (uctest);
INSERT INTO ucchild values(100, 'hundred');
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment