view_Running_Blocked_processes.sql 29 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445
  1. -- 2012-04-07 Pedro Lopes (Microsoft) [email protected] (http://aka.ms/sqlinsights/)
  2. --
  3. -- Returns running sessions/requests; blocking information; sessions that have been granted locks or waiting for locks; SPs stats.
  4. --
  5. -- 2012-09-10 Added extra information
  6. -- 2013-02-02 Added extra information
  7. -- 2013-04-12 Added page type information (PFS; GAM or SGAM) when wait type is PAGELATCH_ or PAGEIOLATCH_ .
  8. -- 2013-05-23 Fixed parse page issue
  9. -- 2013-09-16 Added mem grants information
  10. -- 2013-10-17 Added statements to blocking and blocked sections, fixed head blocker info
  11. -- 2013-12-09 Fixed blocking section showing non-blocked sessions also
  12. -- 2014-02-04 Fixed conversion issue with blocking section
  13. -- 2014-04-09 Added information to blocking section, and fixed conversion issue
  14. -- 2014-12-09 Handle illegal characters in XML conversion
  15. -- 11/16/2016 Added support for SQL Server 2016 SP1 and live query plan snapshot.
  16. SET NOCOUNT ON;
  17. DECLARE @UpTime VARCHAR(12), @StartDate DATETIME, @sqlmajorver int, @sqlcmd NVARCHAR(500), @params NVARCHAR(500)
  18. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  19. IF @sqlmajorver = 9
  20. BEGIN
  21. SET @sqlcmd = N'SELECT @StartDateOUT = login_time, @UpTimeOUT = DATEDIFF(mi, login_time, GETDATE()) FROM master..sysprocesses WHERE spid = 1';
  22. END
  23. ELSE
  24. BEGIN
  25. SET @sqlcmd = N'SELECT @StartDateOUT = sqlserver_start_time, @UpTimeOUT = DATEDIFF(mi,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info';
  26. END
  27. SET @params = N'@StartDateOUT DATETIME OUTPUT, @UpTimeOUT VARCHAR(12) OUTPUT';
  28. EXECUTE sp_executesql @sqlcmd, @params, @StartDateOUT=@StartDate OUTPUT, @UpTimeOUT=@UpTime OUTPUT;
  29. SELECT 'Uptime_Information' AS [Information], GETDATE() AS [Current_Time], @StartDate AS Last_Startup, CONVERT(VARCHAR(4),@UpTime/60/24) + 'd ' + CONVERT(VARCHAR(4),@UpTime/60%24) + 'h ' + CONVERT(VARCHAR(4),@UpTime%60) + 'm' AS Uptime
  30. --SELECT DATEDIFF(hh,'2011-09-08 11:35:00',GETDATE()) AS since_lst_clear
  31. GO
  32. -- Running Sessions/Requests Report
  33. DECLARE @sqlmajorver int, @sqlbuild int, @sqlcmd VARCHAR(8000)
  34. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  35. SELECT @sqlbuild = CONVERT(int, @@microsoftversion & 0xffff);
  36. IF @sqlmajorver = 9
  37. BEGIN
  38. SELECT @sqlcmd = N'SELECT es.session_id, DB_NAME(er.database_id) AS [database_name], OBJECT_NAME(qp.objectid, qp.dbid) AS [object_name], -- NULL if Ad-Hoc or Prepared statements
  39. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  40. qt.text,
  41. NCHAR(1),N''?''),NCHAR(2),N''?''),NCHAR(3),N''?''),NCHAR(4),N''?''),NCHAR(5),N''?''),NCHAR(6),N''?''),NCHAR(7),N''?''),NCHAR(8),N''?''),NCHAR(11),N''?''),NCHAR(12),N''?''),NCHAR(14),N''?''),NCHAR(15),N''?''),NCHAR(16),N''?''),NCHAR(17),N''?''),NCHAR(18),N''?''),NCHAR(19),N''?''),NCHAR(20),N''?''),NCHAR(21),N''?''),NCHAR(22),N''?''),NCHAR(23),N''?''),NCHAR(24),N''?''),NCHAR(25),N''?''),NCHAR(26),N''?''),NCHAR(27),N''?''),NCHAR(28),N''?''),NCHAR(29),N''?''),NCHAR(30),N''?''),NCHAR(31),N''?'')
  42. AS [text()]
  43. FROM sys.dm_exec_sql_text(er.sql_handle) AS qt
  44. FOR XML PATH(''''), TYPE) AS [running_batch],
  45. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  46. SUBSTRING(qt2.text,
  47. (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END),
  48. (CASE WHEN er.statement_end_offset = -1 THEN DATALENGTH(qt2.text) ELSE er.statement_end_offset/2 END - (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END))),
  49. NCHAR(1),N''?''),NCHAR(2),N''?''),NCHAR(3),N''?''),NCHAR(4),N''?''),NCHAR(5),N''?''),NCHAR(6),N''?''),NCHAR(7),N''?''),NCHAR(8),N''?''),NCHAR(11),N''?''),NCHAR(12),N''?''),NCHAR(14),N''?''),NCHAR(15),N''?''),NCHAR(16),N''?''),NCHAR(17),N''?''),NCHAR(18),N''?''),NCHAR(19),N''?''),NCHAR(20),N''?''),NCHAR(21),N''?''),NCHAR(22),N''?''),NCHAR(23),N''?''),NCHAR(24),N''?''),NCHAR(25),N''?''),NCHAR(26),N''?''),NCHAR(27),N''?''),NCHAR(28),N''?''),NCHAR(29),N''?''),NCHAR(30),N''?''),NCHAR(31),N''?'')
  50. AS [text()]
  51. FROM sys.dm_exec_sql_text(er.sql_handle) AS qt2
  52. FOR XML PATH(''''), TYPE) AS [running_statement],
  53. --ot.task_state AS [status],
  54. er.status,
  55. --er.command,
  56. qp.query_plan,
  57. er.percent_complete,
  58. CONVERT(VARCHAR(20),DATEADD(ms,er.estimated_completion_time,GETDATE()),20) AS [ETA_completion_time],
  59. (er.cpu_time/1000) AS cpu_time_sec,
  60. (er.reads*8)/1024 AS physical_reads_KB,
  61. (er.logical_reads*8)/1024 AS logical_reads_KB,
  62. (er.writes*8)/1024 AS writes_KB,
  63. (er.total_elapsed_time/1000)/60 AS elapsed_minutes,
  64. er.wait_type,
  65. er.wait_resource,
  66. er.last_wait_type,
  67. (SELECT CASE
  68. WHEN pageid = 1 OR pageid % 8088 = 0 THEN ''Is_PFS_Page''
  69. WHEN pageid = 2 OR pageid % 511232 = 0 THEN ''Is_GAM_Page''
  70. WHEN pageid = 3 OR (pageid - 1) % 511232 = 0 THEN ''Is_SGAM_Page''
  71. WHEN pageid IS NULL THEN NULL
  72. ELSE ''Is_not_PFS_GAM_SGAM_page'' END
  73. FROM (SELECT CASE WHEN er.[wait_type] LIKE ''PAGE%LATCH%'' AND er.[wait_resource] LIKE ''%:%''
  74. THEN CAST(RIGHT(er.[wait_resource], LEN(er.[wait_resource]) - CHARINDEX('':'', er.[wait_resource], LEN(er.[wait_resource])-CHARINDEX('':'', REVERSE(er.[wait_resource])))) AS int)
  75. ELSE NULL END AS pageid) AS latch_pageid
  76. ) AS wait_resource_type,
  77. er.wait_time AS wait_time_ms,
  78. er.cpu_time AS cpu_time_ms,
  79. er.open_transaction_count,
  80. DATEADD(s, (er.estimated_completion_time/1000), GETDATE()) AS estimated_completion_time,
  81. LEFT (CASE COALESCE(er.transaction_isolation_level, es.transaction_isolation_level)
  82. WHEN 0 THEN ''0-Unspecified''
  83. WHEN 1 THEN ''1-ReadUncommitted''
  84. WHEN 2 THEN ''2-ReadCommitted''
  85. WHEN 3 THEN ''3-RepeatableRead''
  86. WHEN 4 THEN ''4-Serializable''
  87. WHEN 5 THEN ''5-Snapshot''
  88. ELSE CONVERT (VARCHAR(30), er.transaction_isolation_level) + ''-UNKNOWN''
  89. END, 30) AS transaction_isolation_level,
  90. mg.requested_memory_kb,
  91. mg.granted_memory_kb,
  92. --mg.ideal_memory_kb,
  93. mg.query_cost,
  94. ((((ssu.user_objects_alloc_page_count + (SELECT SUM(tsu.user_objects_alloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)) -
  95. (ssu.user_objects_dealloc_page_count + (SELECT SUM(tsu.user_objects_dealloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)))*8)/1024) AS user_obj_in_tempdb_MB,
  96. ((((ssu.internal_objects_alloc_page_count + (SELECT SUM(tsu.internal_objects_alloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)) -
  97. (ssu.internal_objects_dealloc_page_count + (SELECT SUM(tsu.internal_objects_dealloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)))*8)/1024) AS internal_obj_in_tempdb_MB,
  98. es.[host_name],
  99. es.login_name,
  100. --es.original_login_name,
  101. es.[program_name],
  102. --ec.client_net_address,
  103. es.is_user_process
  104. FROM sys.dm_exec_requests er
  105. LEFT OUTER JOIN sys.dm_exec_query_memory_grants mg ON er.session_id = mg.session_id AND er.request_id = mg.request_id
  106. LEFT OUTER JOIN sys.dm_db_session_space_usage ssu ON er.session_id = ssu.session_id
  107. LEFT OUTER JOIN sys.dm_exec_sessions es ON er.session_id = es.session_id
  108. OUTER APPLY sys.dm_exec_query_plan (er.plan_handle) qp
  109. WHERE er.session_id <> @@SPID AND es.is_user_process = 1
  110. ORDER BY er.total_elapsed_time DESC, er.logical_reads DESC, [database_name], session_id'
  111. END
  112. ELSE IF @sqlmajorver IN (10,11,12) OR (@sqlmajorver = 13 AND @sqlbuild < 4000)
  113. BEGIN
  114. SET @sqlcmd = N'SELECT es.session_id, DB_NAME(er.database_id) AS [database_name], OBJECT_NAME(qp.objectid, qp.dbid) AS [object_name],
  115. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  116. qt.text,
  117. NCHAR(1),N''?''),NCHAR(2),N''?''),NCHAR(3),N''?''),NCHAR(4),N''?''),NCHAR(5),N''?''),NCHAR(6),N''?''),NCHAR(7),N''?''),NCHAR(8),N''?''),NCHAR(11),N''?''),NCHAR(12),N''?''),NCHAR(14),N''?''),NCHAR(15),N''?''),NCHAR(16),N''?''),NCHAR(17),N''?''),NCHAR(18),N''?''),NCHAR(19),N''?''),NCHAR(20),N''?''),NCHAR(21),N''?''),NCHAR(22),N''?''),NCHAR(23),N''?''),NCHAR(24),N''?''),NCHAR(25),N''?''),NCHAR(26),N''?''),NCHAR(27),N''?''),NCHAR(28),N''?''),NCHAR(29),N''?''),NCHAR(30),N''?''),NCHAR(31),N''?'')
  118. AS [text()]
  119. FROM sys.dm_exec_sql_text(er.sql_handle) AS qt
  120. FOR XML PATH(''''), TYPE) AS [running_batch],
  121. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  122. SUBSTRING(qt2.text,
  123. (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END),
  124. (CASE WHEN er.statement_end_offset = -1 THEN DATALENGTH(qt2.text) ELSE er.statement_end_offset/2 END - (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END))),
  125. NCHAR(1),N''?''),NCHAR(2),N''?''),NCHAR(3),N''?''),NCHAR(4),N''?''),NCHAR(5),N''?''),NCHAR(6),N''?''),NCHAR(7),N''?''),NCHAR(8),N''?''),NCHAR(11),N''?''),NCHAR(12),N''?''),NCHAR(14),N''?''),NCHAR(15),N''?''),NCHAR(16),N''?''),NCHAR(17),N''?''),NCHAR(18),N''?''),NCHAR(19),N''?''),NCHAR(20),N''?''),NCHAR(21),N''?''),NCHAR(22),N''?''),NCHAR(23),N''?''),NCHAR(24),N''?''),NCHAR(25),N''?''),NCHAR(26),N''?''),NCHAR(27),N''?''),NCHAR(28),N''?''),NCHAR(29),N''?''),NCHAR(30),N''?''),NCHAR(31),N''?'')
  126. AS [text()]
  127. FROM sys.dm_exec_sql_text(er.sql_handle) AS qt2
  128. FOR XML PATH(''''), TYPE) AS [running_statement],
  129. --ot.task_state AS [status],
  130. er.status,
  131. --er.command,
  132. qp.query_plan,
  133. er.percent_complete,
  134. CONVERT(VARCHAR(20),DATEADD(ms,er.estimated_completion_time,GETDATE()),20) AS [ETA_completion_time],
  135. (er.cpu_time/1000) AS cpu_time_sec,
  136. (er.reads*8)/1024 AS physical_reads_KB,
  137. (er.logical_reads*8)/1024 AS logical_reads_KB,
  138. (er.writes*8)/1024 AS writes_KB,
  139. (er.total_elapsed_time/1000)/60 AS elapsed_minutes,
  140. er.wait_type,
  141. er.wait_resource,
  142. er.last_wait_type,
  143. (SELECT CASE
  144. WHEN pageid = 1 OR pageid % 8088 = 0 THEN ''Is_PFS_Page''
  145. WHEN pageid = 2 OR pageid % 511232 = 0 THEN ''Is_GAM_Page''
  146. WHEN pageid = 3 OR (pageid - 1) % 511232 = 0 THEN ''Is_SGAM_Page''
  147. WHEN pageid IS NULL THEN NULL
  148. ELSE ''Is_not_PFS_GAM_SGAM_page'' END
  149. FROM (SELECT CASE WHEN er.[wait_type] LIKE ''PAGE%LATCH%'' AND er.[wait_resource] LIKE ''%:%''
  150. THEN CAST(RIGHT(er.[wait_resource], LEN(er.[wait_resource]) - CHARINDEX('':'', er.[wait_resource], LEN(er.[wait_resource])-CHARINDEX('':'', REVERSE(er.[wait_resource])))) AS int)
  151. ELSE NULL END AS pageid) AS latch_pageid
  152. ) AS wait_resource_type,
  153. er.wait_time AS wait_time_ms,
  154. er.cpu_time AS cpu_time_ms,
  155. er.open_transaction_count,
  156. DATEADD(s, (er.estimated_completion_time/1000), GETDATE()) AS estimated_completion_time,
  157. CASE WHEN mg.wait_time_ms IS NULL THEN DATEDIFF(ms, mg.request_time, mg.grant_time) ELSE mg.wait_time_ms END AS [grant_wait_time_ms],
  158. LEFT (CASE COALESCE(er.transaction_isolation_level, es.transaction_isolation_level)
  159. WHEN 0 THEN ''0-Unspecified''
  160. WHEN 1 THEN ''1-ReadUncommitted''
  161. WHEN 2 THEN ''2-ReadCommitted''
  162. WHEN 3 THEN ''3-RepeatableRead''
  163. WHEN 4 THEN ''4-Serializable''
  164. WHEN 5 THEN ''5-Snapshot''
  165. ELSE CONVERT (VARCHAR(30), er.transaction_isolation_level) + ''-UNKNOWN''
  166. END, 30) AS transaction_isolation_level,
  167. mg.requested_memory_kb,
  168. mg.granted_memory_kb,
  169. mg.ideal_memory_kb,
  170. mg.query_cost,
  171. ((((ssu.user_objects_alloc_page_count + (SELECT SUM(tsu.user_objects_alloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)) -
  172. (ssu.user_objects_dealloc_page_count + (SELECT SUM(tsu.user_objects_dealloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)))*8)/1024) AS user_obj_in_tempdb_MB,
  173. ((((ssu.internal_objects_alloc_page_count + (SELECT SUM(tsu.internal_objects_alloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)) -
  174. (ssu.internal_objects_dealloc_page_count + (SELECT SUM(tsu.internal_objects_dealloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)))*8)/1024) AS internal_obj_in_tempdb_MB,
  175. es.[host_name],
  176. es.login_name,
  177. --es.original_login_name,
  178. es.[program_name],
  179. --ec.client_net_address,
  180. es.is_user_process,
  181. g.name AS workload_group
  182. FROM sys.dm_exec_requests er
  183. LEFT OUTER JOIN sys.dm_exec_query_memory_grants mg ON er.session_id = mg.session_id AND er.request_id = mg.request_id
  184. LEFT OUTER JOIN sys.dm_db_session_space_usage ssu ON er.session_id = ssu.session_id
  185. LEFT OUTER JOIN sys.dm_exec_sessions es ON er.session_id = es.session_id
  186. LEFT OUTER JOIN sys.dm_resource_governor_workload_groups g ON es.group_id = g.group_id
  187. OUTER APPLY sys.dm_exec_query_plan (er.plan_handle) qp
  188. WHERE er.session_id <> @@SPID AND es.is_user_process = 1
  189. ORDER BY er.total_elapsed_time DESC, er.logical_reads DESC, [database_name], session_id'
  190. END
  191. ELSE IF (@sqlmajorver = 13 AND @sqlbuild > 4000) OR @sqlmajorver > 13
  192. BEGIN
  193. SELECT @sqlcmd = N'SELECT es.session_id, DB_NAME(er.database_id) AS [database_name], OBJECT_NAME(qp.objectid, qp.dbid) AS [object_name],
  194. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  195. qt.text,
  196. NCHAR(1),N''?''),NCHAR(2),N''?''),NCHAR(3),N''?''),NCHAR(4),N''?''),NCHAR(5),N''?''),NCHAR(6),N''?''),NCHAR(7),N''?''),NCHAR(8),N''?''),NCHAR(11),N''?''),NCHAR(12),N''?''),NCHAR(14),N''?''),NCHAR(15),N''?''),NCHAR(16),N''?''),NCHAR(17),N''?''),NCHAR(18),N''?''),NCHAR(19),N''?''),NCHAR(20),N''?''),NCHAR(21),N''?''),NCHAR(22),N''?''),NCHAR(23),N''?''),NCHAR(24),N''?''),NCHAR(25),N''?''),NCHAR(26),N''?''),NCHAR(27),N''?''),NCHAR(28),N''?''),NCHAR(29),N''?''),NCHAR(30),N''?''),NCHAR(31),N''?'')
  197. AS [text()]
  198. FROM sys.dm_exec_sql_text(er.sql_handle) AS qt
  199. FOR XML PATH(''''), TYPE) AS [running_batch],
  200. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  201. SUBSTRING(qt2.text,
  202. (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END),
  203. (CASE WHEN er.statement_end_offset = -1 THEN DATALENGTH(qt2.text) ELSE er.statement_end_offset/2 END - (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END))),
  204. NCHAR(1),N''?''),NCHAR(2),N''?''),NCHAR(3),N''?''),NCHAR(4),N''?''),NCHAR(5),N''?''),NCHAR(6),N''?''),NCHAR(7),N''?''),NCHAR(8),N''?''),NCHAR(11),N''?''),NCHAR(12),N''?''),NCHAR(14),N''?''),NCHAR(15),N''?''),NCHAR(16),N''?''),NCHAR(17),N''?''),NCHAR(18),N''?''),NCHAR(19),N''?''),NCHAR(20),N''?''),NCHAR(21),N''?''),NCHAR(22),N''?''),NCHAR(23),N''?''),NCHAR(24),N''?''),NCHAR(25),N''?''),NCHAR(26),N''?''),NCHAR(27),N''?''),NCHAR(28),N''?''),NCHAR(29),N''?''),NCHAR(30),N''?''),NCHAR(31),N''?'')
  205. AS [text()]
  206. FROM sys.dm_exec_sql_text(er.sql_handle) AS qt2
  207. FOR XML PATH(''''), TYPE) AS [running_statement],
  208. --ot.task_state AS [status],
  209. er.status,
  210. --er.command,
  211. qp.query_plan,
  212. CASE WHEN qes.query_plan IS NULL THEN ''Lightweight Query Profiling Infrastructure is not enabled'' ELSE qes.query_plan END AS [live_query_plan_snapshot],
  213. er.percent_complete,
  214. CONVERT(VARCHAR(20),DATEADD(ms,er.estimated_completion_time,GETDATE()),20) AS [ETA_completion_time],
  215. (er.cpu_time/1000) AS cpu_time_sec,
  216. (er.reads*8)/1024 AS physical_reads_KB,
  217. (er.logical_reads*8)/1024 AS logical_reads_KB,
  218. (er.writes*8)/1024 AS writes_KB,
  219. (er.total_elapsed_time/1000)/60 AS elapsed_minutes,
  220. er.wait_type,
  221. er.wait_resource,
  222. er.last_wait_type,
  223. (SELECT CASE
  224. WHEN pageid = 1 OR pageid % 8088 = 0 THEN ''Is_PFS_Page''
  225. WHEN pageid = 2 OR pageid % 511232 = 0 THEN ''Is_GAM_Page''
  226. WHEN pageid = 3 OR (pageid - 1) % 511232 = 0 THEN ''Is_SGAM_Page''
  227. WHEN pageid IS NULL THEN NULL
  228. ELSE ''Is_not_PFS_GAM_SGAM_page'' END
  229. FROM (SELECT CASE WHEN er.[wait_type] LIKE ''PAGE%LATCH%'' AND er.[wait_resource] LIKE ''%:%''
  230. THEN CAST(RIGHT(er.[wait_resource], LEN(er.[wait_resource]) - CHARINDEX('':'', er.[wait_resource], LEN(er.[wait_resource])-CHARINDEX('':'', REVERSE(er.[wait_resource])))) AS int)
  231. ELSE NULL END AS pageid) AS latch_pageid
  232. ) AS wait_resource_type,
  233. er.wait_time AS wait_time_ms,
  234. er.cpu_time AS cpu_time_ms,
  235. er.open_transaction_count,
  236. DATEADD(s, (er.estimated_completion_time/1000), GETDATE()) AS estimated_completion_time,
  237. CASE WHEN mg.wait_time_ms IS NULL THEN DATEDIFF(ms, mg.request_time, mg.grant_time) ELSE mg.wait_time_ms END AS [grant_wait_time_ms],
  238. LEFT (CASE COALESCE(er.transaction_isolation_level, es.transaction_isolation_level)
  239. WHEN 0 THEN ''0-Unspecified''
  240. WHEN 1 THEN ''1-ReadUncommitted''
  241. WHEN 2 THEN ''2-ReadCommitted''
  242. WHEN 3 THEN ''3-RepeatableRead''
  243. WHEN 4 THEN ''4-Serializable''
  244. WHEN 5 THEN ''5-Snapshot''
  245. ELSE CONVERT (VARCHAR(30), er.transaction_isolation_level) + ''-UNKNOWN''
  246. END, 30) AS transaction_isolation_level,
  247. mg.requested_memory_kb,
  248. mg.granted_memory_kb,
  249. mg.ideal_memory_kb,
  250. mg.query_cost,
  251. ((((ssu.user_objects_alloc_page_count + (SELECT SUM(tsu.user_objects_alloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)) -
  252. (ssu.user_objects_dealloc_page_count + (SELECT SUM(tsu.user_objects_dealloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)))*8)/1024) AS user_obj_in_tempdb_MB,
  253. ((((ssu.internal_objects_alloc_page_count + (SELECT SUM(tsu.internal_objects_alloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)) -
  254. (ssu.internal_objects_dealloc_page_count + (SELECT SUM(tsu.internal_objects_dealloc_page_count) FROM sys.dm_db_task_space_usage tsu WHERE tsu.session_id = ssu.session_id)))*8)/1024) AS internal_obj_in_tempdb_MB,
  255. es.[host_name],
  256. es.login_name,
  257. --es.original_login_name,
  258. es.[program_name],
  259. --ec.client_net_address,
  260. es.is_user_process,
  261. g.name AS workload_group
  262. FROM sys.dm_exec_requests er
  263. LEFT OUTER JOIN sys.dm_exec_query_memory_grants mg ON er.session_id = mg.session_id AND er.request_id = mg.request_id
  264. LEFT OUTER JOIN sys.dm_db_session_space_usage ssu ON er.session_id = ssu.session_id
  265. LEFT OUTER JOIN sys.dm_exec_sessions es ON er.session_id = es.session_id
  266. LEFT OUTER JOIN sys.dm_resource_governor_workload_groups g ON es.group_id = g.group_id
  267. OUTER APPLY sys.dm_exec_query_plan (er.plan_handle) qp
  268. OUTER APPLY sys.dm_exec_query_statistics_xml(er.session_id) qes
  269. WHERE er.session_id <> @@SPID AND es.is_user_process = 1
  270. ORDER BY er.total_elapsed_time DESC, er.logical_reads DESC, [database_name], session_id'
  271. END
  272. --PRINT @sqlcmd
  273. EXECUTE (@sqlcmd)
  274. GO
  275. -- Waiter and Blocking Report
  276. SELECT
  277. -- blocked
  278. es.session_id AS blocked_spid,
  279. es.[status] AS [blocked_spid_status],
  280. ot.task_state AS [blocked_task_status],
  281. owt.wait_type AS blocked_spid_wait_type,
  282. COALESCE(owt.wait_duration_ms, DATEDIFF(ms, es.last_request_start_time, GETDATE())) AS blocked_spid_wait_time_ms,
  283. --er.total_elapsed_time AS blocked_elapsed_time_ms,
  284. /*
  285. Check sys.dm_os_waiting_tasks for Exchange wait types in http://technet.microsoft.com/en-us/library/ms188743.aspx.
  286. - Wait Resource e_waitPipeNewRow in CXPACKET waits – Producer waiting on consumer for a packet to fill.
  287. - Wait Resource e_waitPipeGetRow in CXPACKET waits – Consumer waiting on producer to fill a packet.
  288. */
  289. owt.resource_description AS blocked_spid_res_desc,
  290. owt.[objid] AS blocked_objectid,
  291. owt.pageid AS blocked_pageid,
  292. CASE WHEN owt.pageid = 1 OR owt.pageid % 8088 = 0 THEN 'Is_PFS_Page'
  293. WHEN owt.pageid = 2 OR owt.pageid % 511232 = 0 THEN 'Is_GAM_Page'
  294. WHEN owt.pageid = 3 OR (owt.pageid - 1) % 511232 = 0 THEN 'Is_SGAM_Page'
  295. WHEN owt.pageid IS NULL THEN NULL
  296. ELSE 'Is_not_PFS_GAM_SGAM_page' END AS blocked_spid_res_type,
  297. (SELECT qt.text AS [text()]
  298. FROM sys.dm_exec_sql_text(COALESCE(er.sql_handle, ec.most_recent_sql_handle)) AS qt
  299. FOR XML PATH(''), TYPE) AS [blocked_batch],
  300. (SELECT SUBSTRING(qt2.text,
  301. (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END),
  302. (CASE WHEN er.statement_end_offset = -1 THEN DATALENGTH(qt2.text) ELSE er.statement_end_offset/2 END - (CASE WHEN er.statement_start_offset = 0 THEN 0 ELSE er.statement_start_offset/2 END))) AS [text()]
  303. FROM sys.dm_exec_sql_text(COALESCE(er.sql_handle, ec.most_recent_sql_handle)) AS qt2
  304. FOR XML PATH(''), TYPE) AS [blocked_statement],
  305. es.last_request_start_time AS blocked_last_start,
  306. LEFT (CASE COALESCE(es.transaction_isolation_level, er.transaction_isolation_level)
  307. WHEN 0 THEN '0-Unspecified'
  308. WHEN 1 THEN '1-ReadUncommitted(NOLOCK)'
  309. WHEN 2 THEN '2-ReadCommitted'
  310. WHEN 3 THEN '3-RepeatableRead'
  311. WHEN 4 THEN '4-Serializable'
  312. WHEN 5 THEN '5-Snapshot'
  313. ELSE CONVERT (VARCHAR(30), COALESCE(es.transaction_isolation_level, er.transaction_isolation_level)) + '-UNKNOWN'
  314. END, 30) AS blocked_tran_isolation_level,
  315. -- blocker
  316. er.blocking_session_id As blocker_spid,
  317. CASE
  318. -- session has an active request, is blocked, but is blocking others or session is idle but has an open tran and is blocking others
  319. WHEN (er2.session_id IS NULL OR owt.blocking_session_id IS NULL) AND (er.blocking_session_id = 0 OR er.session_id IS NULL) THEN 1
  320. -- session is either not blocking someone, or is blocking someone but is blocked by another party
  321. ELSE 0
  322. END AS is_head_blocker,
  323. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  324. qt2.text,
  325. NCHAR(1),N'?'),NCHAR(2),N'?'),NCHAR(3),N'?'),NCHAR(4),N'?'),NCHAR(5),N'?'),NCHAR(6),N'?'),NCHAR(7),N'?'),NCHAR(8),N'?'),NCHAR(11),N'?'),NCHAR(12),N'?'),NCHAR(14),N'?'),NCHAR(15),N'?'),NCHAR(16),N'?'),NCHAR(17),N'?'),NCHAR(18),N'?'),NCHAR(19),N'?'),NCHAR(20),N'?'),NCHAR(21),N'?'),NCHAR(22),N'?'),NCHAR(23),N'?'),NCHAR(24),N'?'),NCHAR(25),N'?'),NCHAR(26),N'?'),NCHAR(27),N'?'),NCHAR(28),N'?'),NCHAR(29),N'?'),NCHAR(30),N'?'),NCHAR(31),N'?')
  326. AS [text()]
  327. FROM sys.dm_exec_sql_text(COALESCE(er2.sql_handle, ec2.most_recent_sql_handle)) AS qt2
  328. FOR XML PATH(''), TYPE) AS [blocker_batch],
  329. (SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(
  330. SUBSTRING(qt2.text,
  331. (CASE WHEN er2.statement_start_offset = 0 THEN 0 ELSE er2.statement_start_offset/2 END),
  332. (CASE WHEN er2.statement_end_offset = -1 THEN DATALENGTH(qt2.text) ELSE er2.statement_end_offset/2 END - (CASE WHEN er2.statement_start_offset = 0 THEN 0 ELSE er2.statement_start_offset/2 END))),
  333. NCHAR(1),N'?'),NCHAR(2),N'?'),NCHAR(3),N'?'),NCHAR(4),N'?'),NCHAR(5),N'?'),NCHAR(6),N'?'),NCHAR(7),N'?'),NCHAR(8),N'?'),NCHAR(11),N'?'),NCHAR(12),N'?'),NCHAR(14),N'?'),NCHAR(15),N'?'),NCHAR(16),N'?'),NCHAR(17),N'?'),NCHAR(18),N'?'),NCHAR(19),N'?'),NCHAR(20),N'?'),NCHAR(21),N'?'),NCHAR(22),N'?'),NCHAR(23),N'?'),NCHAR(24),N'?'),NCHAR(25),N'?'),NCHAR(26),N'?'),NCHAR(27),N'?'),NCHAR(28),N'?'),NCHAR(29),N'?'),NCHAR(30),N'?'),NCHAR(31),N'?')
  334. AS [text()]
  335. FROM sys.dm_exec_sql_text(COALESCE(er2.sql_handle, ec2.most_recent_sql_handle)) AS qt2
  336. FOR XML PATH(''), TYPE) AS [blocker_statement],
  337. es2.last_request_start_time AS blocker_last_start,
  338. LEFT (CASE COALESCE(er2.transaction_isolation_level, es.transaction_isolation_level)
  339. WHEN 0 THEN '0-Unspecified'
  340. WHEN 1 THEN '1-ReadUncommitted(NOLOCK)'
  341. WHEN 2 THEN '2-ReadCommitted'
  342. WHEN 3 THEN '3-RepeatableRead'
  343. WHEN 4 THEN '4-Serializable'
  344. WHEN 5 THEN '5-Snapshot'
  345. ELSE CONVERT (VARCHAR(30), COALESCE(er2.transaction_isolation_level, es.transaction_isolation_level)) + '-UNKNOWN'
  346. END, 30) AS blocker_tran_isolation_level,
  347. -- blocked - other data
  348. DB_NAME(er.database_id) AS blocked_database,
  349. es.[host_name] AS blocked_host,
  350. es.[program_name] AS blocked_program,
  351. es.login_name AS blocked_login,
  352. CASE WHEN es.session_id = -2 THEN 'Orphaned_distributed_tran'
  353. WHEN es.session_id = -3 THEN 'Defered_recovery_tran'
  354. WHEN es.session_id = -4 THEN 'Unknown_tran' ELSE NULL END AS blocked_session_comment,
  355. es.is_user_process AS [blocked_is_user_process],
  356. -- blocker - other data
  357. DB_NAME(er2.database_id) AS blocker_database,
  358. es2.[host_name] AS blocker_host,
  359. es2.[program_name] AS blocker_program,
  360. es2.login_name AS blocker_login,
  361. CASE WHEN es2.session_id = -2 THEN 'Orphaned_distributed_tran'
  362. WHEN es2.session_id = -3 THEN 'Defered_recovery_tran'
  363. WHEN es2.session_id = -4 THEN 'Unknown_tran' ELSE NULL END AS blocker_session_comment,
  364. es2.is_user_process AS [blocker_is_user_process]
  365. FROM sys.dm_exec_sessions es
  366. LEFT OUTER JOIN sys.dm_exec_requests er ON es.session_id = er.session_id
  367. LEFT OUTER JOIN sys.dm_exec_connections ec ON es.session_id = ec.session_id
  368. LEFT OUTER JOIN sys.dm_os_tasks ot ON er.session_id = ot.session_id AND er.request_id = ot.request_id
  369. LEFT OUTER JOIN sys.dm_exec_sessions es2 ON er.blocking_session_id = es2.session_id
  370. LEFT OUTER JOIN sys.dm_exec_requests er2 ON es2.session_id = er2.session_id
  371. LEFT OUTER JOIN sys.dm_exec_connections ec2 ON es2.session_id = ec2.session_id
  372. LEFT OUTER JOIN
  373. (
  374. -- In some cases (e.g. parallel queries, also waiting for a worker), one thread can be flagged as
  375. -- waiting for several different threads. This will cause that thread to show up in multiple rows
  376. -- in our grid, which we don't want. Use ROW_NUMBER to select the longest wait for each thread,
  377. -- and use it as representative of the other wait relationships this thread is involved in.
  378. SELECT waiting_task_address, session_id, exec_context_id, wait_duration_ms,
  379. wait_type, resource_address, blocking_task_address, blocking_session_id,
  380. blocking_exec_context_id, resource_description,
  381. CASE WHEN [wait_type] LIKE 'PAGE%' AND [resource_description] LIKE '%:%' THEN CAST(RIGHT([resource_description], LEN([resource_description]) - CHARINDEX(':', [resource_description], LEN([resource_description])-CHARINDEX(':', REVERSE([resource_description])))) AS int)
  382. WHEN [wait_type] LIKE 'LCK%' AND [resource_description] LIKE '%pageid%' AND ISNUMERIC(RIGHT(LEFT([resource_description],CHARINDEX('dbid=', [resource_description], CHARINDEX('pageid=', [resource_description])+6)-1),CHARINDEX('=',REVERSE(RTRIM(LEFT([resource_description],CHARINDEX('dbid=', [resource_description], CHARINDEX('pageid=', [resource_description])+6)-1)))))) = 1 THEN CAST(RIGHT(LEFT([resource_description],CHARINDEX('dbid=', [resource_description], CHARINDEX('pageid=', [resource_description])+6)-1),CHARINDEX('=',REVERSE(RTRIM(LEFT([resource_description],CHARINDEX('dbid=', [resource_description], CHARINDEX('pageid=', [resource_description])+6)-1))))) AS bigint)
  383. ELSE NULL END AS pageid,
  384. CASE WHEN [wait_type] LIKE 'LCK%' AND [resource_description] LIKE '%associatedObjectId%' AND ISNUMERIC(RIGHT([resource_description],CHARINDEX('=', REVERSE([resource_description]))-1)) = 1 THEN CAST(RIGHT([resource_description],CHARINDEX('=', REVERSE([resource_description]))-1) AS bigint)
  385. ELSE NULL END AS [objid],
  386. ROW_NUMBER() OVER (PARTITION BY waiting_task_address ORDER BY wait_duration_ms DESC) AS row_num
  387. FROM sys.dm_os_waiting_tasks
  388. ) owt ON ot.task_address = owt.waiting_task_address AND owt.row_num = 1
  389. --OUTER APPLY sys.dm_exec_sql_text (er.sql_handle) est
  390. --OUTER APPLY sys.dm_exec_query_plan (er.plan_handle) eqp
  391. WHERE es.session_id <> @@SPID AND es.is_user_process = 1
  392. --AND ((owt.wait_duration_ms/1000 > 5) OR (er.total_elapsed_time/1000) > 5 OR er.total_elapsed_time IS NULL) --Only report blocks > 5 Seconds plus head blocker
  393. AND (es.session_id IN (SELECT er3.blocking_session_id FROM sys.dm_exec_requests er3) OR er.blocking_session_id IS NOT NULL OR er.blocking_session_id > 0)
  394. ORDER BY blocked_spid, is_head_blocker DESC, blocked_spid_wait_time_ms DESC, blocker_spid
  395. -- Stored procedure stats
  396. DECLARE @sqlmajorver int, @sqlcmd VARCHAR(4000)
  397. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  398. IF @sqlmajorver >= 11
  399. BEGIN
  400. SET @sqlcmd = N'SELECT CASE WHEN ps.database_id = 32767 THEN ''ResourceDB'' ELSE DB_NAME(ps.database_id) END AS DatabaseName,
  401. CASE WHEN ps.database_id = 32767 THEN NULL ELSE OBJECT_NAME(ps.[object_id], ps.database_id) END AS ObjectName,
  402. type_desc,
  403. (SELECT qt.text AS [text()]
  404. FROM sys.dm_exec_procedure_stats AS ps2 CROSS APPLY sys.dm_exec_sql_text(ps2.sql_handle) AS qt
  405. WHERE ps2.database_id = ps.database_id AND ps2.[object_id] = ps.[object_id]
  406. FOR XML PATH(''''), TYPE) AS [sqltext],
  407. qp.query_plan,
  408. ps.cached_time,
  409. ps.last_execution_time,
  410. ps.execution_count,
  411. ps.total_elapsed_time/ps.execution_count AS avg_elapsed_time,
  412. ps.last_elapsed_time,
  413. ps.total_worker_time/ps.execution_count AS avg_cpu_time,
  414. ps.last_worker_time AS last_cpu_time,
  415. ps.min_worker_time AS min_cpu_time, ps.max_worker_time AS max_cpu_time,
  416. ps.total_logical_reads/ps.execution_count AS avg_logical_reads,
  417. ps.last_logical_reads, ps.min_logical_reads, ps.max_logical_reads,
  418. ps.total_physical_reads/ps.execution_count AS avg_physical_reads,
  419. ps.last_physical_reads, ps.min_physical_reads, ps.max_physical_reads,
  420. ps.total_logical_writes/ps.execution_count AS avg_logical_writes,
  421. ps.last_logical_writes, ps.min_logical_writes, ps.max_logical_writes
  422. FROM sys.dm_exec_procedure_stats AS ps
  423. CROSS APPLY sys.dm_exec_query_plan(ps.plan_handle) AS qp'
  424. EXEC (@sqlcmd);
  425. END
  426. -- Acquired locks
  427. /*SELECT tl.*, sp.[object_id], sp.index_id
  428. FROM sys.dm_tran_locks tl
  429. LEFT JOIN sys.partitions sp ON tl.resource_associated_entity_id = sp.[hobt_id]
  430. */
  431. GO