-- GetAlarms: Alarms that ended (cleared) within the specified timeframe -- Shows active alarms ONLY if the timeframe includes current time -- MAXIMUM PERFORMANCE: Optimized for EndTimestamp filtering -- Expected performance: <500ms on 37K rows -- Params: :starttime (DATETIME), :endtime (DATETIME) /*+ 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, SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) AS Location, aed.strValue AS FullTag, a.displaypath AS Device FROM alarm_events a FORCE INDEX (idx_alarm_events_type_time_id) LEFT JOIN ( -- Find first clear time for each alarm 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: -- If endtime is near NOW (within 5 mins), get ALL active alarms + historical in window -- If endtime is in the past, only get alarms that started in the window AND ( -- Historical alarms: started in the time window (a.eventtime >= :starttime AND a.eventtime < :endtime) -- OR Live mode: ALL active alarms if endtime is within 5 mins of NOW 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 ) ) ) -- Final filter: Cleared alarms must have cleared in window AND ( clr.min_clear_time IS NOT NULL -- Cleared alarms in window OR :endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE) -- Active alarms if endtime is recent ) 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;