What is deadlock?
A deadlock is a situation in which two or more competing actions are each waiting for the other to finish, and thus neither ever does.
Refer: http://en.wikipedia.org/wiki/Deadlock

Scenario:
Data Preparation Script: (Script-a)

[sql]
–Create Sample Database
CREATE DATABASE SampleDeadLockDatabase
GO

USE SampleDeadLockDatabase
GO

–Create Sample Tables
CREATE TABLE SampleTable1(ID INT IDENTITY(1,1),VALUE UNIQUEIDENTIFIER)
GO

CREATE TABLE SampleTable2(ID INT IDENTITY(1,1),VALUE UNIQUEIDENTIFIER)
GO

–Populate Sample tables
INSERT INTO SampleTable1(VALUE)
SELECT NEWID()
GO 10

INSERT INTO SampleTable2(VALUE)
SELECT NEWID()
GO 10

–Retreive data for verification
SELECT * FROM SampleTable1
SELECT * FROM SampleTable2
[/sql]

Transaction1 Script: (Script-b)

[sql]
Select @@SPID — Note down this value here (68)
——————Transaction1——————-
–Step1 Begins–
USE SampleDeadLockDatabase
GO
BEGIN TRAN

UPDATE SampleTable1
SET VALUE = ‘1DF1EBE1-322E-4698-A5BD-2E2C6D85AEB6’
WHERE ID=1
–Step1 Ends–

—RUN Step2 in Transaction2

–Step3 Begins–
SELECT * FROM SampleTable2 WHERE ID=4

ROLLBACK TRAN
–Step3 Ends–
——————Transaction1——————-

[/sql]

Transaction2 Script: (Script-c)

[sql]
Select @@SPID — Note down this value here — 65
——————Transaction2——————-
–Step2 Begins–
USE SampleDeadLockDatabase
GO
BEGIN TRAN

UPDATE SampleTable2
SET VALUE = ‘23154CCE-0919-4D3A-92EB-E6B4062F8715’
WHERE ID=3
–Step2 Ends–

–Step4 Begins–
SELECT * FROM SampleTable1 WHERE ID=5

ROLLBACK TRAN
–Step4 Ends–
——————Transaction2——————-
[/sql]

Data Preparation:
In SQL Server Management Studio, Click on new query
Paste the Data Preparation Script, and execute it.

Dead Lock Scenario Creation:
Paste the two code snippets transaction1 and transaction 2 in separate query windows.
In each of them highlight the code (SELECT @@SPID) and run it to note down the SPID
Now run the Step1 in transaction1
This step updates SampleTable1 with a new value for id 1
Now run the Step2 in transaction2
This step updates SampleTable2 with a new value for id 3
Now run the Step3 in transaction1
This step selects the values of SampleTable2 with id 4
You will notice that this step3 is still executing. Why? We will analyze this later in the post.
Now run the Step4 in transaction2
This step selects the values of SampleTable1 with id 5
You will notice that this step executes for few seconds and completes. Also one of the session (Transaction1 or Transaction2 will be deadlocked.) with the errormessage


Msg 1205, Level 13, State 45, Line 1
Transaction (Process ID 65) was deadlocked on lock resources with another process and has been chosen as the deadlock victim. Rerun the transaction.

Analysis:
Why Step3 was waiting (Blocked?)
So now let us replicate the scenario again, by running the above steps1 and 2.
In the new query window (again a new Query window 🙂 ) Run the below script to understand what locks are placed on the tables pages and rows.

Script-d
[sql]
–Update this id with the @@spid of transaction1
SELECT resource_type,
resource_description,
resource_associated_entity_id,
request_mode,
request_type,
request_status FROM sys.dm_tran_locks
where request_session_id = 68

–Update this id with the @@spid of transaction2
SELECT resource_type,
resource_description,
resource_associated_entity_id,
request_mode,
request_type,
request_status FROM sys.dm_tran_locks
where request_session_id = 65

