Skip to content

Instantly share code, notes, and snippets.

@jweyrich
Last active May 16, 2023 09:41
Show Gist options
  • Save jweyrich/5f8b72249e602c15715d3a44a40682ca to your computer and use it in GitHub Desktop.
Save jweyrich/5f8b72249e602c15715d3a44a40682ca to your computer and use it in GitHub Desktop.
SQL Server query stats & average execution time
SELECT *
FROM sys.dm_exec_requests
CROSS APPLY sys.dm_exec_sql_text(sql_handle);
SELECT TOP 30
creation_time
, last_execution_time
, total_physical_reads
, total_logical_reads
, total_logical_writes
, execution_count
, total_worker_time
, total_elapsed_time
, total_elapsed_time / execution_count / 1000 / 60 avg_elapsed_time -- in minutes!
, SUBSTRING(st.text, (qs.statement_start_offset/2) + 1,
((CASE 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) st
ORDER BY total_elapsed_time / execution_count DESC;
USE DATABASE_NAME;
GO
SELECT TOP 5 query_stats.query_hash AS "Query Hash",
SUM(query_stats.total_worker_time) / SUM(query_stats.execution_count) AS "Avg CPU Time",
MIN(query_stats.statement_text) AS "Statement Text"
FROM
(SELECT QS.*,
SUBSTRING(ST.text, (QS.statement_start_offset/2) + 1,
((CASE 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) as query_stats
GROUP BY query_stats.query_hash
ORDER BY 2 DESC;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment