Re: Nested Stored Procedures - ERROR: invalid transaction termination 2D000 - Mailing list pgsql-general

From Christophe Pettus
Subject Re: Nested Stored Procedures - ERROR: invalid transaction termination 2D000
Date
Msg-id E2B9C6B4-4B79-43C6-9FF9-DED41E5CE9A5@thebuild.com
Whole thread Raw
In response to Re: Nested Stored Procedures - ERROR: invalid transaction termination 2D000  (Kevin Stephenson <kjs714@hotmail.com>)
Responses Re: Nested Stored Procedures - ERROR: invalid transaction termination 2D000
List pgsql-general
> On Mar 22, 2025, at 21:37, Kevin Stephenson <kjs714@hotmail.com> wrote:
>
> Christophe and Tom, thank you for your responses, but I'm still a bit confused. In my original email, the Test 2 case
isallowing a ROLLBACK in the EXCEPTION clause without throwing an error. Is it a NOP ROLLBACK being applied to an
abortedsubTX, a real full ROLLBACK, or something else? Please advise. 

That's an interesting question.  It appears to be a no-op, although a quick scan of the code doesn't reveal why.
Here'san illustrative test case: 

xof=# CREATE OR REPLACE PROCEDURE outer() AS $$
BEGIN
   INSERT INTO t VALUES(3);
   BEGIN
      CALL inner();
      PERFORM 1/0;
   EXCEPTION WHEN OTHERS THEN
      RAISE NOTICE 'in outer exception handler';
   END;
END;
$$ language plpgsql;
CREATE PROCEDURE

xof=# create or replace procedure inner() as $$
BEGIN
   BEGIN
      INSERT INTO t VALUES(1);
      PERFORM 1/0;
   EXCEPTION WHEN OTHERS THEN
      ROLLBACK;
      INSERT INTO t VALUES(2);
   END;
END;
$$
language plpgsql;
CREATE PROCEDURE

xof=# call outer();
NOTICE:  in outer exception handler
CALL

xof=# table t;
 i
---
 3
(1 row)

xof=# truncate t;
TRUNCATE TABLE

xof=# call inner();
CALL

xof=# table t;
 i
---
 2
(1 row)

It clearly doesn't roll back the outer transaction.  The savepoint that BEGIN ... EXCEPTION creates is released upon
entryinto the EXCEPTION block, so there's no savepoint in that context to roll back to. 

Pragmatically, the answer is: don't put top-level transaction control statements in procedures where they might be
invokedwithin an EXCEPTION block, either directly or indirectly. 


pgsql-general by date:

Previous
From: Kevin Stephenson
Date:
Subject: Re: Nested Stored Procedures - ERROR: invalid transaction termination 2D000
Next
From: Tom Lane
Date:
Subject: Re: Nested Stored Procedures - ERROR: invalid transaction termination 2D000