As some of you may be aware, triggers are not my favourite thing in the world but like most things, it does have its place.
Whilst onsite with one of my clients, one of the processes fires a trigger on insert which ultimately runs a SSRS subscription to email a report. All sounding fairly feasible so far. However, this process is also used as part of a batch process overnight which would run a separate insert statement (actually another stored procedure in another job step) instead of the “onDemand” insert. Ok, still doesn’t sound like too much of an issue.
Now, they started experiencing occasional failures of this job during the day with the error relating to the fact that the SSRS subscription job was being called when it already was running. Interesting, this in theory shouldn’t ever happen because the process either ran the jobs based on the batch process or the one off onDemand.
Stepping through the process, it led me to an AFTER INSERT trigger. Upon opening it I spotted the issue straight away. Something that as I’ve found over the years as a consultant, a lot of DBA’s and developers have failed to understand that (from MSDN ):
These triggers fire when any valid event is fired, regardless of whether or not any table rows are affected.This is by design.
So, the issue was that step 3 ran a procedure which ultimately ran an insert statement for the onDemand insert, step 4 ran a procedure to insert for the overnight batch process which as it happens doesn’t have any records to insert but will in fact fire the trigger to run the SSRS subscription again! There is a number of ways to fix this but I’ve tended to stick with a basic check of the “inserted” table for results and RETURN out if no records are there to process.
I’ve supplied a bit of test code below for people to try this out.
Lets create a test table and an audit table:
USE tempdb GO IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[TestTable]') AND type in (N'U')) DROP TABLE [dbo].[TestTable] GO CREATE TABLE [dbo].[TestTable] ( TestTableID INT IDENTITY(1,1), TestTableDescr VARCHAR(20) ) GO IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[AuditTrigger]') AND type in (N'U')) DROP TABLE [dbo].[AuditTrigger] GO CREATE TABLE [dbo].[AuditTrigger] ( AuditTriggerID INT IDENTITY(1,1), AuditTriggerDescr VARCHAR(20), DateCreated DATETIME ) GO INSERT INTO dbo.TestTable (TestTableDescr) VALUES ('Test1'), ('Test2'), ('Test3'); SELECT * FROM dbo.TestTable;
Now lets create the trigger with no checking:
USE [TempDB] GO IF EXISTS (SELECT * FROM sys.triggers WHERE object_id = OBJECT_ID(N'[dbo].[trTestTable]')) DROP TRIGGER [dbo].[trTestTable] GO CREATE TRIGGER [dbo].[trTestTable] ON [dbo].[TestTable] AFTER INSERT AS BEGIN --Log the fact the trigger fired INSERT INTO [dbo].[AuditTrigger] (AuditTriggerDescr, DateCreated) SELECT 'Trigger Fired', GETDATE() END GO
Test Inserting a record that exists:
--Valid Insert INSERT INTO dbo.TestTable (TestTableDescr) SELECT TestTableDescr FROM dbo.TestTable WHERE TestTableDescr = 'Test1'; SELECT * FROM [dbo].[AuditTrigger];
Test Inserting a record that doesn’t exist:
--Not a Valid Insert INSERT INTO dbo.TestTable (TestTableDescr) SELECT TestTableDescr FROM dbo.TestTable WHERE TestTableDescr = 'Test4'; SELECT * FROM [dbo].[AuditTrigger];
You’ll now see that there are 2 entries in the AuditTrigger table due to the fact that the trigger fired even though no records were actually valid to insert.
So, lets amend the trigger to check for valid inserts:
USE [TempDB] GO IF EXISTS (SELECT * FROM sys.triggers WHERE object_id = OBJECT_ID(N'[dbo].[trTestTable]')) DROP TRIGGER [dbo].[trTestTable] GO CREATE TRIGGER [dbo].[trTestTable] ON [dbo].[TestTable] AFTER INSERT AS BEGIN --Check to see if any records were inserted IF NOT EXISTS (SELECT 1 FROM INSERTED) RETURN --Log the fact the trigger fired INSERT INTO [dbo].[AuditTrigger] (AuditTriggerDescr, DateCreated) SELECT 'Trigger Fired', GETDATE() END GO
and test the inserts again:
Test Inserting a record that exists:
--Valid Insert INSERT INTO dbo.TestTable (TestTableDescr) SELECT TestTableDescr FROM dbo.TestTable WHERE TestTableDescr = 'Test2'; SELECT * FROM [dbo].[AuditTrigger];
Test Inserting a record that doesn’t exist
--Not a Valid Insert INSERT INTO dbo.TestTable (TestTableDescr) SELECT TestTableDescr FROM dbo.TestTable WHERE TestTableDescr = 'Test4'; SELECT * FROM [dbo].[AuditTrigger];
No record will have been inserted with the final insert statement!
Lets clean up our tempdb:
USE [TempDB] GO --Clean up IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[TestTable]') AND type in (N'U')) DROP TABLE [dbo].[TestTable] GO IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[AuditTrigger]') AND type in (N'U')) DROP TABLE [dbo].[AuditTrigger] GO
Hopefully this will help point out the misconception that triggers only fire when records are actually inserted
As per usual, I’d like to hear peoples thoughts/experiences on this topic.