SQL Nexus: What StartTimeInterval?

When I get asked the same question more than 3 times in less than 48 hours, I guess it’s time to create some documentation around the error.

The issue is when you click on the UniqueStatements link in the ReadTrace_Main report in SQL Nexus, you get the following exception:

image

If you collect a profiler trace, you will find that the error is raised while executing the following command:

exec ReadTrace.spReporter_StmtTopN @StartTimeInterval, @EndTimeInterval, @TopN, @Filter1, @Filter2, @Filter3, @Filter4, @Filter1Name, @Filter2Name, @Filter3Name, @Filter4Name

The error message would be:

Error: 137, Severity: 15, State: 2
Must declare the scalar variable "@StartTimeInterval".

The above error will be reported in the exception message that is raised in SQL Nexus as well. The issue is not with SQL Nexus but with the RML Utilities report. You can get this issue under the following condition:

1. There are no entries in the readtrace.tblStatements and readtrace.tblTimeIntervals tables.
2. Or if you are using an older version of ReadTrace (RML Utilities)

I was able to reproduce the issue on ReadTrace.exe build of 9.01.0109.

The issue stems from the fact that when you click on the UniqueStatements report link and no parameters are specified, thimagee Start Time and the End Time to be analyzed is picked up from the tblTimeIntervals. I was able to reproduce the issue on the same SQL Nexus database using one version of ReadTrace reports and not with the other. You can send an email to sstlbugs@microsoft.com and request the latest build for RML Utilities with the ReadTrace and SQL Nexus log file as attachments. The logs can be retrieved by clicking on the hyperlinks in SQL Nexus shown in the picture on the right.

del.icio.us Tags: ,,

QnA: Performance Dashboard Webcast

I had an overflow of questions during the webcast today and wasn’t able to answer a few as we ran short of time. I shall attempt to address the most common questions asked during the webcast.

How do I configure SQL Server Performance Dashboards?
SQL Server Performance Dashboard was originally released for SQL Server 2005. Setup instructions are available with the download link. However, the same install can be tweaked to work for SQL Server 2008 and SQL Server 2008 R2 using the blog post by Sudarshan: Configuring Performance Dashboard for SQL Server 2008
Download link: SQL Server 2005 Performance Dashboard

The SQL Server instance being monitored must be running SQL Server 2005 SP2 or later. After completing the installation, you must:
1. Run the Setup.sql file on each instance of SQL Server 200x that you wish to monitor with the SQL Server 2005 Performance Dashboard Reports.
2. Open the performance_dashboard_main.rdl file with the Custom Reports functionality new to Management Studio in SQL Sever 2005 Service Pack 2.

Does Performance Dashboard work for SQL Server 2000?
No, Performance Dashboard uses DMVs to generate the data for the reports which are available from SQL Server 2005 and higher.

Where can I get the presentation and webcast recording?
The presentation and webcast recording for the entire webcast series will be made available on the SQLServerFAQ MSDN blog. I shall post an update once both are available.

What is the performance impact of running these reports?
If your server is unresponsive or experiencing high CPU usage on all the processors, then these reports will also face issues while retrieving diagnostic data from the DMVs. However, the overall impact of running this reports on a SQL Server instance is very minimal as compared to any other performance diagnostic tool.

Can these reports be used on SQL Azure or any other RDBMS?
No, they cannot be used to monitor SQL Azure databases or any other non-SQL Server RDMBS environment.

What permissions are required for using Performance Dashboard?
You need to have VIEW SERVER STATE permission to view all the information exposed by Performance Dashboard as most of the information is collected from DMVs.

Can these reports be deployed to a local shared repository?
You can use Visual Studio and create custom reports similar to the Performance Dashboard reports or modify the existing reports as per your needs and deploy them. Be advised, that this will be a customized solution and not supported by CSS w.r.t. performance issues while running these reports or configuration issues.

Lastly, thank you for attending the session! And for your patience.

In case there are more questions, please feel free to add a comment and I shall reply back accordingly.

Cheers!

 

SQL MEME Monday #2

My first SQL MEME Monday, the brainchild of Thomas LaRock [Blog | Twitter], was to create a post less than or equal to 11 words. So here is my second post on the same theme:

Performance has lots of “It Depends” but it’s all about benchmarking!

Technorati Tags: SQL MEME Monday

Webcast: Understanding Performance Bottlenecks using Performance Dashboard

I will be delivering a webcast on “Understanding Performance Bottlenecks using Performance Dashboard”. The idea of this is webcast is demonstrate the use of tools offered by Microsoft to analyze performance bottlenecks when the issue is happening. This will be a good folow-up on the recent write-up that I did for SSWUG on tackling SQL Performance issues using tools provided by Microsoft.

Time: 2:30PM IST – 3:45PM IST
Date: 4th May, 2011

Here is the session abstract:

This session will demonstrate how to troubleshoot a SQL Server performance issue using out-of-the-box features without having to collect diagnostic data for post-mortem analysis.

Apart from this session, there are other sessions being delivering as part of this webcast series.

Managing and Optimizing Resources for SQL Server (Date: May 2, 2011 Time: 2:30 pm – 3:45 pm IST)

Optimizing and Tuning Full Text Search for SQL Server (Date: May 3, 2011 Time: 2:30 pm – 3:45 pm IST)

Cool Tools to have for SQL Server DBA (Date: May 5, 2011 Time: 2:30 pm – 3:45 pm IST)

Learn Underappreciated Features of SQL Server to Improve Productivity (Date: May 6, 2011 Time: 2:30 pm – 3:45 pm IST)

If you are interested, here is the registration link for signing up: http://virtualtechdays.com/SQLServer2008R2/

 

T-SQL Tuesday#17: It’s all about APPLYcation this time

imageIt’s time for another round of T-SQL Tuesday and this round of the revolving blog party is being hosted by Matt Velic [Blog | Twitter].

APPLY – That is the topic for this month’s T-SQL Tuesday! The APPLY operator was added to the T-SQL repertoire and which has resulted in lesser use of cursors for a large number of diagnostic scripts that CSS uses to collect data while working on SQL Performance issues. In this blog, I shall share a few examples of such queries that we use to collect data while working on SQL Performance cases.

TOP Query Plan Statistics

The following query gives you a list of the SQL batches/procedures with their CPU usage, Query/Batch duration and Physical Reads rank. This query helps identify the TOP CPU/Duration/Read consuming queries by making use of system DMVs. The output below is useful for the following reasons:

1. I get the usecount of the procedure/batch and if this batch is called multiple times and the use count of a Compiled Proc cached object is only 1, then the plan is not being re-used. This now tells me that I need to look at reasons behind inability of plan re-use.

2. I get the total and average resource usage statistics for each of the queries listed in the output.

3. A quick glance at the output gives me an idea of the most expensive queries on the instance w.r.t. reads or/and CPU and/or query duration.


SELECT

LEFT(p.cacheobjtype + ' (' + p.objtype + ')',35) AS cacheobjtype,

p.usecounts,

p.size_in_bytes/1024  AS size_in_kb,

PlanStats.total_worker_time/1000 AS tot_cpu_ms,

PlanStats.total_elapsed_time/1000 AS tot_duration_ms,

PlanStats.total_physical_reads,

PlanStats.total_logical_writes,

PlanStats.total_logical_reads,

PlanStats.CpuRank,

PlanStats.PhysicalReadsRank,

PlanStats.DurationRank,

LEFT(CASE WHEN pa.value = 32767 THEN 'ResourceDb' ELSE ISNULL(DB_NAME(CONVERT(sysname,pa.value)),CONVERT(sysname,pa.value)) END,40) AS dbname,

sql.objectid,

