Skip to content
pvmehta.com

pvmehta.com

  • Home
  • About Me
  • Toggle search form
  • UTL_FILE test program Oracle
  • Validating ORACLE_SID againt oratab file. Linux/Unix
  • How to connect to Oracle Database with Wallet with Python. Oracle
  • Pending Distributed Transations Oracle
  • remove archfiles only when it is applied to DR rm_archfiles.sh Linux/Unix
  • All About oracle password and security from metalink Oracle
  • RAC with RHEL4 and 11g Oracle
  • myfile Oracle
  • Removing Blank lines from file using grep Linux/Unix
  • Remove DOS CR/LFs (^M) Linux/Unix
  • Formatter Explain plan Output 1 Oracle
  • default permission on ~/.ssh/authorized_keys2 or authorized_keys Linux/Unix
  • How to hide author name in WordPress BLOG PHP/MYSQL/Wordpress
  • chk_space_SID.ksh Linux/Unix
  • Vivek Tuning for Row Locks. Oracle

Mutating Table Error while using database trigger

Posted on 03-Nov-2005 By Admin No Comments on Mutating Table Error while using database trigger

The Mutating table error is a well-known problem encountered in development; most developers have come across this error.

ORA-04091: table is mutating,

trigger/function may not see it

The basic reason for this error is the way that Oracle manages a read consistent view of data. The error is encountered when a row-level trigger accesses the same table on which it is based, while executing. The table is said to be mutating. Mutation will not occur if a single record is inserted in the table (using VALUES clause). If bulk insertion is done or data is inserted from another table mutation will occur.

The mutating error is not only encountered during queries, but also for insert, updates and deletes present in the trigger. Below is a table that explains the various transaction scenarios that involves a trigger and whether it is prone to generate the mutating error. The OPERATION column explains the DML activity being performed and the TYPE column lists the type of trigger created and the execution level.

Case 1: When Trigger on table refers the same table:

—————————————————————–

OPERATION TYPE MUTATING?

—————————————————————–

insert before/statement-level No

insert after/statement-level No

update before/statement-level No

update after/statement-level No

delete before/statement-level No

delete after/statement-level No

insert before/row-level Single row Multi-row

No Yes

insert after/row-level Yes

update before/row-level Yes

update after/row-level Yes

delete before/row-level Yes

delete after/row-level Yes

—————————————————————–

A very simple example is given below.

SQL> create table am27

2 (col1 number,

3 col2 varchar2(30));

Table created.

SQL> create or replace trigger am27_trg

2 before insert or update or delete

3 on am27

4 for each row

5 declare

6 l_chk pls_integer;

7 begin

8 select count(1)

9 into l_chk

10 from am27;

11 — more processing…

12 end;

13 /

Trigger created.

SQL> insert into am27 values (1, ‘testing’);

1 row created.

SQL> update am27

2 set col1 = 2;

update am27

*

ERROR at line 1:

ORA-04091: table SYSTEM.AM27 is mutating, trigger/function may not see it

ORA-06512: at “SYSTEM.AM27_TRG”, line 4

ORA-04088: error during execution of trigger ‘SYSTEM.AM27_TRG’

In the above example, as table AM27 is being queried in the trigger AM27_TRG that is based on the same table, a mutating error is received.

It is also possible for ORA-4091 to be encountered when querying a table other than the table on which the trigger is based! This happens when a foreign key reference is present with an on-delete-cascade option. A row level trigger on the master table will mutate if the detail table is being referred to in the trigger, for a delete transaction. This will only happen if the foreign key on the detail table is created with the on delete cascade option. No mutation occurs if the master table is being referred in a trigger on the detail table.

There is one odd case where mutation may occur when some other table in the trigger is referred to; below is an example of such a condition.

AM10 is a master table. AM10_DTL is the detail table that is related to the master table with the on-delete-cascade option. AM10_BEF_TRG is created on the master table that queries the detail table for some information. Issuing a delete on the master table results in the mutation error.

SQL> create table am10

