I promised I would write a 'real' SQl subject so here it is: DDL triggers and DDL events for use with DDL triggers
Let's start by creating 2 simple triggers
USE AdventureWorks
GO
CREATE TRIGGER ddlTestEvents1
ON DATABASEFOR DROP_TABLE, ALTER_TABLE, CREATE_TABLE
AS
PRINT 'You must disable Trigger "ddlTestEvents1" to drop,create or alter tables!'ROLLBACK;
GO
CREATE TRIGGER ddlTestEvents2
ON DATABASE
FOR DDL_TABLE_EVENTS
AS
PRINT 'You must disable Trigger "ddlTestEvents2" to drop, create or alter tables!'ROLLBACK;
GO
Let's try creating a table
CREATE TABLE wasabi(id
INT)
GO
And here is the error message, the first trigger fired
You must disable Trigger "ddlTestEvents1" to drop,create or alter tables!
Msg 3609, Level 16, State 2, Line 1
The transaction ended in the trigger. The batch has been aborted.
Let's disable the ddlTestEvents1 trigger and see what happens
DISABLE TRIGGER [ddlTestEvents1]
ON DATABASE
GO
Let's try creating a table again
CREATE TABLE wasabi(id
INT)
GO
Aha, same error message(almost) different trigger
You must disable Trigger "ddlTestEvents2" to drop, create or alter tables!
Msg 3609, Level 16, State 2, Line 1
The transaction ended in the trigger. The batch has been aborted.
so basically the event DDL_TABLE_EVENTS is the same as the DROP_TABLE, ALTER_TABLE, CREATE_TABLE events. To check that run the following code
SELECT name,te.type_desc,te.type
FROM sys.triggers t
JOIN
sys.trigger_events te on t.object_id = te.object_id
WHERE t.parent_class=0
AND name IN(
'ddlTestEvents1',
'ddlTestEvents2')ORDER BY name,te.type_desc
The ouput is the same for both triggers
name...........,type_desc,type
ddlTestEvents1,ALTER_TABLE,22
ddlTestEvents1, CREATE_TABLE,21
ddlTestEvents1, DROP_TABLE, 23
ddlTestEvents2, ALTER_TABLE, 22
ddlTestEvents2, CREATE_TABLE, 21
ddlTestEvents2, DROP_TABLE, 23
So when you use DDL_TABLE_EVENTS in the trigger, then 3 events will be in the sys.trigger_events catalog view. This is all fine but how do you find out these things? I can't find DDL_TABLE_EVENTS anywhere. Also I know that DDL_LOGIN_EVENTS is the same as CREATE LOGIN, ALTER LOGIN and DROP LOGIN combined but where is this documented?
Script out the ddlDatabaseTriggerLog trigger (this is the only trigger that is in the AdventureWorks database when you install SQL server), you will see a DDL_DATABASE_LEVEL_EVENTS event
when you run the following query (same as before, different trigger name) you will see that it returns 76 rows (basically all events)
SELECT name,te.type_desc,te.type
FROM sys.triggers t
JOIN
sys.trigger_events te on t.object_id = te.object_id
WHERE t.parent_class=0
AND name =
'ddlDatabaseTriggerLog'ORDER BY name,te.type_desc
I am sure I will edit this (many times)
But first I will list all the events
You will see the events followed by a grouped event in red for example
CREATE_TABLE
ALTER_TABLE
DROP_TABLE
DDL_TABLE_EVENTSI will have to go through all these events and use the sys.trigger_events to find this info out before I post this (unless someone points to in the right direction where to find this)
DDL Statements with Database Scope:CREATE_APPLICATION_ROLE (Applies to CREATE APPLICATION ROLE statement and sp_addapprole. If a new schema is created, this event also triggers a CREATE_SCHEMA event.) ALTER_APPLICATION_ROLE (Applies to ALTER APPLICATION ROLE statement and sp_approlepassword.)
DROP_APPLICATION_ROLE (Applies to DROP APPLICATION ROLE statement and sp_dropapprole.)
CREATE_ASSEMBLY
ALTER_ASSEMBLY
DROP_ASSEMBLY
-- should be DDL_ASSEMBLY_EVENTS but who knows?ALTER_AUTHORIZATION_DATABASE (Applies to ALTER AUTHORIZATION statement when ON DATABASE is specified, and sp_changedbowner.)
CREATE_CERTIFICATE
ALTER_CERTIFICATE
DROP_CERTIFICATE
CREATE_CONTRACT
DROP_CONTRACT
GRANT_DATABASE
DENY_DATABASE
REVOKE_DATABASE
CREATE_EVENT_NOTIFICATION
DROP_EVENT_NOTIFICATION
CREATE_FUNCTION
ALTER_FUNCTION
DROP_FUNCTION
CREATE_INDEX
ALTER_INDEX
DROP_INDEX
CREATE_MESSAGE_TYPE
ALTER_MESSAGE_TYPE
DROP_MESSAGE_TYPE
CREATE_PARTITION_FUNCTION
ALTER_PARTITION_FUNCTION
DROP_PARTITION_FUNCTION
CREATE_PARTITION_SCHEME
ALTER_PARTITION_SCHEME
DROP_PARTITION_SCHEME
CREATE_PROCEDURE
ALTER_PROCEDURE
DROP_PROCEDURE
CREATE_QUEUE
ALTER_QUEUE
DROP_QUEUE
CREATE_REMOTE_SERVICE_BINDING
ALTER_REMOTE_SERVICE_BINDING
DROP_REMOTE_SERVICE_BINDING
CREATE_ROLE (Applies to CREATE ROLE statement, sp_addrole, and sp_addgroup.)
ALTER_ROLE
DROP_ROLE (Applies to DROP ROLE statement, sp_droprole, and sp_dropgroup.)
CREATE_ROUTE
ALTER_ROUTE
DROP_ROUTE
CREATE_SCHEMA (Applies to CREATE SCHEMA statement, sp_addrole, sp_adduser, sp_addgroup, and sp_grantdbaccess.)
ALTER_SCHEMA (Applies to ALTER SCHEMA statement and sp_changeobjectowner.)
DROP_SCHEMA
CREATE_SERVICE
ALTER_SERVICE
DROP_SERVICE
CREATE_STATISTICS
DROP_STATISTICS
UPDATE_STATISTICS
CREATE_SYNONYM
DROP_SYNONYM
CREATE_TABLE
ALTER_TABLE
DROP_TABLE
DDL_TABLE_EVENTSCREATE_TRIGGER
ALTER_TRIGGER
DROP_TRIGGER
CREATE_TYPE (Applies to CREATE TYPE statement and sp_addtype.)
DROP_TYPE (Applies to DROP TYPE statement and sp_droptype.)
CREATE_USER (Applies to CREATE USER statement, sp_adduser, and sp_grantdbaccess.)
ALTER_USER
DROP_USER (Applies to DROP USER statement, sp_dropuser, and sp_revokedbaccess.)
CREATE_VIEW
ALTER_VIEW
DROP_VIEW
CREATE_XML_SCHEMA_COLLECTION
ALTER_XML_SCHEMA_COLLECTION
DROP_XML_SCHEMA_COLLECTION
DDL Statements with Server Scope:
ALTER_AUTHORIZATION_SERVER
CREATE_DATABASE
ALTER_DATABASE
DROP_DATABASE
CREATE_ENDPOINT
ALTER_ENDPOINT
DROP_ENDPOINT
CREATE_LOGIN (Applies to CREATE LOGIN statement, sp_addlogin, sp_grantlogin, xp_grantlogin, and sp_denylogin when used on a nonexistent login that must be implicitly created.)
ALTER_LOGIN (Applies to ALTER LOGIN statement, sp_defaultdb, sp_defaultlanguage, sp_password, and sp_change_users_login when Auto_Fix is specified.)
DROP_LOGIN (Applies to DROP LOGIN statement, sp_droplogin, sp_revokelogin, and xp_revokelogin.)
DDL_LOGIN_EVENTSGRANT_SERVER
DENY_SERVER
REVOKE_SERVER
And like I said I will edit this after I run my tests