98 lines
2.7 KiB
SQL
98 lines
2.7 KiB
SQL
-- GetAlarmsWithCount: Alarm statistics with activation counts for a time window
|
|
-- Uses: idx_alarm_events_type_time_id, idx_alarm_events_clear, idx_alarm_event_data_lookup
|
|
-- Expected performance: <300ms on 37K rows, <800ms on 1M+ rows
|
|
-- Params: :startTime (DATETIME or NULL/empty), :endTime (DATETIME or NULL/empty)
|
|
|
|
/*+ MAX_EXECUTION_TIME(8000) */
|
|
|
|
WITH ClearedEvents AS (
|
|
-- Pre-aggregate clear times - FORCED index usage for speed
|
|
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,
|
|
|
|
SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) 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,
|
|
|
|
-- First/Last timestamps (clipped to window if provided)
|
|
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,
|
|
|
|
-- Duration within window (formatted as HH:MM:SS string)
|
|
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,
|
|
|
|
-- Activation count: how many times alarm triggered in the window
|
|
COUNT(*) AS ActivationCount,
|
|
|
|
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%'
|
|
-- Time window filter: FORCE INDEX ensures fast range scan
|
|
AND (
|
|
(:startTime IS NULL OR :startTime = '' OR ae.eventtime >= :startTime)
|
|
AND
|
|
(:endTime IS NULL OR :endTime = '' OR ae.eventtime <= :endTime)
|
|
)
|
|
|
|
GROUP BY
|
|
ae.source,
|
|
ae.displaypath,
|
|
ae.priority,
|
|
aed.strValue
|
|
|
|
ORDER BY
|
|
FirstTimestamp DESC,
|
|
MIN(ae.id) DESC; |