/*+ MAX_EXECUTION_TIME(8000) */ WITH ClearedEvents AS ( SELECT eventid, MIN(eventtime) AS clear_time FROM alarm_events FORCE INDEX (idx_alarm_events_clear) WHERE eventtype = 1 GROUP BY eventid ) SELECT CONCAT(IFNULL(ae.displaypath, 'Unknown'), ' - ', SUBSTRING_INDEX(IFNULL(ae.source, ''), ':/alm:', -1)) AS Description, CONCAT(ae.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 ae.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, CASE WHEN ae.priority = 3 THEN 'Alarms-Styles/High' WHEN ae.priority = 2 THEN 'Alarms-Styles/Medium' WHEN ae.priority = 1 THEN 'Alarms-Styles/Low' WHEN ae.priority = 0 THEN 'Alarms-Styles/Diagnostic' ELSE 'Alarms-Styles/NoAlarm' END AS Style, MIN( GREATEST( ae.eventtime, IFNULL(NULLIF(:startTime, ''), ae.eventtime) ) ) AS FirstTimestamp, MAX( LEAST( IFNULL(clr.clear_time, NOW()), IFNULL(NULLIF(:endTime, ''), IFNULL(clr.clear_time, NOW())) ) ) AS LastTimestamp, TIME_FORMAT( SEC_TO_TIME( SUM( GREATEST( TIMESTAMPDIFF( SECOND, GREATEST(ae.eventtime, IFNULL(NULLIF(:startTime, ''), ae.eventtime)), LEAST(IFNULL(clr.clear_time, NOW()), IFNULL(NULLIF(:endTime, ''), IFNULL(clr.clear_time, NOW())) ) ), 0 ) ) ), '%H:%i:%s' ) AS Duration, COUNT(*) AS "Count", aed.strValue AS FullTag, ae.displaypath AS Device FROM alarm_events ae FORCE INDEX (idx_alarm_events_type_time_id) LEFT JOIN ClearedEvents clr ON clr.eventid = ae.eventid LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup) ON aed.id = ae.id AND aed.propname = 'myTag' WHERE ae.eventtype = 0 AND ae.displaypath NOT LIKE '%System Startup%' AND ae.source NOT LIKE '%System Startup%' AND ( (:startTime IS NULL OR :startTime = '' OR ae.eventtime >= :startTime) AND (:endTime IS NULL OR :endTime = '' OR ae.eventtime <= :endTime) ) -- Priority filter AND ( :priority IS NULL OR :priority = '' OR :priority = 0 OR (:priority = 3 AND ae.priority = 3) OR (:priority = 2 AND ae.priority BETWEEN 2 AND 3) OR (:priority = 1 AND ae.priority BETWEEN 1 AND 3) ) -- Location filter (matches if string found anywhere) AND ( :location IS NULL OR :location = '' OR SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) LIKE CONCAT('%', :location, '%') ) GROUP BY ae.source, ae.displaypath, ae.priority, aed.strValue ORDER BY FirstTimestamp DESC, MIN(ae.id) DESC;