94 lines
2.7 KiB
SQL
94 lines
2.7 KiB
SQL
/*+ MAX_EXECUTION_TIME(8000) */
|
|
|
|
SELECT
|
|
a.id AS ID,
|
|
a.eventtime AS StartTimestamp,
|
|
clr.min_clear_time AS EndTimestamp,
|
|
TIME_FORMAT(
|
|
SEC_TO_TIME(TIMESTAMPDIFF(SECOND, a.eventtime, IFNULL(clr.min_clear_time, NOW()))),
|
|
'%H:%i:%s'
|
|
) AS Duration,
|
|
CONCAT(REPLACE(a.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(a.source, ':/alm:', -1)) AS Description,
|
|
|
|
CASE a.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,
|
|
|
|
CONCAT(a.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag,
|
|
|
|
CASE
|
|
WHEN SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) = 'Chute' THEN 'SMC'
|
|
ELSE SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
|
|
END AS Location,
|
|
|
|
CASE
|
|
WHEN a.priority = 3 THEN 'Alarms-Styles/High'
|
|
WHEN a.priority = 2 THEN 'Alarms-Styles/Medium'
|
|
WHEN a.priority = 1 THEN 'Alarms-Styles/Low'
|
|
WHEN a.priority = 0 THEN 'Alarms-Styles/Diagnostic'
|
|
ELSE 'Alarms-Styles/NoAlarm'
|
|
END AS Style,
|
|
|
|
aed.strValue AS FullTag,
|
|
a.displaypath AS Device
|
|
|
|
FROM alarm_events a FORCE INDEX (idx_alarm_events_type_time_id)
|
|
LEFT JOIN (
|
|
SELECT eventid, MIN(eventtime) AS min_clear_time
|
|
FROM alarm_events FORCE INDEX (idx_alarm_events_clear)
|
|
WHERE eventtype = 1
|
|
AND eventtime >= :starttime
|
|
AND eventtime < :endtime
|
|
GROUP BY eventid
|
|
) clr ON clr.eventid = a.eventid AND clr.min_clear_time >= a.eventtime
|
|
LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
|
|
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%'
|
|
|
|
-- Smart time filtering
|
|
AND (
|
|
(a.eventtime >= :starttime AND a.eventtime < :endtime)
|
|
OR (
|
|
:endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE)
|
|
AND NOT EXISTS (
|
|
SELECT 1
|
|
FROM alarm_events clr2 FORCE INDEX (idx_alarm_events_clear)
|
|
WHERE clr2.eventid = a.eventid AND clr2.eventtype = 1
|
|
)
|
|
)
|
|
)
|
|
|
|
AND (
|
|
clr.min_clear_time IS NOT NULL
|
|
OR :endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE)
|
|
)
|
|
|
|
-- Priority filter
|
|
AND (
|
|
:priority IS NULL OR :priority = '' OR :priority = 0
|
|
OR (:priority = 3 AND a.priority = 3)
|
|
OR (:priority = 2 AND a.priority BETWEEN 2 AND 3)
|
|
OR (:priority = 1 AND a.priority BETWEEN 1 AND 3)
|
|
)
|
|
|
|
-- Location filter
|
|
AND (
|
|
:location IS NULL OR :location = ''
|
|
OR SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
|
|
LIKE CONCAT('%', :location, '%')
|
|
)
|
|
|
|
ORDER BY
|
|
CASE WHEN clr.min_clear_time IS NULL THEN 0 ELSE 1 END,
|
|
IFNULL(clr.min_clear_time, a.eventtime) DESC,
|
|
a.id DESC;
|