59 lines
1.9 KiB
SQL
59 lines
1.9 KiB
SQL
/*+ MAX_EXECUTION_TIME(8000) */
|
|
|
|
WITH ranked_clears AS (
|
|
SELECT
|
|
eventid,
|
|
eventtime,
|
|
ROW_NUMBER() OVER (PARTITION BY eventid ORDER BY eventtime) AS rn
|
|
FROM alarm_events
|
|
WHERE eventtype = 1
|
|
),
|
|
base_alarms AS (
|
|
SELECT
|
|
a.id,
|
|
a.eventtime,
|
|
a.eventid,
|
|
a.displaypath,
|
|
a.source,
|
|
a.priority,
|
|
aed.strValue as tag_value
|
|
FROM alarm_events a
|
|
LEFT JOIN alarm_event_data aed ON aed.id = a.id AND aed.propname = 'myTag'
|
|
WHERE
|
|
a.eventtype = 0
|
|
AND a.displaypath NOT LIKE '%System Startup%'
|
|
AND a.source NOT LIKE '%System Startup%'
|
|
)
|
|
SELECT
|
|
b.id AS ID,
|
|
b.eventtime AS StartTimestamp,
|
|
rc.eventtime AS EndTimestamp,
|
|
CONCAT(
|
|
LPAD(FLOOR(TIMESTAMPDIFF(SECOND, b.eventtime, COALESCE(rc.eventtime, NOW())) / 3600), 2, '0'), ':',
|
|
LPAD(FLOOR((TIMESTAMPDIFF(SECOND, b.eventtime, COALESCE(rc.eventtime, NOW())) % 3600) / 60), 2, '0'), ':',
|
|
LPAD((TIMESTAMPDIFF(SECOND, b.eventtime, COALESCE(rc.eventtime, NOW())) % 60), 2, '0')
|
|
) AS Duration,
|
|
CONCAT(REPLACE(b.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(b.source, ':/alm:', -1)) AS Description,
|
|
CASE b.priority
|
|
WHEN 0 THEN 'Diagnostic'
|
|
WHEN 1 THEN 'Low'
|
|
WHEN 2 THEN 'Medium'
|
|
WHEN 3 THEN 'High'
|
|
WHEN 4 THEN 'Critical'
|
|
ELSE 'Unknown'
|
|
END AS Priority,
|
|
SUBSTRING_INDEX(SUBSTRING_INDEX(b.tag_value, '/', 2), '/', -1) AS Location,
|
|
COALESCE(b.tag_value, SUBSTRING_INDEX(b.source, ':/tag:', -1)) AS Tag,
|
|
COALESCE(b.tag_value, b.source) AS FullTag,
|
|
b.displaypath AS Device
|
|
FROM base_alarms b
|
|
LEFT JOIN ranked_clears rc ON rc.eventid = b.eventid AND rc.rn = 1 AND rc.eventtime >= b.eventtime
|
|
WHERE
|
|
(
|
|
(b.eventtime >= :starttime AND b.eventtime < :endtime)
|
|
OR (b.eventtime < :starttime AND (rc.eventtime IS NULL OR rc.eventtime >= :starttime))
|
|
)
|
|
ORDER BY
|
|
CASE WHEN rc.eventtime IS NULL THEN 0 ELSE 1 END,
|
|
COALESCE(rc.eventtime, b.eventtime) DESC,
|
|
b.id DESC; |