BNA8/.resources/454a125880a4c886658b9a2725d0afd435fc31c424318656d23ebb0b82f30480

98 lines
6.9 KiB
Plaintext

WITH DISABLE_EVENTS AS (
/* Group related active & clear events into a single row */
SELECT
id,
NOT eventtype AS eventtype,
IF(eventtype = 1, COALESCE(LEAD(eventid, 1) OVER w, source), eventid) AS eventid,
source, /* Unique alarm path in Ignition */
eventtime,
displaypath /* Get description */
FROM alarm_events
/* The range for both start/end allows for index optimizations */
WHERE eventtime BETWEEN (:startDate - INTERVAL 4 DAY) AND (:endDate + INTERVAL 4 DAY)
/* Filter for disabled messages, full messages, and jam messages */
AND displaypath = "HMI Chute Disabled"
AND (source LIKE "%MCP05/%" or source LIKE "%MCP06/%")
/* Filter out system events and filter for active/clear events only */
AND eventflags & 1 != 1 AND eventtype IN (0, 1)
WINDOW w AS (PARTITION BY source ORDER BY eventtime ASC)
), ENABLES AS (
/* Group related active & clear events into a single row */
SELECT
eventid,
SUBSTRING_INDEX(ANY_VALUE(ddevice.strvalue), '.', 1) AS lane,
GREATEST(COALESCE(MIN(IF(eventtype=0, eventtime, NULL)), (:startDate - INTERVAL 4 DAY)), :startDate) AS starttime,
LEAST(COALESCE(MAX(IF(eventtype=1, eventtime, NULL)), LEAST(NOW(), (:endDate + INTERVAL 4 DAY))), :endDate) AS endtime,
ANY_VALUE(displaypath) AS displaypath /* Get description */
FROM DISABLE_EVENTS e
JOIN alarm_event_data ddevice ON e.id = ddevice.id AND ddevice.propname = "Device"
GROUP BY eventid
HAVING endtime >= :startDate AND starttime <= :endDate
ORDER BY starttime ASC
), STATES AS (
/* Group related active & clear events into a single row */
SELECT
eventid,
SUBSTRING_INDEX(ANY_VALUE(ddevice.strvalue), '.', 1) AS lane,
GREATEST(COALESCE(MIN(IF(eventtype=0, eventtime, NULL)), (:startDate - INTERVAL 4 DAY)), :startDate) AS starttime,
LEAST(COALESCE(MAX(IF(eventtype=1, eventtime, NULL)), LEAST(NOW(), (:endDate + INTERVAL 4 DAY))), :endDate) AS endtime,
ANY_VALUE(displaypath) AS displaypath /* Get description */
FROM alarm_events e
JOIN alarm_event_data ddevice ON e.id = ddevice.id AND ddevice.propname = "Device"
/* The range for both start/end allows for index optimizations */
WHERE eventtime BETWEEN (:startDate - INTERVAL 4 DAY) AND (:endDate + INTERVAL 4 DAY)
/* Filter for disabled messages, full messages, and jam messages */
AND displaypath IN ("Full", "Full Warn", "25% Full Warn", "50% Full Warn", "75% Full Warn", "Jammed", "EStop or Faulted", "Extend PX Faulted", "Retract PX Faulted")
AND (source LIKE "%MCP05/%" or source LIKE "%MCP06/%")
/* Filter out system events and clear events only */
AND eventflags & 1 != 1 AND eventtype IN (0, 1)
GROUP BY eventid
HAVING endtime >= :startDate AND starttime <= :endDate
), COMBINED AS (
SELECT
/* Meta */
MIN(LEAST(e.starttime, COALESCE(s.starttime, e.starttime))) AS firsttime, /* Get the earliest it's been active in the given time range */
MAX(GREATEST(e.endtime, COALESCE(s.endtime, e.endtime))) AS lasttime, /* Get the latest it's been active in the given time range */
MAX(e.lane) AS lane, /* Use latest id to get the latest metadata */
/* Durations */
TIME_TO_SEC(TIMEDIFF(e.endtime, e.starttime)) AS enabled_duration,
SUM(IF(s.displaypath="25% Full Warn", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full25_duration,
SUM(IF(s.displaypath IN ("Full Warn", "50% Full Warn"), TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full50_duration,
SUM(IF(s.displaypath="75% Full Warn", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full75_duration,
SUM(IF(s.displaypath="Full", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full100_duration,
SUM(IF(s.displaypath="Jammed", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS jammed_duration,
SUM(IF(s.displaypath IN ("EStop or Faulted", "Extend PX Faulted", "Retract PX Faulted"), TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS faulted_duration#,
/* Max Durations */
#TIME_TO_SEC(TIMEDIFF(e.endtime, e.starttime)) AS enabled_duration_max,
#MAX(IF(s.displaypath="25% Full Warn", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full25_duration_max,
#MAX(IF(s.displaypath IN ("Full Warn", "50% Full Warn"), TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full50_duration_max,
#MAX(IF(s.displaypath="75% Full Warn", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full75_duration_max,
#MAX(IF(s.displaypath="Full", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS full100_duration_max,
#MAX(IF(s.displaypath="Jammed", TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS jammed_duration_max,
#MAX(IF(s.displaypath IN ("EStop or Faulted", "Extend PX Faulted", "Retract PX Faulted"), TIME_TO_SEC(TIMEDIFF(LEAST(e.endtime, s.endtime), GREATEST(e.starttime, s.starttime))), 0)) AS faulted_duration_max
FROM ENABLES e
LEFT JOIN STATES s ON e.lane = s.lane AND e.starttime <= s.endtime AND e.endtime >= s.starttime
GROUP BY e.eventid
)
SELECT
DATE_FORMAT(MIN(firsttime), '%Y-%m-%d %T') AS firsttime,
DATE_FORMAT(MAX(lasttime), '%Y-%m-%d %T') AS lasttime,
lane,
CAST(SEC_TO_TIME(SUM(enabled_duration)) AS CHAR) AS enabled_duration,
CAST(SEC_TO_TIME(SUM(enabled_duration - full100_duration - jammed_duration - faulted_duration)) AS CHAR) AS available_duration,
CAST(SEC_TO_TIME(SUM(enabled_duration - full25_duration - full50_duration - full75_duration - full100_duration - jammed_duration - faulted_duration)) AS CHAR) AS empty_duration,
CAST(SEC_TO_TIME(SUM(full25_duration)) AS CHAR) AS full25_duration,
CAST(SEC_TO_TIME(SUM(full50_duration)) AS CHAR) AS full50_duration,
CAST(SEC_TO_TIME(SUM(full75_duration)) AS CHAR) AS full75_duration,
CAST(SEC_TO_TIME(SUM(full100_duration)) AS CHAR) AS full100_duration,
CAST(SEC_TO_TIME(SUM(jammed_duration)) AS CHAR) AS jammed_duration,
CAST(SEC_TO_TIME(SUM(faulted_duration)) AS CHAR) AS faulted_duration,
/* Inbound OEE (Loop's Efficiency) wants to have 25%/50%/75%/100% full all the time ==> 100% */
/* (Full25 + Full50 + Full75 + Full100) / (Enabled - Jammed - Faulted) */
SUM(full25_duration + full50_duration + full75_duration + full100_duration) / SUM(enabled_duration - jammed_duration - faulted_duration) AS inbound_oee,
/* Induct OEE (Operator's Efficiency) wants to have Empty or 25%/50%/75% full all the time ==> 100%, and is penalized for the time with active jams */
/* (Empty + Full25 + Full50 + Full75) / (Enabled - Faulted) */
SUM((enabled_duration - full100_duration - jammed_duration - faulted_duration)) / SUM(enabled_duration - faulted_duration) AS induct_oee
FROM COMBINED c
GROUP BY lane
ORDER BY lane;