Deadlocks: let’s do one, understand it, and fix it.
You keep getting warnings and emails about deadlocks, but let’s be honest: you’re not really sure how they happen or what to do about it.
I’ll show you how to build a deadlock in just a few lines of T-SQL so you can see how SQL Server reacts. You’ll be more comfortable with the decisions SQL Server takes, and when you can safely ignore ’em.
When you can’t ignore ’em, you’ll learn how to analyze them with free tools (sp_BlitzLock and SentryOne Plan Explorer), and how to fix them with index and code changes.
https://www.slideshare.net/BrentOzar/deadlocks-lets-do-one-understand-it-and-fix-it
Demo Scripts
To follow along, you can use any version of the Stack Overflow database (even the small one is fine.)
NOLOCK Demo Script – Left Side
|
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
EXEC DropIndexes; GO BEGIN TRAN UPDATE dbo.Users SET Location = N'The Derek Zoolander School for Kids Who Can''t Read Good and Want to Do Other Stuff Good Too', WebsiteUrl = N'https://www.youtube.com/watch?v=NQ-8IuUkJJc' WHERE DisplayName <> 'alex'; GO ROLLBACK GO ALTER TABLE dbo.Users REBUILD; GO |
NOLOCK Demo Script – Right Side
|
1 2 3 4 |
SELECT COUNT(*) FROM dbo.Users WITH (NOLOCK) WHERE DisplayName = 'alex'; GO 20 |
Deadlock Demo Script – Left Side
|
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 |
DROP TABLE IF EXISTS dbo.Lefty; DROP TABLE IF EXISTS dbo.Righty; GO CREATE TABLE dbo.Lefty (Numbers INT PRIMARY KEY CLUSTERED); INSERT INTO dbo.Lefty VALUES (1), (2), (3); CREATE TABLE dbo.Righty (Numbers INT PRIMARY KEY CLUSTERED); INSERT INTO dbo.Righty VALUES (1), (2), (3); GO /* LEFT SIDE: */ BEGIN TRAN UPDATE dbo.Lefty SET Numbers = Numbers + 1; GO UPDATE dbo.Righty SET Numbers = Numbers + 1; GO ROLLBACK GO sp_BlitzLock; GO |
Deadlock Demo Script – Right Side
|
1 2 3 4 5 6 7 8 9 10 11 |
/* RIGHT SIDE: */ BEGIN TRAN UPDATE dbo.Righty SET Numbers = Numbers + 1; GO UPDATE dbo.Lefty SET Numbers = Numbers + 1; GO ROLLBACK |
More Complex Stored Procedure Example
With this example, I use a single stored procedure that we’ll call from different sessions, and we’ll produce deadlocks with it, and then fix ’em.
|
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 |
/* Mastering Query Tuning - How SQL Server Builds Query Plans This script is from our Mastering Query Tuning class. To learn more: https://www.brentozar.com/go/masterqueries This demo requires: * Any supported version of SQL Server * Any Stack Overflow database: https://www.brentozar.com/go/querystack License: Creative Commons Attribution-ShareAlike 3.0 Unported (CC BY-SA 3.0) More info: https://creativecommons.org/licenses/by-sa/3.0/ You are free to: * Share - copy and redistribute the material in any medium or format * Adapt - remix, transform, and build upon the material for any purpose, even commercially Under the following terms: * Attribution - You must give appropriate credit, provide a link to the license, and indicate if changes were made. * ShareAlike - If you remix, transform, or build upon the material, you must distribute your contributions under the same license as the original. This first RAISERROR is just to make sure you don't accidentally hit F5 and run the entire script. You don't need to run this: */ RAISERROR(N'Oops! No, don''t just hit F5. Run these demos one at a time.', 20, 1) WITH LOG; GO CREATE OR ALTER PROC dbo.usp_CastUpVote @VoterId INT, @PostId INT AS BEGIN BEGIN TRAN /* Update the voter's LastAccessDate because they were active on Stack Overflow: */ UPDATE dbo.Users SET LastAccessDate = GETDATE() WHERE Id = @VoterId; /* Cast an upvote: */ INSERT INTO dbo.Votes (PostId, UserId, VoteTypeId, CreationDate) VALUES (@PostId, @VoterId, 2, GETDATE()); /* Update the post's score: */ UPDATE dbo.Posts SET Score = Score + 1 WHERE Id = @PostId; WAITFOR DELAY '00:00:10' /* 10 seconds */ /* Grant a reputation point to the post's owner: */ UPDATE u SET Reputation = Reputation + 1 FROM dbo.Posts p INNER JOIN dbo.Users u ON p.OwnerUserId = u.Id WHERE p.Id = @PostId; COMMIT; END; GO /* Run these in two separate windows: */ EXEC usp_CastUpVote @VoterId = 8741, @PostId = 1251636; EXEC usp_CastUpVote @VoterId = 149190, @PostId = 338156; GO /* Try moving both Users updates to the top: */ CREATE OR ALTER PROC dbo.usp_CastUpVote @VoterId INT, @PostId INT AS BEGIN BEGIN TRAN /* Update the voter's LastAccessDate because they were active on Stack Overflow: */ UPDATE dbo.Users SET LastAccessDate = GETDATE() WHERE Id = @VoterId; WAITFOR DELAY '00:00:10' /* 10 seconds */ /* Grant a reputation point to the post's owner: */ UPDATE u SET Reputation = Reputation + 1 FROM dbo.Posts p INNER JOIN dbo.Users u ON p.OwnerUserId = u.Id WHERE p.Id = @PostId; /* Cast an upvote: */ INSERT INTO dbo.Votes (PostId, UserId, VoteTypeId, CreationDate) VALUES (@PostId, @VoterId, 2, GETDATE()); /* Update the post's score: */ UPDATE dbo.Posts SET Score = Score + 1 WHERE Id = @PostId; COMMIT; END; GO /* Run these in two separate windows: */ EXEC usp_CastUpVote @VoterId = 8741, @PostId = 1251636; EXEC usp_CastUpVote @VoterId = 149190, @PostId = 338156; GO /* Try merging the two Users updates into one: */ CREATE OR ALTER PROC dbo.usp_CastUpVote @VoterId INT, @PostId INT AS BEGIN BEGIN TRAN /* Update both the voter and the question-owner */ UPDATE u SET LastAccessDate = CASE WHEN u.Id = @VoterId THEN GETDATE() ELSE u.LastAccessDate END, Reputation = CASE WHEN u.Id = p.OwnerUserId THEN u.Reputation + 1 ELSE u.Reputation END FROM dbo.Posts p INNER JOIN dbo.Users u ON (p.OwnerUserId = u.Id OR u.Id = @VoterId) WHERE p.Id = @PostId; WAITFOR DELAY '00:00:10' /* 10 seconds */ /* Cast an upvote: */ INSERT INTO dbo.Votes (PostId, UserId, VoteTypeId, CreationDate) VALUES (@PostId, @VoterId, 2, GETDATE()); /* Update the post's score: */ UPDATE dbo.Posts SET Score = Score + 1 WHERE Id = @PostId; COMMIT; END; GO /* Run these in two separate windows: */ EXEC usp_CastUpVote @VoterId = 8741, @PostId = 1251636; EXEC usp_CastUpVote @VoterId = 149190, @PostId = 338156; GO /* Try doing one update outside of the transaction: */ CREATE OR ALTER PROC dbo.usp_CastUpVote @VoterId INT, @PostId INT AS BEGIN /* Update the voter's LastAccessDate because they were active on Stack Overflow: */ UPDATE dbo.Users SET LastAccessDate = GETDATE() WHERE Id = @VoterId; BEGIN TRAN WAITFOR DELAY '00:00:10' /* 10 seconds */ /* Grant a reputation point to the post's owner: */ UPDATE u SET Reputation = Reputation + 1 FROM dbo.Posts p INNER JOIN dbo.Users u ON p.OwnerUserId = u.Id WHERE p.Id = @PostId; /* Cast an upvote: */ INSERT INTO dbo.Votes (PostId, UserId, VoteTypeId, CreationDate) VALUES (@PostId, @VoterId, 2, GETDATE()); /* Update the post's score: */ UPDATE dbo.Posts SET Score = Score + 1 WHERE Id = @PostId; COMMIT; END; GO /* Run these in two separate windows: */ EXEC usp_CastUpVote @VoterId = 8741, @PostId = 1251636; EXEC usp_CastUpVote @VoterId = 149190, @PostId = 338156; GO |
