From: | Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at> |
---|---|
To: | "'Alexander Farber *EXTERN*'" <alexander(dot)farber(at)gmail(dot)com> |
Cc: | pgsql-general <pgsql-general(at)postgresql(dot)org> |
Subject: | Re: Does RAISE EXCEPTION rollback previous commands in a stored function? |
Date: | 2016-03-02 10:18:33 |
Message-ID: | A737B7A37273E048B164557ADEF4A58B53805AB4@ntex2010i.host.magwien.gv.at |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | 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
From | Date | Subject | |
---|---|---|---|
Next Message | David Bennett | 2016-03-02 10:27:37 | Re: Looking for pure C function APIs for server extension: language handler and SPI |
Previous Message | Pavel Stehule | 2016-03-02 10:10:33 | Re: Does RAISE EXCEPTION rollback previous commands in a stored function? |