forked from vitortff/DBAToolKit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathSystemHealth_ErrorReported_Count.sql
56 lines (50 loc) · 1.83 KB
/
SystemHealth_ErrorReported_Count.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
SET NOCOUNT ON
-- Store the XML data in a temporary table
SELECT CAST(xet.target_data as xml) as XMLDATA
INTO #SystemHealthSessionData
FROM sys.dm_xe_session_targets xet
JOIN sys.dm_xe_sessions xe
ON (xe.address = xet.event_session_address)
WHERE xe.name = 'system_health'
-- Get statistical information about all the errors reported
;WITH CTE_HealthSession (EventXML) AS
(
SELECT C.query('.') EventXML
FROM #SystemHealthSessionData a
CROSS APPLY a.XMLDATA.nodes('/RingBufferTarget/event') as T(C)
),
CTE_ErrorReported (EventTime, ErrorNum) AS
(
SELECT EventXML.value('(/event/@timestamp)[1]', 'datetime') as EventTime,
EventXML.value('(/event/data/value)[1]', 'int') as ErrorNum
FROM CTE_HealthSession
WHERE EventXML.value('(/event/@name)[1]', 'varchar(255)') = 'error_reported'
)
SELECT ErrorNum,
MAX(EventTime) as LastRecordedEvent,
MIN(EventTime) as FirstRecordedEvent,
COUNT(*) as Occurrences,
b.[text] as ErrDescription
FROM CTE_ErrorReported a
INNER JOIN sys.messages b
ON a.ErrorNum = b.message_id
WHERE b.language_id = SERVERPROPERTY('LCID')
GROUP BY a.ErrorNum,b.[text]
-- Get information about each of the errors reported
;WITH CTE_HealthSession (EventXML) AS
(
SELECT C.query('.') EventXML
FROM #SystemHealthSessionData a
CROSS APPLY a.XMLDATA.nodes('/RingBufferTarget/event') as T(C)
WHERE C.query('.').value('(/event/@name)[1]', 'varchar(255)') = 'error_reported'
)
SELECT
EventXML.value('(/event/@timestamp)[1]', 'datetime') as EventTime,
EventXML.value('(/event/data/value)[1]', 'int') as ErrNum,
EventXML.value('(/event/data/value)[2]', 'int') as ErrSeverity,
EventXML.value('(/event/data/value)[3]', 'int') as ErrState,
EventXML.value('(/event/data/value)[5]', 'varchar(max)') as ErrText,
EventXML.value('(/event/action/value)[2]', 'varchar(10)') as Session_ID
FROM CTE_HealthSession
-- Drop the temporary table
DROP TABLE #SystemHealthSessionData