mirror of
https://github.com/postgres/postgres.git
synced 2025-12-10 14:22:35 +03:00
Allow committing inside cursor loop
Previously, committing or aborting inside a cursor loop was prohibited because that would close and remove the cursor. To allow that, automatically convert such cursors to holdable cursors so they survive commits or rollbacks. Portals now have a new state "auto-held", which means they have been converted automatically from pinned. An auto-held portal is kept on transaction commit or rollback, but is still removed when returning to the main loop on error. This supports all languages that have cursor loop constructs: PL/pgSQL, PL/Python, PL/Perl. Reviewed-by: Ildus Kurbangaliev <i.kurbangaliev@postgrespro.ru>
This commit is contained in:
@@ -105,11 +105,44 @@ while (defined($row = spi_fetchrow($sth))) {
|
||||
spi_commit();
|
||||
}
|
||||
$$;
|
||||
ERROR: cannot commit transaction while a cursor is open at line 6.
|
||||
CONTEXT: PL/Perl anonymous code block
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
0 |
|
||||
1 |
|
||||
2 |
|
||||
3 |
|
||||
4 |
|
||||
(5 rows)
|
||||
|
||||
-- check that this doesn't leak a holdable portal
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- error in cursor loop with commit
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plperl $$
|
||||
my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
|
||||
my $row;
|
||||
while (defined($row = spi_fetchrow($sth))) {
|
||||
spi_exec_query("INSERT INTO test1 (a) VALUES (12/(" . $row->{x} . "-2))");
|
||||
spi_commit();
|
||||
}
|
||||
$$;
|
||||
ERROR: division by zero at line 5.
|
||||
CONTEXT: PL/Perl anonymous code block
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
-----+---
|
||||
-6 |
|
||||
-12 |
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- rollback inside cursor loop
|
||||
@@ -122,12 +155,42 @@ while (defined($row = spi_fetchrow($sth))) {
|
||||
spi_rollback();
|
||||
}
|
||||
$$;
|
||||
ERROR: cannot abort transaction while a cursor is open at line 6.
|
||||
CONTEXT: PL/Perl anonymous code block
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
(0 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- first commit then rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plperl $$
|
||||
my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
|
||||
my $row;
|
||||
while (defined($row = spi_fetchrow($sth))) {
|
||||
spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
|
||||
if ($row->{x} % 2 == 0) {
|
||||
spi_commit();
|
||||
} else {
|
||||
spi_rollback();
|
||||
}
|
||||
}
|
||||
$$;
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
0 |
|
||||
2 |
|
||||
4 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE test1;
|
||||
DROP TABLE test2;
|
||||
|
||||
@@ -3965,10 +3965,7 @@ plperl_spi_commit(void)
|
||||
|
||||
PG_TRY();
|
||||
{
|
||||
if (ThereArePinnedPortals())
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot commit transaction while a cursor is open")));
|
||||
HoldPinnedPortals();
|
||||
|
||||
SPI_commit();
|
||||
SPI_start_transaction();
|
||||
@@ -3995,10 +3992,7 @@ plperl_spi_rollback(void)
|
||||
|
||||
PG_TRY();
|
||||
{
|
||||
if (ThereArePinnedPortals())
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
|
||||
errmsg("cannot abort transaction while a cursor is open")));
|
||||
HoldPinnedPortals();
|
||||
|
||||
SPI_rollback();
|
||||
SPI_start_transaction();
|
||||
|
||||
@@ -100,6 +100,26 @@ $$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
-- check that this doesn't leak a holdable portal
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- error in cursor loop with commit
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plperl $$
|
||||
my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
|
||||
my $row;
|
||||
while (defined($row = spi_fetchrow($sth))) {
|
||||
spi_exec_query("INSERT INTO test1 (a) VALUES (12/(" . $row->{x} . "-2))");
|
||||
spi_commit();
|
||||
}
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
@@ -115,6 +135,29 @@ $$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- first commit then rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plperl $$
|
||||
my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
|
||||
my $row;
|
||||
while (defined($row = spi_fetchrow($sth))) {
|
||||
spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
|
||||
if ($row->{x} % 2 == 0) {
|
||||
spi_commit();
|
||||
} else {
|
||||
spi_rollback();
|
||||
}
|
||||
}
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
DROP TABLE test1;
|
||||
DROP TABLE test2;
|
||||
|
||||
@@ -195,11 +195,47 @@ BEGIN
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
ERROR: committing inside a cursor loop is not supported
|
||||
CONTEXT: PL/pgSQL function inline_code_block line 7 at COMMIT
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
0 |
|
||||
1 |
|
||||
2 |
|
||||
3 |
|
||||
4 |
|
||||
(5 rows)
|
||||
|
||||
-- check that this doesn't leak a holdable portal
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- error in cursor loop with commit
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
BEGIN
|
||||
FOR r IN SELECT * FROM test2 ORDER BY x LOOP
|
||||
INSERT INTO test1 (a) VALUES (12/(r.x-2));
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
ERROR: division by zero
|
||||
CONTEXT: SQL statement "INSERT INTO test1 (a) VALUES (12/(r.x-2))"
|
||||
PL/pgSQL function inline_code_block line 6 at SQL statement
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
-----+---
|
||||
-6 |
|
||||
-12 |
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- rollback inside cursor loop
|
||||
@@ -214,13 +250,79 @@ BEGIN
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
ERROR: cannot abort transaction inside a cursor loop
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
(0 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- first commit then rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
BEGIN
|
||||
FOR r IN SELECT * FROM test2 ORDER BY x LOOP
|
||||
INSERT INTO test1 (a) VALUES (r.x);
|
||||
IF r.x % 2 = 0 THEN
|
||||
COMMIT;
|
||||
ELSE
|
||||
ROLLBACK;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
0 |
|
||||
2 |
|
||||
4 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
BEGIN
|
||||
FOR r IN UPDATE test2 SET x = x * 2 RETURNING x LOOP
|
||||
INSERT INTO test1 (a) VALUES (r.x);
|
||||
ROLLBACK;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
ERROR: cannot perform transaction commands inside a cursor loop that is not read-only
|
||||
CONTEXT: PL/pgSQL function inline_code_block line 7 at ROLLBACK
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
(0 rows)
|
||||
|
||||
SELECT * FROM test2;
|
||||
x
|
||||
---
|
||||
0
|
||||
1
|
||||
2
|
||||
3
|
||||
4
|
||||
(5 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 $$
|
||||
|
||||
@@ -4677,14 +4677,7 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
|
||||
static int
|
||||
exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
|
||||
{
|
||||
/*
|
||||
* XXX This could be implemented by converting the pinned portals to
|
||||
* holdable ones and organizing the cleanup separately.
|
||||
*/
|
||||
if (ThereArePinnedPortals())
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("committing inside a cursor loop is not supported")));
|
||||
HoldPinnedPortals();
|
||||
|
||||
SPI_commit();
|
||||
SPI_start_transaction();
|
||||
@@ -4703,14 +4696,7 @@ exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
|
||||
static int
|
||||
exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
|
||||
{
|
||||
/*
|
||||
* Unlike the COMMIT case above, this might not make sense at all,
|
||||
* especially if the query driving the cursor loop has side effects.
|
||||
*/
|
||||
if (ThereArePinnedPortals())
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
|
||||
errmsg("cannot abort transaction inside a cursor loop")));
|
||||
HoldPinnedPortals();
|
||||
|
||||
SPI_rollback();
|
||||
SPI_start_transaction();
|
||||
|
||||
@@ -175,6 +175,28 @@ $$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
-- check that this doesn't leak a holdable portal
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- error in cursor loop with commit
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
BEGIN
|
||||
FOR r IN SELECT * FROM test2 ORDER BY x LOOP
|
||||
INSERT INTO test1 (a) VALUES (12/(r.x-2));
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
@@ -192,6 +214,51 @@ $$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- first commit then rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
BEGIN
|
||||
FOR r IN SELECT * FROM test2 ORDER BY x LOOP
|
||||
INSERT INTO test1 (a) VALUES (r.x);
|
||||
IF r.x % 2 = 0 THEN
|
||||
COMMIT;
|
||||
ELSE
|
||||
ROLLBACK;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
BEGIN
|
||||
FOR r IN UPDATE test2 SET x = x * 2 RETURNING x LOOP
|
||||
INSERT INTO test1 (a) VALUES (r.x);
|
||||
ROLLBACK;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
SELECT * FROM test2;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- commit inside block with exception handler
|
||||
TRUNCATE test1;
|
||||
|
||||
@@ -111,11 +111,44 @@ for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
|
||||
plpy.commit()
|
||||
$$;
|
||||
ERROR: cannot commit transaction while a cursor is open
|
||||
CONTEXT: PL/Python anonymous code block
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
0 |
|
||||
1 |
|
||||
2 |
|
||||
3 |
|
||||
4 |
|
||||
(5 rows)
|
||||
|
||||
-- check that this doesn't leak a holdable portal
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- error in cursor loop with commit
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plpythonu $$
|
||||
for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (12/(%s-2))" % row['x'])
|
||||
plpy.commit()
|
||||
$$;
|
||||
ERROR: spiexceptions.DivisionByZero: division by zero
|
||||
CONTEXT: Traceback (most recent call last):
|
||||
PL/Python anonymous code block, line 3, in <module>
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (12/(%s-2))" % row['x'])
|
||||
PL/Python anonymous code block
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
-----+---
|
||||
-6 |
|
||||
-12 |
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- rollback inside cursor loop
|
||||
@@ -125,12 +158,38 @@ for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
|
||||
plpy.rollback()
|
||||
$$;
|
||||
ERROR: cannot abort transaction while a cursor is open
|
||||
CONTEXT: PL/Python anonymous code block
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
(0 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
-- first commit then rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
DO LANGUAGE plpythonu $$
|
||||
for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
|
||||
if row['x'] % 2 == 0:
|
||||
plpy.commit()
|
||||
else:
|
||||
plpy.rollback()
|
||||
$$;
|
||||
SELECT * FROM test1;
|
||||
a | b
|
||||
---+---
|
||||
0 |
|
||||
2 |
|
||||
4 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
name | statement | is_holdable | is_binary | is_scrollable | creation_time
|
||||
------+-----------+-------------+-----------+---------------+---------------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE test1;
|
||||
DROP TABLE test2;
|
||||
|
||||
@@ -594,10 +594,7 @@ PLy_commit(PyObject *self, PyObject *args)
|
||||
{
|
||||
PLyExecutionContext *exec_ctx = PLy_current_execution_context();
|
||||
|
||||
if (ThereArePinnedPortals())
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot commit transaction while a cursor is open")));
|
||||
HoldPinnedPortals();
|
||||
|
||||
SPI_commit();
|
||||
SPI_start_transaction();
|
||||
@@ -613,10 +610,7 @@ PLy_rollback(PyObject *self, PyObject *args)
|
||||
{
|
||||
PLyExecutionContext *exec_ctx = PLy_current_execution_context();
|
||||
|
||||
if (ThereArePinnedPortals())
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
|
||||
errmsg("cannot abort transaction while a cursor is open")));
|
||||
HoldPinnedPortals();
|
||||
|
||||
SPI_rollback();
|
||||
SPI_start_transaction();
|
||||
|
||||
@@ -99,6 +99,23 @@ $$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
-- check that this doesn't leak a holdable portal
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- error in cursor loop with commit
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plpythonu $$
|
||||
for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (12/(%s-2))" % row['x'])
|
||||
plpy.commit()
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
@@ -111,6 +128,25 @@ $$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
-- first commit then rollback inside cursor loop
|
||||
TRUNCATE test1;
|
||||
|
||||
DO LANGUAGE plpythonu $$
|
||||
for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
|
||||
if row['x'] % 2 == 0:
|
||||
plpy.commit()
|
||||
else:
|
||||
plpy.rollback()
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
SELECT * FROM pg_cursors;
|
||||
|
||||
|
||||
DROP TABLE test1;
|
||||
DROP TABLE test2;
|
||||
|
||||
Reference in New Issue
Block a user