Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Lasse.

Asked: January 29, 2024 - 4:47 pm UTC

Last updated: February 05, 2024 - 1:24 am UTC

Version: 19

Viewed 1000+ times

You Asked

Hi

We are using autonomous transactions for logging and debugging purposes. In PL/SQL code there are calls to packages, which are logging information using autonomous transactions.

Are autonomous transactions using commit point optimization ? Are there waits happening for writing data to redo logs? Do commit write options (write/nowait or immediate/batch) have any relevance when using autonomous transactions ?

If autonomous transactions are used for solely for debugging purposes, which are best parameters in commit regarding performanc ?


lh

and Connor said...

In PLSQL (autonomous transaction or otherwise) we can 'cheat' a little because the only time you get control back is at the conclusion of the call. Thus the only the time we need to ensure that the redo is in sync with the work done is at the conclusion of the call.

For example

SQL> create table t ( x int );

Table created.

SQL>
SQL> create or replace
  2  procedure do_commit is
  3    --pragma autonomous_transaction;
  4  begin
  5    insert into t values(1);
  6    commit;
  7  end;
  8  /

Procedure created.

SQL> -- before value
SQL> @stat
Enter value for sid: my
Enter value for stat_prefix: redo synch writes

 SID_STAT# NAME                                                                                  VALUE
---------- -------------------------------------------------------------------------------- ----------
       407 redo synch writes                                                                        13

SQL>
SQL> begin
  2  for i in 1 .. 10000 loop
  3    insert into t values(1);
  4    do_commit;
  5    commit;
  6  end loop;
  7  end;
  8  /

PL/SQL procedure successfully completed.

SQL> -- after value
SQL> @stat
Enter value for sid: my
Enter value for stat_prefix: redo synch writes

 SID_STAT# NAME                                                                                  VALUE
---------- -------------------------------------------------------------------------------- ----------
       407 redo synch writes                                                                        14


We did thousands of commits, but only 1 of them actually waited on LGWR to say "yup, you're good".

You'll see the same result if you comment in the pragma above

Is this answer out of date? If it is, please let us know via a Comment

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library