Re: Does RAISE EXCEPTION rollback previous commands in a stored function? - Mailing list pgsql-general

From Albe Laurenz
Subject Re: Does RAISE EXCEPTION rollback previous commands in a stored function?
Date
Msg-id A737B7A37273E048B164557ADEF4A58B53805AB4@ntex2010i.host.magwien.gv.at
Whole thread Raw
In response to Re: Does RAISE EXCEPTION rollback previous commands in a stored function?  (Alexander Farber <alexander.farber@gmail.com>)
Responses Re: Does RAISE EXCEPTION rollback previous commands in a stored function?  (Alexander Farber <alexander.farber@gmail.com>)
List pgsql-general
Alexander Farber wrote:
> how to set such a savepoint inside of a stored function?
> 
> Can I call "START TRANSACTION", and then at some point later in the same stored function call RAISE
> EXCEPTION?

I realize that what I wrote must be confusing.

You cannot use START TRANSACTION, BEGIN, SAVEPOINT, COMMIT or ROLLBACK
inside a function.  A function always runs within one transaction.

Savepoints or subtransactions are written with a BEGIN ... EXCEPTION
block in PL/pgSQL, so you could write:

DECLARE FUNCTION .... AS
$$BEGIN
   /* UPDATE 1 */
   UPDATE ...;
   BEGIN  /* sets a savepoint */
      /* UPDATE 2, can cause an error */
      UPDATE ...;
   EXCEPTION
      /* rollback to savepoint, ignore error */
      WHEN OTHERS THEN NULL;
   END;
END;$$;

Even if UPDATE 2 throws an error, UPDATE 1 will be committed.

Yours,
Laurenz Albe

pgsql-general by date:

Previous
From: Pavel Stehule
Date:
Subject: Re: Does RAISE EXCEPTION rollback previous commands in a stored function?
Next
From:
Date:
Subject: Re: Looking for pure C function APIs for server extension: language handler and SPI