Re: Transactions within a function body

Lists: pgsql-generalpgsql-hackers
From: Reg Me Please <regmeplease(at)gmail(dot)com>
To: pgsql-general(at)postgresql(dot)org
Subject: Transactions within a function body
Date: 2008-10-01 15:54:01
Message-ID: 200810011754.01357.regmeplease@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Hi all.

Is there a way to have (sub)transactions within a function body?
I'd like to execute some code (a transaction!) inside a function and later
decide whether that transaction is to be committed or not.

Thanks.


From: Andreas Kretschmer <akretschmer(at)spamfence(dot)net>
To: pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-01 16:16:03
Message-ID: 20081001161603.GA9479@tux
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Reg Me Please <regmeplease(at)gmail(dot)com> schrieb:

> Hi all.
>
> Is there a way to have (sub)transactions within a function body?

No.

Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect. (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly." (unknown)
Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°


From: "Dennis Brakhane" <brakhane(at)googlemail(dot)com>
To: "Reg Me Please" <regmeplease(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-01 21:20:47
Message-ID: 226a19190810011420j4dfe4a74oded00094895395be@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

On Wed, Oct 1, 2008 at 5:54 PM, Reg Me Please <regmeplease(at)gmail(dot)com> wrote:
> Hi all.
>
> Is there a way to have (sub)transactions within a function body?
> I'd like to execute some code (a transaction!) inside a function and later
> decide whether that transaction is to be committed or not.

You could issue a "SAVEPOINT name". If at the end you don't want your
changes to apply, you can issue a "ROLLBACK to name"


From: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
To: Dennis Brakhane <brakhane(at)googlemail(dot)com>
Cc: Reg Me Please <regmeplease(at)gmail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 00:34:42
Message-ID: 20081002003442.GG3878@alvh.no-ip.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Dennis Brakhane escribió:
> On Wed, Oct 1, 2008 at 5:54 PM, Reg Me Please <regmeplease(at)gmail(dot)com> wrote:
> > Hi all.
> >
> > Is there a way to have (sub)transactions within a function body?
> > I'd like to execute some code (a transaction!) inside a function and later
> > decide whether that transaction is to be committed or not.
>
> You could issue a "SAVEPOINT name". If at the end you don't want your
> changes to apply, you can issue a "ROLLBACK to name"

Actually you can't use SAVEPOINT nor ROLLBACK TO within a function. In
PL/pgSQL you can use EXCEPTION blocks (if you don't like the changes,
just do a RAISE EXCEPTION, and the exception block is run).

--
Alvaro Herrera http://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support


From: "Albe Laurenz" <laurenz(dot)albe(at)wien(dot)gv(dot)at>
To: "Alvaro Herrera *EXTERN*" <alvherre(at)commandprompt(dot)com>, "Dennis Brakhane" <brakhane(at)googlemail(dot)com>
Cc: "Reg Me Please" <regmeplease(at)gmail(dot)com>, <pgsql-general(at)postgresql(dot)org>
Subject: Re: Transactions within a function body
Date: 2008-10-02 09:01:37
Message-ID: D960CB61B694CF459DCFB4B0128514C202901E88@exadv11.host.magwien.gv.at
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Alvaro Herrera wrote:
> > > Is there a way to have (sub)transactions within a function body?
> > > I'd like to execute some code (a transaction!) inside a function and later
> > > decide whether that transaction is to be committed or not.
> >
> > You could issue a "SAVEPOINT name". If at the end you don't want your
> > changes to apply, you can issue a "ROLLBACK to name"
>
> Actually you can't use SAVEPOINT nor ROLLBACK TO within a function. In
> PL/pgSQL you can use EXCEPTION blocks (if you don't like the changes,
> just do a RAISE EXCEPTION, and the exception block is run).

After a discussion on comp.databases.postgresql I realized that this
is actually a limitation.

Consider the following:

BEGIN
UPDATE ...
UPDATE ...
UPDATE ...
EXCEPTION
WHEN integrity_constraint_violation THEN
...
END;

If the first UPDATE succeeds but the second one bombs, there is no way
to undo the first update short of having the whole transaction cancelled.

So while exceptions are implemented using savepoints, they give you only
part of the functionality, namely to make a group of statements
all-or-nothing within one transaction.

If you need all three of these UPDATEs to either all succeed or fail,
but the whole transaction should continue, you cannot do that in PL/pgSQL.

Is there a chance to get savepoint support in PL/pgSQL at some point?
Does it make sense to raise this on -hackers?

Yours,
Laurenz Albe


From: Richard Huxton <dev(at)archonet(dot)com>
To: Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>
Cc: Alvaro Herrera *EXTERN* <alvherre(at)commandprompt(dot)com>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, Reg Me Please <regmeplease(at)gmail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 09:53:17
Message-ID: 48E49A0D.6030506@archonet.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Albe Laurenz wrote:
> After a discussion on comp.databases.postgresql I realized that this
> is actually a limitation.
>
> Consider the following:
>
> BEGIN
> UPDATE ...
> UPDATE ...
> UPDATE ...
> EXCEPTION
> WHEN integrity_constraint_violation THEN
> ...
> END;
>
> If the first UPDATE succeeds but the second one bombs, there is no way
> to undo the first update short of having the whole transaction cancelled.

No, I think you've got that backwards Albe. You can even nest exceptions.

> If you need all three of these UPDATEs to either all succeed or fail,
> but the whole transaction should continue, you cannot do that in PL/pgSQL.

Try the following script. By commenting out the second INSERT you can
change whether you get one or no rows inserted into t1. The
BEGIN...EXCEPTION...END block has a savepoint set at the "BEGIN".

BEGIN;

CREATE TABLE t1 (a integer);

CREATE OR REPLACE FUNCTION test_exception()
RETURNS boolean AS $$
DECLARE
n integer;
BEGIN
INSERT INTO t1 (a) VALUES (1);
-- INSERT INTO t1 (a) VALUES ('b');
BEGIN
INSERT INTO t1 (a) VALUES (2);
INSERT INTO t1 (a) VALUES ('c');
EXCEPTION
WHEN OTHERS THEN
SELECT INTO n count(*) FROM t1;
RAISE NOTICE 'n2 = %', n;
RETURN false;
END;
RETURN true;
EXCEPTION
WHEN OTHERS THEN
SELECT INTO n count(*) FROM t1;
RAISE NOTICE 'n1 = %', n;
RETURN false;
END;
$$ LANGUAGE plpgsql;

SELECT test_exception();

SELECT count(*) FROM t1;

ROLLBACK;

--
Richard Huxton
Archonet Ltd


From: Reg Me Please <regmeplease(at)gmail(dot)com>
To: "Albe Laurenz" <laurenz(dot)albe(at)wien(dot)gv(dot)at>
Cc: "Alvaro Herrera *EXTERN*" <alvherre(at)commandprompt(dot)com>, "Dennis Brakhane" <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 10:24:59
Message-ID: 200810021224.59496.regmeplease@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Well, if it is a limitation, and having it would lead to a "better product",
why not making it a feature for the next still-open release?

In my opinion that's more than a limitation, it's a missing feature.
In your code you often need to create savepoints to delay the decision for the
commitment.
A Pl/PgSQL function is just a bunch of code you want to move into the DB.
So the need for savepoints seems to me to be still there.

Useless to say I would vote for a "GO".

On Thursday 02 October 2008 11:01:37 Albe Laurenz wrote:
> Alvaro Herrera wrote:
> > > > Is there a way to have (sub)transactions within a function body?
> > > > I'd like to execute some code (a transaction!) inside a function and
> > > > later decide whether that transaction is to be committed or not.
> > >
> > > You could issue a "SAVEPOINT name". If at the end you don't want your
> > > changes to apply, you can issue a "ROLLBACK to name"
> >
> > Actually you can't use SAVEPOINT nor ROLLBACK TO within a function. In
> > PL/pgSQL you can use EXCEPTION blocks (if you don't like the changes,
> > just do a RAISE EXCEPTION, and the exception block is run).
>
> After a discussion on comp.databases.postgresql I realized that this
> is actually a limitation.
>
> Consider the following:
>
> BEGIN
> UPDATE ...
> UPDATE ...
> UPDATE ...
> EXCEPTION
> WHEN integrity_constraint_violation THEN
> ...
> END;
>
> If the first UPDATE succeeds but the second one bombs, there is no way
> to undo the first update short of having the whole transaction cancelled.
>
> So while exceptions are implemented using savepoints, they give you only
> part of the functionality, namely to make a group of statements
> all-or-nothing within one transaction.
>
> If you need all three of these UPDATEs to either all succeed or fail,
> but the whole transaction should continue, you cannot do that in PL/pgSQL.
>
> Is there a chance to get savepoint support in PL/pgSQL at some point?
> Does it make sense to raise this on -hackers?
>
> Yours,
> Laurenz Albe


From: Reg Me Please <regmeplease(at)gmail(dot)com>
To: Richard Huxton <dev(at)archonet(dot)com>
Cc: Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, "Alvaro Herrera *EXTERN*" <alvherre(at)commandprompt(dot)com>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 10:31:47
Message-ID: 200810021231.48198.regmeplease@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Hi.

My humble opinion follows.

One point here is that the decision for the ROLLBACK could possibly be
different from errors.
It could simply be based upon a generic expression, not just the conditions
seen in "Appendix A" of the manual.
An exception is something different from a transaction, despite the former is
implemented with the latter.

On Thursday 02 October 2008 11:53:17 Richard Huxton wrote:
> Albe Laurenz wrote:
> > After a discussion on comp.databases.postgresql I realized that this
> > is actually a limitation.
> >
> > Consider the following:
> >
> > BEGIN
> > UPDATE ...
> > UPDATE ...
> > UPDATE ...
> > EXCEPTION
> > WHEN integrity_constraint_violation THEN
> > ...
> > END;
> >
> > If the first UPDATE succeeds but the second one bombs, there is no way
> > to undo the first update short of having the whole transaction cancelled.
>
> No, I think you've got that backwards Albe. You can even nest exceptions.
>
> > If you need all three of these UPDATEs to either all succeed or fail,
> > but the whole transaction should continue, you cannot do that in
> > PL/pgSQL.
>
> Try the following script. By commenting out the second INSERT you can
> change whether you get one or no rows inserted into t1. The
> BEGIN...EXCEPTION...END block has a savepoint set at the "BEGIN".
>
>
> BEGIN;
>
> CREATE TABLE t1 (a integer);
>
> CREATE OR REPLACE FUNCTION test_exception()
> RETURNS boolean AS $$
> DECLARE
> n integer;
> BEGIN
> INSERT INTO t1 (a) VALUES (1);
> -- INSERT INTO t1 (a) VALUES ('b');
> BEGIN
> INSERT INTO t1 (a) VALUES (2);
> INSERT INTO t1 (a) VALUES ('c');
> EXCEPTION
> WHEN OTHERS THEN
> SELECT INTO n count(*) FROM t1;
> RAISE NOTICE 'n2 = %', n;
> RETURN false;
> END;
> RETURN true;
> EXCEPTION
> WHEN OTHERS THEN
> SELECT INTO n count(*) FROM t1;
> RAISE NOTICE 'n1 = %', n;
> RETURN false;
> END;
> $$ LANGUAGE plpgsql;
>
> SELECT test_exception();
>
> SELECT count(*) FROM t1;
>
> ROLLBACK;


From: "Albe Laurenz" <laurenz(dot)albe(at)wien(dot)gv(dot)at>
To: "Richard Huxton *EXTERN*" <dev(at)archonet(dot)com>
Cc: "Alvaro Herrera *EXTERN*" <alvherre(at)commandprompt(dot)com>, "Dennis Brakhane" <brakhane(at)googlemail(dot)com>, "Reg Me Please" <regmeplease(at)gmail(dot)com>, <pgsql-general(at)postgresql(dot)org>
Subject: Re: Transactions within a function body
Date: 2008-10-02 11:49:06
Message-ID: D960CB61B694CF459DCFB4B0128514C202901F6A@exadv11.host.magwien.gv.at
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Richard Huxton wrote:
>> After a discussion on comp.databases.postgresql I realized that this
>> is actually a limitation.
>>
>> Consider the following:
>>
>> BEGIN
>> UPDATE ...
>> UPDATE ...
>> UPDATE ...
>> EXCEPTION
>> WHEN integrity_constraint_violation THEN
>> ...
>> END;
>>
>> If the first UPDATE succeeds but the second one bombs, there is no way
>> to undo the first update short of having the whole transaction cancelled.
>
> No, I think you've got that backwards Albe. You can even nest exceptions.
>
[...]
>
> The BEGIN...EXCEPTION...END block has a savepoint set at the "BEGIN".

You are right, and I'm happy to find myself wrong:

CREATE TABLE t1 (a integer PRIMARY KEY);

CREATE FUNCTION test_exception() RETURNS boolean LANGUAGE plpgsql AS
$$BEGIN
INSERT INTO t1 (a) VALUES (1);
INSERT INTO t1 (a) VALUES (2);
INSERT INTO t1 (a) VALUES (1);
INSERT INTO t1 (a) VALUES (3);
RETURN TRUE;
EXCEPTION
WHEN integrity_constraint_violation THEN
RAISE NOTICE 'Rollback to savepoint';
RETURN FALSE;
END;$$;

BEGIN;

SELECT test_exception();
NOTICE: Rollback to savepoint
test_exception
----------------
f
(1 row)

COMMIT;

SELECT count(*) FROM t1;
count
-------
0
(1 row)

Great, thank you!

Yours,
Laurenz Albe


From: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
To: Reg Me Please <regmeplease(at)gmail(dot)com>
Cc: Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 14:15:10
Message-ID: 20081002141510.GA4151@alvh.no-ip.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Reg Me Please escribió:
> Well, if it is a limitation, and having it would lead to a "better product",
> why not making it a feature for the next still-open release?

Because no one is working on implementing it?

> In my opinion that's more than a limitation, it's a missing feature.
> In your code you often need to create savepoints to delay the decision for the
> commitment.
> A Pl/PgSQL function is just a bunch of code you want to move into the DB.
> So the need for savepoints seems to me to be still there.

You can nest blocks arbitrarily, giving you the chance to selectively
rollback pieces of the function. It's only a bit more awkward.

--
Alvaro Herrera http://www.CommandPrompt.com/
The PostgreSQL Company - Command Prompt, Inc.


From: Reg Me Please <regmeplease(at)gmail(dot)com>
To: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
Cc: Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 14:25:19
Message-ID: 200810021625.19719.regmeplease@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Il Thursday 02 October 2008 16:15:10 Alvaro Herrera ha scritto:
> Reg Me Please escribió:
> > Well, if it is a limitation, and having it would lead to a "better
> > product", why not making it a feature for the next still-open release?
>
> Because no one is working on implementing it?
>
> > In my opinion that's more than a limitation, it's a missing feature.
> > In your code you often need to create savepoints to delay the decision
> > for the commitment.
> > A Pl/PgSQL function is just a bunch of code you want to move into the DB.
> > So the need for savepoints seems to me to be still there.
>
> You can nest blocks arbitrarily, giving you the chance to selectively
> rollback pieces of the function. It's only a bit more awkward.

You mean I can issue a ROLLBACK command within a BEGIN...END; block to roll it
back?


From: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
To: Reg Me Please <regmeplease(at)gmail(dot)com>
Cc: Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 15:10:23
Message-ID: 20081002151023.GB4151@alvh.no-ip.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Reg Me Please escribió:
> Il Thursday 02 October 2008 16:15:10 Alvaro Herrera ha scritto:

> > You can nest blocks arbitrarily, giving you the chance to selectively
> > rollback pieces of the function. It's only a bit more awkward.
>
> You mean I can issue a ROLLBACK command within a BEGIN...END; block to roll it
> back?

No -- I mean you can use BEGIN/EXCEPTION/END blocks as you like, nesting
them or putting one after another. Complementing this with RAISE
EXCEPTION you can cause savepoints to roll back at will.

--
Alvaro Herrera http://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support


From: Reg Me Please <regmeplease(at)gmail(dot)com>
To: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
Cc: Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 15:18:59
Message-ID: 200810021718.59515.regmeplease@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Il Thursday 02 October 2008 17:10:23 Alvaro Herrera ha scritto:
> Reg Me Please escribió:
> > Il Thursday 02 October 2008 16:15:10 Alvaro Herrera ha scritto:
> > > You can nest blocks arbitrarily, giving you the chance to selectively
> > > rollback pieces of the function. It's only a bit more awkward.
> >
> > You mean I can issue a ROLLBACK command within a BEGIN...END; block to
> > roll it back?
>
> No -- I mean you can use BEGIN/EXCEPTION/END blocks as you like, nesting
> them or putting one after another. Complementing this with RAISE
> EXCEPTION you can cause savepoints to roll back at will.

Now I understand. (Sorry, me dumb!)

Looks quirky, but I trust it's working. I'll give that a try.


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
Cc: Reg Me Please <regmeplease(at)gmail(dot)com>, Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 15:28:13
Message-ID: 1510.1222961293@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Alvaro Herrera <alvherre(at)commandprompt(dot)com> writes:
> Reg Me Please escribi:
>> You mean I can issue a ROLLBACK command within a BEGIN...END; block to roll it
>> back?

> No -- I mean you can use BEGIN/EXCEPTION/END blocks as you like, nesting
> them or putting one after another. Complementing this with RAISE
> EXCEPTION you can cause savepoints to roll back at will.

Yeah, it's essentially the same functionality as savepoints, but
different syntax.

regards, tom lane


From: "Gurjeet Singh" <singh(dot)gurjeet(at)gmail(dot)com>
To: "Alvaro Herrera" <alvherre(at)commandprompt(dot)com>, "PGSQL Hackers" <pgsql-hackers(at)postgresql(dot)org>
Cc: "Reg Me Please" <regmeplease(at)gmail(dot)com>, "Albe Laurenz" <laurenz(dot)albe(at)wien(dot)gv(dot)at>, "Dennis Brakhane" <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 15:30:52
Message-ID: 65937bea0810020830h1f3d780an94b6e9cdba312f64@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

On Thu, Oct 2, 2008 at 8:40 PM, Alvaro Herrera
<alvherre(at)commandprompt(dot)com>wrote:

> Reg Me Please escribió:
> > Il Thursday 02 October 2008 16:15:10 Alvaro Herrera ha scritto:
>
> > > You can nest blocks arbitrarily, giving you the chance to selectively
> > > rollback pieces of the function. It's only a bit more awkward.
> >
> > You mean I can issue a ROLLBACK command within a BEGIN...END; block to
> roll it
> > back?
>
> No -- I mean you can use BEGIN/EXCEPTION/END blocks as you like, nesting
> them or putting one after another. Complementing this with RAISE
> EXCEPTION you can cause savepoints to roll back at will.

I have seen this feature being asked for, and this work-around suggested so
many times. If plpgql does it internally, why not provide a clean interface
for this? Is there some road-block, or that nobody has ever tried it?

If there are no known limitations, I'd like to start work on it.

Best regards,
--
gurjeet[(dot)singh](at)EnterpriseDB(dot)com
singh(dot)gurjeet(at){ gmail | hotmail | indiatimes | yahoo }.com

EnterpriseDB http://www.enterprisedb.com

Mail sent from my BlackLaptop device


From: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
To: Gurjeet Singh <singh(dot)gurjeet(at)gmail(dot)com>
Cc: PGSQL Hackers <pgsql-hackers(at)postgresql(dot)org>, Reg Me Please <regmeplease(at)gmail(dot)com>, Albe Laurenz <laurenz(dot)albe(at)wien(dot)gv(dot)at>, Dennis Brakhane <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 15:40:22
Message-ID: 20081002154022.GD4151@alvh.no-ip.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Gurjeet Singh escribió:

> I have seen this feature being asked for, and this work-around suggested so
> many times. If plpgql does it internally, why not provide a clean interface
> for this? Is there some road-block, or that nobody has ever tried it?

Initially we aimed at just exposing SAVEPOINT and ROLLBACK TO in
functions, but ran into the problem that the SPI stack needs to be dealt
with appropriately and you can't do it if the user is able to modify it
arbitrarily by calling transaction-modifying commands. That's when the
EXCEPTION idea came up. We never went back and studied whether we could
have fixed the SPI limitation, but it's not trivial.

--
Alvaro Herrera http://www.CommandPrompt.com/
The PostgreSQL Company - Command Prompt, Inc.


From: "Bob Henkel" <bob(dot)henkel(at)gmail(dot)com>
To: "Alvaro Herrera" <alvherre(at)commandprompt(dot)com>
Cc: "Gurjeet Singh" <singh(dot)gurjeet(at)gmail(dot)com>, "PGSQL Hackers" <pgsql-hackers(at)postgresql(dot)org>, "Reg Me Please" <regmeplease(at)gmail(dot)com>, "Albe Laurenz" <laurenz(dot)albe(at)wien(dot)gv(dot)at>, "Dennis Brakhane" <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: Transactions within a function body
Date: 2008-10-02 15:46:25
Message-ID: fedea56b0810020846x36211682h5b2c3d68ab9c1f58@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

Have you looked at creating a function in perl and creating a new
connection? Or using a dblink query which can create a new connection?
These two methods work. I have used them to insert to a log table regardless
of the parent transaction being commited or rolled back.

A old example I posted of using pl/perl can be found here ->
http://www.postgresqlforums.com/forums/viewtopic.php?f=4&t=647

The key is opening a new session which using dblink or pl/perl dbi
connection will do. This is not ideal or efficient. It would be nice if you
could just do autonomous transactions natively in pl/pgsql, but I find this
method works for the cases where you need it(logging, huge batch processing
tasks where it's not ideal to process everything in one transaction).

Bob

"Hi all.
Is there a way to have (sub)transactions within a function body?
I'd like to execute some code (a transaction!) inside a function and later
decide whether that transaction is to be committed or not.
Thanks."

On Thu, Oct 2, 2008 at 10:40 AM, Alvaro Herrera
<alvherre(at)commandprompt(dot)com>wrote:

> Gurjeet Singh escribió:
>
> > I have seen this feature being asked for, and this work-around suggested
> so
> > many times. If plpgql does it internally, why not provide a clean
> interface
> > for this? Is there some road-block, or that nobody has ever tried it?
>
> Initially we aimed at just exposing SAVEPOINT and ROLLBACK TO in
> functions, but ran into the problem that the SPI stack needs to be dealt
> with appropriately and you can't do it if the user is able to modify it
> arbitrarily by calling transaction-modifying commands. That's when the
> EXCEPTION idea came up. We never went back and studied whether we could
> have fixed the SPI limitation, but it's not trivial.
>
> --
> Alvaro Herrera
> http://www.CommandPrompt.com/ <http://www.commandprompt.com/>
> The PostgreSQL Company - Command Prompt, Inc.
>
> --
> Sent via pgsql-general mailing list (pgsql-general(at)postgresql(dot)org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general
>


From: "Asko Oja" <ascoja(at)gmail(dot)com>
To: "Bob Henkel" <bob(dot)henkel(at)gmail(dot)com>
Cc: "Alvaro Herrera" <alvherre(at)commandprompt(dot)com>, "Gurjeet Singh" <singh(dot)gurjeet(at)gmail(dot)com>, "PGSQL Hackers" <pgsql-hackers(at)postgresql(dot)org>, "Reg Me Please" <regmeplease(at)gmail(dot)com>, "Albe Laurenz" <laurenz(dot)albe(at)wien(dot)gv(dot)at>, "Dennis Brakhane" <brakhane(at)googlemail(dot)com>, pgsql-general(at)postgresql(dot)org
Subject: Re: [HACKERS] Transactions within a function body
Date: 2008-10-03 06:30:46
Message-ID: ecd779860810022330h404babd1ncafc3290d2d826c7@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

On Thu, Oct 2, 2008 at 6:46 PM, Bob Henkel <bob(dot)henkel(at)gmail(dot)com> wrote:

> Have you looked at creating a function in perl and creating a new
> connection? Or using a dblink query which can create a new connection?
> These two methods work. I have used them to insert to a log table regardless
> of the parent transaction being commited or rolled back.
>
> A old example I posted of using pl/perl can be found here ->
> http://www.postgresqlforums.com/forums/viewtopic.php?f=4&t=647
>
> The key is opening a new session which using dblink or pl/perl dbi
> connection will do. This is not ideal or efficient. It would be nice if you
> could just do autonomous transactions natively in pl/pgsql, but I find this
> method works for the cases where you need it(logging, huge batch processing
> tasks where it's not ideal to process everything in one transaction).
>
>
The same can be done with plProxy which is quite efficient but yes opening
connections is not. So if used extensively it would be clever to use
pgBouncer to reuse connections. Thanks for interesting idea.

>
> Bob
>
> "Hi all.
> Is there a way to have (sub)transactions within a function body?
> I'd like to execute some code (a transaction!) inside a function and later
> decide whether that transaction is to be committed or not.
> Thanks."
>
> On Thu, Oct 2, 2008 at 10:40 AM, Alvaro Herrera <
> alvherre(at)commandprompt(dot)com> wrote:
>
>> Gurjeet Singh escribió:
>>
>> > I have seen this feature being asked for, and this work-around suggested
>> so
>> > many times. If plpgql does it internally, why not provide a clean
>> interface
>> > for this? Is there some road-block, or that nobody has ever tried it?
>>
>> Initially we aimed at just exposing SAVEPOINT and ROLLBACK TO in
>> functions, but ran into the problem that the SPI stack needs to be dealt
>> with appropriately and you can't do it if the user is able to modify it
>> arbitrarily by calling transaction-modifying commands. That's when the
>> EXCEPTION idea came up. We never went back and studied whether we could
>> have fixed the SPI limitation, but it's not trivial.
>>
>> --
>> Alvaro Herrera
>> http://www.CommandPrompt.com/ <http://www.commandprompt.com/>
>> The PostgreSQL Company - Command Prompt, Inc.
>>
>> --
>> Sent via pgsql-general mailing list (pgsql-general(at)postgresql(dot)org)
>> To make changes to your subscription:
>> http://www.postgresql.org/mailpref/pgsql-general
>>
>
>