Share via


DDL Triggers and LOGON Triggers

DDL Triggers:  

DDL triggers can be used for administrative tasks such as auditing and regulating database operations. Use DDL triggers when you want to do the following:

¾ You want to prevent certain changes to your database schema.

¾ You want something to occur in the database in response to a change in your database schema.

¾ You want to record changes or events in the database schema.

DDL triggers fire only after the DDL statements that trigger them are run. DDL triggers cannot be used as INSTEAD OF triggers.

Example of DDL Trigger:

This example tracks the Login Events on a server level. It uses DDL_LOGIN_EVENTS event group from server scope events from above diagram. It fires against DDL Login activities such as CREATE, ALTER, DROP Login.

CREATE Trigger [Trg_TrackLoginManagement]

on ALL Server

for DDL_LOGIN_EVENTS

as

set nocount on

declare @data xml,

@EventType varchar(100),

@EventTime datetime,

@ServerName varchar(100),

@AffectedLoginName varchar(100),

@WhoDidIt varchar(100),

@EmailSubject varchar(500),

@EmailBody varchar(800),

@EmailRecipients varchar(300)

set @EmailRecipients = <'DBAS@microsoft.com'>

set @data = eventdata()

set @EventType = @data.value('(/EVENT_INSTANCE/EventType)[1]', 'varchar(100)')

set @EventTime = @data.value('(/EVENT_INSTANCE/PostTime)[1]','datetime')

set @ServerName = @data.value('(/EVENT_INSTANCE/ServerName)[1]','varchar(100)')

set @AffectedLoginName = @data.value('(/EVENT_INSTANCE/ObjectName)[1]','varchar(100)')

set @WhoDidIt = @data.value('(/EVENT_INSTANCE/LoginName)[1]','varchar(100)')

insert into msdb..TrackLoginManagement values (@EventType,@EventTime,@ServerName,@AffectedLoginName,@WhoDidIt)

set @EmailSubject = 'ALERT: DDL_LOGIN_Event: ' + @EventType + ' occured by ' + @WhoDidIt + ' on ' + @ServerName

set @EmailBody = 'DDL_Login_Event: ' + @EventType + char(10) +

'Event Occured at: ' + convert(Varchar, @EventTime) + char(10) +

'ServerName: ' + @ServerName + char(10) +

'Affected Login Name: ' + @AffectedLoginName + char(10) +

'Event Done by: ' + @WhoDidIt

EXEC msdb.dbo.sp_send_dbmail

@recipients = @EmailRecipients,

@body = @EmailBody,

@subject = @EmailSubject ;

print @Eventtype + ' activity completed successfully.'

GO

LOGON Triggers:

Similar to DDL Triggers, LOGON Triggers fire stored procedures or T-SQL statements in response to LOGON events. Logon triggers fire after the authentication phase of logging in finishes, but before the user session is actually established. Therefore, all messages originating inside the trigger that would typically reach the user, such as error messages and messages from the PRINT statement, are diverted to the SQL Server error log. Logon triggers do not fire if authentication fails.

You can use logon triggers to audit and control server sessions, such as by tracking logon activity, restricting logons to SQL Server, or limiting the number of sessions for a specific logon.

Example of LOGON Trigger:

In the following code, the logon trigger captures information from EventData() functions such as LoginName, HostName, LoginTime, and LoginType when any logon activity happened by a SQL Login which are connecting from hosts other than application servers. This is useful to monitor people connecting to SQL Server using application ids during peak hours and possibly causing performance issues by running inefficient queries outside of an application.

create table myTest

(LogonTime datetime,

LoginName varchar(50),

ClientHost varchar(50),

LoginType varchar(50)

)

create TRIGGER myTest_LogonTrigger

ON ALL SERVER WITH EXECUTE AS 'sa'

FOR LOGON

AS

BEGIN

declare @LogonTriggerData xml,

@EventTime datetime,

@LoginName varchar(50),

@HostName varchar(50),

@LoginType varchar(50)

set @LogonTriggerData = eventdata()

set @EventTime = @LogonTriggerData.value('(/EVENT_INSTANCE/PostTime)[1]', 'datetime')

set @LoginName = @LogonTriggerData.value('(/EVENT_INSTANCE/LoginName)[1]', 'varchar(50)')

set @HostName = @LogonTriggerData.value('(/EVENT_INSTANCE/ClientHost)[1]', 'varchar(50)')

set @LoginType = @LogonTriggerData.value('(/EVENT_INSTANCE/LoginType)[1]', 'varchar(50)')

if @LoginType = 'SQL Login' and @HostName not in ('<comma separated list of hostname>')

and @LoginName not in ('<comma separated list of SQL logins>')

insert into master..myTest values (@EventTime, @LoginName, @HostName, @LoginType)

end

go

Comments

  • Anonymous
    January 01, 2003
    if @LoginType = 'SQL Login' and @HostName not in ('<comma separated list of hostname>') @HostName returns ip address if its not local. so in you example it has to be HOST_NAME() NOT IN

  • Anonymous
    December 07, 2015
    The comment has been removed