Why INSERT causes TX – row lock contention or TM – contention in #Oracle

Inserts may cause enq: TX – row lock contention and enq: TM – contention under special circumstances:

Bitmap Indexes

First session inserts. Second session inserts with the same values for the indexed column. Second session experiences wait event enq: TX – row lock contention until first session commits, then proceeds without error message.

Unique Indexes

First session inserts. Second session inserts with the same values for the indexed column. Second session experiences wait event enq: TX – row lock contention until first session commits, then gets ORA-00001: unique constraint violated.

Parallel Inserts

First session inserts with parallel dml enabled. Second session inserts sequentially or in parallel doesn’t matter. Second session experiences wait event enq: TM – contention. This is also true for partitioned tables unless the partitions are explicitly referred to!

My test cases for the above scenarios have been done with 12.2.0.1 and  look as follows.

Bitmap Index scenario:

SQL> grant dba to adam identified by adam;

Grant succeeded.

SQL> connect adam/adam
Connected.
SQL> create table t1 (n number);

Table created.

SQL> create bitmap index b on t1(n);

Index created.

SQL> insert into t1 values(1);

1 row created.

Second session inserts the same and waits. You see the wait event in v$session then.
Unique Index

SQL> create table t2 (n number);

Table created.

SQL> alter table t2 add constraint u unique(n);

Table altered.

SQL> insert into t2 values (1);

1 row created.

Second session inserts the same and waits.
Parallel insert

SQL> create table t3 (n number);

Table created.

SQL> alter table t3 parallel;

Table altered.

SQL> alter session enable parallel dml;

Session altered.

SQL> insert into t3 select 1 from dual;

1 row created.

Second session waits for any DML.
Partitioned table parallel insert without partition clause

SQL> create table t4 (n number) partition by list (n) (partition p1 values(1),partition p2 values(2));

Table created.

SQL> alter table t4 parallel;

Table altered.

SQL> alter session enable parallel dml;

Session altered.

SQL> insert into t4 select 1 from dual;

1 row created.

Second session waits for any DML.
Non-blocking parallel insert with explicit partition clause
Same table as above, same parallel degree and parallel DML enabled, but:

SQL> insert into t4 partition (p1) select 1 from dual;

This blocks only partition p1. Second session can do any DML against p2 explicitly.

I have the feeling that this is not widely known – could actually be a good interview question: When do inserts lead to locking waits? As always: Don’t believe it, test it! 🙂

  1. Hinterlasse einen Kommentar

Kommentar verfassen

Trage deine Daten unten ein oder klicke ein Icon um dich einzuloggen:

WordPress.com-Logo

Du kommentierst mit Deinem WordPress.com-Konto. Abmelden /  Ändern )

Twitter-Bild

Du kommentierst mit Deinem Twitter-Konto. Abmelden /  Ändern )

Facebook-Foto

Du kommentierst mit Deinem Facebook-Konto. Abmelden /  Ändern )

Verbinde mit %s

Diese Seite verwendet Akismet, um Spam zu reduzieren. Erfahre, wie deine Kommentardaten verarbeitet werden..