–Fetch the partition_id of the table
select p.partition_id,t.name,t.object_id From sys.partitions p join sys.tables t
on t.object_id = p.object_id
where t.name in (‘SampleTable1′,’SampleTable2’)
[/sql]

Update the values above with the respective @@spud’s that we noted down earlier. (SPID’s of the respective queries)
Output:

Table Locks

When you execute this you can find that each session has created exclusive lock (X) on the row level and intent exclusive (IX) locks on the page and table level.
Let’s find what exactly those rows are.
Copy the resource_description values for resource_type RID to the below script and run it.

Script-e:
[sql]
select * From SampleTable1 (nolock) where %%lockres%% = ‘1:154:0’
select * From SampleTable2 (nolock) where %%lockres%% = ‘1:156:2’
[/sql]

This would output the rows that we updated in respective transactions.

Lockres Output

Now run the step3 in transaction1, and run the script-d pasted above.
Output:
Shared Lock Waiting

You will notice that transaction1 now has the new lock for RID 1:156:2 which is in waiting state.
It’s waiting for an exclusive lock to be released on a row on SampleTable2
In order to find out the row for which transaction 1 is waiting copy the resource_description values to the below script and run it.
Script-f:
[sql]
select * From SampleTable2 (nolock) where %%lockres%% = ‘1:156:2’
[/sql]

Shared Lock Waiting For Row

So transaction1 is waiting for exclusive lock on row ID 3 to be released.
But in no way we are referring to rowid3 of transaction1., we were actually referring to row ID 4.

Why is SQL Server waiting for this row?

In order to understand this stop the step3 in transaction1 (it’s still getting executed) , select step3 code and click on Display estimated execution plan button ( or Query – Display estimated execution plan button) (or Ctrl + L )
You will find a table scans in the execution plan.

Waiting Transaction Execution Plan

So this table scan is forcing SQL Server to actually scan all the rows in the table(for ID=4) , as the ID=3 is blocked by transaction 2 it is waiting for transaction 2 to actually complete in order to take shared lock on the row and compare its value with 4.

Similarly when step4 is executed it is blocked by transaction 1, as step 4 has to do a table scan on the table SampleTable1 for ID = 5, but the transaction 1 has exclusively locked the row ID = 1.
So,
Transaction 1 is blocked by Transaction 2
AND
Transaction 2 is blocked by Transaction 1
This causes deadlock situation.
As both transactions would stay for infinite time blocking each other.
So, one of the transaction that is easier to rollback is terminated by SQL Server giving deadlock error: 1205

Resolutions:
1. Change to Snapshot Isolation.
[sql]
ALTER DATABASE SampleDeadLockDatabase
SET READ_COMMITTED_SNAPSHOT ON
[/sql]

Run the above query after disconnecting all the queries connected to SampleDeadLockDatabase
Now if you run the above Dead Lock Scenario steps you will notice that the deadlock is not occurring now.

2.Create index on the table so that there will be alternates for Table Scan.
Before testing the below approach remove snapshot isolation

[sql]
ALTER DATABASE SampleDeadLockDatabase
SET READ_COMMITTED_SNAPSHOT OFF
[/sql]

Script to Create clustered indexes on tables.
[sql]
ALTER TABLE SampleTable1
ADD CONSTRAINT SampleTable1_PK PRIMARY KEY (ID)
GO

ALTER TABLE SampleTable2
ADD CONSTRAINT SampleTable2_PK PRIMARY KEY (ID)
[/sql]

Now if you run the above Dead Lock Scenario steps you will notice that the deadlock is not occurring now. But you can reproduce dead lock if you force SQL Server to do an index /table scan instead of index seek. Using WITH (INDEX (0)) hint in Step 3 and Step 4.

[sql]
–Step3 Begins–
SELECT * FROM SampleTable2 WITH (INDEX(0)) WHERE ID=4

ROLLBACK TRAN
–Step3 Ends—

–Step4 Begins–
SELECT * FROM SampleTable1 WITH (INDEX(0)) WHERE ID=3

ROLLBACK TRAN
–Step4 Ends–
[/sql]

Leave a Reply

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