DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports Events Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
What's in store for DevOps in 2023? Hear from the experts in our "DZone 2023 Preview: DevOps Edition" on Fri, Jan 27!
Save your seat
  1. DZone
  2. Data Engineering
  3. Databases
  4. Mutating Table Errors and Multi-Row Inserts

Mutating Table Errors and Multi-Row Inserts

A BEFORE INSERT trigger will not cause a mutating table error as long as the triggering INSERT statement is a single row insert (INSERT-VALUES).

Steven Feuerstein user avatar by
Steven Feuerstein
·
May. 09, 18 · Analysis
Like (1)
Save
Tweet
Share
5.06K Views

Join the DZone community and get the full member experience.

Join For Free

The Oracle Dev GymPL/SQL Challenge quiz (played April 28-May 4) explored the interactions between row-level triggers and multi-row inserts, particularly when it comes to mutating table errors. If you didn't happen to take the quiz and already learn its lesson, here goes.

Note: You can also click on the link above and play the quiz right now before you read this post!

Here's the main rule to keep in mind:

A BEFORE INSERT trigger will not cause a mutating table error as long as the triggering INSERT statement is a single row insert (INSERT-VALUES).

Let's take a closer look.

I create a table and a trigger on that table:

CREATE TABLE qz_flowers
(
   fl_num    NUMBER,
   fl_name   VARCHAR2 (30)
)
/

CREATE OR REPLACE TRIGGER qz_flowers_bir
   BEFORE INSERT ON qz_flowers
   FOR EACH ROW
DECLARE
   l_count INTEGER;
BEGIN
   SELECT COUNT (*) INTO l_count FROM qz_flowers;
   DBMS_OUTPUT.PUT_LINE ('Count = ' || l_count);
END;
/

The trigger queries from the qz_flowers table, which introduces the possibility of a mutating table error.

But if I insert a single row using the INSERT-VALUES format, I do not get that error:

SQL> BEGIN
  2     INSERT INTO qz_flowers VALUES (100, 'Orchid');
  3     DBMS_OUTPUT.PUT_LINE ('Inserted');
  4  END;
  5* /

Count = 0
Inserted

That makes, right? If I am inserting a single row in the table and a BEFORE INSERT trigger fires, that row is not yet in the table, the table is not mutating, and there can be no mutating table error.

I can even insert two rows in the same block and no error:

SQL> BEGIN
  2     INSERT INTO qz_flowers VALUES (100, 'Orchid');
  3     INSERT INTO qz_flowers VALUES (200, 'Tulip');
  4     DBMS_OUTPUT.PUT_LINE ('Inserted');
  5  END;
  6  /
Count = 0
Count = 1
Inserted

The trigger fires for each individual row inserted. The logic I stated above applies to each insert separately: no mutating table error. Ah, but if my INSERT statement inserts (or, as we shall soon see, might insert) more than one row, KABOOM!

SQL> BEGIN
  2     INSERT INTO qz_flowers 
  3        SELECT 100, 'Orchid' FROM DUAL 
  4        UNION ALL
  5        SELECT 200, 'Tulip' FROM DUAL;
  6     DBMS_OUTPUT.PUT_LINE ('Inserted');
  7  END;
  8  /

Error starting at line : 1 in command -
BEGIN
   INSERT INTO qz_flowers 
      SELECT 100, 'Orchid' FROM DUAL 
      UNION ALL
      SELECT 200, 'Tulip' FROM DUAL;
   DBMS_OUTPUT.PUT_LINE ('Inserted');
END;
Error report -
ORA-04091: table QDB_PROD.QZ_FLOWERS is mutating, trigger/function may not see it
ORA-06512: at "QDB_PROD.QZ_FLOWERS_BIR", line 4
ORA-04088: error during execution of trigger 'QDB_PROD.QZ_FLOWERS_BIR'
ORA-06512: at line 2
04091. 00000 -  "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.

Once that first row is inserted, the table is now "mutating" and the SELECT against that table cannot be safely performed.

And even if my INSERT-SELECT  only inserts a single row, the ORA-04091 error will be raised.

SQL> BEGIN
  2     INSERT INTO qz_flowers 
  3        SELECT 100, 'Orchid' FROM DUAL;
  4     DBMS_OUTPUT.PUT_LINE ('Inserted');
  5  END;
  6  /

Error report -
ORA-04091: table QDB_PROD.QZ_FLOWERS is mutating, trigger/function may not see it

And what about FORALL? In at least one way, that PL/SQL bulk processing statement acts like an INSERT-SELECT. Specifically, ON INSERT statement-level triggers (firing before or after) fire just once for the entire FORALL statement.

When it comes to the mutating table errors and the BEFORE INSERT trigger, FORALL behaves like a mix of INSERT-VALUES and INSERT-SELECT.

If the FORALL statement binds just a single value from its array, then it behaves like a single-row INSERT-VALUES statement:

SQL> DECLARE
  2     TYPE flowers_t IS TABLE OF qz_flowers%ROWTYPE;
  3     l_flowers flowers_t := flowers_t();
  4  BEGIN
  5     l_flowers.EXTEND;
  6     l_flowers (1).fl_num := 100;
  7     l_flowers (1).fl_name := 'Orchid';
  8  
  9     FORALL indx IN 1 .. l_flowers.COUNT
 10        INSERT INTO qz_flowers VALUES l_flowers (indx);
 11     DBMS_OUTPUT.PUT_LINE ('Inserted');
 12  END;
 13  /
Count = 0
Inserted

If the FORALL statement binds more than one value from its array, then it behaves like INSERT-SELECT:

SQL> DECLARE
  2     TYPE flowers_t IS TABLE OF qz_flowers%ROWTYPE;
  3     l_flowers flowers_t := flowers_t();
  4  BEGIN
  5     l_flowers.EXTEND (2);
  6     l_flowers (1).fl_num := 100;
  7     l_flowers (1).fl_name := 'Orchid';
  8     l_flowers (2).fl_num := 200;
  9     l_flowers (2).fl_name := 'Tulip';
 10  
 11     FORALL indx IN 1 .. l_flowers.COUNT
 12        INSERT INTO qz_flowers VALUES l_flowers (indx);
 13     DBMS_OUTPUT.PUT_LINE ('Inserted');
 14  END;
 15  /
Count = 0

Error report -
ORA-04091: table QDB_PROD.QZ_FLOWERS is mutating, trigger/function may not see it

Check out these links for more information on mutating table errors and getting around them:

  • Mutating Table Exceptions by Tim Hall

  • Get Rid of Mutating Table Trigger Errors With the Compound Trigger (my blog)

Database

Published at DZone with permission of Steven Feuerstein, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Popular on DZone

  • PostgreSQL: Bulk Loading Data With Node.js and Sequelize
  • How To Use Terraform to Provision an AWS EC2 Instance
  • Choosing the Best Cloud Provider for Hosting DevOps Tools
  • How Do the Docker Client and Docker Servers Work?

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 600 Park Offices Drive
  • Suite 300
  • Durham, NC 27709
  • support@dzone.com
  • +1 (919) 678-0300

Let's be friends: