Upcoming Zeollar Presentation

I will be presenting a 30 minute demo on how to perform post mortem analysis for SQL Performance issues using RML Utilities and SQL Nexus on 24th June, 2010. The recorded and live session will be available on Zeollar. Zeollar is a Microsoft India DPE initiative that gets you the latest technical content on a daily basis in different channels. Think of it like a personal television that switches on every day at a specified hour allowing you to switch channels and view the channel of your interest.

You can download the calendar invite from here.

How to create a Profiler Trace during Server startup

I think I answered this question more than once on multiple different forums. So, I thought it was time to create a blog post on it.   

One of my previous post has the steps to create a .sql file containing the server side trace definition. Once you have the .sql file generated by the SQL Profiler Trace GUI. Use the script to convert that into the stored procedure with the following changes:   

declare @tracefilename nvarchar(255) 

set @tracefilename = N'D:\StartupTrace'+CAST(DATEPART(d,GETDATE()) AS varchar(2))+CAST(DATEPART(M,GETDATE()) AS varchar(2))+CAST(DATEPART(YYYY,GETDATE()) AS varchar(4))+CAST(DATEPART(HH,GETDATE()) AS varchar(2))+CAST(DATEPART(MI,GETDATE()) AS varchar(2)) 

exec @rc = sp_trace_create @TraceID output, 0, @tracefilename, @maxfilesize, NULL

You will have to add the lines highlighted above and the make a change for the trace file name in the line that is not highlighted. This will ensure that every time your SQL instance starts up, you have a unique trace file name. If the filename is not unique, then the second time the service restarts you will get a trace creation error stating that the file already exists. You will see the following error in your SQL Errorlog:   

Launched startup procedure ‘usp_startup_trace’.

Windows error occurred while running SP_TRACE_CREATE. Error = 0x80070050(The file exists.).

Error: 19062, Severity: 16, State: 1.Could not create a trace file. 

After this is done, create the stored procedure to create the trace definition. Let’s say the proc name was “usp_startup_trace”.   

Now, you will need to mark this stored procedure as a startup procedure using the following:

EXEC sp_procoption 'usp_startup_trace','startup',true

 Once that is done, you will need to set the configuration options for the instance to scan for startup procedures. The default is set to 0.   

EXEC sp_configure 'scan for startup procs',1 RECONFIGURE

 When your SQL instance restarts the next time a new file will be created for the profiler trace and sys.traces will show you new trace active on the server.  

Reference: sp_procoption

How to identify the SQL Server version from a Profiler Trace

You use certain little tips and tricks with the SQL Server tools which are not documented anywhere. This is one of them. I needed to find out the version of a SQL Server instance from which the Profiler Trace was captured. I opened the Profiler trace using SQL Profiler 2008. I clicked on the Trace properties and lo behold I had the SQL Server instance name and version.

image

I got the SQL Server release, version and the instance name (Trace provider name).

RML Utilities OR ReadTrace

The Microsoft Download site has a tool called RML Utilities which can be used to process the profiler traces collected from a SQL Server instance.
SQL Profiler Traces are very helpful when we need to perform a Bottleneck Analysis in any SQL environment or you need to find out the before & after picture. But the daunting task remains in analyzing the Profiler Traces because the size and volume of the trace files.

SQL Server provides an in-built function fn_trace_gettable() to load the collected profiler traces into a SQL Server database table.
Then you can run queries on this table to draw inferences from the profiler traces collected during that period. Lets say you wanted to find out all queries that had a duration above 10,000 and group the results by host name, then you could write a query in the following manner:

SELECT hostname, count(*) as counts
FROM tbl_trace
WHERE Duration > 10000
GROUP BY hostname

This is a tool that is used by Microsoft PSS to analyze SQL Server Profiler Traces collected by the PSSDIAG utility.

