Skip to main content

Mutating table errors and multi-row inserts

The Oracle Dev Gym PL/SQL Challenge quiz played 28 Apr - 4 May 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)

Comments

Popular posts from this blog

Get rid of mutating table trigger errors with the compound trigger

When something mutates, it is changing. Something that is changing is hard to analyze and to quantify. A mutating table error (ORA-04091) occurs when a row-level trigger tries to examine or change a table that is already undergoing change (via an INSERT, UPDATE, or DELETE statement). In particular, this error occurs when a row-level trigger attempts to read or write the table from which the trigger was fired. Fortunately, the same restriction does not apply in statement-level triggers.

In this post, I demonstrate the kind of scenario that will result in an ORA-04091 errors. I then show the "traditional" solution, using a collection defined in a package. Then I demonstrate how to use the compound trigger, added in Oracle Database 11g Release1,  to solve the problem much more simply.

All the code shown in this example may be found in this LiveSQL script.

How to Get a Mutating Table Error

I need to implement this rule on my employees table:
Your new salary cannot be more than 25x th…

Table Functions, Part 1: Introduction and Exploration

August 2018 update: please do feel encourage to read this and my other posts on table functions, but you will learn much more about table functions by taking my Get Started with PL/SQL Table Functions class at the Oracle Dev Gym. Videos, tutorials and quizzes - then print a certificate when you are done!


Table functions - functions that can be called in the FROM clause of a query from inside the TABLE operator - are fascinating and incredibly helpful constructs.

So I've decided to write a series of blog posts on them: how to build them, how to use them, issues you might run into.

Of course, I am not the first to do so. I encourage to check out the documentation, as well as excellent posts from Adrian Billington (search for "table functions") and Tim Hall. Adrian and Tim mostly focus on pipelined table functions, a specialized variant of table functions designed to improve performance and reduce PGA consumption. I will take a look at pipelined table functions in the latte…

Quick Guide to User-Defined Types in Oracle PL/SQL

A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post.

PL/SQL is a strongly-typed language. Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type).

PL/SQL offers a wide array of pre-defined data types, both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package).

Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types.

You can't really declare your own "user-defined" scalars, though you can define subtypes from those scalars, which can be very helpful from the perspective…