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.

Advertisement

Identify the cause of SQL Server blocking

In my previous article (Different techniques to identify blocking in SQL Server) on MSSQLTips.com, I discussed about locks and blocks, and presented you with an overview on how to troubleshoot and resolve blocks using dynamic management views and Activity Monitor. After I wrote this article, I received several emails from readers asking how they can use the information returned by these dynamic management views (DMVs) to identify SPIDs and other useful information about the processes that are actually causing blocking on a SQL Server instance.

Check out my latest article (Identify the cause of SQL Server blocking) on MSSQLTips.com, in which I shared the query that will help you to quickly identify SPIDs and other useful information about the processes that are causing blocking on SQL Server instance.

SQL Server DMV: sys.dm_exec_requests

Today, I’ve received an email from friend asking that that is there any way to find out the progress of following operation using T- SQL query. As we know, with the release of SQL Server 2005, Microsoft provides set of dynamic management views (DMVs) which helps ease the administration SQL Server Database Engine. These sets of new DMVs include one particular DMV that is sys.dm_exec_requests, which we can use to return information about the requests that are currently executing on SQL Server instance. I used this DMV to write the following query, which helps to find the progress of following operations programmatically:

  • ALTER INDEX REORGANIZE
  • AUTO_SHRINK
  • BACKUP DATABASE
  • DBCC CHECKDB
  • DBCC CHECKFILEGROUP
  • DBCC CHECKTABLE
  • DBCC INDEXDEFRAG
  • DBCC SHRINKDATABASE
  • DBCC SHRINKFILE
  • RECOVERY
  • RESTORE DATABASE
  • ROLLBACK
  • TDE ENCRYPTION
  • RESTORE LOG
  • BACKUP LOG
SELECT dmv1.[session_id] AS [UserSessionID]
	,dmv2.[login_name] AS [SessionLoginName]
	,dmv2.[original_login_name] AS [ConnectionLoginName]
	,dmv1.[command] AS [TSQLCommandType]
	,est.[text] AS [TSQLCommandText]
	,dmv2.[status] AS [Status]
	,dmv2.[cpu_time] AS [CPUTime]
	,dmv2.[memory_usage] AS [MemoryUsage]
	,dmv1.[start_time] AS [StartTime]
	,dmv1.[percent_complete] AS [PercentComplete]
	,dmv2.[program_name] AS [ProgramName]
	,CAST(((DATEDIFF(s, dmv1.[start_time], CURRENT_TIMESTAMP)) / 3600) AS [varchar](32)) + ' hour(s), ' + CAST((DATEDIFF(s, dmv1.[start_time], CURRENT_TIMESTAMP) % 3600) / 60 AS [varchar](32)) + 'min, ' + CAST((DATEDIFF(s, dmv1.[start_time], CURRENT_TIMESTAMP) % 60) AS [varchar](32)) + ' sec' AS [RunningTime]
	,CAST((dmv1.[estimated_completion_time] / 3600000) AS [varchar](32)) + ' hour(s), ' + CAST((dmv1.[estimated_completion_time] % 3600000) / 60000 AS [varchar](32)) + 'min, ' + CAST((dmv1.[estimated_completion_time] % 60000) / 1000 AS [varchar](32)) + ' sec' AS [TimeRequiredToCompleteOperation]
	,dateadd(second, dmv1.[estimated_completion_time] / 1000, CURRENT_TIMESTAMP) AS [EstimatedCompletionTime]
FROM [sys].[dm_exec_requests] dmv1
CROSS APPLY [sys].[dm_exec_sql_text](dmv1.[sql_handle]) est
INNER JOIN [sys].[dm_exec_sessions] dmv2
	ON dmv1.[session_id] = dmv2.[session_id]
WHERE dmv1.[command] IN ('ALTER INDEX REORGANIZE', 'AUTO_SHRINK', 'BACKUP DATABASE', 'DBCC CHECKDB', 'DBCC CHECKFILEGROUP', 'DBCC CHECKTABLE', 'DBCC INDEXDEFRAG', 'DBCC SHRINKDATABASE', 'DBCC SHRINKFILE', 'RECOVERY', 'RESTORE DATABASE', 'ROLLBACK', 'TDE ENCRYPTION', 'RESTORE LOG', 'BACKUP LOG')

Then following is the resultset this query returned, when I executed against server where I’m performing backup of the database (Note: To fit the resultset on the page, I splitted into two images):

progress_1

progress_2

For more information about this DMV, see sys.dm_exec_requests (Transact-SQL).