2 (col1 number, col2 varchar2(10));

Table created.

SQL> create table am10_dtl

2 (col1 number,

3 col2 varchar2(10));

Table created.

SQL> alter table am10 add primary key (col1);

Table altered.

SQL> alter table am10_dtl add foreign key (col1) references am10(col1) on delete cascade;

Table altered.

SQL> create or replace trigger am10_bef_trg

2 before insert or update or delete on am10

3 for each row

4 declare

5 l_chk pls_integer;

6 begin

7 select 1

8 into l_chk

9 from am10_dtl

10 where col1 = :new.col1;

11 dbms_output.put_line(‘ok’);

12 exception

13 when no_data_found then

14 dbms_output.put_line(‘no dtl recs’);

15 end;

16 /

Trigger created.

SQL> insert into am10 values (1, ‘amar’);

err

1 row created.

SQL> insert into am10 values (2, ‘chk’);

err

1 row created.

SQL> insert into am10_dtl values(1, ‘cooler’);

1 row created.

SQL> insert into am10_dtl values (2, ‘validator’);

1 row created.

SQL> delete from am10 where col1= 1;

delete from am10 where col1= 1

*

ERROR at line 1:

ORA-04091: table SYSTEM.AM10_DTL is mutating, trigger/function may not see it

ORA-06512: at “SYSTEM.AM10_BEF_TRG”, line 4

ORA-04088: error during execution of trigger ‘SYSTEM.AM10_BEF_TRG’

Oracle, SQL scripts

Post navigation

Previous Post: Adding Datafile on Primary Server and Impact on Standby Server
Next Post: Vivek Tuning for Row Locks.

Related Posts

  • SYSOPER Mystery Oracle
  • DETERMINING WHICH INSTANCE OWNS WHICH SHARED MEMORY & SEMAPHORE SEGMENTS Oracle
  • How to find where datafile is created dbf_info.sql Oracle
  • How to specify 2 arch location to avoid any kind of DB hanging. Oracle
  • Rman Notes -1 Oracle
  • Good Oracle Architecture In Short and point to point Oracle

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Categories

  • Ansible (0)
  • AWS (2)
  • Azure (1)
  • Linux/Unix (149)
  • MYSQL (5)
  • Oracle (393)
  • PHP/MYSQL/Wordpress (10)
  • POSTGRESQL (0)
  • Power-BI (0)
  • Python/PySpark (7)
  • RAC (17)
  • rman-dataguard (26)
  • shell (149)
  • SQL scripts (342)
  • SQL Server (6)
  • Uncategorized (0)
  • Videos (0)

Recent Posts

  • Trace a SQL session from another session using ORADEBUG30-Sep-2025
  • SQL Server Vs Oracle Architecture difference25-Jul-2025
  • SQL Server: How to see historical transactions25-Jul-2025
  • SQL Server: How to see current transactions or requests25-Jul-2025
  • T-SQL Vs PL/SQL Syntax25-Jul-2025
  • Check SQL Server edition25-Jul-2025
  • Checking SQL Server Version25-Jul-2025
  • Oracle vs MYSQL Architecture differences (For DBAs)24-Jul-2025
  • V$INSTANCE of Oracle in MYSQL24-Jul-2025
  • Day to day MYSQL DBA operations (Compared with Oracle DBA)24-Jul-2025

Archives

  • 2025
  • 2024
  • 2023
  • 2010
  • 2009
  • 2008
  • 2007
  • 2006
  • 2005
  • Load testing on Oracle 19C RAC with HammerDB Oracle
  • ORA-8031 issue and solution if it is occuring due to truncate. Oracle
  • All Hints for Oracle Databases Oracle
  • dbms_job.submit example Oracle
  • Library cahe Latches and internal explaination Oracle
  • Pending Distributed Transations Oracle
  • get_vmstat_solaris Oracle
  • To find all disk io ( EMC as well as local) Linux/Unix

Copyright © 2025 pvmehta.com.

Powered by PressBook News WordPress theme