CONVERT(nvarchar(50), CASE WHEN sql.objectid IS NULL THEN NULL ELSE REPLACE(REPLACE(sql.[text],CHAR(13),' '),CHAR(10),' ') END) AS procname,  REPLACE(REPLACE(SUBSTRING(sql.[text],PlanStats.statement_start_offset/2+1,CASE WHEN PlanStats.statement_end_offset=-1 THEN LEN(CONVERT(nvarchar(max),sql.[text]))

ELSE PlanStats.statement_end_offset/2 - PlanStats.statement_start_offset/2+1 END),CHAR(13),' '),CHAR(10),' ') AS stmt_text

FROM

(

SELECT

stat.plan_handle,

statement_start_offset,

statement_end_offset,

stat.total_worker_time,

stat.total_elapsed_time,

stat.total_physical_reads,

stat.total_logical_writes,

stat.total_logical_reads,

ROW_NUMBER()OVER ( ORDER BY stat.total_worker_time DESC ) AS CpuRank,

ROW_NUMBER()OVER ( ORDER BY stat.total_physical_reads DESC ) AS PhysicalReadsRank,

ROW_NUMBER()OVER ( ORDER BY stat.total_elapsed_time DESC ) AS DurationRank

FROM sys.dm_exec_query_stats stat

) AS PlanStats

INNER JOIN sys.dm_exec_cached_plans p

ON p.plan_handle =  PlanStats.plan_handle

OUTER APPLY sys.dm_exec_plan_attributes ( p.plan_handle ) pa

OUTER APPLY sys.dm_exec_sql_text ( p.plan_handle ) AS sql

WHERE

(PlanStats.CpuRank<50

OR PlanStats.PhysicalReadsRank<50

OR PlanStats.DurationRank<50)

AND

pa.attribute='dbid'

ORDER BY tot_cpu_ms DESC


Top Queries with Similar Query Hash and Query Plan Hash

 

SELECT TOP 10 query_plan_hash, query_hash,

COUNT (distinct query_plan_hash) as 'distinct query_plan_hash count',

SUM(execution_count) as 'execution_count',

SUM(total_worker_time) as 'total_worker_time',

SUM(total_elapsed_time) as 'total_elapsed_time',

SUM (total_logical_reads) as 'total_logical_reads',

MAX(REPLACE (REPLACE (SUBSTRING (st.[text], qs.statement_start_offset/2 + 1,CASE WHEN qs.statement_end_offset = -1 THEN LEN (CONVERT(nvarchar(max), st.[text])) ELSE qs.statement_end_offset/2 - qs.statement_start_offset/2 + 1 END), CHAR(13), ' '), CHAR(10), ' '))  AS sample_statement_text,

MIN(CAST(query_plan as varchar(max))) AS 'ShowPlan XML'

FROM sys.dm_exec_query_stats AS qs

CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st

CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) as sp

GROUP BY query_plan_hash, query_hash

ORDER BY sum(total_worker_time) ASC;

This is a query which can help you identify queries which have the same query plan hash

SQL Server Books Online topic “Finding and Tuning Similar Queries by Using Query and Query Plan Hashes” has more information on this topic. The query hash feature was added in SQL Server 2008 which made it easier to troubleshooting performance issues caused by ad-hoc queries which differed in just literal values. RML Utilities does a similar task by creating query hash but now if you are troubleshooting on the server, you can do this using DMVs without having to capture a profiler trace.

The right operand supplied to the Apply operator is a function of one or more column values that are present in the left operand. So basically, the right operand is a table-valued expression of which is evaluated once for each row that appears in the left operand. The Cross Apply and Outer Apply are the two flavors of the Apply operator. So if I wanted to simulate an Apply Operation without the Operator itself, it would require the use of temporary tables or table variables.

I use the APPLY operator a lot while parsing XML data like Process Monitor traces or XML query plans which make life a lot easier and saves me from writing a huge bunch of T-SQL code.