Updated Alarms

This commit is contained in:
gigi.mamaladze 2025-10-24 02:07:54 +04:00
parent ac83fcc74b
commit bc5bc841b9
4 changed files with 356 additions and 515 deletions

View File

@ -1,13 +1,11 @@
-- GetActiveAlarms: Returns all currently active (uncleared) alarms /*+ MAX_EXECUTION_TIME(8000) */
-- Uses: idx_alarm_events_active, idx_alarm_events_clear, idx_alarm_event_data_lookup
-- Expected performance: <200ms on 37K rows, <500ms on 1M+ rows
-- Param: :priorityList (comma-separated priority numbers, or empty string for all)
SELECT SELECT
ae.id AS ID, ae.id AS ID,
ae.eventtime AS StartTimestamp, ae.eventtime AS StartTimestamp,
TIME_FORMAT(SEC_TO_TIME(TIMESTAMPDIFF(SECOND, ae.eventtime, NOW())), '%H:%i:%s') AS Duration, TIME_FORMAT(SEC_TO_TIME(TIMESTAMPDIFF(SECOND, ae.eventtime, NOW())), '%H:%i:%s') AS Duration,
CONCAT(REPLACE(ae.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(ae.source, ':/alm:', -1)) AS Description, CONCAT(REPLACE(ae.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(ae.source, ':/alm:', -1)) AS Description,
CASE ae.priority CASE ae.priority
WHEN 0 THEN 'Diagnostic' WHEN 0 THEN 'Diagnostic'
WHEN 1 THEN 'Low' WHEN 1 THEN 'Low'
@ -16,22 +14,55 @@ SELECT
WHEN 4 THEN 'Critical' WHEN 4 THEN 'Critical'
ELSE 'Unknown' ELSE 'Unknown'
END AS Priority, END AS Priority,
CONCAT(ae.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag, 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
WHEN SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) = 'Chute' THEN 'SMC'
ELSE SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
END AS Location,
CASE
WHEN ae.priority = 3 THEN 'Alarms-Styles/High'
WHEN ae.priority = 2 THEN 'Alarms-Styles/Medium'
WHEN ae.priority = 1 THEN 'Alarms-Styles/Low'
WHEN ae.priority = 0 THEN 'Alarms-Styles/Diagnostic'
ELSE 'Alarms-Styles/NoAlarm'
END AS Style,
aed.strValue AS FullTag, aed.strValue AS FullTag,
ae.displaypath AS Device ae.displaypath AS Device
FROM alarm_events ae FORCE INDEX (idx_alarm_events_active) FROM alarm_events ae FORCE INDEX (idx_alarm_events_active)
LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup) LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
ON aed.id = ae.id AND aed.propname = 'myTag' ON aed.id = ae.id AND aed.propname = 'myTag'
WHERE ae.eventtype = 0
WHERE
ae.eventtype = 0
AND ae.displaypath NOT LIKE '%System Startup%' AND ae.displaypath NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%' AND ae.source NOT LIKE '%System Startup%'
AND (:priorityList = '' OR FIND_IN_SET(CAST(ae.priority AS CHAR), :priorityList) > 0)
-- FORCE INDEX ensures idx_alarm_events_clear is used in subquery -- Priority filter (same logic as other queries)
AND (
:priority IS NULL OR :priority = '' OR :priority = 0
OR (:priority = 3 AND ae.priority = 3)
OR (:priority = 2 AND ae.priority BETWEEN 2 AND 3)
OR (:priority = 1 AND ae.priority BETWEEN 1 AND 3)
)
-- Location filter
AND (
:location IS NULL OR :location = ''
OR SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
LIKE CONCAT('%', :location, '%')
)
-- Exclude cleared alarms
AND NOT EXISTS ( AND NOT EXISTS (
SELECT 1 SELECT 1
FROM alarm_events clr FORCE INDEX (idx_alarm_events_clear) FROM alarm_events clr FORCE INDEX (idx_alarm_events_clear)
WHERE clr.eventid = ae.eventid WHERE clr.eventid = ae.eventid
AND clr.eventtype = 1 AND clr.eventtype = 1
) )
ORDER BY ae.eventtime DESC;
ORDER BY ae.eventtime DESC;

View File

@ -1,9 +1,3 @@
-- 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) */ /*+ MAX_EXECUTION_TIME(8000) */
SELECT SELECT
@ -15,6 +9,7 @@ SELECT
'%H:%i:%s' '%H:%i:%s'
) AS Duration, ) AS Duration,
CONCAT(REPLACE(a.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(a.source, ':/alm:', -1)) AS Description, CONCAT(REPLACE(a.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(a.source, ':/alm:', -1)) AS Description,
CASE a.priority CASE a.priority
WHEN 0 THEN 'Diagnostic' WHEN 0 THEN 'Diagnostic'
WHEN 1 THEN 'Low' WHEN 1 THEN 'Low'
@ -23,13 +18,27 @@ SELECT
WHEN 4 THEN 'Critical' WHEN 4 THEN 'Critical'
ELSE 'Unknown' ELSE 'Unknown'
END AS Priority, END AS Priority,
CONCAT(a.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag, CONCAT(a.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag,
SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) AS Location,
CASE
WHEN SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) = 'Chute' THEN 'SMC'
ELSE SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
END AS Location,
CASE
WHEN a.priority = 3 THEN 'Alarms-Styles/High'
WHEN a.priority = 2 THEN 'Alarms-Styles/Medium'
WHEN a.priority = 1 THEN 'Alarms-Styles/Low'
WHEN a.priority = 0 THEN 'Alarms-Styles/Diagnostic'
ELSE 'Alarms-Styles/NoAlarm'
END AS Style,
aed.strValue AS FullTag, aed.strValue AS FullTag,
a.displaypath AS Device a.displaypath AS Device
FROM alarm_events a FORCE INDEX (idx_alarm_events_type_time_id) FROM alarm_events a FORCE INDEX (idx_alarm_events_type_time_id)
LEFT JOIN ( LEFT JOIN (
-- Find first clear time for each alarm
SELECT eventid, MIN(eventtime) AS min_clear_time SELECT eventid, MIN(eventtime) AS min_clear_time
FROM alarm_events FORCE INDEX (idx_alarm_events_clear) FROM alarm_events FORCE INDEX (idx_alarm_events_clear)
WHERE eventtype = 1 WHERE eventtype = 1
@ -39,17 +48,15 @@ LEFT JOIN (
) clr ON clr.eventid = a.eventid AND clr.min_clear_time >= a.eventtime ) 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) LEFT JOIN alarm_event_data aed FORCE INDEX (idx_alarm_event_data_lookup)
ON aed.id = a.id AND aed.propname = 'myTag' ON aed.id = a.id AND aed.propname = 'myTag'
WHERE WHERE
a.eventtype = 0 a.eventtype = 0
AND a.displaypath NOT LIKE '%System Startup%' AND a.displaypath NOT LIKE '%System Startup%'
AND a.source 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 -- Smart time filtering
-- If endtime is in the past, only get alarms that started in the window
AND ( AND (
-- Historical alarms: started in the time window
(a.eventtime >= :starttime AND a.eventtime < :endtime) (a.eventtime >= :starttime AND a.eventtime < :endtime)
-- OR Live mode: ALL active alarms if endtime is within 5 mins of NOW
OR ( OR (
:endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE) :endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE)
AND NOT EXISTS ( AND NOT EXISTS (
@ -59,13 +66,28 @@ WHERE
) )
) )
) )
-- Final filter: Cleared alarms must have cleared in window
AND ( AND (
clr.min_clear_time IS NOT NULL -- Cleared alarms in window clr.min_clear_time IS NOT NULL
OR :endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE) -- Active alarms if endtime is recent OR :endtime >= DATE_SUB(NOW(), INTERVAL 5 MINUTE)
)
-- Priority filter
AND (
:priority IS NULL OR :priority = '' OR :priority = 0
OR (:priority = 3 AND a.priority = 3)
OR (:priority = 2 AND a.priority BETWEEN 2 AND 3)
OR (:priority = 1 AND a.priority BETWEEN 1 AND 3)
)
-- Location filter
AND (
:location IS NULL OR :location = ''
OR SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
LIKE CONCAT('%', :location, '%')
) )
ORDER BY ORDER BY
CASE WHEN clr.min_clear_time IS NULL THEN 0 ELSE 1 END, CASE WHEN clr.min_clear_time IS NULL THEN 0 ELSE 1 END,
IFNULL(clr.min_clear_time, a.eventtime) DESC, IFNULL(clr.min_clear_time, a.eventtime) DESC,
a.id DESC; a.id DESC;

