Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 

Basit's SQL Server Tips

Basit Farooq is a Lead Database Administrator, Trainer and Technical Author. He has more than a decade of IT experience in development, technical training and database administration on Microsoft SQL Server platforms. Basit has authored numerous SQL Server technical articles, and developed and implemented many successful database infrastructure, data warehouse and business intelligence projects. He holds a master's degree in computer science from London Metropolitan University, and industry standard certifications from Microsoft, Sun, Cisco, Brainbench, Prosoft and APM, including MCITP Database Administrator 2008, MCITP Database Administrator 2005, MCDBA SQL Server 2000 and MCTS .NET Framework 2.0 Web Applications.

Get performance statistics for queries and query plans that are cached by SQL Server for faster query execution

You can use the following two DMVs to give you that information:

  • sys.dm_exec_cached_plans – You can use this dynamic management view to see information about the plans that are cached by SQL Server, along with other information such as cached query text, the amount of memory taken by cached plans, and the reuse count of the cached plans. This DMV supersedes the syscachesobjects system catalog.
  • sys.dm_exec_query_stats – You can use this dynamic management view to see the row per query statement within the cached plan. The initial run of the query may return incorrect results if a workload is running on the server. More accurate results can be determined by rerunning the query.

With these DMVs we can troubleshoot complex performance problems.

Example 1:

The following example uses sys.dm_exec_cached_plans, sys.dm_exec_sql_text and sys.dm_exec_query_plan dynamic manage views, to return all queries and query plans that are cached by SQL Server for faster query execution:

SELECT cp.[usecounts]
	,cp.[refcounts]
	,cp.[cacheobjtype]
	,CASE cp.[objtype]
		WHEN 'Proc'
			THEN 'Stored procedure'
		WHEN 'Prepared'
			THEN 'Prepared statement'
		WHEN 'Adhoc'
			THEN 'Ad hoc query'
		WHEN 'ReplProc'
			THEN 'Replication-filter-procedure'
		WHEN 'UsrTab'
			THEN 'User table'
		WHEN 'SysTab'
			THEN 'System table'
		WHEN 'Check'
			THEN 'Check constraint'
		ELSE cp.[objtype]
		END AS [object_type]
	,cp.[size_in_bytes]
	,ISNULL(DB_NAME(qt.[dbid]), 'resourcedb') AS [db_name]
	,qp.[query_plan]
	,qt.[text]
FROM sys.dm_exec_cached_plans cp
CROSS APPLY sys.dm_exec_sql_text(cp.[plan_handle]) qt
CROSS APPLY sys.dm_exec_query_plan(cp.[plan_handle]) qp
ORDER BY cp.[usecounts] DESC;
GO

Example 2:

The following example uses sys.dm_exec_query_stats, sys.dm_exec_sql_text and sys.dm_exec_query_plan to return execution statistics about the top ten queries ranked by average CPU time.

SELECT TOP 10 SUBSTRING(qt.[text], qs.[statement_start_offset] / 2 + 1, (
			CASE 
				WHEN qs.[statement_end_offset] = - 1
					THEN LEN(CONVERT([nvarchar](max), qt.[text])) * 2
				ELSE qs.[statement_end_offset]
				END - qs.[statement_start_offset]
			) / 2) AS [query_text]
	,qp.[query_plan]
	,qs.[last_execution_time]
	,qs.[execution_count]
	,qs.[last_logical_reads]
	,qs.[last_logical_writes]
	,qs.[last_worker_time]
	,qs.[last_elapsed_time]
	,qs.[total_logical_reads]
	,qs.[total_logical_writes]
	,qs.[total_worker_time]
	,qs.[total_elapsed_time]
	,qs.[total_worker_time] / qs.[execution_count] AS [avg_cpu_time]
	,qs.[total_elapsed_time] / qs.[execution_count] AS [avg_running_time]
FROM sys.dm_exec_query_stats qs
CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS qt
CROSS APPLY sys.dm_exec_query_plan(qs.[plan_handle]) AS qp
WHERE qt.[text] LIKE '%SELECT%'
ORDER BY [avg_cpu_time]
	,qs.[execution_count] DESC;

For more information on these dynamic management views, see “sys.dm_exec_cached_plans (Transact-SQL) ” and “sys.dm_exec_query_stats (Transact-SQL)” on MSDN website.


Comments

Leave a comment on the original post [basitaalishan.com, opens in a new window]

Loading comments...