64 lines
1.7 KiB
SQL
64 lines
1.7 KiB
SQL
SELECT
|
|
CONCAT(Active.displaypath, ' - ', SUBSTRING_INDEX(Active.source, ':/alm:', -1)) AS Description,
|
|
|
|
SUBSTRING_INDEX(SUBSTRING_INDEX(aed.strValue, '/', 2), '/', -1) AS Location,
|
|
|
|
CONCAT(
|
|
Active.displaypath,
|
|
'.HMI.',
|
|
SUBSTRING_INDEX(aed.strValue, '/', -1)
|
|
) AS Tag,
|
|
|
|
CASE Active.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 and last seen times for this alarm
|
|
MIN(Active.eventtime) AS FirstTimestamp,
|
|
MAX(Active.eventtime) AS LastTimestamp,
|
|
|
|
-- Total duration summed from each active-clear pair
|
|
CONCAT(
|
|
LPAD(FLOOR(SUM(Active.duration_seconds) / 3600), 2, '0'), ':',
|
|
LPAD(FLOOR((SUM(Active.duration_seconds) % 3600) / 60), 2, '0'), ':',
|
|
LPAD(SUM(Active.duration_seconds) % 60, 2, '0')
|
|
) AS Duration,
|
|
|
|
-- Total number of activations
|
|
COUNT(*) AS Count,
|
|
|
|
-- Newly added columns
|
|
aed.strValue AS FullTag,
|
|
Active.displaypath AS Device
|
|
|
|
FROM (
|
|
SELECT
|
|
ae.id,
|
|
ae.source,
|
|
ae.eventid,
|
|
ae.eventtime,
|
|
ae.priority,
|
|
ae.displaypath,
|
|
TIMESTAMPDIFF(SECOND, ae.eventtime, COALESCE(ae_clear.eventtime, NOW())) AS duration_seconds
|
|
FROM alarm_events ae
|
|
LEFT JOIN alarm_events ae_clear
|
|
ON ae.eventid = ae_clear.eventid AND ae_clear.eventtype = 1
|
|
WHERE ae.eventtype = 0
|
|
AND ae.displaypath NOT LIKE '%System Startup%'
|
|
AND ae.source NOT LIKE '%System Startup%'
|
|
) AS Active
|
|
|
|
-- OPC tag path for building .hmi.Tag output
|
|
LEFT JOIN alarm_event_data aed
|
|
ON aed.id = Active.id AND aed.propname = 'myTag'
|
|
|
|
-- 🔹 Group by the full unique alarm key (tag + alarm name)
|
|
GROUP BY Active.source, Active.displaypath, aed.strValue
|
|
|
|
ORDER BY FirstTimestamp DESC;
|