4
4
DECLARE @p_collection_time datetime2
5
5
SET @p_collection_time = ' 2019-04-23 02:45:09.033' ;
6
6
7
- /*
8
- IF OBJECT_ID('tempdb..#T') IS NOT NULL
9
- DROP TABLE #T;
10
-
11
- ;WITH t_processes AS
12
- (
13
- SELECT SPID = [session_id], BLOCKED = ISNULL([blocking_session_id],0),
14
- [BATCH] = REPLACE(REPLACE(REPLACE(REPLACE(CAST(COALESCE([sql_command],[sql_text]) AS VARCHAR(MAX)),char(13),''),CHAR(10),''),'<?query --',''),'--?>','')
15
- FROM [DBA].[dbo].WhoIsActive_ResultSets AS r
16
- WHERE r.collection_Time = @p_collection_time
17
- )
18
- SELECT SPID, BLOCKED,
19
- [BATCH] = CASE WHEN LEFT([BATCH],1) = '(' THEN SUBSTRING([BATCH],CHARINDEX('exec',[BATCH]),LEN([BATCH])) ELSE [BATCH] END
20
- INTO #T
21
- FROM t_processes;
22
-
23
- ;WITH BLOCKERS (SPID, BLOCKED, LEVEL, BATCH) AS
24
- (
25
- SELECT SPID,
26
- BLOCKED,
27
- [LEVEL] = CAST (REPLICATE ('0', 4-LEN (CAST (SPID AS VARCHAR))) + CAST (SPID AS VARCHAR) AS VARCHAR (1000)),
28
- BATCH
29
- FROM #T R
30
- WHERE (BLOCKED = 0 OR BLOCKED = SPID)
31
- AND EXISTS (SELECT * FROM #T R2 WHERE R2.BLOCKED = R.SPID AND R2.BLOCKED <> R2.SPID)
32
- --
33
- UNION ALL
34
- --
35
- SELECT R.SPID,
36
- R.BLOCKED,
37
- CAST (BLOCKERS.LEVEL + RIGHT (CAST ((1000 + R.SPID) AS VARCHAR (100)), 4) AS VARCHAR (1000)) AS LEVEL,
38
- R.BATCH
39
- FROM #T AS R
40
- INNER JOIN BLOCKERS
41
- ON R.BLOCKED = BLOCKERS.SPID
42
- WHERE R.BLOCKED > 0 AND R.BLOCKED <> R.SPID
43
- )
44
- SELECT [BLOCKING_TREE] = N' ' + REPLICATE (N'| ', LEN (LEVEL)/4 - 1)
45
- + CASE WHEN (LEN(LEVEL)/4 - 1) = 0
46
- THEN 'HEAD - '
47
- ELSE '|------ '
48
- END
49
- + CAST (SPID AS NVARCHAR (10)) + N' ' + BATCH
50
- FROM BLOCKERS ORDER BY LEVEL ASC;
51
- */
52
-
53
7
;WITH T_BLOCKERS AS
54
8
(
55
9
-- Find block Leaders
56
10
SELECT [collection_time], [TimeInMinutes], [session_id],
57
11
[sql_text] = REPLACE (REPLACE (REPLACE (REPLACE (CAST (COALESCE ([sql_command],[sql_text]) AS VARCHAR (MAX )),char (13 ),' ' ),CHAR (10 ),' ' ),' <?query --' ,' ' ),' --?>' ,' ' ),
58
- [login_name],
59
- [wait_info], [blocking_session_id], [blocked_session_count], [locks],
12
+ [login_name], [wait_info], [blocking_session_id], [blocked_session_count], [locks],
60
13
[status], [tran_start_time], [open_tran_count], [host_name], [database_name], [program_name],
14
+ r.[CPU], r.[tempdb_allocations], r.[tempdb_current], r.[reads], r.[writes], r.[physical_io], r.[physical_reads], r.[query_plan],
61
15
[LEVEL] = CAST (REPLICATE (' 0' , 4 - LEN (CAST (r .session_id AS VARCHAR ))) + CAST (r .session_id AS VARCHAR ) AS VARCHAR (1000 ))
62
16
FROM [DBA].[dbo].WhoIsActive_ResultSets AS r
63
17
WHERE r .collection_Time = @p_collection_time
@@ -68,9 +22,9 @@ FROM BLOCKERS ORDER BY LEVEL ASC;
68
22
--
69
23
SELECT r.[collection_time], r.[TimeInMinutes], r.[session_id],
70
24
[sql_text] = REPLACE (REPLACE (REPLACE (REPLACE (CAST (COALESCE (r.[sql_command],r.[sql_text]) AS VARCHAR (MAX )),char (13 ),' ' ),CHAR (10 ),' ' ),' <?query --' ,' ' ),' --?>' ,' ' ),
71
- r.[login_name],
72
- r.[wait_info], r.[blocking_session_id], r.[blocked_session_count], r.[locks],
25
+ r.[login_name], r.[wait_info], r.[blocking_session_id], r.[blocked_session_count], r.[locks],
73
26
r.[status], r.[tran_start_time], r.[open_tran_count], r.[host_name], r.[database_name], r.[program_name],
27
+ r.[CPU], r.[tempdb_allocations], r.[tempdb_current], r.[reads], r.[writes], r.[physical_io], r.[physical_reads], r.[query_plan],
74
28
CAST (B .LEVEL + RIGHT (CAST ((1000 + r .session_id ) AS VARCHAR (100 )), 4 ) AS VARCHAR (1000 )) AS LEVEL
75
29
FROM [DBA].[dbo].WhoIsActive_ResultSets AS r
76
30
INNER JOIN
@@ -91,9 +45,8 @@ SELECT [collection_time],
91
45
[sql_commad] = CONVERT (XML , ' <?query -- '+ char (13 )
92
46
+ (CASE WHEN LEFT ([sql_text],1 ) = ' (' THEN SUBSTRING ([sql_text],CHARINDEX (' exec' ,[sql_text]),LEN ([sql_text])) ELSE [sql_text] END )
93
47
+ char (13 )+ ' --?>' ),
94
- [host_name], [database_name], [login_name], [program_name],
95
- [wait_info], [blocked_session_count], [locks],
96
- [tran_start_time], [open_tran_count]
48
+ [host_name], [database_name], [login_name], [program_name], [wait_info], [blocked_session_count], [locks], [tran_start_time], [open_tran_count]
49
+ ,r.[CPU], r.[tempdb_allocations], r.[tempdb_current], r.[reads], r.[writes], r.[physical_io], r.[physical_reads], r.[query_plan]
97
50
FROM T_BLOCKERS AS r
98
51
OUTER APPLY
99
52
(
@@ -117,4 +70,50 @@ OUTER APPLY
117
70
END
118
71
) as wi
119
72
) AS w
120
- ORDER BY LEVEL ASC ;
73
+ ORDER BY LEVEL ASC ;
74
+
75
+ /*
76
+ IF OBJECT_ID('tempdb..#T') IS NOT NULL
77
+ DROP TABLE #T;
78
+
79
+ ;WITH t_processes AS
80
+ (
81
+ SELECT SPID = [session_id], BLOCKED = ISNULL([blocking_session_id],0),
82
+ [BATCH] = REPLACE(REPLACE(REPLACE(REPLACE(CAST(COALESCE([sql_command],[sql_text]) AS VARCHAR(MAX)),char(13),''),CHAR(10),''),'<?query --',''),'--?>','')
83
+ FROM [DBA].[dbo].WhoIsActive_ResultSets AS r
84
+ WHERE r.collection_Time = @p_collection_time
85
+ )
86
+ SELECT SPID, BLOCKED,
87
+ [BATCH] = CASE WHEN LEFT([BATCH],1) = '(' THEN SUBSTRING([BATCH],CHARINDEX('exec',[BATCH]),LEN([BATCH])) ELSE [BATCH] END
88
+ INTO #T
89
+ FROM t_processes;
90
+
91
+ ;WITH BLOCKERS (SPID, BLOCKED, LEVEL, BATCH) AS
92
+ (
93
+ SELECT SPID,
94
+ BLOCKED,
95
+ [LEVEL] = CAST (REPLICATE ('0', 4-LEN (CAST (SPID AS VARCHAR))) + CAST (SPID AS VARCHAR) AS VARCHAR (1000)),
96
+ BATCH
97
+ FROM #T R
98
+ WHERE (BLOCKED = 0 OR BLOCKED = SPID)
99
+ AND EXISTS (SELECT * FROM #T R2 WHERE R2.BLOCKED = R.SPID AND R2.BLOCKED <> R2.SPID)
100
+ --
101
+ UNION ALL
102
+ --
103
+ SELECT R.SPID,
104
+ R.BLOCKED,
105
+ CAST (BLOCKERS.LEVEL + RIGHT (CAST ((1000 + R.SPID) AS VARCHAR (100)), 4) AS VARCHAR (1000)) AS LEVEL,
106
+ R.BATCH
107
+ FROM #T AS R
108
+ INNER JOIN BLOCKERS
109
+ ON R.BLOCKED = BLOCKERS.SPID
110
+ WHERE R.BLOCKED > 0 AND R.BLOCKED <> R.SPID
111
+ )
112
+ SELECT [BLOCKING_TREE] = N' ' + REPLICATE (N'| ', LEN (LEVEL)/4 - 1)
113
+ + CASE WHEN (LEN(LEVEL)/4 - 1) = 0
114
+ THEN 'HEAD - '
115
+ ELSE '|------ '
116
+ END
117
+ + CAST (SPID AS NVARCHAR (10)) + N' ' + BATCH
118
+ FROM BLOCKERS ORDER BY LEVEL ASC;
119
+ */
0 commit comments