Yes, you heard me correctly. If you have got one trigger on a table, then you might be surprised to find that perhaps having a second one will be a better option. Then again, I also love the sweet scent of a clickbaity, inflammatory blog post title to draw the readers in so you’ll just have to read on to see which is true.
As much as I am not a fan of using triggers to populate metadata in tables, I also concede that it is a popular approach taken by many of us as we code up our applications. Sure, we’d like to have our application code store that all important “who did this change” information with each database row, but more often than not, this get shoe-horned into the codebase via triggers as an afterthought to the development process.
But our well-read developer will often be thinking: “I’m a savvy developer – I’ve been reading blogs, and websites that tell me that less triggers is better, so I’ll use as few as I can” which leads to a scenario like the one I’ll present now.
I’ll start with a standard parent and child table setup, connected via an obvious foreign key
SQL> create table par (
2 id number(10) not null primary key,
3 description varchar2(20) not null,
4 created_by varchar2(20) not null,
5 updated_by varchar2(20) not null
6 );
Table created.
SQL>
SQL> create sequence par_seq;
Sequence created.
SQL>
SQL> create sequence chd_seq;
Sequence created.
SQL>
SQL> create table chd (
2 id number(10) not null primary key,
3 par_id number(10) not null,
4 constraint fk foreign key ( par_id ) references par ( id )
5 );
Table created.
SQL>
SQL>
SQL> create index chd_fk_idx on chd (par_id);
Index created.
I’ve got a sequence for each table, so in order to “bind” that sequence to the primary key for each table I’ll create a trigger. So I’ll add some trigger code to implement some other common application requirements at the same time:
- Populate the primary key with a sequence value,
- Populate the CREATED_BY, UPDATED_BY columns on insert of a new row
- Amend the UPDATED_BY column when I later update that row
Here is a trigger to implement that.
SQL> create or replace trigger trg_par
2 before insert or update on par
3 for each row
4 begin
5 if inserting then
6 :new.id := par_seq.nextval;
7 :new.created_by := user;
8 :new.updated_by := user;
9 end if;
10
11 if updating then
12 :new.updated_by := user;
13 end if;
14 end;
15 /
Trigger created.
Now my application is ready go. I’ll insert some data to verify that my trigger has not broken any functionality.
SQL> insert into par (description) values ('test');
1 row created.
SQL> insert into par (description) values ('test2');
1 row created.
SQL> select * from par;
ID DESCRIPTION CREATED_BY UPDATED_BY
---- -------------------- -------------------- --------------------
1 test MCDONAC MCDONAC
2 test2 MCDONAC MCDONAC
2 rows selected.
SQL>
SQL> insert into chd (id,par_id) values (chd_seq.nextval,1);
1 row created.
SQL> insert into chd (id,par_id) values (chd_seq.nextval,2);
1 row created.
SQL> select * from chd;
ID PAR_ID
---- ----------
1 1
2 2
2 rows selected.
SQL>
SQL> commit;
Commit complete.
So far so good. Let us see now what happens when I do a simple update on the parent table on the DESCRIPTION column. Note that this column is not involved with any primary key, or index or foreign key relationship – it’s just a simple string column.
SQL> update par set description = 'anything' where id = 1;
1 row updated.
SQL> select locked_mode, object_name
2 from v$locked_object l, all_objects ob
3 where ob.object_id =l.object_id;
LOCKED_MODE OBJECT_NAME
----------- ----------------------------------------
3 PAR
3 CHD
2 rows selected.
Notice the locks that have been taken. Understandably, I had to take a lock on the PAR table because I’ve just updated a row on the table, so I need to make sure that no-one does anything like drop it, or modify the structure whilst I’ve got an outstanding transaction. But here is the interesting part – we also took a lock on the child table CHD. That seems superfluous because as I said – we are not performing an update of anything that could possibly impact the child table in any way.
Why did the database choose to add this extra lock?
The cause is due to the way I coded the trigger. Notice that the trigger has a reference to the primary key in the trigger body:
5 if inserting then
6 :new.id := par_seq.nextval;
Even though that part of the trigger body is not executed (because I am performing an update not an insert) the mere presence of it is enough for the database to cautiously add that extra lock on the CHD table because we “just might” be messing around with the parent table primary key here.
So now I’ll roll back that update and convert the single triggers to two triggers – one for insert and one dedicated for update.
SQL> rollback;
Rollback complete.
SQL>
SQL> drop trigger trg_par ;
Trigger dropped.
SQL>
SQL> create or replace trigger trg1_par
2 before insert on par
3 for each row
4 begin
5 :new.id := par_seq.nextval;
6 :new.created_by := user;
7 :new.updated_by := user;
8 end;
9 /
Trigger created.
SQL>
SQL> create or replace trigger trg2_par
2 before update on par
3 for each row
4 begin
5 if updating then
6 :new.updated_by := user;
7 end if;
8 end;
9 /
Trigger created.
Now I’ll run the same update
SQL> update par set description = 'anything' where id = 1;
1 row updated.
SQL> select locked_mode, object_name
2 from v$locked_object l, all_objects ob
3 where ob.object_id =l.object_id;
LOCKED_MODE OBJECT_NAME
----------- ----------------------------------------
3 PAR
1 row selected.
Because the reference to the primary key columns for table PAR are no longer in the firing (update) trigger, I no longer longer see the lock on the CHD table.
In practice, it is unlikely that this additional lock is going to cause you a lot of harm – it will block some operations on the child table such as a truncate or DDL to make a structural change, so it is reasonably to assume that these are rare occurrences. But I’m a fan of the philosophy of: Have as few locks as possible, but always as many as required. So in this case, you might to want to consider opting for two triggers instead of one.
And of course, perhaps getting to zero triggers might be the best option
Hello Connor,
Excellent finding 🙂
Are you sure that this behavior is not a result of some huge improvements implemented in the last versions ?
I ask because just a few days ago I (re)read the post below, which deals in much detail with the change
in locking behavior between versions 10g and 11g, related to parent-child table relationships.
https://jonathanlewis.wordpress.com/2010/02/15/lock-horror/
Thanks a lot & Best Regards,
Iudith Mentzel
Great post, nice to read and interesting impact.
I think separate triggers also follow the single responsibility principle, don’t you think?
Cheers, Sam