Files
postgresql/src/pl/plpgsql/src/expected/plpgsql_transaction.out
Tom Lane 22f2a98cf3 Redesign the caching done by get_cached_rowtype().
Previously, get_cached_rowtype() cached a pointer to a reference-counted
tuple descriptor from the typcache, relying on the ExprContextCallback
mechanism to release the tupdesc refcount when the expression tree
using the tupdesc was destroyed.  This worked fine when it was designed,
but the introduction of within-DO-block COMMITs broke it.  The refcount
is logged in a transaction-lifespan resource owner, but plpgsql won't
destroy simple expressions made within the DO block (before its first
commit) until the DO block is exited.  That results in a warning about
a leaked tupdesc refcount when the COMMIT destroys the original resource
owner, and then an error about the active resource owner not holding a
matching refcount when the expression is destroyed.

To fix, get rid of the need to have a shutdown callback at all, by
instead caching a pointer to the relevant typcache entry.  Those
survive for the life of the backend, so we needn't worry about the
pointer becoming stale.  (For registered RECORD types, we can still
cache a pointer to the tupdesc, knowing that it won't change for the
life of the backend.)  This mechanism has been in use in plpgsql
and expandedrecord.c since commit 4b93f5799, and seems to work well.

This change requires modifying the ExprEvalStep structs used by the
relevant expression step types, which is slightly worrisome for
back-patching.  However, there seems no good reason for extensions
to be familiar with the details of these particular sub-structs.

Per report from Rohit Bhogate.  Back-patch to v11 where within-DO-block
COMMITs became a thing.

Discussion: https://postgr.es/m/CAAV6ZkQRCVBh8qAY+SZiHnz+U+FqAGBBDaDTjF2yiKa2nJSLKg@mail.gmail.com
2021-04-13 13:37:07 -04:00

597 lines
13 KiB
Plaintext

