mirror of
https://github.com/postgres/postgres.git
synced 2025-12-12 02:37:31 +03:00
Transaction control in PL procedures
In each of the supplied procedural languages (PL/pgSQL, PL/Perl, PL/Python, PL/Tcl), add language-specific commit and rollback functions/commands to control transactions in procedures in that language. Add similar underlying functions to SPI. Some additional cleanup so that transaction commit or abort doesn't blow away data structures still used by the procedure call. Add execution context tracking to CALL and DO statements so that transaction control commands can only be issued in top-level procedure and block calls, not function calls or other procedure or block calls. - SPI Add a new function SPI_connect_ext() that is like SPI_connect() but allows passing option flags. The only option flag right now is SPI_OPT_NONATOMIC. A nonatomic SPI connection can execute transaction control commands, otherwise it's not allowed. This is meant to be passed down from CALL and DO statements which themselves know in which context they are called. A nonatomic SPI connection uses different memory management. A normal SPI connection allocates its memory in TopTransactionContext. For nonatomic connections we use PortalContext instead. As the comment in SPI_connect_ext() (previously SPI_connect()) indicates, one could potentially use PortalContext in all cases, but it seems safest to leave the existing uses alone, because this stuff is complicated enough already. SPI also gets new functions SPI_start_transaction(), SPI_commit(), and SPI_rollback(), which can be used by PLs to implement their transaction control logic. - portalmem.c Some adjustments were made in the code that cleans up portals at transaction abort. The portal code could already handle a command *committing* a transaction and continuing (e.g., VACUUM), but it was not quite prepared for a command *aborting* a transaction and continuing. In AtAbort_Portals(), remove the code that marks an active portal as failed. As the comment there already predicted, this doesn't work if the running command wants to keep running after transaction abort. And it's actually not necessary, because pquery.c is careful to run all portal code in a PG_TRY block and explicitly runs MarkPortalFailed() if there is an exception. So the code in AtAbort_Portals() is never used anyway. In AtAbort_Portals() and AtCleanup_Portals(), we need to be careful not to clean up active portals too much. This mirrors similar code in PreCommit_Portals(). - PL/Perl Gets new functions spi_commit() and spi_rollback() - PL/pgSQL Gets new commands COMMIT and ROLLBACK. Update the PL/SQL porting example in the documentation to reflect that transactions are now possible in procedures. - PL/Python Gets new functions plpy.commit and plpy.rollback. - PL/Tcl Gets new commands commit and rollback. Reviewed-by: Andrew Dunstan <andrew.dunstan@2ndquadrant.com>
This commit is contained in:
115
src/pl/plpython/sql/plpython_transaction.sql
Normal file
115
src/pl/plpython/sql/plpython_transaction.sql
Normal file
@@ -0,0 +1,115 @@
|
||||
CREATE TABLE test1 (a int, b text);
|
||||
|
||||
|
||||
CREATE PROCEDURE transaction_test1()
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
for i in range(0, 10):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
|
||||
if i % 2 == 0:
|
||||
plpy.commit()
|
||||
else:
|
||||
plpy.rollback()
|
||||
$$;
|
||||
|
||||
CALL transaction_test1();
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
TRUNCATE test1;
|
||||
|
||||
DO
|
||||
LANGUAGE plpythonu
|
||||
$$
|
||||
for i in range(0, 10):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
|
||||
if i % 2 == 0:
|
||||
plpy.commit()
|
||||
else:
|
||||
plpy.rollback()
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
TRUNCATE test1;
|
||||
|
||||
-- not allowed in a function
|
||||
CREATE FUNCTION transaction_test2() RETURNS int
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
for i in range(0, 10):
|
||||
plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
|
||||
if i % 2 == 0:
|
||||
plpy.commit()
|
||||
else:
|
||||
plpy.rollback()
|
||||
return 1
|
||||
$$;
|
||||
|
||||
SELECT transaction_test2();
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
-- also not allowed if procedure is called from a function
|
||||
CREATE FUNCTION transaction_test3() RETURNS int
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
plpy.execute("CALL transaction_test1()")
|
||||
return 1
|
||||
$$;
|
||||
|
||||
SELECT transaction_test3();
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
-- DO block inside function
|
||||
CREATE FUNCTION transaction_test4() RETURNS int
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
|
||||
return 1
|
||||
$$;
|
||||
|
||||
SELECT transaction_test4();
|
||||
|
||||
|
||||
-- commit inside subtransaction (prohibited)
|
||||
DO LANGUAGE plpythonu $$
|
||||
with plpy.subtransaction():
|
||||
plpy.commit()
|
||||
$$;
|
||||
|
||||
|
||||
-- commit inside cursor loop
|
||||
CREATE TABLE test2 (x int);
|
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
|
||||
|
||||
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'])
|
||||
plpy.commit()
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
-- 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'])
|
||||
plpy.rollback()
|
||||
$$;
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
DROP TABLE test1;
|
||||
DROP TABLE test2;
|
||||
Reference in New Issue
Block a user