forked from Trivadis/plsql-and-sql-coding-guidelines
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Fix Trivadis#84 - Created rule G-7730: Avoid multiple DML events per …
…trigger if primary key is assigned in trigger.
- Loading branch information
Showing
1 changed file
with
62 additions
and
0 deletions.
There are no files selected for viewing
62 changes: 62 additions & 0 deletions
62
docs/4-language-usage/7-stored-objects/7-triggers/g-7730.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,62 @@ | ||
# G-7730: Avoid multiple DML events per trigger if primary key is assigned in trigger. | ||
|
||
!!! warning "Major" | ||
Efficiency, Reliability | ||
|
||
## Reason | ||
|
||
If a trigger makes assignment to the primary key anywhere in the trigger code, that causes the session firing the trigger to take a lock on any child tables with a foreign key to this primary key. Even if the assignment is in for example an `if inserting` block and the trigger is fired by an `update` statement, such locks still happen unnecessarily. The issue is avoided by having one trigger for the insert containing the primary key assignment, and another trigger for the update. Or even better by handling the insert assignment as ´default on null´ clauses, so that only an `on update` trigger is needed. | ||
|
||
## Example (bad) | ||
|
||
``` sql | ||
create or replace trigger dept_br_iu | ||
before insert or update | ||
on departments for each row | ||
begin | ||
if inserting then | ||
:new.department_id := department_seq.nextval; | ||
:new.created_date := sysdate; | ||
end if; | ||
if updating then | ||
:new.changed_date := sysdate; | ||
end if; | ||
end; | ||
/ | ||
``` | ||
|
||
## Example (better) | ||
|
||
``` sql | ||
create or replace trigger dept_br_i | ||
before insert | ||
on departments for each row | ||
begin | ||
:new.department_id := department_seq.nextval; | ||
:new.created_date := sysdate; | ||
end; | ||
/ | ||
|
||
create or replace trigger dept_br_u | ||
before update | ||
on departments for each row | ||
begin | ||
:new.changed_date := sysdate; | ||
end; | ||
/ | ||
``` | ||
|
||
## Example (good) | ||
|
||
``` sql | ||
alter table department modify department_id default on null department_seq.nextval; | ||
alter table department modify created_date default on null sysdate; | ||
|
||
create or replace trigger dept_br_u | ||
before update | ||
on departments for each row | ||
begin | ||
:new.changed_date := sysdate; | ||
end; | ||
/ | ||
``` |