By: Aaron Bertrand | Updated: 2012-11-01 | Comments | Related: > Triggers
Problem
Occasionally you may find that business logic in a trigger has not been executed. Sometimes it is because of a logic error in the trigger code, but sometimes it is because someone disabled the trigger. SQL Server does not track the enabling and disabling of triggers by default. Unfortunately the syntax one might use to disable a trigger, DISABLE TRIGGER, is not captured in the default trace, nor is it captured in the DDL Trigger event ALTER_TRIGGER. Sadly, the latter seems to be an intended gap in functionality, according to this Connect item. You could capture the information with a server-side trace (important: not a Profiler trace!), capturing SQL:StmtCompleted and optionally filtering on TextData, but on a busy system this could get quite expensive.
Solution
If you are using Enterprise Edition, one facility you have is SQL Server Audit. You can capture these events using a DATABASE AUDIT SPECIFICATION. You first need to create a SERVER AUDIT SPECIFICATION:
USE master; GO CREATE SERVER AUDIT ServerAudit TO FILE (FILEPATH = 'C:\temp\', MAXSIZE = 1 GB) WITH (ON_FAILURE = CONTINUE); GO ALTER SERVER AUDIT ServerAudit WITH (STATE = ON);
Now at the database level we need to create a DATABASE AUDIT SPECIFICATION. The audit group we're interested in capturing in this case is SCHEMA_OBJECT_CHANGE_GROUP. Note: there isn't an audit group to capture ENABLE/DISABLE TRIGGER exclusively.
USE [your_database_name]; GO CREATE DATABASE AUDIT SPECIFICATION schema_change FOR SERVER AUDIT ServerAudit ADD (SCHEMA_OBJECT_CHANGE_GROUP) WITH (STATE = ON); GO
In your database, create a simple table with an even simpler trigger:
CREATE TABLE dbo.splunge(id INT); GO CREATE TRIGGER dbo.splunge_trigger ON dbo.splunge FOR INSERT AS BEGIN SELECT 1; END GO
We can look at the audit right away, using sys.fn_get_audit_file, to see these CREATE events being captured:
SELECT event_time, succeeded, server_principal_name, [object_name], [statement] FROM sys.fn_get_audit_file ('C:\Temp\ServerAudit*', NULL, NULL) WHERE database_name = 'your_database_name';
Results:
Next we can disable the trigger:
DISABLE TRIGGER dbo.splunge_trigger ON dbo.splunge;
And then if we query the audit again, we will see the additional row, telling us who disabled the trigger and when:
And if you re-enable the trigger, you'll see yet another row. Of course we can restrict the result set to those statements that actually disabled triggers, by adding a WHERE clause such as:
AND [statement] LIKE '%disable%trigger%'
There could be false positives here, since you could, for example, have entities or code containing this same string pattern. Depending on how much audit activity you are collecting, adding a table or trigger name to the search string when performing very specific investigations may prove useful in filtering the results.
Conclusion
There are many ways to capture certain actions with SQL Server. While it's certainly not the only solution (and for some it is not an option), for customers using Enterprise Edition, a Database Audit is a fairly straightforward implementation that can help with these tasks. What I haven't tested at this point is how much overhead is added by the audit and how much this can be impacted by the mix of DDL and DML in your workload.
Next Steps
- Review the following tips and other resources:
About the author
This author pledges the content of this article is based on professional experience and not AI generated.
View all my tips
Article Last Updated: 2012-11-01