72 lines
2.4 KiB
SQL

SELECT
a.id AS ID,
a.eventtime AS StartTimestamp,
clr.eventtime AS EndTimestamp,
-- Duration calculation (HH:MM:SS format)
CONCAT(
LPAD(FLOOR(TIMESTAMPDIFF(SECOND, a.eventtime, COALESCE(clr.eventtime, NOW())) / 3600), 2, '0'), ':',
LPAD(FLOOR((TIMESTAMPDIFF(SECOND, a.eventtime, COALESCE(clr.eventtime, NOW())) % 3600) / 60), 2, '0'), ':',
LPAD( (TIMESTAMPDIFF(SECOND, a.eventtime, COALESCE(clr.eventtime, NOW())) % 60) , 2, '0')
) AS Duration,
-- Description combining display path and alarm name
CONCAT(REPLACE(a.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(a.source, ':/alm:', -1)) AS Description,
-- Priority mapping
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,
-- Tag information
CONCAT(a.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(aed.strValue, '/', -1)) AS Tag,
SUBSTRING_INDEX(SUBSTRING_INDEX(aed.strValue, '/', 2), '/', -1) AS Location,
aed.strValue AS FullTag,
a.displaypath AS Device
FROM alarm_events a
-- Join to get the earliest clear event for each alarm
LEFT JOIN (
SELECT eventid, MIN(eventtime) AS eventtime
FROM alarm_events
WHERE eventtype = 1
GROUP BY eventid
) AS clr ON clr.eventid = a.eventid
-- Join to get additional tag data
LEFT JOIN (
SELECT id, strValue
FROM alarm_event_data
WHERE propname = 'myTag'
GROUP BY id
) AS aed ON aed.id = a.id
WHERE
-- Only active alarm events (not clear events)
a.eventtype = 0
-- Exclude system startup alarms
AND a.displaypath NOT LIKE '%System Startup%'
AND a.source NOT LIKE '%System Startup%'
-- Simple date filtering using named parameters
AND (
-- Case 1: Alarm was cleared within the specified time range
(clr.eventtime IS NOT NULL AND clr.eventtime >= :starttime AND clr.eventtime < :endtime)
OR
-- Case 2: Alarm is still active (no clear time) and started within or before the range
(clr.eventtime IS NULL AND a.eventtime < :endtime)
)
-- Order by end time (most recent clears first), active alarms (NULL) at top, then by ID
ORDER BY clr.eventtime IS NULL DESC, clr.eventtime DESC, a.id DESC
-- Pagination support (100 records per page)
LIMIT 100 OFFSET :offset;