Event Notifications
Event notifications differ from triggers by the fact that the actual notification does not execute any code. Instead, information about the event is posted to a SQL Server Service Broker (SSB) service and is placed on a message queue from where it can be read by some other process.1 Another difference between triggers and event notifications is that the event notifications execute in response to not only DDL and DML statements but also some trace events.
The syntax for creating an event notification is as follows.
CREATE EVENT NOTIFICATION event_notification_name ON { SERVER | DATABASE | [ ENABLED | DISABLED ] { FOR { event_type | DDL_DATABASE_LEVEL_EVENTS } [ ,...n ] TO broker_service
The syntax looks a little like the syntax for creating a DDL trigger, and the arguments are as follows.
event_notification_nameThis is the name of the event notification.
SERVERThe scope of the event notification is the current server.
DATABASEThe scope of the event notification is the current database.
ENABLEDThis specifies that the event notification is active when the CREATE statement has executed.
DISABLEDThis specifies that the event notification is inactive until the notification is activated by executing an ALTER EVENT NOTIFICATION statement.
event_typeThis is the name of an event that, after execution, causes the event notification to execute. SQL Server Books Online has the full list of events included in event_type.
DDL_DATABASE_LEVEL_EVENTSThe event notification fires after any of the CREATE, ALTER, or DROP statements that can be indicated in event_type execute.
broker_serviceThis is the SSB service to which SQL Server posts the data about an event.
The event notification contains the same information received from the eventdata function mentioned previously. When the event notification fires, the notification mechanism executes the eventdata function and posts the information to the Service Broker. For an event notification to be created, an existing SQL Server Service Broker instance needs to be located either locally or remotely. The steps to create the SQL Server Service Broker are shown in Listing 7-5. Chapter 15 covers SSB in detail and also covers how to create queues, services, and so on.
Listing 7-5: Steps to Create a Service Broker Instance
first we need a queue CREATE QUEUE queue evtDdlNotif WITH STATUS = ON then we can create the service CREATE SERVICE evtDdlService ON QUEUE evtDdlNotif this is a MS supplied contract which uses an existing message type {http://schemas.microsoft.com/SQL/Notifications}EventNotification (http://schemas.microsoft.com/SQL/Notifications/PostEventNotification)
First, the message queue that will hold the eventdata information is created. Typically, another process listens for incoming messages on this queue, or another process will kick off when a message arrives. A service is then built on the queue. When a SQL Server Service Broker service is created, there needs to be a contract to indicate what types of messages this service understands. In a SQL Server Service Broker application, the developer usually defines message types and contracts based on the application's requirements. For event notifications, however, Microsoft has a predefined message type, {http://schemas.microsoft.com/SQL/Notifications}EventNotification, and a contract, http://schemas.microsoft.com/SQL/Notifications/PostEventNotification.
The following code shows how to create an event notification for DDL events scoped to the local database, sending the notifications to the evt DdlService.
CREATE EVENT NOTIFICATION ddlEvents ON DATABASE FOR DDL_DATABASE_LEVEL_EVENTS TO SERVICE evtDdlService
With both the event notification and the service in place, a new process can now be started in SQL Server Management Studio, using the WAITFOR and RECEIVE statements (more about this in Chapter 15) as in the following code.
WAITFOR( RECEIVE * FROM evtDdlNotif )
You can now execute a DDL statement, and then switch to the process with the WAITFOR statement and view the result. Running CREATE TABLE evtNotifTbl (id INT) shows in the WAITFOR process a two-row resultset, where one of the rows has a message_type_id of 20. This is the {http://schemas.microsoft.com/SQL/Notifications}EventNotification message type. The eventdata information is stored as a binary value in the message_body column. To see the actual data, we need to change the WAITFOR statement a little bit.
DECLARE @msgtypeid INT DECLARE @msg VARBINARY(MAX) WAITFOR( RECEIVE TOP(1) @msgtypeid = message_type_id, @msg = message_body FROM evtDdlNotif ) check if this is the correct message type IF @msgtypeid = 20 BEGIN do something useful WITH the message here we just select it as a result SELECT CONVERT(NVARCHAR(MAX), @msg) END
Running this code against the CREATE TABLE statement shown earlier produces the same output as in Listing 7-4. An additional benefit with event notifications is that they can be used for both system level and trace events in addition to DDL events. The following code shows how to create an event notification for SQL Server logins.
CREATE EVENT NOTIFICATION loginEvents ON SERVER FOR audit_login TO SERVICE evtLoginService
For system-level event notifications, the ON SERVER keyword needs to be explicitly specified; it cannot be used at the database level. Listing 7-6 shows the eventdata information received after executing a login.
Listing 7-6: eventdata Output from Login
<EVENT_INSTANCE> <PostTime>2003-06-29T09:46:23.623</PostTime> <SPID>51</SPID> <EventType>AUDIT_LOGIN</EventType> <ServerName>ZMV44</ServerName> <LoginName>ZMV44\Administrator</LoginName> <UserName>ZMV44\Administrator</UserName> <Database>eventstest</Database> <! additional information elided > </EVENT_INSTANCE>
You may wonder what happens if the transaction that caused the notification is rolled back. In that case, the posting of the notification is rolled back as well. If for some reason the delivery of a notification fails, the original transaction is not affected.
Some of the previous code examples have used VARCHAR(MAX) as the data type for a column. Let's look at what that is all about.