Recently I wrote a short post on the default trace in SQL Server. You can read that here. In this post I am going to discuss the advantages of a server side trace over the SQL Server profiler GUI. I’ll look at an easy method for creating server side traces, especially if you are familiar with the SQL Server profiler GUI. And I’ll demonstrate how to stop and start and remove a server side trace.
Server Side Trace Versus SQL Server Profiler GUI
The main advantage of server side traces over its SQL Profiler counterpart lie in the fact that server side traces use less resources than a SQL profiler trace. You can also programmatically start and stop Server side traces.
OK, technically to create a server side trace you need to learn the syntax of the following system stored procedures:
- sp_trace_create
- sp_trace_generateevent
- sp_trace_setevent
- sp_trace_setfilter
- sp_trace_setstatus
Along with
I’m not going to explain the syntax of these events here, instead I’m going to show how can get the Profiler GUI to generate the necessary scripts to do this for you.
So you fire up the SQL Profiler GUI and setup your your profiler trace. In this case I am looking to audit backup and restores events on one of my Dev instances, but you can use whatever events suit your needs performance tuning, auditing etc.
The first step is to fire up profiler and connect to an instance of SQL Server.
Then you setup the trace as you would normally, you can save the results to a file if you like too:
Then move on to <Event Selection> tab and select the events you want to include in your trace. In my case I am auditing backups and restores so I selected the Audit Backup/Restore event, along with Audit Login and Audit Logout.
You have to click on <run> here to start the trace in the GUI and this can be a bit of a pain if you don’t want the trace to start straight away but you can stop as soon as it starts if you want too. If this case I let it run for a while and took a backup of my database to ensure that it was capturing what I expected:
So I then stop the trace and click on the following Menu…File > Export > Script Trace Definition > For SQL Server 2005 – 2008 the generates the necessary scripts to create the profiler trace on the server.
You have to pick a location and a name for your newly created script and click on save.
On the instance that I want to create and run the trace, I run the following query to return the currently running traces, on my instance I just have the default trace running:
select * from sys.traces
The output of my trace file is below, if i run this, after entering a valid file name for the trace, a server side trace capturing the same events as my profiler trace above is created:
/****************************************************/
/* Created by: SQL Server 2008 Profiler */
/* Date: 10/03/2010 22:55:01 */
/****************************************************/
-- Create a Queue
declare @rc int
declare @TraceID int
declare @maxfilesize bigint
set @maxfilesize = 5
-- Please replace the text InsertFileNameHere, with an appropriate
-- filename prefixed by a path, e.g., c:\MyFolder\MyTrace. The .trc extension
-- will be appended to the filename automatically. If you are writing from
-- remote server to local drive, please use UNC path and make sure server has
-- write access to your network share
exec @rc = sp_trace_create @TraceID output, 0, N'InsertFileNameHere', @maxfilesize, NULL
if (@rc != 0) goto error
-- Client side File and Table cannot be scripted
-- Set the events
declare @on bit
set @on = 1
exec sp_trace_setevent @TraceID, 115, 7, @on
exec sp_trace_setevent @TraceID, 115, 23, @on
exec sp_trace_setevent @TraceID, 115, 8, @on
exec sp_trace_setevent @TraceID, 115, 40, @on
exec sp_trace_setevent @TraceID, 115, 64, @on
exec sp_trace_setevent @TraceID, 115, 1, @on
exec sp_trace_setevent @TraceID, 115, 9, @on
exec sp_trace_setevent @TraceID, 115, 21, @on
exec sp_trace_setevent @TraceID, 115, 41, @on
exec sp_trace_setevent @TraceID, 115, 49, @on
exec sp_trace_setevent @TraceID, 115, 6, @on
exec sp_trace_setevent @TraceID, 115, 10, @on
exec sp_trace_setevent @TraceID, 115, 14, @on
exec sp_trace_setevent @TraceID, 115, 26, @on
exec sp_trace_setevent @TraceID, 115, 50, @on
exec sp_trace_setevent @TraceID, 115, 3, @on
exec sp_trace_setevent @TraceID, 115, 11, @on
exec sp_trace_setevent @TraceID, 115, 35, @on
exec sp_trace_setevent @TraceID, 115, 51, @on
exec sp_trace_setevent @TraceID, 115, 4, @on
exec sp_trace_setevent @TraceID, 115, 12, @on
exec sp_trace_setevent @TraceID, 115, 60, @on
exec sp_trace_setevent @TraceID, 14, 1, @on
exec sp_trace_setevent @TraceID, 14, 9, @on
exec sp_trace_setevent @TraceID, 14, 2, @on
exec sp_trace_setevent @TraceID, 14, 6, @on
exec sp_trace_setevent @TraceID, 14, 10, @on
exec sp_trace_setevent @TraceID, 14, 14, @on
exec sp_trace_setevent @TraceID, 14, 11, @on
exec sp_trace_setevent @TraceID, 14, 12, @on
exec sp_trace_setevent @TraceID, 15, 15, @on
exec sp_trace_setevent @TraceID, 15, 16, @on
exec sp_trace_setevent @TraceID, 15, 9, @on
exec sp_trace_setevent @TraceID, 15, 13, @on
exec sp_trace_setevent @TraceID, 15, 17, @on
exec sp_trace_setevent @TraceID, 15, 6, @on
exec sp_trace_setevent @TraceID, 15, 10, @on
exec sp_trace_setevent @TraceID, 15, 14, @on
exec sp_trace_setevent @TraceID, 15, 18, @on
exec sp_trace_setevent @TraceID, 15, 11, @on
exec sp_trace_setevent @TraceID, 15, 12, @on
-- Set the Filters
declare @intfilter int
declare @bigintfilter bigint
exec sp_trace_setfilter @TraceID, 10, 0, 7, N'SQL Server Profiler - 6a02a8ea-d71c-4318-87a0-5289ec84fa1f'
-- Set the trace status to start
exec sp_trace_setstatus @TraceID, 1
-- display trace id for future references
select TraceID=@TraceID
goto finish
error:
select ErrorCode=@rc
finish:
go
After running the script the following result is returned:
The output is the ID of the Server Side trace that has just been created. You need the ID of the trace to stop, start and remove traces. When you run the script it automatically starts the trace. You can prove this by running:
select * from sys.traces
As you can see we now have two traces running, the status of 1 means the trace is running, a status or 0 means that the trace is stopped.
You can stop and start the trace by running the sp_trace_setstatus stored procedure and pass the traceid and required status as parameters. For the Trace we have just created:
exec sp_trace_setstatus 2, 0 -- This stops the trace running
exec sp_trace_setstatus 2, 1 --This starts the trace running
exec sp_trace_setstatus 2, 2 -- This closes the trace and deletes the definition from the server