BNA8/.resources/2fcf590ada70344d7a6466c165fb4531ddf3680898912d4bd1366644920a70f5
2025-08-13 21:41:10 +04:00

83 lines
4.4 KiB
Plaintext

WITH ALARM_TIMELAPSES AS (
/* Group related active & clear events into a single row */
SELECT
e.id, /* Unique to each row in alarm_events, used to look up metadata in alarm_event_data */
source, /* Unique alarm path in Ignition */
eventtime AS starttime,
displaypath, /* Get description */
/* Get the last time this event was active within the given time range*/
CAST(LEAST(COALESCE((
/* Search for the clear event (if exists) for the outer query's active event */
SELECT MIN(eventtime)
FROM alarm_events e2
WHERE e2.eventid = e.eventid /* eventid is unique per alarm instance */
AND e2.eventtime >= e.eventtime
AND e2.eventtype = 1 /* Look only for the clear event */
ORDER BY eventtime ASC
), NOW()), :endDate) AS DATETIME) AS endtime, /* Clamp to end of time range if clear event is after end time */
priority
FROM alarm_events e
/* The range for both start/end allows for index optimizations */
WHERE e.eventtime BETWEEN :startDate AND :endDate
/* Filter for disabled messages, full messages, and jam messages */
AND e.displaypath IN ("Available", "Full", "Full Warn", "25% Full Warn", "50% Full Warn", "75% Full Warn", "HMI Chute Disabled", "Jammed", "EStop or Faulted")
/* Filter out system events and active events only */
AND e.eventflags & 1 != 1 AND e.eventtype = 0
), HITLIST AS (
/* Group the same type of alarms together to get hit counts and total durations */
SELECT
MAX(id) AS id, /* Use latest id to get the latest metadata */
MIN(starttime) AS firsttime, /* Get the earliest it's been active in the given time range */
MAX(endtime) AS lasttime, /* Get the latest it's been active in the given time range */
MIN(displaypath) AS displaypath, /* Get one of the displaypaths associated with source */
MAX(priority) AS priority,
COUNT(*) AS count,
SUM(TIME_TO_SEC(TIMEDIFF(endtime, starttime))) AS duration
FROM ALARM_TIMELAPSES
GROUP BY source
ORDER BY count DESC
LIMIT 2000
), HITLIST_DATA AS (
/* Finally, merge metadata into hitlist */
SELECT e.id,
e.firsttime, e.lasttime,
SUBSTRING_INDEX(SUBSTRING_INDEX(dtag.strvalue, ']', 1), '[', -1) AS sorter,
SUBSTRING_INDEX(ddevice.strvalue, '.', 1) AS lane,
displaypath AS description,
/* Retrieve instance count and total duration */
e.count,
e.duration
FROM HITLIST e
/* Lookup PLCTag */
JOIN alarm_event_data dtag ON e.id = dtag.id AND dtag.propname = "PLCTag"
/* Lookup Device */
JOIN alarm_event_data ddevice ON e.id = ddevice.id AND ddevice.propname = "Device"
)
SELECT
DATE_FORMAT(MIN(firsttime), '%Y-%m-%d %T') AS start_timestamp,
DATE_FORMAT(MAX(lasttime), '%Y-%m-%d %T') AS end_timestamp,
lane,
/* Counts */
SUM(IF(description="Available", count, 0)) AS available_count,
SUM(IF(description="Full", count, 0)) AS full_count,
SUM(IF(description IN ("Full Warn", "50% Full Warn"), count, 0)) AS full_warn_count,
SUM(IF(description="25% Full Warn", count, 0)) AS full_warn_25_count,
SUM(IF(description IN ("Full Warn", "50% Full Warn"), count, 0)) AS full_warn_50_count,
SUM(IF(description="75% Full Warn", count, 0)) AS full_warn_75_count,
SUM(IF(description="HMI Chute Disabled", count, 0)) AS disabled_count,
SUM(IF(description="Jammed", count, 0)) AS jam_count,
SUM(IF(description="EStop or Faulted", count, 0)) AS faulted_count,
/* Durations, translated to strings */
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="Available", duration, 0)))) AS CHAR) AS available_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="Full", duration, 0)))) AS CHAR) AS full_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description IN ("Full Warn", "50% Full Warn"), duration, 0)))) AS CHAR) AS full_warn_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="25% Full Warn", duration, 0)))) AS CHAR) AS full_warn_25_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description IN ("Full Warn", "50% Full Warn"), duration, 0)))) AS CHAR) AS full_warn_50_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="75% Full Warn", duration, 0)))) AS CHAR) AS full_warn_75_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="HMI Chute Disabled", duration, 0)))) AS CHAR) AS disabled_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="Jammed", duration, 0)))) AS CHAR) AS jam_duration,
CAST(SEC_TO_TIME(FLOOR(SUM(IF(description="EStop or Faulted", duration, 0)))) AS CHAR) AS faulted_duration
FROM HITLIST_DATA
WHERE {where}
GROUP BY lane
ORDER BY lane;