You Come And Go
I go back and forth when it comes to Lookups.
On the one hand, I don’t think the optimizer uses them enough. There are times when hinting a nonclustered index, or re-writing a query to get it to use a nonclustered index can really help performance.
On the other hand, they can really exacerbate parameter sniffing problems, and can even lead to read queries blocking write queries. And quite often, they lead to people creating very wide indexes to make sure particular queries are covered.
It’s quite a tedious dilemma, and in the case of blocking and, as we’ll see, deadlocks, one that can be avoided with an optimistic isolation level Read Committed Snapshot Isolation, or Snapshot Isolation.
Bigger Deal
There are ways to repro this sort of deadlock that rely mostly on luck, but the brute force approach is easiest.
First, create an index that will only partially help out some of our queries:
CREATE INDEX dethklok ON dbo.Votes(VoteTypeId);
Next, get a couple queries that should be able to co-exist ready to run in a loop.
A select:
/* Selecter */ SET NOCOUNT ON; DECLARE @i INT, @PostId INT; SET @i = 0; WHILE @i < 10000 BEGIN SELECT @PostId = v.PostId, @i += 1 FROM dbo.Votes AS v WHERE v.VoteTypeId = 8; END;
An update:
/* Updater */ SET NOCOUNT ON; DECLARE @i INT = 0; WHILE @i < 10000 BEGIN UPDATE v SET v.VoteTypeId = 8 - v.VoteTypeId, @i += 1 FROM dbo.Votes AS v WHERE v.Id = 55537618; END;
After several seconds, the select query will hit a deadlock.
But Why?
The reason, of course, if that these two queries compete for the same indexes:
The update query needs to update both indexes on the table, the read query needs to read from both indexes on the table, and they end up blocking each other:
We could fix this by expanding the index to also have PostId in it:
CREATE INDEX dethklok ON dbo.Votes(VoteTypeId, PostId);
Using an optimistic isolation level:
ALTER DATABASE StackOverflow2013 SET READ_COMMITTED_SNAPSHOT ON WITH ROLLBACK IMMEDIATE;
Or rewriting the select query to use a hash or merge join:
/* Selecter */ SET NOCOUNT ON; DECLARE @i INT, @PostId INT; SET @i = 0; WHILE @i < 10000 BEGIN SELECT @PostId = v2.PostId, @i += 1 FROM dbo.Votes AS v INNER /*MERGE OR HASH*/ JOIN dbo.Votes AS v2 ON v.Id = v2.Id WHERE v.VoteTypeId = 8 END;
Thanks for reading!
Going Further
If this is the kind of SQL Server stuff you love learning about, you’ll love my training. I’m offering a 75% discount to my blog readers if you click from here. I’m also available for consulting if you just don’t have time for that and need to solve performance problems quickly.
I’m noticing key lookup deadlocks (read blocking read queries) in our ERP database. The vendor does not recommend enabling snapshot isolation or modifying indexes. They feel that the deadlocks are caused by a different query and are “filtered down” from a more expensive process. Is there a way to find the specific expensive process that is causing deadlocks on processes that are “less expensive”? I’m seeing these deadlocks when there is low CPU/disk utilization and am having trouble pinpointing the exact culprit.
Have you tried sp_BlitzLock yet?