View File

@ -1,12 +1,6 @@
-- 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) */ /*+ MAX_EXECUTION_TIME(8000) */
WITH ClearedEvents AS ( WITH ClearedEvents AS (
-- Pre-aggregate clear times - FORCED index usage for speed
SELECT SELECT
eventid, eventid,
MIN(eventtime) AS clear_time MIN(eventtime) AS clear_time
@ -20,7 +14,10 @@ SELECT
CONCAT(ae.displaypath, '.HMI.Alarm.', SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', -1)) AS Tag, 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
WHEN SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) = 'Chute' THEN 'SMC'
ELSE SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1)
END AS Location,
CASE ae.priority CASE ae.priority
WHEN 0 THEN 'Diagnostic' WHEN 0 THEN 'Diagnostic'
@ -30,8 +27,15 @@ SELECT
WHEN 4 THEN 'Critical' WHEN 4 THEN 'Critical'
ELSE 'Unknown' ELSE 'Unknown'
END AS Priority, END AS Priority,
CASE
WHEN ae.priority = 3 THEN 'Alarms-Styles/High'
WHEN ae.priority = 2 THEN 'Alarms-Styles/Medium'
WHEN ae.priority = 1 THEN 'Alarms-Styles/Low'
WHEN ae.priority = 0 THEN 'Alarms-Styles/Diagnostic'
ELSE 'Alarms-Styles/NoAlarm'
END AS Style,
-- First/Last timestamps (clipped to window if provided)
MIN( MIN(
GREATEST( GREATEST(
ae.eventtime, ae.eventtime,
@ -46,7 +50,6 @@ SELECT
) )
) AS LastTimestamp, ) AS LastTimestamp,
-- Duration within window (formatted as HH:MM:SS string)
TIME_FORMAT( TIME_FORMAT(
SEC_TO_TIME( SEC_TO_TIME(
SUM( SUM(
@ -55,7 +58,7 @@ SELECT
SECOND, SECOND,
GREATEST(ae.eventtime, IFNULL(NULLIF(:startTime, ''), ae.eventtime)), GREATEST(ae.eventtime, IFNULL(NULLIF(:startTime, ''), ae.eventtime)),
LEAST(IFNULL(clr.clear_time, NOW()), LEAST(IFNULL(clr.clear_time, NOW()),
IFNULL(NULLIF(:endTime, ''), IFNULL(clr.clear_time, NOW()))) IFNULL(NULLIF(:endTime, ''), IFNULL(clr.clear_time, NOW())) )
), ),
0 0
) )
@ -64,9 +67,7 @@ SELECT
'%H:%i:%s' '%H:%i:%s'
) AS Duration, ) AS Duration,
-- Activation count: how many times alarm triggered in the window
COUNT(*) AS "Count", COUNT(*) AS "Count",
aed.strValue AS FullTag, aed.strValue AS FullTag,
ae.displaypath AS Device ae.displaypath AS Device
@ -80,11 +81,22 @@ WHERE
ae.eventtype = 0 ae.eventtype = 0
AND ae.displaypath NOT LIKE '%System Startup%' AND ae.displaypath NOT LIKE '%System Startup%'
AND ae.source NOT LIKE '%System Startup%' AND ae.source NOT LIKE '%System Startup%'
-- Time window filter: FORCE INDEX ensures fast range scan
AND ( AND (
(:startTime IS NULL OR :startTime = '' OR ae.eventtime >= :startTime) (:startTime IS NULL OR :startTime = '' OR ae.eventtime >= :startTime)
AND AND
(:endTime IS NULL OR :endTime = '' OR ae.eventtime <= :endTime) (:endTime IS NULL OR :endTime = '' OR ae.eventtime <= :endTime)
)
-- Priority filter
AND (
:priority IS NULL OR :priority = '' OR :priority = 0
OR (:priority = 3 AND ae.priority = 3)
OR (:priority = 2 AND ae.priority BETWEEN 2 AND 3)
OR (:priority = 1 AND ae.priority BETWEEN 1 AND 3)
)
-- Location filter (matches if string found anywhere)
AND (
:location IS NULL OR :location = ''
OR SUBSTRING_INDEX(SUBSTRING_INDEX(IFNULL(aed.strValue, ''), '/', 2), '/', -1) LIKE CONCAT('%', :location, '%')
) )
GROUP BY GROUP BY
@ -95,4 +107,4 @@ GROUP BY
ORDER BY ORDER BY
FirstTimestamp DESC, FirstTimestamp DESC,
MIN(ae.id) DESC; MIN(ae.id) DESC;