For more details, please refer:
Replay Markup Language
http://support.microsoft.com/?kbid=944837
RML Utilities (x86) Download
http://www.microsoft.com/downloads/details.aspx?familyid=7EDFA95A-A32F-440F-A3A8-5160C8DBE926&displaylang=en
RML Utilities (x64) Download
http://www.microsoft.com/downloads/details.aspx?familyid=B60CDFA3-732E-4347-9C06-2D1F1F84C342&displaylang=en

WMI Tracing equivalent of SQL Server Profiler Traces

A lot of companies find the need to monitor all DDL and DML activity on the server for Compliance reasons. Though SQL Profiler Traces provides this functionality by using Stored Procedures and Functions. These system stored procedures can be used from within your own applications to create traces manually, instead of using SQL Server Profiler. This allows you to write custom applications specific to the needs of your enterprise. However, you might choose not to use this approach due to the overhead of running profiler traces on the server. You can use server side profiler traces which tend to have a lesser performance impact on the server. 

Another method is to use WMI Events to monitor SQL Server Events. Consider the following example, let’s say you want to monitor the SQL Server events for all Update Statistics Events. Then you can use script below to create the WMI Alert and also the job to put the event details into a SQL Server database table. 

<script> 

USE TestDB 

GO 

-- Creating the table to store the DDL Events 

CREATE TABLE [dbo].[UPD_STATS_Events]( 

[AlertTime] [datetime] NULL, 

[SPID] [int] NULL, 

[DBName] [nvarchar](100) NULL, 

[TextData] [nvarchar](max) NULL 

) ON [PRIMARY] 

GO 

-- Adding the job to run when the WMI Alert is raised 

EXEC msdb.dbo.sp_add_job @job_name=N'Capture Update Statistics Events', 

@enabled=1, 

@description=N'Job for responding to DDL events' ; 

GO 

-- Adding the job step 

EXEC msdb.dbo.sp_add_jobstep 

@job_name = N'Capture Update Statistics Events', 

@step_name=N'Insert data into Update Statistics Events table', 

@step_id=1, 

@on_success_action=1, 

@on_fail_action=2, 

@subsystem=N'TSQL', 

@command= N'INSERT INTO UPD_STATS_Events 

(AlertTime, Spid,DBName,TextData) 

VALUES (getdate(), $(ESCAPE_NONE(WMI(SPID))), 

''$(ESCAPE_SQUOTE(WMI(DatabaseName)))'', 

''$(ESCAPE_SQUOTE(WMI(TSQLCommand)))'')', 

@database_name=N'TestDB' ; 

GO 

-- Set the job server for the job to the current instance of SQL Server. 

EXEC msdb.dbo.sp_add_jobserver @job_name = N'Capture Update Stats Events' ; 

GO 

-- For the named instance you need to use \\.\root\Microsoft\SqlServer\ServerEvents\<INSTANCE NAME> 

EXEC msdb.dbo.sp_add_alert @name=N'Respond to Update Statistics Events', 

@wmi_namespace=N'\\.\root\Microsoft\SqlServer\ServerEvents\MSSQLSERVER', 

@wmi_query=N'SELECT * FROM UPDATE_STATISTICS', 

@job_name='Capture Update Statistics Events' ; 

GO

</script> 

You will have to give the SQL Agent account WMI Token replacement rights. You need to create a registry key in SQLAgent for this.
Add a Reg_DWORD HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\Microsoft SQL
Server\MSSQL.x\SQLServerAgent\AlertReplaceRuntimeTokens
and set it to 1.
and no SQLAgent restarts needed. 

Where x = the number of the SQL instance. This can be found out by looking under the regisry key: HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\Microsoft SQL Server\Instance Names\SQL 

Whenever an update statistics task is fired against a database, the time when the command was executed, the SPID number, the database name and the T-SQL Command command associated with the event would be put into the table in the TestDB database. 

Service Broker should be enabled for the MSDB and the database in which you are storing the event details. 

Information about the namespaces can be found on MSDN. Also, you could use WMI Code Creator to browse through the namespace and the classes available and their properties. 

Furthermore, you can also use the WMI Event Watcher Task or the WMI Data Reader Task of SQL Server 2005 SSIS to perform the same.