-
Notifications
You must be signed in to change notification settings - Fork 0
/
Monitor Sessoes 2008 e anterior.sql
104 lines (104 loc) · 5.5 KB
/
Monitor Sessoes 2008 e anterior.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
SELECT
RIGHT('00' + CAST(DATEDIFF(SECOND, COALESCE(B.start_time, A.login_time), GETDATE()) / 86400 AS VARCHAR), 2) + ' ' +
RIGHT('00' + CAST((DATEDIFF(SECOND, COALESCE(B.start_time, A.login_time), GETDATE()) / 3600) % 24 AS VARCHAR), 2) + ':' +
RIGHT('00' + CAST((DATEDIFF(SECOND, COALESCE(B.start_time, A.login_time), GETDATE()) / 60) % 60 AS VARCHAR), 2) + ':' +
RIGHT('00' + CAST(DATEDIFF(SECOND, COALESCE(B.start_time, A.login_time), GETDATE()) % 60 AS VARCHAR), 2) + '.' +
RIGHT('000' + CAST(DATEDIFF(SECOND, COALESCE(B.start_time, A.login_time), GETDATE()) AS VARCHAR), 3)
AS Duration,
A.session_id AS session_id,
B.command,
CAST('<?query --' + CHAR(10) + (
SELECT TOP 1 SUBSTRING(X.[text], B.statement_start_offset / 2 + 1, ((CASE
WHEN B.statement_end_offset = -1 THEN (LEN(CONVERT(NVARCHAR(MAX), X.[text])) * 2)
ELSE B.statement_end_offset
END
) - B.statement_start_offset
) / 2 + 1
)
) + CHAR(10) + '--?>' AS XML) AS sql_text,
CAST('<?query --' + CHAR(10) + X.[text] + CHAR(10) + '--?>' AS XML) AS sql_command,
A.login_name,
'(' + CAST(COALESCE(E.wait_duration_ms, B.wait_time) AS VARCHAR(20)) + 'ms)' + COALESCE(E.wait_type, B.wait_type) + COALESCE((CASE
WHEN COALESCE(E.wait_type, B.wait_type) LIKE 'PAGEIOLATCH%' THEN ':' + DB_NAME(LEFT(E.resource_description, CHARINDEX(':', E.resource_description) - 1)) + ':' + SUBSTRING(E.resource_description, CHARINDEX(':', E.resource_description) + 1, 999)
WHEN COALESCE(E.wait_type, B.wait_type) = 'OLEDB' THEN '[' + REPLACE(REPLACE(E.resource_description, ' (SPID=', ':'), ')', '') + ']'
ELSE ''
END), '') AS wait_info,
COALESCE(B.cpu_time, 0) AS CPU,
COALESCE(F.tempdb_allocations, 0) AS tempdb_allocations,
COALESCE((CASE WHEN F.tempdb_allocations > F.tempdb_current THEN F.tempdb_allocations - F.tempdb_current ELSE 0 END), 0) AS tempdb_current,
COALESCE(B.logical_reads, 0) AS reads,
COALESCE(B.writes, 0) AS writes,
COALESCE(B.reads, 0) AS physical_reads,
COALESCE(B.granted_query_memory, 0) AS used_memory,
NULLIF(B.blocking_session_id, 0) AS blocking_session_id,
COALESCE(G.blocked_session_count, 0) AS blocked_session_count,
'KILL ' + CAST(A.session_id AS VARCHAR(10)) AS kill_command,
(CASE
WHEN B.[deadlock_priority] <= -5 THEN 'Low'
WHEN B.[deadlock_priority] > -5 AND B.[deadlock_priority] < 5 AND B.[deadlock_priority] < 5 THEN 'Normal'
WHEN B.[deadlock_priority] >= 5 THEN 'High'
END) + ' (' + CAST(B.[deadlock_priority] AS VARCHAR(3)) + ')' AS [deadlock_priority],
B.row_count,
B.open_transaction_count,
(CASE B.transaction_isolation_level
WHEN 0 THEN 'Unspecified'
WHEN 1 THEN 'ReadUncommitted'
WHEN 2 THEN 'ReadCommitted'
WHEN 3 THEN 'Repeatable'
WHEN 4 THEN 'Serializable'
WHEN 5 THEN 'Snapshot'
END) AS transaction_isolation_level,
A.[status],
NULLIF(B.percent_complete, 0) AS percent_complete,
A.[host_name],
COALESCE(DB_NAME(CAST(B.database_id AS VARCHAR)), 'master') AS [database_name],
A.[program_name],
H.[name] AS resource_governor_group,
COALESCE(B.start_time, A.last_request_end_time) AS start_time,
A.login_time,
COALESCE(B.request_id, 0) AS request_id,
W.query_plan
FROM
sys.dm_exec_sessions AS A WITH (NOLOCK)
LEFT JOIN sys.dm_exec_requests AS B WITH (NOLOCK) ON A.session_id = B.session_id
JOIN sys.dm_exec_connections AS C WITH (NOLOCK) ON A.session_id = C.session_id AND A.endpoint_id = C.endpoint_id
LEFT JOIN (
SELECT
session_id,
wait_type,
wait_duration_ms,
resource_description,
ROW_NUMBER() OVER(PARTITION BY session_id ORDER BY (CASE WHEN wait_type LIKE 'PAGEIO%' THEN 0 ELSE 1 END), wait_duration_ms) AS Ranking
FROM
sys.dm_os_waiting_tasks
) E ON A.session_id = E.session_id AND E.Ranking = 1
LEFT JOIN (
SELECT
session_id,
request_id,
SUM(internal_objects_alloc_page_count + user_objects_alloc_page_count) AS tempdb_allocations,
SUM(internal_objects_dealloc_page_count + user_objects_dealloc_page_count) AS tempdb_current
FROM
sys.dm_db_task_space_usage
GROUP BY
session_id,
request_id
) F ON B.session_id = F.session_id AND B.request_id = F.request_id
LEFT JOIN (
SELECT
blocking_session_id,
COUNT(*) AS blocked_session_count
FROM
sys.dm_exec_requests
WHERE
blocking_session_id != 0
GROUP BY
blocking_session_id
) G ON A.session_id = G.blocking_session_id
OUTER APPLY sys.dm_exec_sql_text(COALESCE(B.[sql_handle], C.most_recent_sql_handle)) AS X
OUTER APPLY sys.dm_exec_query_plan(B.[plan_handle]) AS W
LEFT JOIN sys.dm_resource_governor_workload_groups H ON A.group_id = H.group_id
WHERE
A.session_id > 50
AND A.session_id <> @@SPID
AND (A.[status] != 'sleeping' OR (A.[status] = 'sleeping' AND B.open_transaction_count > 0))