BNA8/.resources/e8236158501ac7f7c6b5a82cd4de043bb355173efa57d8a3347a6bf962024c9c

97 lines
3.0 KiB
Plaintext

/*+ MAX_EXECUTION_TIME(8000) */
-- Simple historical alarms query: get all alarms in time period
-- Filter by priority, location, and time range - that's it
SELECT
a.id AS ID,
a.eventtime AS StartTimestamp,
(SELECT MIN(clr.eventtime)
FROM alarm_events clr USE INDEX (idx_alarm_events_eventid)
WHERE clr.eventid = a.eventid
AND clr.eventtype IN (1, 2)
AND clr.id > a.id
) AS EndTimestamp,
TIME_FORMAT(SEC_TO_TIME(TIMESTAMPDIFF(SECOND, a.eventtime,
COALESCE(
(SELECT MIN(clr.eventtime)
FROM alarm_events clr USE INDEX (idx_alarm_events_eventid)
WHERE clr.eventid = a.eventid
AND clr.eventtype IN (1, 2)
AND clr.id > a.id
),
NOW()
)
)), '%H:%i:%s') AS Duration,
CONCAT(REPLACE(a.displaypath, '_', '-'), ' ', SUBSTRING_INDEX(a.source, ':/alm:', -1)) AS Description,
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,
IFNULL(tag.strValue, '') AS Tag,
-- Use myLocation property directly (99.96% coverage) - MUCH faster than parsing tags!
IFNULL(loc.strValue, '') 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
FROM alarm_events a FORCE INDEX (idx_alarm_events_type_time_id)
LEFT JOIN alarm_event_data tag FORCE INDEX (idx_alarm_event_data_lookup)
ON tag.id = a.id AND tag.propname = 'myTag'
LEFT JOIN alarm_event_data loc FORCE INDEX (idx_alarm_event_data_lookup)
ON loc.id = a.id AND loc.propname = 'myLocation'
WHERE
a.eventtype = 0
AND a.displaypath NOT LIKE '%System Startup%'
AND a.source NOT LIKE '%System Startup%'
AND a.displaypath NOT LIKE '%System Shutdown%'
AND a.source NOT LIKE '%System Shutdown%'
AND a.eventtime >= :starttime
AND a.eventtime < :endtime
-- Exclude active alarms: only show alarms that have been cleared
-- Check if a later clear/ack event exists for this eventid
AND EXISTS (
SELECT 1
FROM alarm_events clr USE INDEX (idx_alarm_events_eventid)
WHERE clr.eventid = a.eventid
AND clr.eventtype IN (1, 2)
AND clr.id > a.id
LIMIT 1
)
-- Priority filter: Only evaluate priority conditions when parameter is provided
AND (
:priority IS NULL OR :priority = '' OR :priority = 0
OR (
:priority IS NOT NULL AND :priority != '' AND :priority != 0 AND (
(: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: Use myLocation property directly (much faster than parsing tags!)
AND (
:location IS NULL OR :location = ''
OR (
:location IS NOT NULL AND :location != '' AND
IFNULL(loc.strValue, '') LIKE CONCAT('%', :location, '%')
)
)
ORDER BY a.eventtime DESC;