mirror of https://github.com/postgres/postgres
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>pull/28/merge
parent
b9ff79b8f1
commit
8561e4840c
@ -0,0 +1,133 @@ |
||||
CREATE TABLE test1 (a int, b text); |
||||
CREATE PROCEDURE transaction_test1() |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
foreach my $i (0..9) { |
||||
spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); |
||||
if ($i % 2 == 0) { |
||||
spi_commit(); |
||||
} else { |
||||
spi_rollback(); |
||||
} |
||||
} |
||||
$$; |
||||
CALL transaction_test1(); |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
TRUNCATE test1; |
||||
DO |
||||
LANGUAGE plperl |
||||
$$ |
||||
foreach my $i (0..9) { |
||||
spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); |
||||
if ($i % 2 == 0) { |
||||
spi_commit(); |
||||
} else { |
||||
spi_rollback(); |
||||
} |
||||
} |
||||
$$; |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
TRUNCATE test1; |
||||
-- not allowed in a function |
||||
CREATE FUNCTION transaction_test2() RETURNS int |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
foreach my $i (0..9) { |
||||
spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); |
||||
if ($i % 2 == 0) { |
||||
spi_commit(); |
||||
} else { |
||||
spi_rollback(); |
||||
} |
||||
} |
||||
return 1; |
||||
$$; |
||||
SELECT transaction_test2(); |
||||
ERROR: invalid transaction termination at line 5. |
||||
CONTEXT: PL/Perl function "transaction_test2" |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- also not allowed if procedure is called from a function |
||||
CREATE FUNCTION transaction_test3() RETURNS int |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
spi_exec_query("CALL transaction_test1()"); |
||||
return 1; |
||||
$$; |
||||
SELECT transaction_test3(); |
||||
ERROR: invalid transaction termination at line 5. at line 2. |
||||
CONTEXT: PL/Perl function "transaction_test3" |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- DO block inside function |
||||
CREATE FUNCTION transaction_test4() RETURNS int |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$'); |
||||
return 1; |
||||
$$; |
||||
SELECT transaction_test4(); |
||||
ERROR: invalid transaction termination at line 1. at line 2. |
||||
CONTEXT: PL/Perl function "transaction_test4" |
||||
-- commit inside cursor loop |
||||
CREATE TABLE test2 (x int); |
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4); |
||||
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} . ")"); |
||||
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 rows) |
||||
|
||||
-- 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} . ")"); |
||||
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) |
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
@ -0,0 +1,120 @@ |
||||
CREATE TABLE test1 (a int, b text); |
||||
|
||||
|
||||
CREATE PROCEDURE transaction_test1() |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
foreach my $i (0..9) { |
||||
spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); |
||||
if ($i % 2 == 0) { |
||||
spi_commit(); |
||||
} else { |
||||
spi_rollback(); |
||||
} |
||||
} |
||||
$$; |
||||
|
||||
CALL transaction_test1(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
TRUNCATE test1; |
||||
|
||||
DO |
||||
LANGUAGE plperl |
||||
$$ |
||||
foreach my $i (0..9) { |
||||
spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); |
||||
if ($i % 2 == 0) { |
||||
spi_commit(); |
||||
} else { |
||||
spi_rollback(); |
||||
} |
||||
} |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
TRUNCATE test1; |
||||
|
||||
-- not allowed in a function |
||||
CREATE FUNCTION transaction_test2() RETURNS int |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
foreach my $i (0..9) { |
||||
spi_exec_query("INSERT INTO test1 (a) VALUES ($i)"); |
||||
if ($i % 2 == 0) { |
||||
spi_commit(); |
||||
} else { |
||||
spi_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 plperl |
||||
AS $$ |
||||
spi_exec_query("CALL transaction_test1()"); |
||||
return 1; |
||||
$$; |
||||
|
||||
SELECT transaction_test3(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- DO block inside function |
||||
CREATE FUNCTION transaction_test4() RETURNS int |
||||
LANGUAGE plperl |
||||
AS $$ |
||||
spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$'); |
||||
return 1; |
||||
$$; |
||||
|
||||
SELECT transaction_test4(); |
||||
|
||||
|
||||
-- commit inside cursor loop |
||||
CREATE TABLE test2 (x int); |
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4); |
||||
|
||||
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} . ")"); |
||||
spi_commit(); |
||||
} |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- 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} . ")"); |
||||
spi_rollback(); |
||||
} |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
@ -0,0 +1,241 @@ |
||||
CREATE TABLE test1 (a int, b text); |
||||
CREATE PROCEDURE transaction_test1() |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
FOR i IN 0..9 LOOP |
||||
INSERT INTO test1 (a) VALUES (i); |
||||
IF i % 2 = 0 THEN |
||||
COMMIT; |
||||
ELSE |
||||
ROLLBACK; |
||||
END IF; |
||||
END LOOP; |
||||
END |
||||
$$; |
||||
CALL transaction_test1(); |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
TRUNCATE test1; |
||||
DO |
||||
LANGUAGE plpgsql |
||||
$$ |
||||
BEGIN |
||||
FOR i IN 0..9 LOOP |
||||
INSERT INTO test1 (a) VALUES (i); |
||||
IF i % 2 = 0 THEN |
||||
COMMIT; |
||||
ELSE |
||||
ROLLBACK; |
||||
END IF; |
||||
END LOOP; |
||||
END |
||||
$$; |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
-- transaction commands not allowed when called in transaction block |
||||
START TRANSACTION; |
||||
CALL transaction_test1(); |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/pgSQL function transaction_test1() line 6 at COMMIT |
||||
COMMIT; |
||||
START TRANSACTION; |
||||
DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$; |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/pgSQL function inline_code_block line 1 at COMMIT |
||||
COMMIT; |
||||
TRUNCATE test1; |
||||
-- not allowed in a function |
||||
CREATE FUNCTION transaction_test2() RETURNS int |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
FOR i IN 0..9 LOOP |
||||
INSERT INTO test1 (a) VALUES (i); |
||||
IF i % 2 = 0 THEN |
||||
COMMIT; |
||||
ELSE |
||||
ROLLBACK; |
||||
END IF; |
||||
END LOOP; |
||||
RETURN 1; |
||||
END |
||||
$$; |
||||
SELECT transaction_test2(); |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/pgSQL function transaction_test2() line 6 at COMMIT |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- also not allowed if procedure is called from a function |
||||
CREATE FUNCTION transaction_test3() RETURNS int |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
CALL transaction_test1(); |
||||
RETURN 1; |
||||
END; |
||||
$$; |
||||
SELECT transaction_test3(); |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/pgSQL function transaction_test1() line 6 at COMMIT |
||||
SQL statement "CALL transaction_test1()" |
||||
PL/pgSQL function transaction_test3() line 3 at SQL statement |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- DO block inside function |
||||
CREATE FUNCTION transaction_test4() RETURNS int |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$'; |
||||
RETURN 1; |
||||
END; |
||||
$$; |
||||
SELECT transaction_test4(); |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/pgSQL function inline_code_block line 1 at COMMIT |
||||
SQL statement "DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$" |
||||
PL/pgSQL function transaction_test4() line 3 at EXECUTE |
||||
-- proconfig settings currently disallow transaction statements |
||||
CREATE PROCEDURE transaction_test5() |
||||
LANGUAGE plpgsql |
||||
SET work_mem = 555 |
||||
AS $$ |
||||
BEGIN |
||||
COMMIT; |
||||
END; |
||||
$$; |
||||
CALL transaction_test5(); |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/pgSQL function transaction_test5() line 3 at COMMIT |
||||
-- commit inside cursor loop |
||||
CREATE TABLE test2 (x int); |
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4); |
||||
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); |
||||
COMMIT; |
||||
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 rows) |
||||
|
||||
-- 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); |
||||
ROLLBACK; |
||||
END LOOP; |
||||
END; |
||||
$$; |
||||
ERROR: cannot abort transaction inside a cursor loop |
||||
CONTEXT: PL/pgSQL function inline_code_block line 7 at ROLLBACK |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- commit inside block with exception handler |
||||
TRUNCATE test1; |
||||
DO LANGUAGE plpgsql $$ |
||||
BEGIN |
||||
BEGIN |
||||
INSERT INTO test1 (a) VALUES (1); |
||||
COMMIT; |
||||
INSERT INTO test1 (a) VALUES (1/0); |
||||
COMMIT; |
||||
EXCEPTION |
||||
WHEN division_by_zero THEN |
||||
RAISE NOTICE 'caught division_by_zero'; |
||||
END; |
||||
END; |
||||
$$; |
||||
ERROR: cannot commit while a subtransaction is active |
||||
CONTEXT: PL/pgSQL function inline_code_block line 5 at COMMIT |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- rollback inside block with exception handler |
||||
TRUNCATE test1; |
||||
DO LANGUAGE plpgsql $$ |
||||
BEGIN |
||||
BEGIN |
||||
INSERT INTO test1 (a) VALUES (1); |
||||
ROLLBACK; |
||||
INSERT INTO test1 (a) VALUES (1/0); |
||||
ROLLBACK; |
||||
EXCEPTION |
||||
WHEN division_by_zero THEN |
||||
RAISE NOTICE 'caught division_by_zero'; |
||||
END; |
||||
END; |
||||
$$; |
||||
ERROR: cannot roll back while a subtransaction is active |
||||
CONTEXT: PL/pgSQL function inline_code_block line 5 at ROLLBACK |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- COMMIT failures |
||||
DO LANGUAGE plpgsql $$ |
||||
BEGIN |
||||
CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED); |
||||
COMMIT; |
||||
INSERT INTO test3 (y) VALUES (1); |
||||
COMMIT; |
||||
INSERT INTO test3 (y) VALUES (1); |
||||
INSERT INTO test3 (y) VALUES (2); |
||||
COMMIT; |
||||
INSERT INTO test3 (y) VALUES (3); -- won't get here |
||||
END; |
||||
$$; |
||||
ERROR: duplicate key value violates unique constraint "test3_y_key" |
||||
DETAIL: Key (y)=(1) already exists. |
||||
CONTEXT: PL/pgSQL function inline_code_block line 9 at COMMIT |
||||
SELECT * FROM test3; |
||||
y |
||||
--- |
||||
1 |
||||
(1 row) |
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
DROP TABLE test3; |
||||
@ -0,0 +1,215 @@ |
||||
CREATE TABLE test1 (a int, b text); |
||||
|
||||
|
||||
CREATE PROCEDURE transaction_test1() |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
FOR i IN 0..9 LOOP |
||||
INSERT INTO test1 (a) VALUES (i); |
||||
IF i % 2 = 0 THEN |
||||
COMMIT; |
||||
ELSE |
||||
ROLLBACK; |
||||
END IF; |
||||
END LOOP; |
||||
END |
||||
$$; |
||||
|
||||
CALL transaction_test1(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
TRUNCATE test1; |
||||
|
||||
DO |
||||
LANGUAGE plpgsql |
||||
$$ |
||||
BEGIN |
||||
FOR i IN 0..9 LOOP |
||||
INSERT INTO test1 (a) VALUES (i); |
||||
IF i % 2 = 0 THEN |
||||
COMMIT; |
||||
ELSE |
||||
ROLLBACK; |
||||
END IF; |
||||
END LOOP; |
||||
END |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- transaction commands not allowed when called in transaction block |
||||
START TRANSACTION; |
||||
CALL transaction_test1(); |
||||
COMMIT; |
||||
|
||||
START TRANSACTION; |
||||
DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$; |
||||
COMMIT; |
||||
|
||||
|
||||
TRUNCATE test1; |
||||
|
||||
-- not allowed in a function |
||||
CREATE FUNCTION transaction_test2() RETURNS int |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
FOR i IN 0..9 LOOP |
||||
INSERT INTO test1 (a) VALUES (i); |
||||
IF i % 2 = 0 THEN |
||||
COMMIT; |
||||
ELSE |
||||
ROLLBACK; |
||||
END IF; |
||||
END LOOP; |
||||
RETURN 1; |
||||
END |
||||
$$; |
||||
|
||||
SELECT transaction_test2(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- also not allowed if procedure is called from a function |
||||
CREATE FUNCTION transaction_test3() RETURNS int |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
CALL transaction_test1(); |
||||
RETURN 1; |
||||
END; |
||||
$$; |
||||
|
||||
SELECT transaction_test3(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- DO block inside function |
||||
CREATE FUNCTION transaction_test4() RETURNS int |
||||
LANGUAGE plpgsql |
||||
AS $$ |
||||
BEGIN |
||||
EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$'; |
||||
RETURN 1; |
||||
END; |
||||
$$; |
||||
|
||||
SELECT transaction_test4(); |
||||
|
||||
|
||||
-- proconfig settings currently disallow transaction statements |
||||
CREATE PROCEDURE transaction_test5() |
||||
LANGUAGE plpgsql |
||||
SET work_mem = 555 |
||||
AS $$ |
||||
BEGIN |
||||
COMMIT; |
||||
END; |
||||
$$; |
||||
|
||||
CALL transaction_test5(); |
||||
|
||||
|
||||
-- commit inside cursor loop |
||||
CREATE TABLE test2 (x int); |
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4); |
||||
|
||||
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); |
||||
COMMIT; |
||||
END LOOP; |
||||
END; |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- 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); |
||||
ROLLBACK; |
||||
END LOOP; |
||||
END; |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- commit inside block with exception handler |
||||
TRUNCATE test1; |
||||
|
||||
DO LANGUAGE plpgsql $$ |
||||
BEGIN |
||||
BEGIN |
||||
INSERT INTO test1 (a) VALUES (1); |
||||
COMMIT; |
||||
INSERT INTO test1 (a) VALUES (1/0); |
||||
COMMIT; |
||||
EXCEPTION |
||||
WHEN division_by_zero THEN |
||||
RAISE NOTICE 'caught division_by_zero'; |
||||
END; |
||||
END; |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- rollback inside block with exception handler |
||||
TRUNCATE test1; |
||||
|
||||
DO LANGUAGE plpgsql $$ |
||||
BEGIN |
||||
BEGIN |
||||
INSERT INTO test1 (a) VALUES (1); |
||||
ROLLBACK; |
||||
INSERT INTO test1 (a) VALUES (1/0); |
||||
ROLLBACK; |
||||
EXCEPTION |
||||
WHEN division_by_zero THEN |
||||
RAISE NOTICE 'caught division_by_zero'; |
||||
END; |
||||
END; |
||||
$$; |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- COMMIT failures |
||||
DO LANGUAGE plpgsql $$ |
||||
BEGIN |
||||
CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED); |
||||
COMMIT; |
||||
INSERT INTO test3 (y) VALUES (1); |
||||
COMMIT; |
||||
INSERT INTO test3 (y) VALUES (1); |
||||
INSERT INTO test3 (y) VALUES (2); |
||||
COMMIT; |
||||
INSERT INTO test3 (y) VALUES (3); -- won't get here |
||||
END; |
||||
$$; |
||||
|
||||
SELECT * FROM test3; |
||||
|
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
DROP TABLE test3; |
||||
@ -0,0 +1,135 @@ |
||||
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; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
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; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
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(); |
||||
ERROR: invalid transaction termination |
||||
CONTEXT: PL/Python function "transaction_test2" |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- 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(); |
||||
ERROR: spiexceptions.InvalidTransactionTermination: invalid transaction termination |
||||
CONTEXT: Traceback (most recent call last): |
||||
PL/Python function "transaction_test3", line 2, in <module> |
||||
plpy.execute("CALL transaction_test1()") |
||||
PL/Python function "transaction_test3" |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- 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(); |
||||
ERROR: spiexceptions.InvalidTransactionTermination: invalid transaction termination |
||||
CONTEXT: Traceback (most recent call last): |
||||
PL/Python function "transaction_test4", line 2, in <module> |
||||
plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$") |
||||
PL/Python function "transaction_test4" |
||||
-- commit inside subtransaction (prohibited) |
||||
DO LANGUAGE plpythonu $$ |
||||
with plpy.subtransaction(): |
||||
plpy.commit() |
||||
$$; |
||||
WARNING: forcibly aborting a subtransaction that has not been exited |
||||
ERROR: cannot commit while a subtransaction is active |
||||
CONTEXT: PL/Python anonymous code block |
||||
-- 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() |
||||
$$; |
||||
ERROR: cannot commit transaction while a cursor is open |
||||
CONTEXT: PL/Python anonymous code block |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- 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() |
||||
$$; |
||||
ERROR: cannot abort transaction while a cursor is open |
||||
CONTEXT: PL/Python anonymous code block |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
@ -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; |
||||
@ -0,0 +1,100 @@ |
||||
-- suppress CONTEXT so that function OIDs aren't in output |
||||
\set VERBOSITY terse |
||||
CREATE TABLE test1 (a int, b text); |
||||
CREATE PROCEDURE transaction_test1() |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
for {set i 0} {$i < 10} {incr i} { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($i)" |
||||
if {$i % 2 == 0} { |
||||
commit |
||||
} else { |
||||
rollback |
||||
} |
||||
} |
||||
$$; |
||||
CALL transaction_test1(); |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
0 | |
||||
2 | |
||||
4 | |
||||
6 | |
||||
8 | |
||||
(5 rows) |
||||
|
||||
TRUNCATE test1; |
||||
-- not allowed in a function |
||||
CREATE FUNCTION transaction_test2() RETURNS int |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
for {set i 0} {$i < 10} {incr i} { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($i)" |
||||
if {$i % 2 == 0} { |
||||
commit |
||||
} else { |
||||
rollback |
||||
} |
||||
} |
||||
return 1 |
||||
$$; |
||||
SELECT transaction_test2(); |
||||
ERROR: invalid transaction termination |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- also not allowed if procedure is called from a function |
||||
CREATE FUNCTION transaction_test3() RETURNS int |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
spi_exec "CALL transaction_test1()" |
||||
return 1 |
||||
$$; |
||||
SELECT transaction_test3(); |
||||
ERROR: invalid transaction termination |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- commit inside cursor loop |
||||
CREATE TABLE test2 (x int); |
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4); |
||||
TRUNCATE test1; |
||||
CREATE PROCEDURE transaction_test4a() |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
spi_exec -array row "SELECT * FROM test2 ORDER BY x" { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($row(x))" |
||||
commit |
||||
} |
||||
$$; |
||||
CALL transaction_test4a(); |
||||
ERROR: cannot commit while a subtransaction is active |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
-- rollback inside cursor loop |
||||
TRUNCATE test1; |
||||
CREATE PROCEDURE transaction_test4b() |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
spi_exec -array row "SELECT * FROM test2 ORDER BY x" { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($row(x))" |
||||
rollback |
||||
} |
||||
$$; |
||||
CALL transaction_test4b(); |
||||
ERROR: cannot roll back while a subtransaction is active |
||||
SELECT * FROM test1; |
||||
a | b |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
@ -0,0 +1,98 @@ |
||||
-- suppress CONTEXT so that function OIDs aren't in output |
||||
\set VERBOSITY terse |
||||
|
||||
CREATE TABLE test1 (a int, b text); |
||||
|
||||
|
||||
CREATE PROCEDURE transaction_test1() |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
for {set i 0} {$i < 10} {incr i} { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($i)" |
||||
if {$i % 2 == 0} { |
||||
commit |
||||
} else { |
||||
rollback |
||||
} |
||||
} |
||||
$$; |
||||
|
||||
CALL transaction_test1(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
TRUNCATE test1; |
||||
|
||||
-- not allowed in a function |
||||
CREATE FUNCTION transaction_test2() RETURNS int |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
for {set i 0} {$i < 10} {incr i} { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($i)" |
||||
if {$i % 2 == 0} { |
||||
commit |
||||
} else { |
||||
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 pltcl |
||||
AS $$ |
||||
spi_exec "CALL transaction_test1()" |
||||
return 1 |
||||
$$; |
||||
|
||||
SELECT transaction_test3(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- commit inside cursor loop |
||||
CREATE TABLE test2 (x int); |
||||
INSERT INTO test2 VALUES (0), (1), (2), (3), (4); |
||||
|
||||
TRUNCATE test1; |
||||
|
||||
CREATE PROCEDURE transaction_test4a() |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
spi_exec -array row "SELECT * FROM test2 ORDER BY x" { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($row(x))" |
||||
commit |
||||
} |
||||
$$; |
||||
|
||||
CALL transaction_test4a(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
-- rollback inside cursor loop |
||||
TRUNCATE test1; |
||||
|
||||
CREATE PROCEDURE transaction_test4b() |
||||
LANGUAGE pltcl |
||||
AS $$ |
||||
spi_exec -array row "SELECT * FROM test2 ORDER BY x" { |
||||
spi_exec "INSERT INTO test1 (a) VALUES ($row(x))" |
||||
rollback |
||||
} |
||||
$$; |
||||
|
||||
CALL transaction_test4b(); |
||||
|
||||
SELECT * FROM test1; |
||||
|
||||
|
||||
DROP TABLE test1; |
||||
DROP TABLE test2; |
||||
Loading…
Reference in new issue