Skip to content

add G-3330: Avoid autonomous transactions. #216

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 2 commits into from
Mar 13, 2024
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
# G-3330: Avoid autonomous transactions.

!!! bug "Blocker"
Reliability, Testability

## Reason

>Before we take a look at how autonomous transactions work, I’d like to emphasize that this type of transaction is
a powerful and therefore dangerous tool when used improperly. The true need for an autonomous transaction is very
rare indeed. I would be very suspicious of any code that makes use of them—that code would get extra examination.
It is far too easy to accidentally introduce logical data integrity issues into a system using them. (page 300)

>In my experience, that is the only truly valid use of an autonomous transaction—to log errors or informational
messages in a manner that can be committed independently of the parent transaction. (page 305)

>-- Kyte, Thomas (2013). _Expert Oracle Database Architecture. Third Edition_. Apress.

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.


## Example (bad)

``` sql
create or replace package body dept_api is
procedure ins_dept(in_dept_row in dept%rowtype) is
pragma autonomous_transaction;
begin
insert into dept
values in_dept_row;
commit; -- required by autonomous transaction
end ins_dept;
end dept_api;
/
```

## Example (good)

``` sql
create or replace package body dept_api is
procedure ins_dept(in_dept_row in dept%rowtype) is
begin
insert into dept
values in_dept_row;
-- transaction is commited in calling module
-- after the completion of the unit of work
end ins_dept;
end dept_api;
/
```
3 changes: 2 additions & 1 deletion docs/9-appendix/appendix.md
Original file line number Diff line number Diff line change
@@ -54,7 +54,7 @@ n/a | 3150 | Try to use identity columns for surrogate keys. | Critical | | |
n/a | 3160 | Avoid visible virtual columns. | Blocker | | | ✘ | | ✘ | | |
n/a | 3170 | Always use DEFAULT ON NULL declarations to assign default values to table columns if you refuse to store NULL values. | Blocker | | | | | ✘ | | |
n/a | 3180 | Always specify column names instead of positional references in ORDER BY clauses. | Major | ✘ | | | | ✘ | | |
n/a | 3182 | Always specify column names instead of positional references in GROUP BY clauses. | Blocker | | | | | ✘ | | |
n/a | 3182 | Always specify column names/aliases instead of positional references in GROUP BY clauses. | Blocker | | | | | ✘ | | |
n/a | 3183 | Always specify column aliases instead of expressions in GROUP BY clauses. | Minor | | | ✘ | | | | |
n/a | 3185 | Never use ROWNUM at the same query level as ORDER BY. | Blocker | | | | | ✘ | | | ✘
n/a | 3190 | Avoid using NATURAL JOIN. | Blocker | ✘ | | | | ✘ | | |
@@ -63,6 +63,7 @@ n/a | 3195 | Always use wildcards in a LIKE clause. | Blocker | | | ✘ |
n/a | 3220 | Always process saved exceptions from a FORALL statement. | Critical | | | | | ✘ | | | ✘
n/a | 3310 | Never commit within a cursor loop. | Blocker | | ✘ | | | ✘ | | |
n/a | 3320 | Try to move transactions within a non-cursor loop into procedures. | Major | | | ✘ | | | ✘ | | ✘
n/a | 3330 | Avoid autonomous transactions. | Blocker | | | | | ✘ | | | ✘
31 | 4110 | Always use %NOTFOUND instead of NOT %FOUND to check whether a cursor returned data. | Minor | | | ✘ | | | | |
32 | 4120 | Avoid using %NOTFOUND directly after the FETCH when working with BULK OPERATIONS and LIMIT clause. | Blocker | | | | | ✘ | | |
33 | 4130 | Always close locally opened cursors. | Blocker | | ✘ | | | ✘ | | |