Tuesday, May 26, 2009

differences between before and after triggers

Before, after, each row and table level triggers Oracle]



The goal of this page is to demonstrate the most important differences between before and after triggers as well as the differences between for each row and table level triggers.

Before / for each row trigger

A before trigger is called before because it fires before the new values (:new.field_name) are stored in the table. That means that the new value can be changed in the trigger.
create table t_update_before_each_row (
txt varchar2(10)
);

create table log (
txt varchar2(20)
);


create trigger update_before_each_row
before update on t_update_before_each_row
for each row
begin

:new.txt := upper(:new.txt);

insert into log values ('old: ' || :old.txt);
insert into log values ('new: ' || :new.txt);

end update_before_each_row;
/
insert into t_update_before_each_row values('one');
insert into t_update_before_each_row values('two');
insert into t_update_before_each_row values('three');
insert into t_update_before_each_row values('four');
Updating (that is: concatenating the value with itself) the rows containing two and three:
update t_update_before_each_row set txt = txt || txt
where
substr(txt,1,1) = 't';
select * from t_update_before_each_row;
As can be seen by the output of the select statement, the trigger changed the values of the new values; they're in uppercase now:
one
TWOTWO
THREETHREE
four
The log displays the old and new values:
select * from log;
old: two
new: TWOTWO
old: three
new: THREETHREE
Cleaning up:
drop table t_update_before_each_row;
drop table log;

After / for each row trigger

In contrast to a before trigger, an after trigger does not allow to change :new.field_name because the value is, when the trigger fires, already written to the table.
If one tries to assign a value to :new.field_name, Oracle throws an ORA-04084: cannot change NEW values for this trigger type.
create table t_update_after_each_row (
txt varchar2(10)
);

create table log (
txt varchar2(20)
);


create trigger update_after_each_row
after update on t_update_after_each_row
for each row
begin

-- :new.txt := upper(:old.txt); -- ORA-04084: cannot change NEW values for this trigger type

insert into log values ('old: ' || :old.txt);
insert into log values ('new: ' || :new.txt);

end update_after_each_row;
/
insert into t_update_after_each_row values('one');
insert into t_update_after_each_row values('two');
insert into t_update_after_each_row values('three');
insert into t_update_after_each_row values('four');
update t_update_after_each_row set txt = txt || txt
where substr(txt,1,1) = 't';
select * from t_update_after_each_row;
one
twotwo
threethree
four
select * from log;
As the log table shows, it is possible to use :new and :old although it's not possible to assign something to :new.
old: two
new: twotwo
old: three
new: threethree
Cleaning up:
drop table t_update_after_each_row;
drop table log;

Table level trigger

A table level trigger is a trigger that doesn't fire for each row to be changed. Accordingly, it lacks the for each row. Consequently, both, the :new and :old are not permitted in the trigger's PL/SQL block, otherwise, an ORA-04082: NEW or OLD references not allowed in table level triggers is thrown.
create table t_update_before (
txt varchar2(10)
);

create table log (
txt varchar2(20)
);


create trigger update_before
before update on t_update_before
begin

-- :new.txt := upper(:old.txt); -- ORA-04082

insert into log values ('update trigger');

end update_before;
/
insert into t_update_before values('one');
insert into t_update_before values('two');
insert into t_update_before values('three');
insert into t_update_before values('four');
update t_update_before set txt = txt || txt
where substr(txt,1,1) = 't';
select * from t_update_before;
one
twotwo
threethree
four
select * from log;
Although two rows were updated, only one record is found in the log table:
select * from log;
update trigger
An update statement that doesn't update any row:
update t_update_before set txt = txt || txt
where txt = 'no update';
Still, the trigger fires...
select * from log;
... which results in another row found in the log table:
update trigger
update trigger
Cleaning up:
drop table t_update_before;
drop table log;

Order of execution

Oracle allows to create multiple triggers on the same table. The order of the execution of these triggers is undeterministic (or random, if you want this word) except that all before triggers fire before the after triggers.

No comments:

Post a Comment