Find Inefficient T-SQL Stored Procedures

The following is a stored procedure you can use when you want to quickly identify procedures in your SQL Server database which are taking up excessive CPU time.

The script returns 3 recordsets:

  • The number of active connections by database name, with login name and hostname
  • All stored procedures with execution count and total/average CPU times
  • All stored procedures with average and total elapsed time
CREATE PROCEDURE [dbo].[procProcessTimes]ASSELECT DB_NAME(dbid) as DBName, COUNT(dbid) as NumberOfConnections, loginame as LoginName , HostnameFROM    sys.sysprocesses WHERE     dbid > 0 GROUP BY     dbid, loginame, HostnameSELECT DB_NAME(st.dbid) DBName      ,OBJECT_SCHEMA_NAME(st.objectid,dbid) SchemaName      ,OBJECT_NAME(st.objectid,dbid) StoredProcedure      ,max(cp.usecounts) Execution_count      ,sum(qs.total_worker_time) total_cpu_time      ,sum(qs.total_worker_time) / (max(cp.usecounts) * 1.0)  avg_cpu_time  FROM sys.dm_exec_cached_plans cp join sys.dm_exec_query_stats qs on cp.plan_handle = qs.plan_handle      CROSS APPLY sys.dm_exec_sql_text(cp.plan_handle) st where DB_NAME(st.dbid) is not null and cp.objtype = 'proc' group by DB_NAME(st.dbid),OBJECT_SCHEMA_NAME(objectid,st.dbid), OBJECT_NAME(objectid,st.dbid)  order by sum(qs.total_worker_time) descSELECT DB_NAME(st.dbid) DBName      ,OBJECT_SCHEMA_NAME(objectid,st.dbid) SchemaName      ,OBJECT_NAME(objectid,st.dbid) StoredProcedure      ,max(cp.usecounts) execution_count      ,sum(qs.total_elapsed_time) total_elapsed_time      ,sum(qs.total_elapsed_time) / max(cp.usecounts) avg_elapsed_time FROM sys.dm_exec_query_stats qs CROSS APPLY sys.dm_exec_sql_text(qs.plan_handle) st   join sys.dm_exec_cached_plans cp on qs.plan_handle = cp.plan_handle  where DB_NAME(st.dbid) is not null and cp.objtype = 'proc' group by DB_NAME(st.dbid),OBJECT_SCHEMA_NAME(objectid,st.dbid), OBJECT_NAME(objectid,st.dbid)  order by sum(qs.total_elapsed_time) desc

Leave a Reply

This site uses Akismet to reduce spam. Learn how your comment data is processed.