Skip to content

Commit 0aa4374

Browse files
add G-3330: Avoid autonomous transactions
1 parent 7bc79d9 commit 0aa4374

File tree

1 file changed

+49
-0
lines changed
  • docs/4-language-usage/3-dml-and-sql/3-transaction-control

1 file changed

+49
-0
lines changed
Lines changed: 49 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,49 @@
1+
# G-3330: Avoid autonomous transactions.
2+
3+
!!! bug "Blocker"
4+
Reliability, Testability
5+
6+
## Reason
7+
8+
>Before we take a look at how autonomous transactions work, I’d like to emphasize that this type of transaction is
9+
a powerful and therefore dangerous tool when used improperly. The true need for an autonomous transaction is very
10+
rare indeed. I would be very suspicious of any code that makes use of them—that code would get extra examination.
11+
It is far too easy to accidentally introduce logical data integrity issues into a system using them. (page 300)
12+
13+
>In my experience, that is the only truly valid use of an autonomous transaction—to log errors or informational
14+
messages in a manner that can be committed independently of the parent transaction. (page 305)
15+
16+
>-- Kyte, Thomas (2013). _Expert Oracle Database Architecture. Third Edition_. Apress.
17+
18+
It is most likely not possible to distinguish legitimate uses of autonomous transactions from illegitimate ones via static code analysis. However, since we expect exactly one autonomous transaction per application, the number of false positives is manageable.
19+
20+
21+
## Example (bad)
22+
23+
``` sql
24+
create or replace package body dept_api is
25+
procedure ins_dept(in_dept_row in dept%rowtype) is
26+
pragma autonomous_transaction;
27+
begin
28+
insert into dept
29+
values in_dept_row;
30+
commit; -- required by autonomous transaction
31+
end ins_dept;
32+
end dept_api;
33+
/
34+
```
35+
36+
## Example (good)
37+
38+
``` sql
39+
create or replace package body dept_api is
40+
procedure ins_dept(in_dept_row in dept%rowtype) is
41+
begin
42+
insert into dept
43+
values in_dept_row;
44+
-- transaction is commited in calling module
45+
-- after the completion of the unit of work
46+
end ins_dept;
47+
end dept_api;
48+
/
49+
```

0 commit comments

Comments
 (0)