2025-10-11 19:11:04 +04:00

94 lines
3.4 KiB
SQL

-- Params (can be NULL or empty string '')
-- :startTime DATETIME or NULL
-- :endTime DATETIME or NULL
SELECT
CONCAT(COALESCE(ae.displaypath,'Unknown'), ' - ',
SUBSTRING_INDEX(COALESCE(ae.source,''), ':/alm:', -1)) AS Description,
SUBSTRING_INDEX(SUBSTRING_INDEX(COALESCE(aed.strValue,''), '/', 2), '/', -1) AS Location,
CONCAT(COALESCE(ae.displaypath,'Unknown'), '.HMI.',
SUBSTRING_INDEX(COALESCE(aed.strValue,''),'/',-1)) AS Tag,
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 if a window is provided)
MIN(
CASE
WHEN NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL
THEN ae.eventtime
ELSE GREATEST(ae.eventtime, COALESCE(NULLIF(:startTime,''), ae.eventtime))
END
) AS FirstTimestamp,
MAX(
CASE
WHEN NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL
THEN COALESCE(clr.clear_time, NOW())
ELSE LEAST(COALESCE(clr.clear_time, NOW()),
COALESCE(NULLIF(:endTime,''), COALESCE(clr.clear_time, NOW())))
END
) AS LastTimestamp,
-- Duration within window (full if no window)
DATE_FORMAT(
SEC_TO_TIME(
SUM(
CASE
WHEN NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL
THEN TIMESTAMPDIFF(SECOND, ae.eventtime, COALESCE(clr.clear_time, NOW()))
ELSE GREATEST(
TIMESTAMPDIFF(
SECOND,
GREATEST(ae.eventtime, COALESCE(NULLIF(:startTime,''), ae.eventtime)),
LEAST(COALESCE(clr.clear_time, NOW()),
COALESCE(NULLIF(:endTime,''), COALESCE(clr.clear_time, NOW())))
),
0
)
END
)
),
'%H:%i:%s'
) AS Duration,
-- This is the key metric: how many times it was jammed (activations started in window)
CAST(COUNT(*) AS SIGNED) AS ActivationCount,
aed.strValue AS FullTag,
ae.displaypath AS Device
FROM alarm_events ae
LEFT JOIN (
-- earliest clear per event
SELECT eventid, MIN(eventtime) AS clear_time
FROM alarm_events
WHERE eventtype = 1
GROUP BY eventid
) clr ON clr.eventid = ae.eventid
LEFT JOIN alarm_event_data aed
ON aed.id = ae.id AND aed.propname = 'myTag'
WHERE ae.eventtype = 0
AND COALESCE(ae.displaypath,'') NOT LIKE '%System Startup%'
AND COALESCE(ae.source,'') NOT LIKE '%System Startup%'
-- Only filter by time if a bound is provided; we count activations STARTED in the window
AND (
(NULLIF(:startTime,'') IS NULL AND NULLIF(:endTime,'') IS NULL)
OR (
ae.eventtime >= COALESCE(NULLIF(:startTime,''), ae.eventtime)
AND ae.eventtime <= COALESCE(NULLIF(:endTime,''), ae.eventtime)
)
)
GROUP BY
ae.source, ae.displaypath, aed.strValue
ORDER BY
FirstTimestamp DESC, MIN(ae.id) DESC;