Can a Postgres Commit Exist in Procedure that has an Exception Block?
The problem is the EXCEPTION
clause.
This is implemented in PL/pgSQL as a subtransaction (the same thing as a SAVEPOINT
in SQL), which is rolled back when the exception block is reached.
You cannot COMMIT
while a subtransaction is active.
See this comment in src/backend/executor/spi.c
:
/*
* This restriction is required by PLs implemented on top of SPI. They
* use subtransactions to establish exception blocks that are supposed to
* be rolled back together if there is an error. Terminating the
* top-level transaction in such a block violates that idea. A future PL
* implementation might have different ideas about this, in which case
* this restriction would have to be refined or the check possibly be
* moved out of SPI into the PLs.
*/
if (IsSubTransaction())
ereport(ERROR,
(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
errmsg("cannot commit while a subtransaction is active")));
The semantics of PL/pgSQL's error handling dictate that:
When an error is caught by an EXCEPTION clause ... all changes to persistent database state within the block are rolled back.
This is implemented using subtransactions, which are basically the same as savepoints. In other words, when you run the following PL/pgSQL code:
BEGIN
PERFORM foo();
EXCEPTION WHEN others THEN
PERFORM handle_error();
END
...what's actually happening is something like this:
BEGIN
SAVEPOINT a;
PERFORM foo();
RELEASE SAVEPOINT a;
EXCEPTION WHEN others THEN
ROLLBACK TO SAVEPOINT a;
PERFORM handle_error();
END
A COMMIT
within the block would break this completely; your changes would be made permanent, the savepoint would be discarded, and the exception handler would be left with no way to roll back. As a result, commits are not allowed in this context, and trying to execute a COMMIT
will result in a "cannot commit while a subtransaction is active" error.
That's why you see your procedure jump to the exception handler instead of running the raise notice 'B'
: when it reaches the commit
, it throws an error, and the handler catches it.
This is fairly straightforward to work around, though. BEGIN ... END
blocks can be nested, and only blocks with EXCEPTION
clauses involve setting savepoints, so you can just wrap the commands before and after the commit in their own exception handlers:
create or replace procedure x_transaction_try() language plpgsql
as $$
declare
my_ex_state text;
my_ex_message text;
my_ex_detail text;
my_ex_hint text;
my_ex_ctx text;
begin
begin
raise notice 'A';
exception when others then
raise notice 'C';
GET STACKED DIAGNOSTICS
my_ex_state = RETURNED_SQLSTATE,
my_ex_message = MESSAGE_TEXT,
my_ex_detail = PG_EXCEPTION_DETAIL,
my_ex_hint = PG_EXCEPTION_HINT,
my_ex_ctx = PG_EXCEPTION_CONTEXT
;
raise notice '% % % % %', my_ex_state, my_ex_message, my_ex_detail, my_ex_hint, my_ex_ctx;
end;
commit;
begin
raise notice 'B';
exception when others then
raise notice 'C';
GET STACKED DIAGNOSTICS
my_ex_state = RETURNED_SQLSTATE,
my_ex_message = MESSAGE_TEXT,
my_ex_detail = PG_EXCEPTION_DETAIL,
my_ex_hint = PG_EXCEPTION_HINT,
my_ex_ctx = PG_EXCEPTION_CONTEXT
;
raise notice '% % % % %', my_ex_state, my_ex_message, my_ex_detail, my_ex_hint, my_ex_ctx;
end;
end;
$$;
Unfortunately, it does lead to a lot of duplication in the error handlers, but I can't think of a nice way to avoid it.