Wednesday, July 18, 2012

The EVENTDATA() Function

    The use of the EVENTDATA() function within SQL Server allows us to extract valuable and necessary information pertaining to auditing and triggers, such as Event Notifications and DDL triggers.  The Database Engine strategically provides the capturing mechanism with a handful of well-structured data.

What is the format of this data?
    The format of the provided data is XML.  When working with EVENTDATA(), one of the best tools that you can use is the XML Schema Definition to reference when looking for the elements you'd like to query and capture.  This XSD can be found at the following link: SQL Server EVENTDATA() XSD file.  This definition is dauntingly vast, but there's a neat little trick.  In order to quickly search through this XML Schema Definition file, you simple need to search for the keyword "EVENT_INSTANCE_EventType".  For instance, say you are creating a DDL Trigger for the CREATE_PROCEDURE event.  Search for the text "EVENT_INSTANCE_CREATE_PROCEDURE", and you will be brought to your desired event and containing elements:



<xs:complexType name="EVENT_INSTANCE_CREATE_PROCEDURE">
 <xs:sequence>
  <!-- Basic Envelope -->
  <xs:element name="EventType" type="SSWNAMEType"/>
  <xs:element name="PostTime" type="xs:string"/>
  <xs:element name="SPID" type="xs:int"/>
  <!-- Server Scoped DDL -->
  <xs:element name="ServerName" type="PathType"/>
  <xs:element name="LoginName" type="SSWNAMEType"/>
  <!-- DB Scoped DDL -->
  <xs:element name="UserName" type="SSWNAMEType"/>
  <!-- Main Body -->
  <xs:element name="DatabaseName" type="SSWNAMEType"/>
  <xs:element name="SchemaName" type="SSWNAMEType"/>
  <xs:element name="ObjectName" type="SSWNAMEType"/>
  <xs:element name="ObjectType" type="SSWNAMEType"/>
  <xs:element name="TSQLCommand" type="EventTag_TSQLCommand"/>
 </xs:sequence>
</xs:complexType>

This is the bulk of the information you'll need in order to start utilizing the EVENTDATA() function.

Using the EVENTDATA() function
    Say you want to create a DDL Trigger in order to gather event information for the CREATE PROCEDURE command.  In the aforementioned paragraph, we already have laid out the elements that we can use and capture, as well as their names and types.  In the interest of an example, let's create a database and some basic objects to illustrate this trigger.

use master;
go

create database EventDataDemo;
go

use EventDataDemo;
go

create table DdlAudit
(
       EventType nvarchar(128) null,
       DatabaseName nvarchar(128) null,
       SchemaName nvarchar(128) null,
       ObjectName nvarchar(128) null,
       LoginName nvarchar(128) null,
       UserName nvarchar(128) null,
       SqlText nvarchar(1024) null,
       AuditDateTime datetime null
);
go


Now that we have the audit table setup, we can create the DDL Trigger that will be capturing and handling the CREATE PROCEDURE event.  This is one of those times where SQL Server XML knowledge comes in handy, as we'll be relying heavily on the use of the XML value() method and an XQuery to extract our desired data.

create trigger DdlCreateProc
on all server
for create_procedure
as
       declare @eventdata xml = eventdata();

       insert into EventDataDemo.dbo.DdlAudit
       select
              @eventdata.value('(/EVENT_INSTANCE/EventType)[1]', 'nvarchar(128)'),
              @eventdata.value('(/EVENT_INSTANCE/DatabaseName)[1]', 'nvarchar(128)'),
              @eventdata.value('(/EVENT_INSTANCE/SchemaName)[1]', 'nvarchar(128)'),
              @eventdata.value('(/EVENT_INSTANCE/ObjectName)[1]', 'nvarchar(128)'),
              @eventdata.value('(/EVENT_INSTANCE/LoginName)[1]', 'nvarchar(128)'),
              @eventdata.value('(/EVENT_INSTANCE/UserName)[1]', 'nvarchar(128)'),
              @eventdata.value('(/EVENT_INSTANCE/TSQLCommand/CommandText)[1]',
                     'nvarchar(1024)'),
              getdate()
go

To test out our audit, simple create a stored procedure and query the DdlAudit table.

use EventDataDemo;
go

create procedure dbo.MyTestProcedure
as
       select 1;
go

select *
from DdlAudit;

    The above example shows a good use of the EVENTDATA() function, and how you can extract valuable information from it under given circumstances.  If there are any comments, questions, or issues please feel free to leave a comment below or email me at sqlsalt@gmail.com.


No comments:

Post a Comment