Why create trace files?
SQL Server is a dynamic system knowing how your users access the system is invaluable.
- Security. Trace files record activity on the SQL Server. Any attempts to compromise security or compromise database data will be shown by the trace file analysis.
- Performance. With a daily trace file collection you can group queries by DURATION and CPU. This way your developers know exactly where the problems are. In addition to daily trace file collection changes, a historical analysis can show if recent stored procedures or DDL is efficient or not.
- Index Utilization. In addition to performance, knowing what indexes are used and which ones are not helps a lot. This way you can conserve system resources by eliminating indexes that are not used and improve performance by adding indexes where they are needed.
Create a trace generation script
The following script creates a trace file with a unique name. You can easily create a SQL Trace script by selecting a trace that is running and then selecting FILE / SCRIPT TRACE. / FOR SQL SERVER 2000.
CREATE procedure sp_trace @dbname sysname = NULL as -- pass database name as parameter or NULL for all databases -- Create a Queue declare @rc int declare @TraceID int declare @maxfilesize bigint declare @filename nvarchar(128) set @maxfilesize = 40 -- create filename if @dbname is not null begin Select @filename = 'C:\SQLTrace\SEC_' + @dbname + '_' + replace(replace(convert(varchar(20),getdate(),100),':','_'),' ','_') + '_trace' end else begin Select @filename = 'C:\SQLTrace\SEC_All_' + replace(replace(convert(varchar(20),getdate(),100),':','_'),' ','_') + '_trace' end exec @rc = sp_trace_create @TraceID output, 0,@filename, @maxfilesize, NULL if (@rc != 0) goto error -- Set the events declare @on bit set @on = 1 -- Place scripted trace information here.. -- exec sp_trace_setevent @TraceID, 10, 1, @on -- Set the Filters declare @intfilter int declare @intdbFilter int declare @bigintfilter bigint exec sp_trace_setfilter @TraceID, 10, 0, 7, N'SQL Profiler' set @intfilter = 100 exec sp_trace_setfilter @TraceID, 22, 0, 4, @intfilter -- check for NULL if @dbname is not null begin -- database filter set @intdbFilter = db_id(@dbname) exec sp_trace_setfilter @TraceID, 3, 1, 0, @intdbFilter end exec sp_trace_setfilter @TraceID, 10, 0, 7, N'SQL Profiler' -- Set the trace status to start exec sp_trace_setstatus @TraceID, 1 WAITFOR DELAY '00:05:00' exec sp_trace_setstatus @TraceID, 0 WAITFOR DELAY '00:00:30' exec sp_trace_setstatus @TraceID, 2 -- display trace id for future references select TraceID=@TraceID goto finish error: select ErrorCode=@rc finish:
Schedule the trace capture
This trace runs for 5 minutes and 30 seconds and it is schedule to run every 10 minutes. On systems that are very active you may want to set the delay to 1 minute and trace every 30 minutes. You would be amazed how must data you can collect on some systems almost 10 MB per minute.
Here is the script to create a trace table. In addition you can create this with a SELECT INTO from the system function
FN_TRACE_GETTABLE.
CREATE TABLE [dbo].[tblTrace] ( [TextData] [ntext] COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [BinaryData] [image] NULL , [DatabaseID] [int] NULL , [TransactionID] [bigint] NULL , [NTUserName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [NTDomainName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [HostName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [ClientProcessID] [int] NULL , [ApplicationName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [LoginName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [SPID] [int] NULL , [Duration] [bigint] NULL , [StartTime] [datetime] NULL , [EndTime] [datetime] NULL , [Reads] [bigint] NULL , [Writes] [bigint] NULL , [CPU] [int] NULL , [Permissions] [int] NULL , [Severity] [int] NULL , [EventSubClass] [int] NULL , [ObjectID] [int] NULL , [Success] [int] NULL , [IndexID] [int] NULL , [IntegerData] [int] NULL , [ServerName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [EventClass] [int] NOT NULL , [ObjectType] [int] NULL , [NestLevel] [int] NULL , [State] [int] NULL , [Error] [int] NULL , [Mode] [int] NULL , [Handle] [int] NULL , [ObjectName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [DatabaseName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [FileName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [OwnerName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [RoleName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [TargetUserName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [DBUserName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [LoginSid] [image] NULL , [TargetLoginName] [nvarchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AS NULL , [TargetLoginSid] [image] NULL , [ColumnPermissions] [int] NULL ) GO
Create an ActiveX job script
In order to get the trace files into the trace table you will need to create an INSERT SELECT statement that references every trace file in a directory.
Dim objFSO Dim Cnxn, strCnxn Dim rsCustomers, strSQLCustomers Dim Cmd Dim rsProducts, strSQLProducts Set Cnxn = SQLActiveScriptHost.CreateObject("ADODB.Connection") strCnxn="Provider=SQLOLEDB.1;Password=passw0rd!;Persist Security Info=True;User ID=sa;Initial Catalog=Admin;Data Source=84_SPORSTER\SQL1" Cnxn.Open strCnxn Set Cmd = SQLActiveScriptHost.CreateObject("ADODB.Command") Cmd.ActiveConnection = Cnxn Set objFSO = SQLActiveScriptHost.CreateObject("Scripting.FileSystemObject") strFolderName = "C:\SQLTrace" Set Folder=objFSO.GetFolder(strFolderName) For Each objFile in Folder.Files If objFile.Size > 0 Then strAttachment = strFolderName & "\" & objFile.Name strSQLProducts = "INSERT INTO tblTrace SELECT * FROM ::fn_trace_gettable(" & "'" & strAttachment & "'" & "," & "default)" Cmd.CommandText = strSQLProducts Cmd.Execute End If Next Set Cmd = Nothing Set Cnxn = Nothing Set objFSO = Nothing
Note that this code is designed to run inside a SQL Agent job. You could create a VBScript job that could be executed with CSCRIPT at the command line. By echoing out the strSQLProducts SQL call into a file and adding carriage returns and go statements, you would have an backup executable script.
How to schedule this across a group of SQL Servers
- Set up the trace file collection with out a schedule and then execute this with the MSDB stored procedure
sp_run_job
- Import collected trace information to a central location
- Use the transform data method to import from the collection server table to reporting server table
- Run a report for all managed SQL Servers
When all of the trace files are collected a summary report can be created and emailed. In addition a SQL web task is very useful for creating a report that your developers will appreciate.