CREATE TABLE test1 (a int, b text);
CREATE PROCEDURE transaction_test1(x int, y text)
LANGUAGE plpgsql
AS $$
BEGIN
FOR i IN 0..x LOOP
INSERT INTO test1 (a, b) VALUES (i, y);
IF i % 2 = 0 THEN
COMMIT;
ELSE
ROLLBACK;
END IF;
END LOOP;
END
$$;
CALL transaction_test1(9, 'foo');
SELECT * FROM test1;
a | b
---+-----
0 | foo
2 | foo
4 | foo
6 | foo
8 | foo
(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(9, 'error');
ERROR: invalid transaction termination
CONTEXT: PL/pgSQL function transaction_test1(integer,text) 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(9, 'error');
RETURN 1;
END;
$$;
SELECT transaction_test3();
ERROR: invalid transaction termination
CONTEXT: PL/pgSQL function transaction_test1(integer,text) line 6 at COMMIT
SQL statement "CALL transaction_test1(9, 'error')"
PL/pgSQL function transaction_test3() line 3 at CALL
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
-- SECURITY DEFINER currently disallow transaction statements
CREATE PROCEDURE transaction_test5b()
LANGUAGE plpgsql
SECURITY DEFINER
AS $$
BEGIN
COMMIT;
END;
$$;
CALL transaction_test5b();
ERROR: invalid transaction termination
CONTEXT: PL/pgSQL function transaction_test5b() line 3 at COMMIT
TRUNCATE test1;
-- nested procedure calls
CREATE PROCEDURE transaction_test6(c text)
LANGUAGE plpgsql
AS $$
BEGIN
CALL transaction_test1(9, c);
END;
$$;
CALL transaction_test6('bar');
SELECT * FROM test1;
a | b
---+-----
0 | bar
2 | bar
4 | bar
6 | bar
8 | bar
(5 rows)
TRUNCATE test1;
CREATE PROCEDURE transaction_test7()
LANGUAGE plpgsql
AS $$
BEGIN
DO 'BEGIN CALL transaction_test1(9, $x$baz$x$); END;';
END;
$$;
CALL transaction_test7();
SELECT * FROM test1;
a | b
---+-----
0 | baz
2 | baz
4 | baz
6 | baz
8 | baz
(5 rows)
CREATE PROCEDURE transaction_test8()
LANGUAGE plpgsql
AS $$
BEGIN
EXECUTE 'CALL transaction_test1(10, $x$baz$x$)';
END;
$$;
CALL transaction_test8();
ERROR: invalid transaction termination
CONTEXT: PL/pgSQL function transaction_test1(integer,text) line 6 at COMMIT
SQL statement "CALL transaction_test1(10, $x$baz$x$)"
PL/pgSQL function transaction_test8() line 3 at EXECUTE
-- 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;
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
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;
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 $$
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)
-- operations on composite types vs. internal transactions
DO LANGUAGE plpgsql $$
declare
c test1 := row(42, 'hello');
r bool;
begin
for i in 1..3 loop
r := c is not null;
raise notice 'r = %', r;
commit;
end loop;
for i in 1..3 loop
r := c is null;
raise notice 'r = %', r;
rollback;
end loop;
end
$$;
NOTICE: r = t
NOTICE: r = t
NOTICE: r = t
NOTICE: r = f
NOTICE: r = f
NOTICE: r = f
-- 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)
-- failure while trying to persist a cursor across a transaction (bug #15703)
CREATE PROCEDURE cursor_fail_during_commit()
LANGUAGE plpgsql
AS $$
DECLARE id int;
BEGIN
FOR id IN SELECT 1/(x-1000) FROM generate_series(1,1000) x LOOP
INSERT INTO test1 VALUES(id);
COMMIT;
END LOOP;
END;
$$;
TRUNCATE test1;
CALL cursor_fail_during_commit();
ERROR: division by zero
CONTEXT: PL/pgSQL function cursor_fail_during_commit() line 6 at COMMIT
-- note that error occurs during first COMMIT, hence nothing is in test1
SELECT count(*) FROM test1;
count
-------
0
(1 row)
CREATE PROCEDURE cursor_fail_during_rollback()
LANGUAGE plpgsql
AS $$
DECLARE id int;
BEGIN
FOR id IN SELECT 1/(x-1000) FROM generate_series(1,1000) x LOOP
INSERT INTO test1 VALUES(id);
ROLLBACK;
END LOOP;
END;
$$;
TRUNCATE test1;
CALL cursor_fail_during_rollback();
ERROR: division by zero
CONTEXT: PL/pgSQL function cursor_fail_during_rollback() line 6 at ROLLBACK
SELECT count(*) FROM test1;
count
-------
0
(1 row)
-- SET TRANSACTION
DO LANGUAGE plpgsql $$
BEGIN
PERFORM 1;
RAISE INFO '%', current_setting('transaction_isolation');
COMMIT;
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
PERFORM 1;
RAISE INFO '%', current_setting('transaction_isolation');
COMMIT;
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
RESET TRANSACTION ISOLATION LEVEL;
PERFORM 1;
RAISE INFO '%', current_setting('transaction_isolation');
COMMIT;
END;
$$;
INFO: read committed
INFO: repeatable read
INFO: read committed
-- error cases
DO LANGUAGE plpgsql $$
BEGIN
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
END;
$$;
ERROR: SET TRANSACTION ISOLATION LEVEL must be called before any query
CONTEXT: SQL statement "SET TRANSACTION ISOLATION LEVEL REPEATABLE READ"
PL/pgSQL function inline_code_block line 3 at SET
DO LANGUAGE plpgsql $$
BEGIN
SAVEPOINT foo;
END;
$$;
ERROR: unsupported transaction command in PL/pgSQL
CONTEXT: PL/pgSQL function inline_code_block line 3 at SQL statement
DO LANGUAGE plpgsql $$
BEGIN
EXECUTE 'COMMIT';
END;
$$;
ERROR: EXECUTE of transaction commands is not implemented
CONTEXT: PL/pgSQL function inline_code_block line 3 at EXECUTE
-- snapshot handling test
TRUNCATE test2;
CREATE PROCEDURE transaction_test9()
LANGUAGE SQL
AS $$
INSERT INTO test2 VALUES (42);
$$;
DO LANGUAGE plpgsql $$
BEGIN
ROLLBACK;
CALL transaction_test9();
END
$$;
SELECT * FROM test2;
x
----
42
(1 row)
-- Test transaction in procedure with output parameters. This uses a
-- different portal strategy and different code paths in pquery.c.
CREATE PROCEDURE transaction_test10a(INOUT x int)
LANGUAGE plpgsql
AS $$
BEGIN
x := x + 1;
COMMIT;
END;
$$;
CALL transaction_test10a(10);
x
----
11
(1 row)
CREATE PROCEDURE transaction_test10b(INOUT x int)
LANGUAGE plpgsql
AS $$
BEGIN
x := x - 1;
ROLLBACK;
END;
$$;
CALL transaction_test10b(10);
x
---
9
(1 row)
-- transaction timestamp vs. statement timestamp
CREATE PROCEDURE transaction_test11()
LANGUAGE plpgsql
AS $$
DECLARE
s1 timestamp with time zone;
s2 timestamp with time zone;
s3 timestamp with time zone;
t1 timestamp with time zone;
t2 timestamp with time zone;
t3 timestamp with time zone;
BEGIN
s1 := statement_timestamp();
t1 := transaction_timestamp();
ASSERT s1 = t1;
PERFORM pg_sleep(0.001);
COMMIT;
s2 := statement_timestamp();
t2 := transaction_timestamp();
ASSERT s2 = s1;
ASSERT t2 > t1;
PERFORM pg_sleep(0.001);
ROLLBACK;
s3 := statement_timestamp();
t3 := transaction_timestamp();
ASSERT s3 = s1;
ASSERT t3 > t2;
END;
$$;
CALL transaction_test11();
DROP TABLE test1;
DROP TABLE test2;
DROP TABLE test3;