B. Obtain information about the top five queries by average CPU time
The following example returns the text of the SQL statement and average CPU time for the top five queries.
SQLCopy
SELECT TOP 5 total_worker_time/execution_count AS [Avg CPU Time],
SUBSTRING(st.text, (qs.statement_start_offset/2)+1,
((CASE qs.statement_end_offset
WHEN -1 THEN DATALENGTH(st.text)
ELSE qs.statement_end_offset
END - qs.statement_start_offset)/2) + 1) AS statement_text
FROM sys.dm_exec_query_stats AS qs
CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st
ORDER BY total_worker_time/execution_count DESC;
C. Provide batch-execution statistics
The following example returns the text of SQL queries that are being executed in batches and provides statistical information about them.
SQLCopy
SELECT s2.dbid,
s1.sql_handle,
(SELECT TOP 1 SUBSTRING(s2.text,statement_start_offset / 2+1 ,
( (CASE WHEN statement_end_offset = -1
THEN (LEN(CONVERT(nvarchar(max),s2.text)) * 2)
ELSE statement_end_offset END) - statement_start_offset) / 2+1)) AS sql_statement,
execution_count,
plan_generation_num,
last_execution_time,
total_worker_time,
last_worker_time,
min_worker_time,
max_worker_time,
total_physical_reads,
last_physical_reads,
min_physical_reads,
max_physical_reads,
total_logical_writes,
last_logical_writes,
min_logical_writes,
max_logical_writes
FROM sys.dm_exec_query_stats AS s1
CROSS APPLY sys.dm_exec_sql_text(sql_handle) AS s2
WHERE s2.objectid is null
ORDER BY s1.sql_handle, s1.statement_start_offset, s1.statement_end_offset;
A. Find the query text for a running batch
The following example queries sys.dm_exec_requests
to find the interesting query and copy its sql_handle
from the output.
SQLCopy
SELECT * FROM sys.dm_exec_requests;
GO
Then, to obtain the statement text, use the copied sql_handle
with system function sys.dm_exec_sql_text(sql_handle)
.
SQLCopy
SELECT * FROM sys.dm_exec_sql_text(< copied sql_handle >);
GO
B. Find all locks that a running batch is holding
The following example queries sys.dm_exec_requests
to find the interesting batch and copy its transaction_id
from the output.
SQLCopy
SELECT * FROM sys.dm_exec_requests;
GO
Then, to find lock information, use the copied transaction_id
with the system function sys.dm_tran_locks
.
SQLCopy
SELECT * FROM sys.dm_tran_locks
WHERE request_owner_type = N'TRANSACTION'
AND request_owner_id = < copied transaction_id >;
GO
C. Find all currently blocked requests
The following example queries sys.dm_exec_requests
to find information about blocked requests.
SQLCopy
SELECT session_id,
status,
blocking_session_id,
wait_type,
wait_time,
wait_resource,
transaction_id
FROM sys.dm_exec_requests
WHERE status = N'suspended';
GO
D. Order existing requests by CPU
SQLCopy
SELECT
[req].[session_id],
[req].[start_time],
[req].[cpu_time] AS [cpu_time_ms],
OBJECT_NAME([ST].[objectid], [ST].[dbid]) AS [ObjectName],
SUBSTRING(
REPLACE(
REPLACE(
SUBSTRING(
[ST].[text], ([req].[statement_start_offset] / 2) + 1,
((CASE [req].[statement_end_offset]
WHEN -1 THEN DATALENGTH([ST].[text])
ELSE [req].[statement_end_offset]
END - [req].[statement_start_offset]
) / 2
) + 1
), CHAR(10), ' '
), CHAR(13), ' '
), 1, 512
) AS [statement_text]
FROM
[sys].[dm_exec_requests] AS [req]
CROSS APPLY [sys].dm_exec_sql_text([req].[sql_handle]) AS [ST]
ORDER BY
[req].[cpu_time] DESC;
GO
