Mohamed Houri’s Oracle Notes

March 20, 2011

Deadlock – Part 2: Unindexed Foreign keys

Filed under: Deadlock — hourim @ 8:43 am

I the Part-1 of the deadlock graph interpretation, I have introduced the deadlock graph that have been generated by the use of bitmap indexes in a heavy concurrent OLTP application. Part 2 of this series aims to show two points:

  1. How a session can deadlock itself
  2. How to know from the deadlock graph that this deadlock is due to un-indexed Foreign Keys

Let’s simulate this kind of deadlock via a simple demo:

SQL> create table p as select * from all_users;

Table créée.

SQL> select count(1) from p;

COUNT(1)
----------
31

SQL> alter table p add constraint p_pk primary key (user_id);

Table modifiée.

SQL> create table c (user_id references p, data varchar2(10));

Table créée.

SQL> select min(user_id), max(user_id) from p;

MIN(USER_ID) MAX(USER_ID)
------------ ------------
0             2147483638

SQL> insert into c(user_id,data) values (0,'test');

1 ligne créée.

SQL> declare
2  pragma autonomous_transaction;
3  begin
4  delete from p where user_id = 72;
5  commit;
6  end;
7  /

declare
*
ERREUR à la ligne 1 :
ORA-00060: détection d'interblocage pendant l'attente d'une ressource
ORA-06512: à ligne 4

SQL> rollback;

Annulation (rollback) effectuée.

So, here we are; I have simulated the ORA-00060 deadlock error when I was deleting from a parent table having a child table with un-indexed Foreign Key. Below is the corresponding deadlock graph generated internally by Oracle:

[Transaction Deadlock]

The following deadlock is not an ORACLE error. It is a
deadlock due to user error in the design of an application
or from issuing incorrect ad-hoc SQL. The following
information may aid in determining the deadlock:

Deadlock graph:
 ---------Blocker(s)--------  ---------Waiter(s)---------
Resource Name          process session holds waits  process session holds waits
TM-000121c1-00000000        24      18    SX             24      18           S

session 18: DID 0001-0018-00000052    session 18: DID 0001-0018-00000052

Rows waited on:
 Session 18: obj - rowid = 000121C1 - AAAAAAAAAAAAAAAAAA
 (dictionary objn - 74177, file - 0, block - 0, slot - 0)

----- Information for the OTHER waiting sessions -----
----- End of information for the OTHER waiting sessions -----

Information for THIS session:

----- Current SQL Statement for this session (sql_id=6y61nc5zbc9w5) -----
DELETE FROM P WHERE USER_ID = 72
----- PL/SQL Stack -----
----- PL/SQL Call Stack -----
 object      line  object
 handle    number  name
23C9D90C         4  anonymous block
===================================================

Two remarks from the above deadlock graph should be emphasized:

  • (a) we have the same session 18 that is deadlocking itself and
  • (b) the deadlock is due to a TM-enqueue :
 ---------Blocker(s)--------  ---------Waiter(s)---------
Resource Name          process session holds waits  process session holds waits
TM-000121c1-00000000        24      18    SX             24      18           S

And two conclusions can also be done from the above deadlock graph

  1. It is possible that a single session can deadlock itself when using autonomous transaction. This is why it is worth to mention that you have to use the autonomous transaction carrefully
  2. a TM-Enqueue in the deadlock graph is generally a clear indication that the deadlock is due to a DML on parent table with child table having a non-indexed Foreign Key

Leave a Comment »

No comments yet.

RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Create a free website or blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud Oracle's blog

Just another Oracle blog : Database topics and techniques

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

EU Careers info

Your career in the European Union

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)

%d bloggers like this: