Over a million developers have joined DZone.
{{announcement.body}}
{{announcement.title}}

Nested Blocks, Autonomous Transactions, and 'Where Do I Commit?'

DZone's Guide to

Nested Blocks, Autonomous Transactions, and 'Where Do I Commit?'

If you have a procedure that is AUTONOMOUS_TRANSACTION that does an insert and then it calls a procedure with an insert, the second procedure doesn't need a commit.

· Database Zone ·
Free Resource

RavenDB vs MongoDB: Which is Better? This White Paper compares the two leading NoSQL Document Databases on 9 features to find out which is the best solution for your next project.  

This question rolled into my inbox today:

If I have a procedure that is AUTONOMOUS_TRANSACTION that does an insert and then it calls a procedure with an insert, does the second procedure need a commit, or will the procedure with the AUTONOMOUS_TRANSACTION handle the commit? If you don't know off the top of your head, don't worry, I can build a test.

First of all, if you ever find yourself writing something like, "If you don't know off the top of your head, don't worry, I can build a test," then please, by all means, go right ahead and build yourself a test script.

By doing so, you will better understand the feature in question and remember what you learned. Plus, you end up with a script you can share with the community on LiveSQL.

But I don't mind answering such questions. That way I get to better understand the feature in question, remember what I learned, share a script on LiveSQL and also add to my blog!

So here goes: the answer is no. The "second" procedure — invoked by the first — does not have to include a COMMIT statement.

Would you like proof or more information about the autonomous transaction feature of PL/SQL? Then keep reading.

When you add this statement to the declaration section of a procedure or function...

PRAGMA AUTONOMOUS_TRANSACTION; 

The following rule then applies:

Before the subprogram can be closed and control passed back to the calling block, any DML changes made within that subprogram must be committed or rolled back.

If there are any unsaved changes, the PL/SQL engine will raise the ORA-06519 exception, as shown below:

CREATE OR REPLACE FUNCTION nothing RETURN INTEGER
IS
   PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
   UPDATE employees SET last_name = 'abc';

   RETURN 1;
END;
/

BEGIN
   DBMS_OUTPUT.put_line (nothing);
END;
/

ORA-06519: active autonomous transaction detected and rolled back
ORA-06512: at "STEVEN.NOTHING", line 10
ORA-06512: at line 2

OK, so that's the basic idea. Now, let's move on the specific question. What if an autonomous transaction procedure calls another procedure, which does not include the pragma shown above but does execute a DML statement and does not commit? Will we see an ORA-06519 error? The code below shows that we will not.

CREATE TABLE me_and_my_lovelies (name VARCHAR2 (100));

BEGIN
   INSERT INTO me_and_my_lovelies VALUES ('Grandpa Steven');
   INSERT INTO me_and_my_lovelies VALUES ('Loey');
   INSERT INTO me_and_my_lovelies VALUES ('Juna');
   COMMIT;
END;
/

CREATE OR REPLACE PROCEDURE not_auton_no_commit
   AUTHID DEFINER
IS
BEGIN
   UPDATE me_and_my_lovelies
      SET name = UPPER (name);
END not_auton_no_commit;
/

CREATE OR REPLACE PROCEDURE auton_commit
   AUTHID DEFINER
IS
   PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
   not_auton_no_commit ();

   COMMIT;
END auton_commit;
/

BEGIN
   auton_commit;
END;
/

SELECT COUNT(*) low_name
  FROM me_and_my_lovelies
 WHERE name <> UPPER (name)
/

LOW_NAME
--------
0

No error is raised. All rows have been updated. So, let's go back to the rule:

Before the subprogram can be closed and control passed back to the calling block, any DML changes made within that subprogram must be committed or rolled back.

You might be thinking: But the UPDATE statement (the "DML change") was not made "within" auton_commit. Yes and no. Yes, the UPDATE statement is not part of the text of auton_commit. But the UPDATE statement was executed within the scope of auton_commit. And that's what counts. Any code executed by auton_commit, either "directly" in its executable section or "indirectly" by invoking another subprogram, is part of the autonomous transaction.

The only point at which the rule is applied is when PL/SQL attempts to closea uton_commit and return control to the outer block.

You can get more information about autonomous transactions here.

Get comfortable using NoSQL in a free, self-directed learning course provided by RavenDB. Learn to create fully-functional real-world programs on NoSQL Databases. Register today.

Topics:
database ,autonomy ,transactions ,nested blocks

Published at DZone with permission of

Opinions expressed by DZone contributors are their own.

{{ parent.title || parent.header.title}}

{{ parent.tldr }}

{{ parent.urlSource.name }}