Re: BUG #17050: cursor with for update + commit in loop - Mailing list pgsql-bugs

From Tom Lane
Subject Re: BUG #17050: cursor with for update + commit in loop
Date
Msg-id 1175209.1623182506@sss.pgh.pa.us
Whole thread Raw
In response to Re: BUG #17050: cursor with for update + commit in loop  (Tom Lane <tgl@sss.pgh.pa.us>)
List pgsql-bugs
I wrote:
> The only obvious way to fix this is to always save aside the output
> of a cursor query in case we need to persist it later, so that
> PersistHoldablePortal doesn't have to assume that rewinding is safe.
> That would be pretty catastrophic for performance, though, so I doubt
> anybody will be happy with that answer.
> For cursors that aren't marked scrollable, we might be able to say
> that we only save the *rest* of the query output, and then adjust
> the cursor state appropriately for that choice.  Seems possibly
> nontrivial though, and there's still the question of what to do
> for scrollable ones.

Actually ... maybe it's not that bad.  The nonscrollable case seems
to be quite simple to fix, and as for the scrollable case, maybe
we can just say it's on the user's head that the query produce
stable results.  There's already a prohibition on using FOR UPDATE
with SCROLL, and the DECLARE CURSOR reference page has some warnings
about volatile queries with WITH HOLD, which is basically the same
case as we're worried about here.

I think the DECLARE CURSOR page needs some modernization to mention
that cursors in procedures are basically the same as WITH HOLD.
But as far as code changes go, the attached seems sufficient.

            regards, tom lane

diff --git a/src/backend/commands/portalcmds.c b/src/backend/commands/portalcmds.c
index 6f2397bd36..d34cc39fde 100644
--- a/src/backend/commands/portalcmds.c
+++ b/src/backend/commands/portalcmds.c
@@ -374,10 +374,23 @@ PersistHoldablePortal(Portal portal)
         PushActiveSnapshot(queryDesc->snapshot);

         /*
-         * Rewind the executor: we need to store the entire result set in the
-         * tuplestore, so that subsequent backward FETCHs can be processed.
+         * If the portal is marked scrollable, we need to store the entire
+         * result set in the tuplestore, so that subsequent backward FETCHs
+         * can be processed.  Otherwise, store only the not-yet-fetched rows.
+         * (The latter is not only more efficient, but avoids semantic
+         * problems if the query's output isn't stable.)
          */
-        ExecutorRewind(queryDesc);
+        if (portal->cursorOptions & CURSOR_OPT_SCROLL)
+        {
+            ExecutorRewind(queryDesc);
+        }
+        else
+        {
+            /* We must reset the cursor state as though at start of query */
+            portal->atStart = true;
+            portal->atEnd = false;
+            portal->portalPos = 0;
+        }

         /*
          * Change the destination to output to the tuplestore.  Note we tell
diff --git a/src/pl/plpgsql/src/expected/plpgsql_transaction.out b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
index 8fceb88c9b..4565107073 100644
--- a/src/pl/plpgsql/src/expected/plpgsql_transaction.out
+++ b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
@@ -335,6 +335,32 @@ SELECT * FROM pg_cursors;
 ------+-----------+-------------+-----------+---------------+---------------
 (0 rows)

+-- interaction of FOR UPDATE cursor with subsequent updates (bug #17050)
+TRUNCATE test1;
+INSERT INTO test1 VALUES (1,'one'), (2,'two'), (3,'three');
+DO LANGUAGE plpgsql $$
+DECLARE
+    l_cur CURSOR FOR SELECT a FROM test1 ORDER BY 1 FOR UPDATE;
+BEGIN
+    FOR r IN l_cur LOOP
+      UPDATE test1 SET b = b || ' ' || b WHERE a = r.a;
+      COMMIT;
+    END LOOP;
+END;
+$$;
+SELECT * FROM test1;
+ a |      b
+---+-------------
+ 1 | one one
+ 2 | two two
+ 3 | three three
+(3 rows)
+
+SELECT * FROM pg_cursors;
+ name | statement | is_holdable | is_binary | is_scrollable | creation_time
+------+-----------+-------------+-----------+---------------+---------------
+(0 rows)
+
 -- commit inside block with exception handler
 TRUNCATE test1;
 DO LANGUAGE plpgsql $$
diff --git a/src/pl/plpgsql/src/sql/plpgsql_transaction.sql b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
index 94fd406b7a..e65f840a0e 100644
--- a/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
+++ b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
@@ -273,6 +273,27 @@ SELECT * FROM test2;
 SELECT * FROM pg_cursors;


+-- interaction of FOR UPDATE cursor with subsequent updates (bug #17050)
+TRUNCATE test1;
+
+INSERT INTO test1 VALUES (1,'one'), (2,'two'), (3,'three');
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    l_cur CURSOR FOR SELECT a FROM test1 ORDER BY 1 FOR UPDATE;
+BEGIN
+    FOR r IN l_cur LOOP
+      UPDATE test1 SET b = b || ' ' || b WHERE a = r.a;
+      COMMIT;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+SELECT * FROM pg_cursors;
+
+
 -- commit inside block with exception handler
 TRUNCATE test1;


pgsql-bugs by date:

Previous
From: Tom Lane
Date:
Subject: Re: BUG #17050: cursor with for update + commit in loop
Next
From: Przemysław Biernat
Date:
Subject: Problem with the Polish language