ORA-04091: table string.string is mutating, trigger/function may not see it
Cause: A trigger (or a user defined plsql function that is referenced in this statement) attempted to look at (or modify) a table that was in the middle of being modified by the statement which fired it.
Action: Rewrite the trigger (or function) so it does not read that table.
Action: Rewrite the trigger (or function) so it does not read that table.
ORACLE MUTATING TABLE PROBLEM
The mutating trigger error (ORA-04091) is a pretty common problem in Oracle that happens and frustrates many application developers and DBAs as the application developers bug them to find a solution. It happens when a trigger on a table tries to insert, update, or even select from the same table of whose trigger is being executed. Sometimes the inability to see the table causes standstill in the development.
The following explanation and the associated scripts attempt to present just one work-around for the problem. The work around may not be the best but rather does show that a work-around is possible and provides a solution that will be applicable in most cases. The approach is described by a case study.
SCENARIO
The mutating table problem comes when the trigger tries to select or modify any row of the same table. This situation comes when a table preserves some effective date.
To describe this method, the SALGRADE table will be used.
The table SALGRADE contains information on salary limits for each grade. The salary limits are also based on a time factor, i.e. the employees' salary is determined by checking which grade level was effective when they joined or reviewed, not necessarily the grade effective now.
So the table looks like this:
SQL> desc salgrade;
Name Null? Type
------------------------------- -------- ----
GRADE NUMBER
LOSAL NUMBER
HISAL NUMBER
START_DATE DATE
END_DATE DATE
The table data looks like:
GRADE LOSAL HISAL START_DATE END_DATE
------- ------- ------- ---------- ---------
1 1000 2000 1-APR-94 3-AUG-95
1 1200 2200 3-AUG-95 <---- Null
2 1500 3000 23-JUL-92 12-DEC-93
2 1600 3200 12-DEC-93 11-JAN-95
2 1800 3400 11-JAN-95 <---- Null
This means the effective salary range of Grade 1 now is (1200-2200) not the employees who had review between 1-APR-94 to 3-AUG-95 will be in the range (1000-2000). This is a purely hypothetical scenario. The objective is to devise a trigger that does the following when a new record is inserted:
(1) Integrity checking for overlapping dates, i.e. the new record can't have a start date that is already covered.
(2) Update the record for the current grade to make the end_date equal to the start date of the new record (the new record's end_date must be null as that is the current record).
In both cases the table SALGRADE has to be selected and updated on the after insert row trigger on the same table. But the table will be mutating when the trigger fires and thus a run-time error will occur.
For the first requirement, consider the following trigger:
create or replace trigger taiudr_salgrade
after insert on salgrade
for each row
declare
hold_found varchar2(1);
begin
select 'Y' into hold_found
from salgrade
where grade = :new.grade
and end_date is null
and start_date > :new.start_date;
exception
when NO_DATA_FOUND then
raise_application_error(-20000,'Overlapping Dates');
end;
/
Although the trigger can be created with no errors, when a user tries to
insert into the table the following mutating table error is returned:
SQL> insert into salgrade values (2, 9000, 100000, '25-dec-95', null);
insert into salgrade values (2, 9000, 100000, '25-dec-93', null)
*
ERROR at line 1:
ORA-04091: table SCOTT.SALGRADE is mutating, trigger/function may not see it
ORA-06512: at "SCOTT.TAIUDR_SALGRADE", line 4
ORA-04088: error during execution of trigger 'SCOTT.TAIUDR_SALGRADE'
SOLUTION
The following approach is another possibility for the task:
1. Create a package "SALGRADE_PKG" that contains PL/SQL tables for holding the
SALGRADE data. Here 3 tables are created - one for holding start_dates, one
for end_dates, and one for holding the change_flag that identifies the
updated row.
2. Create a BEFORE INSERT STATEMENT trigger that populates the PL/SQL table with the start dates, end_dates and changed_grades flag ('N'). Although this still executes a SELECT agaist the SALGRADE table, the mutating table restriction, applies to all triggers that use the FOR EACH ROW clause and this new trigger will be a STATEMENT or table level trigger.
3. Create an AFTER INSERT ROW trigger that compares the newly inserted row against this PL/SQL table not the Database table. This way the integrity check can be done. The same trigger should assign the new end_date value to the PL/SQL table and update the value of the flag to indicate that this
has to be changed.
4. Create a AFTER INSERT STATEMENT trigger to update the SALGRADE table with the values in the PL/SQL table after looking at the change flag.
All these programs can be created by the sources found below.
CODE:
Code to create test table and populate it with data:
Code to create test table and populate it with data:
drop table salgrade;
CREATE TABLE SALGRADE
(GRADE NUMBER,
LOSAL NUMBER,
HISAL NUMBER,
START_DATE DATE,
END_DATE DATE);
INSERT INTO SALGRADE VALUES (1,1000,2000, '1-apr-94', '3-aug-95');
INSERT INTO SALGRADE VALUES (1,1200,2200, '3-aug-95', null);
INSERT INTO SALGRADE VALUES (2,1500,3000, '23-Jul-92', '12-dec-93');
INSERT INTO SALGRADE VALUES (2,1600,3200, '12-dec-93', '11-jan-95');
INSERT INTO SALGRADE VALUES (2,1800,3400, '11-jan-95', null);
Code for package STEP 1 above:
create or replace package salgrade_pkg as
type datetabtype is table of date index by binary_integer;
type chartabtype is table of char(1) index by binary_integer;
type rowidtabtype is table of rowid index by binary_integer;
start_date_tab datetabtype;
end_date_tab datetabtype;
rowid_tab rowidtabtype;
changed_grade chartabtype;
start_date_tab_size binary_integer;
end;
/
Code for before insert statement trigger STEP 2 above:
create or replace trigger tbiuds_salgrade
before insert on salgrade
declare
hold_start_date date;
hold_end_date date;
hold_rowid rowid;
hold_grade binary_integer;
cursor start_date_cur is
select rowid, grade, start_date
from salgrade
where end_date is null
order by grade;
begin
open start_date_cur;
loop
fetch start_date_cur into
hold_rowid, hold_grade, hold_start_date;
exit when start_date_cur%notfound;
salgrade_pkg.start_date_tab(hold_grade) := hold_start_date;
salgrade_pkg.end_date_tab(hold_grade) := hold_end_date;
salgrade_pkg.rowid_tab(hold_grade) := hold_rowid;
salgrade_pkg.changed_grade(hold_grade) := 'N';
end loop;
salgrade_pkg.start_date_tab_size := hold_grade;
close start_date_cur;
end;
/
Code for after insert row trigger STEP 3 above:
create or replace trigger taiudr_salgrade
after insert on salgrade
for each row
begin
if (:new.grade <= salgrade_pkg.start_date_tab_size) then
if salgrade_pkg.start_date_tab(:new.grade)
> :new.start_date then
raise_application_error(-20001,'Overlapping Dates');
end if;
salgrade_pkg.end_date_tab(:new.grade) := :new.start_date;
salgrade_pkg.changed_grade(:new.grade) := 'Y';
else
salgrade_pkg.start_date_tab(:new.grade) := :new.start_date;
salgrade_pkg.end_date_tab(:new.grade) := :new.end_date;
salgrade_pkg.changed_grade(:new.grade) := 'N';
salgrade_pkg.start_date_tab_size :=
salgrade_pkg.start_date_tab_size + 1;
end if;
end;
/
Code for after insert statement trigger STEP 4 above:
create or replace trigger taiuds_salgrade
after insert on salgrade
begin
for i in 1..(salgrade_pkg.start_date_tab_size) loop
if (salgrade_pkg.changed_grade(i) = 'Y') then
update salgrade
set end_date = salgrade_pkg.end_date_tab(i)
where rowid = salgrade_pkg.rowid_tab(i);
end if;
end loop;
end;
/
Once all the package and triggers are created, the same insert doesn't succeed but gives the user the a more appropriate error:
SQL> insert into salgrade values (2, 9000, 100000, '25-dec-93', null);
insert into salgrade values (2, 9000, 100000, '25-dec-93', null)
*
ERROR at line 1:
ORA-20001: Overlapping Dates
ORA-06512: at "SCOTT.TAIUDR_SALGRADE", line 5
ORA-04088: error during execution of trigger 'JACK.TAIUDR_SALGRADE'
The above method is one possible solution to Mutating problem.
The following section provides more in depth details about this mutating problem and some other possible solutions and workarounds:
ORA-4091 Mutating Table Explanation and Workarounds
The purpose of this explanation is to illustrate to those customers who require one of the following functional capabilities whilst being able to maintain referential integrity among objects:
* Cascade Update
* Cascade Delete
* Cascade Insert
* Cascade Delete
* Cascade Insert
For cascade Update and Insert functions, using stored triggers and procedures will result in an ORA-04091 - "Table is mutating" error.
ORA-04091: "table %s.%s is mutating, trigger/function may not see it"
Cause: A trigger (or a user defined plsql function that is referenced in this statement) attempted to look at (or modify) a table that was in the middle of being modified by the statement which fired it.
Action: Rewrite the trigger (or function) so it does not read that table.
Cause: A trigger (or a user defined plsql function that is referenced in this statement) attempted to look at (or modify) a table that was in the middle of being modified by the statement which fired it.
Action: Rewrite the trigger (or function) so it does not read that table.
ORA-04091 is a very common error that occurs with triggers if triggers are not managed properly. A full understanding of triggers will help you avoid that error.
A mutating table is a table that is currently being modified by an update, delete, or insert statement. You will encounter the ORA-04091 error if you have a row trigger that reads or modifies the mutating table. For example, if your trigger contains a select statement or an update statement referencing the table it is triggering off of you will receive the error.
Another way that this error can occur is if the trigger has statements to change the primary, foreign or unique key columns of the table the trigger is triggering from.
If you must have triggers on tables that have referential constraints, the workaround is to enforce the referential integrity through triggers as well.
It must be stressed that this solution should ONLY be used to overcome DML restrictions imposed on triggers in order to maintain referential integrity. Whenever possible it is recommended that normal declarative integrity should be used to maintain foreign key integrity. Enforcing this integrity through stored triggers and procedures will have an effect on performance compared with declarative integrity.
For this solution to work correctly there must be no declarative integrity constraints between objects to enforce the foreign key constraint. The basic principle behind this solution is to suppress the validation checks performed as a result of inserting or updating a foreign key in the CHILD table triggered by a cascade Update or Insert. These checks would normally verify the existence of the new foreign key value in the PARENT record (by SELECTING from the parent table). The suppression of this check is only carried out as a direct result of Cascade Update or Delete, as we can be confident that this new value for the foreign key in the CHILD record does exist (i.e. a result of it being inserted or updated in the PARENT table). In all other circumstances no suppression will take place (e.g. when changing the DEPTNO of an employee or when inserting a new employee).
The following code illustrates how this is achieved for the cascade Update scenario, the code can easily be modified to add the other functionality and encapsulate it all within the same package. The EMP and DEPT table have been used, with the column EMP.DEPTNO in the EMP table referencing DEPT.DEPTNO in the DEPT table.
Conceptual Model
------------- 1. Trigger on PARENT for cascade function
| | SET global_variable = 'NO';
| PARENT | do cascade update;
| | SET global_variable = 'YES';
------------- End;
| -------------------
| | GLOBAL_VARIABLE |
| -------------------
/|\
------------ 2. Trigger on CHILD to maintain referential integrity
| | CHECK global_variable;
| CHILD | IF global_variable = 'YES' THEN
| | check existence of (fk) in PARENT;
------------ ELSE
null;
End;
EXAMPLE:
Oracle does not allow you the reading of a mutating table in a row trigger as it may lead to consistent data.
Attempt to do so, results in the following error:
ORA-04091 Table %s.%s is mutating, trigger/function may not see it
However, this operation can be performed within a statement trigger.
One way to work-around the mutating error within a row level trigger is to use a package PL/SQL table to store ROWIDs of updated records in a row trigger, and reprocess the updated records in a statement trigger.
Solution
Solution
Note that there are concurrency issues with this if more than one session tries to perform operations simultaneously. This is not intended as a total solution, but as the framework to help show one option.
The following is the sample work-around that used the EMP table.
Create the package to define the objects that will house the data.
create or replace package emp_pkg as
type emp_tab_type is table of rowid index by binary_integer;
emp_tab emp_tab_type;
emp_index binary_integer;
end emp_pkg;
/
type emp_tab_type is table of rowid index by binary_integer;
emp_tab emp_tab_type;
emp_index binary_integer;
end emp_pkg;
/
Create the table level trigger to reset the index BEFORE any changes take place.
create or replace trigger emp_bef_stm_all before insert or update or delete on emp
begin
--Remember to reset the pl/sql table before each statement
emp_pkg.emp_index := 0;
end;
/
begin
--Remember to reset the pl/sql table before each statement
emp_pkg.emp_index := 0;
end;
/
The following Row level trigger will fire for each row being modified and copy the RowID for each row to the EMP_TAB object defined within the package.
create or replace trigger emp_aft_row_all after insert or update or delete on emp
for each row
begin
--Store the rowid of updated record into global pl/sql table
emp_pkg.emp_index := emp_pkg.emp_index + 1;
emp_pkg.emp_tab(emp_pkg.emp_index) := :new.rowid;
end;
/
for each row
begin
--Store the rowid of updated record into global pl/sql table
emp_pkg.emp_index := emp_pkg.emp_index + 1;
emp_pkg.emp_tab(emp_pkg.emp_index) := :new.rowid;
end;
/
The following table level trigger will fire AFTER the others and will print out each RowID affected.
create or replace trigger emp_aft_stm_all after insert or update or delete on emp
begin
for i in 1 .. emp_pkg.emp_index loop
-- Re-process the updated records.
--There is no restriction here.
dbms_output.put_line(emp_pkg.emp_tab(i));
end loop;
emp_pkg.emp_index := 0;
end;
/
begin
for i in 1 .. emp_pkg.emp_index loop
-- Re-process the updated records.
--There is no restriction here.
dbms_output.put_line(emp_pkg.emp_tab(i));
end loop;
emp_pkg.emp_index := 0;
end;
/
In order to see how this work from SQL*Plus, the output must be turned on.
SQL> SET SERVEROUTPUT ON
This first example, displays the RowIDs for Department 20 then issues a DELETE command. The trigger should fire and display the same RowIDs to confirm it is working. (The RowIDs will vary from machine to machine.)
SQL> SELECT ROWID, DEPTNO FROM EMP WHERE DEPTNO = 20;
ROWID DEPTNO
------------------ ----------
AAAM4iAAEAAAAG+AAA 20
AAAM4iAAEAAAAG+AAD 20
AAAM4iAAEAAAAG+AAH 20
AAAM4iAAEAAAAG+AAK 20
AAAM4iAAEAAAAG+AAM 20
------------------ ----------
AAAM4iAAEAAAAG+AAA 20
AAAM4iAAEAAAAG+AAD 20
AAAM4iAAEAAAAG+AAH 20
AAAM4iAAEAAAAG+AAK 20
AAAM4iAAEAAAAG+AAM 20
SQL> DELETE EMP WHERE DEPTNO = 20;
AAAM4iAAEAAAAG+AAA
AAAM4iAAEAAAAG+AAD
AAAM4iAAEAAAAG+AAH
AAAM4iAAEAAAAG+AAK
AAAM4iAAEAAAAG+AAM
AAAM4iAAEAAAAG+AAA
AAAM4iAAEAAAAG+AAD
AAAM4iAAEAAAAG+AAH
AAAM4iAAEAAAAG+AAK
AAAM4iAAEAAAAG+AAM
This second example, displays the RowIDs for Department 10 then issues an UPDATE command. The trigger should fire and display the same RowIDs to confirm it is working. (The RowIDs will vary from machine to machine.)
SQL> SELECT ROWID, DEPTNO FROM EMP WHERE DEPTNO=10;
ROWID DEPTNO
------------------ ----------
AAAM4iAAEAAAAG+AAG 10
AAAM4iAAEAAAAG+AAI 10
AAAM4iAAEAAAAG+AAN 10
------------------ ----------
AAAM4iAAEAAAAG+AAG 10
AAAM4iAAEAAAAG+AAI 10
AAAM4iAAEAAAAG+AAN 10
SQL> UPDATE EMP SET JOB='Test' WHERE DEPTNO=10;
AAAM4iAAEAAAAG+AAG
AAAM4iAAEAAAAG+AAI
AAAM4iAAEAAAAG+AAN
AAAM4iAAEAAAAG+AAG
AAAM4iAAEAAAAG+AAI
AAAM4iAAEAAAAG+AAN
3 rows updated.
To rollback the changes, issue the Rollback command.
SQL> ROLLBACK;
Rollback complete.
CONCLUSION :
CONCLUSION :
The above methods are not submitted as solutions to all cases, however, those are provided as some of the possibilities for the Mutating problem. By following the above examples and customizing them to the individual needs , these Mutating problems can be avoided or fixed.
About Mindsforest
0 comments:
Post a Comment