Deadlocks due to different Access Order

A deadlock can occur when two sessions try to access the same index in a different order in non-compatible lock modes. The following script demonstrates this behavior.

Setup

Run the below scripts to create the necessary tables.

IF DB_ID(‘DeadLockTest’) IS NULL
CREATE Database DeadLockTest
GO

USE DeadLockTest
GO

CREATE TABLE dbo.aodl(id int identity(1,1) primary key clustered, filler char(100) default ‘abc’)
GO

SET NOCOUNT ON

DECLARE @i int
SET @i = 1
WHILE @i < 10000
BEGIN
INSERT INTO dbo.aodl DEFAULT VALUES
SET @i = @i+1
END

Now open a new session (session 1) and run the below script. Make sure to change the WAITFOR TIME value according to the time you are running. Its is used to ensure that both the queries will be starting at the same time.

WAITFOR TIME ’18:02′
BEGIN TRAN
SELECT * from dbo.aodl WITH(UPDLOCK)
WHERE Id > 4000
ORDER BY ID ASC
ROLLBACK TRAN

Now open another session (Session 2) and run the below script after changing the start time according to the first script.

WAITFOR TIME ’18:02′
BEGIN TRAN
SELECT * from dbo.aodl WITH(UPDLOCK)
WHERE Id < 6000
ORDER BY ID DESC
ROLLBACK TRAN

One of the session will fail with the deadlock error.

Analyze

From the script itself, it is obvious why the deadlock is happening. Lets confirm this by preparing the deadlock table.

Process Resource Mode State Command Object
process6dd708 KEY: 26:72057594042318848 (c904e608358d) U WAIT SELECT indexname=PK__spdl1
process6dd708 KEY: 26:72057594042318848 (30488d9fd081) U GRANT SELECT indexname=PK__spdl2
process6c34c8 KEY: 26:72057594042318848 (30488d9fd081) U WAIT SELECT indexname=PK__spdl2
process6c34c8 KEY: 26:72057594042318848 (c904e608358d) U GRANT SELECT indexname=PK__spdl1

 

Lets also find out what are the rows involved in deadlock using the below query.

SELECT %%lockres%% as LockResource, ID
FROM dbo.aodl
WHERE %%lockres%% IN(‘(c904e608358d)’, ‘(30488d9fd081)’)

On my machine it yields the below result.

LockResource ID
(c904e608358d) 5006
(30488d9fd081) 5007

You can see that both the processes were scanning the table in the opposite order and collided in the middle.

Fix

Change the ORDER BY clause to ensure that both the processes were accessing the table in the same order. One process will be blocked until the other finishes, but it won’t fail with a deadlock error.

This post is part of the series SQL Server deadlocks and live locks – Common Patterns. If you have questions, please post a comment here or reach me at @sqlindian

Advertisement

Deadlocks due to different Access Paths

A common deadlock pattern involving a single table is when the table is accessed using different access paths by means of different indexes. This post in Bart Duncan’s series explains this with a proper example.

Jonathan (b|t) offers a visual representation of the concept here.

Remus Rusanu(b|t) also offers an example of the problem here.

This post is part of the series SQL Server deadlocks and live locks – Common Patterns. If you have questions, please post a comment here or reach me at @sqlindian

Deadlock due to Savepoint Rollback behavior

Today I want to introduce you to a specific behavior about how locks are rolled back when you rollback a transaction to a Savepoint and how it can cause a deadlock.

Setup

Run the below script to create the necessary tables.

IF DB_ID(‘DeadLockTest’) IS NULL
CREATE Database DeadLockTest
GO

USE DeadLockTest
GO

CREATE TABLE dbo.spdl1(id int identity(1,1) primary key clustered, status char(20))
CREATE TABLE dbo.spdl2(id int identity(1,1) primary key clustered, status char(20))
GO
SET NOCOUNT ON

INSERT INTO dbo.spdl1 DEFAULT VALUES
INSERT INTO dbo.spdl2 DEFAULT VALUES

Now open a new session (session 1) and run the below script.

USE DeadLockTest
GO

SET TRANSACTION ISOLATION LEVEL REPEATABLE READ

BEGIN TRAN

SELECT * FROM dbo.spdl1 WHERE id = 1

SAVE TRANSACTION SP;

SELECT * FROM dbo.spdl2 WHERE id = 1

UPDATE dbo.spdl2 SET Status = ‘In Progress’
UPDATE dbo.spdl1 SET Status = ‘In Progress’

–Something went wrong.
–Rollback to the save point

ROLLBACK TRANSACTION SP;

Note that we performed two update statements and rolled it back. Open a second session (session 2) and run the below script.

USE DeadLockTest
GO

SET DEADLOCK_PRIORITY LOW

BEGIN TRAN

UPDATE dbo.spdl2 SET Status = ‘In Progress’ WHERE id = 1

The update will succeed.  Now run the below statement in the same window (session 2)

SELECT * FROM dbo.spdl1 WHERE id = 1

The above statement will be (surprisingly) blocked. Now go back to Session 1 and run the below script to cause a deadlock condition.

UPDATE dbo.spdl2 SET Status = ‘Failed’

The second session will now fail with the deadlock error.

Analyze

To see what is happening here, lets build the deadlock analysis table.

Process Resource Mode State Command Object
process6dd708 KEY: 26:72057594042122240 (8194443284a0) S WAIT SELECT indexname=PK__spdl1
process6dd708 KEY: 26:72057594042253312 (8194443284a0) X GRANT UPDATE indexname=PK__spdl2
process6c2e08 KEY: 26:72057594042253312 (8194443284a0) U WAIT UPDATE indexname=PK__spdl2
process6c2e08 KEY: 26:72057594042122240 (8194443284a0)  X GRANT SELECT ? indexname=PK__spdl1

As you can see above the process process6c2e08, which executed two update statements and rolled it back is still holding an exclusive lock (X) on one table, but obviously it released the exclusive lock on the other table, because the second session was able to acquire an X lock on that table and the UPDATE statement succeeded.

Couple of things to note here is that we are running Session 1 in REPEATABLE READ isolation level so we expect the shared locks to be held until the end of the transaction. The first SELECT statement is before the SAVE TRANSACTION statement and the second SELECT statement is after the SAVE TRANSACTION statement. So both these SELECT statements will first acquire Shared locks. When the update statements are executed, both the Shared locks will be converted to Exclusive locks. When we hit the ROLLBACK Savepoint, the ideal behavior is

1. Release the exclusive lock on the second table.

2. Downgrade the Exclusive lock on the first table to Shared Lock since the SELECT statement is outside the Savepoint.

But SQL Server does not undo a lock conversion by changing the lock mode to the previous mode existed before the Savepoint. So in our case, the exclusive lock on the first table will be held even if we rollback the UPDATE Statements.

IF you query the DMV sys.dm_tran_locks after the ROLLBACK savepoint statement, you can see that the process is still holding the exclusive lock.

Fix

Just move the first select statement below the SAVE TRANSACTION statement!

This post is part of the series SQL Server deadlocks and live locks – Common Patterns. If you have questions, please post a comment here or reach me at @sqlindian