The Oracle mutating trigger error occurs when a trigger references the table that owns the trigger, resulting in the “ORA-04091: table name is mutating, trigger/function may not see it” message.
Let’s have a look at the existing workarounds.
The first one, through the package, is ancient and seems to be effective, however, it takes much time to prepare and run it. The second one is simple and performed using compound triggers.
create table turtles as select 'Splinter' name, 'Rat' essence from dual union all select 'Leonardo', 'Painter' from dual union all select 'Rafael', 'Painter' from dual union all select 'Michelangelo', 'Painter' from dual union all select 'Donatello', 'Painter' from dual;
When Splinter mutates from a rat into a sensei, the painters will have to automatically turn into ninja. This trigger seems to be suited:
create or replace trigger tr_turtles_bue before update of essence on turtles for each row when ( new.name = 'Splinter' and old.essence = 'Rat' and new.essence = 'Sensei' ) begin update turtles set essence = 'Ninja' where essence = 'Painter'; end;
However, when updating the record:
update turtles set essence = 'Sensei' where name = 'Splinter'
The following error occurs:
ORA-04091: table SCOTT.TURTLES is mutating, trigger/function may not see it
Let’s delete this trigger:
drop trigger tr_turtles_bue;
The method 1: Using the package and the instruction-level trigger.
create or replace package pkg_around_mutation is bUpdPainters boolean; procedure update_painters; end pkg_around_mutation; / create or replace package body pkg_around_mutation is procedure update_painters is begin if bUpdPainters then bUpdPainters := false; update turtles set essence = 'Ninja' where essence = 'Painter'; end if; end; end pkg_around_mutation; / create or replace trigger tr_turtles_bue before update of essence on turtles for each row when ( new.name = 'Splinter' and old.essence = 'Rat' and new.essence = 'Sensei' ) begin pkg_around_mutation.bUpdPainters := true; end tr_turtles_bue; / create or replace trigger tr_turtles_bu after update on turtles begin pkg_around_mutation.update_painters; end tr_turtles_bu; /
The method 2: Using compound DML triggers (available starting with Oracle 11g).
create or replace trigger tr_turtles_ue for update of essence on turtles compound trigger bUpdPainters boolean; before each row is begin if :new.name = 'Splinter' and :old.essence = 'Rat' and :new.essence = 'Sensei' then bUpdPainters := true; end if; end before each row; after statement is begin if bUpdPainters then update Turtles set essence = 'Ninja' where essence = 'Painter'; end if; end after statement; end tr_turtles_ue;
Let’s try the following:
update turtles set essence = 'Sensei' where name = 'Splinter'
Even if you faced a more complex case of mutation, you can use the above-mentioned idea as a workaround. In the instruction-level trigger, unlike the row-level trigger, no mutation occurs. You can use either variables (tags, latches, PL SQL tables) in an additional package, or variables that are global for all sections of the compound trigger, which is preferable starting with the version Oracle 11g. So, now you also know kung fu.
You may find additional information about triggers at: Compound DML Triggers
Feel free to add any comments.
Tags: oracle, sql Last modified: September 23, 2021