Skip navigation
Practical SQL Server
yellow envelope with email symbol on black computer keyboard

A Better Way to Enable Email Alerts for Deadlocks

yellow envelope with email @ sign on black computer keyboardA while back I wrote about a way to enable email alerts for deadlock conditions with SQL Server. I outlined how, in order to set up these alerts, I ended up having to tweak SQL Server's internal sys.messages table via sp_altermessage—something I wasn't too excited about (given how I mentioned that I don't typically recommend doing so and that I felt this was a bit of a "gateway script").

Happily, Wayne Sheffield (Twitter/blog) saw my article, noticed that I was trying to use a hammer in an unnatural way, and recommended I use a gas-powered brad nailer instead. Or, in other words, Wayne was nice enough to email me with a much better and cleaner solution.

Wayne's solution is quite spiffy, doesn't require any modifications to system tables, and is drop-dead easy to implement. (Of course, I double-checked that the solution works as expected, without any hiccups or problems—which it does.) Listing 1 contains Wayne's ingenious script.

-- Tested SQL 2005 - 2012.
DECLARE @perfcond NVARCHAR(100);
DECLARE @sqlversion TINYINT;

-- get the major version of sql running
SELECT  @sqlversion = ca2.Ver
FROM    (SELECT CONVERT(VARCHAR(20), 
			SERVERPROPERTY('ProductVersion')) AS Ver) dt1
    CROSS APPLY (SELECT CHARINDEX('.', dt1.Ver) AS Pos) ca1
    CROSS APPLY (SELECT SUBSTRING(dt1.Ver, 1, ca1.Pos-1) AS Ver) ca2;

-- handle the performance condition depending on the version of sql running
-- and whether this is a named instance or a default instance.
SELECT  @perfcond = 
    CASE WHEN @sqlversion >= 11 THEN ''
    ELSE ISNULL(N'MSSQL$' + 
		CONVERT(sysname, SERVERPROPERTY('InstanceName')), N'SQLServer') + N':'
    END +
    N'Locks|Number of Deadlocks/sec|_Total|>|0';

EXEC msdb.dbo.sp_add_alert 
    @name=N'Deadlock Alert', 
    @message_id=0, 
    @severity=0, 
    @enabled=1, 
    @delay_between_responses=0, 
    @include_event_description_in=0, 
    @category_name=N'[Uncategorized]', 
    @performance_condition=@perfcond, 
    --@job_name=N'Job to run when a deadlock happens, if applicable'
    -- or 
    @job_id=N'00000000-0000-0000-0000-000000000000'
GO

EXEC msdb.dbo.sp_add_notification 
    @alert_name = N'Deadlock Alert',
    @notification_method = 1, --email
    @operator_name = N'General'; -- name of the operator to notify
GO

Under the hood, this script uses a SQL Server performance condition to specify alert logic—which is pretty visible/obvious in the script. If you want a better way to see how Wayne tackled this issue, you can crack open the alert in SQL Server Management Studio (SSMS) and take a peek at it, as Figure 1 shows.

Using SQL Server Management Studio to View a Deadlock Alert
Figure 1: Using SQL Server Management Studio to View a Deadlock Alert

Hide comments

Comments

  • Allowed HTML tags: <em> <strong> <blockquote> <br> <p>

Plain text

  • No HTML tags allowed.
  • Web page addresses and e-mail addresses turn into links automatically.
  • Lines and paragraphs break automatically.
Publish