Re: autonomous transactions

From: "Roberts, Jon" <Jon(dot)Roberts(at)asurion(dot)com>
To: "Decibel!" <decibel(at)decibel(dot)org>, "Tom Lane" <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: "Simon Riggs" <simon(at)2ndquadrant(dot)com>, "Neil Conway" <neilc(at)samurai(dot)com>, "Pavel Stehule" <pavel(dot)stehule(at)gmail(dot)com>, "Alvaro Herrera" <alvherre(at)commandprompt(dot)com>, <pgsql-hackers(at)postgresql(dot)org>
Subject: Re: autonomous transactions
Date: 2008-01-28 21:33:05
Message-ID: 1A6E6D554222284AB25ABE3229A927627154E7@nrtexcus702.int.asurion.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

> On Wed, Jan 23, 2008 at 05:50:02PM -0500, Tom Lane wrote:
> > Simon Riggs <simon(at)2ndquadrant(dot)com> writes:
> > >> From looking at how Oracle does them, autonomous transactions are
> > >> completely independent of the transaction that originates them --
> they
> > >> take a new database snapshot. This means that uncommitted changes
in
> the
> > >> originating transaction are not visible to the autonomous
> transaction.
> >
> > > Oh! Recursion depth would need to be tested for as well. Nasty.
> >
> > Seems like the cloning-a-session idea would be a possible
implementation
> > path for these too.
>
> Oracle has a feature where you can effectively save a session and
return
> to it. For example, if filling out a multi-page web form, you could
save
> state in the database between those calls. I'm assuming that they use
> that capability for their autonomous transactions; save the current
> session to the stack, clone it, run the autonomous transaction, then
> restore the saved one.
> --

You are describing an uncommitted transaction and not an autonomous
transaction. Transactions in Oracle are not automatically committed
like they are in PostgreSQL.

Here is a basic example of an autonomous transaction:

create or replace procedure pr_log_error (p_error_message
errorlog.message%type) is
pragma autonomous_transaction;
begin
insert
into errorlog
(log_user,
log_time,
error_message)
values (user,
sysdate(),
p_error_message);
commit;
exception
when others then
rollback;
raise;
end;

And then you can call it from a procedure like this:

create or replace procedure pr_example is
begin
null;--do some work
commit; --commit the work
exception
when others
pr_log_error(p_error_message => sqlerrm);
rollback;
raise;
end;

The autonomous transaction allows me to insert and commit a record in
different transaction than the calling procedure so the calling
procedure can rollback or commit.

You can also remove the commit/rollback from pr_example and instead do
it from the anonymous block that calls it. I just added it to make it
clear that it is a different transaction than the error logging
transaction.

Jon

In response to

Browse pgsql-hackers by date

  From Date Subject
Next Message Jeff Davis 2008-01-28 22:11:43 Re: RFC: array_agg() per SQL:200n
Previous Message Tom Lane 2008-01-28 21:21:44 Re: [PATCHES] Proposed patch: synchronized_scanning GUC variable