BNA8/.resources/8397ebb9950f53d9a780ed3097ebd27c69828d238312b422e20b5ac065cf224b

67 lines
2.3 KiB
Plaintext

-- Generate all lanes 101-124 excluding 102, 104, 106
WITH DesiredLanes AS (
SELECT 101 + n AS lane_number
FROM (
SELECT a.N + b.N * 10 AS n
FROM (SELECT 0 AS N UNION SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION SELECT 4
UNION SELECT 5 UNION SELECT 6 UNION SELECT 7 UNION SELECT 8 UNION SELECT 9) a,
(SELECT 0 AS N UNION SELECT 1 UNION SELECT 2) b
) numbers
WHERE n <= 23 -- 101 to 124
AND (101 + n) NOT IN (102, 104, 106)
),
-- Aggregate Full alarms per lane
FullAlarms AS (
SELECT
aed.strValue AS myLocation,
COUNT(*) AS FullCount,
SUM(TIMESTAMPDIFF(SECOND, ae.eventtime, COALESCE(ae_clear.eventtime, NOW()))) AS FullDuration
FROM alarm_events ae
LEFT JOIN alarm_events ae_clear
ON ae.eventid = ae_clear.eventid AND ae_clear.eventtype = 1
JOIN alarm_event_data aed
ON aed.id = ae.id AND aed.propname = 'myLocation'
WHERE ae.eventtype = 0
AND ae.source LIKE '%Full%'
AND ae.source LIKE '%Chute%'
AND ae.eventtime BETWEEN :startDate AND :endDate
GROUP BY aed.strValue
),
-- Aggregate Jammed alarms per lane
JammedAlarms AS (
SELECT
aed.strValue AS myLocation,
COUNT(*) AS JamCount,
SUM(TIMESTAMPDIFF(SECOND, ae.eventtime, COALESCE(ae_clear.eventtime, NOW()))) AS JamDuration
FROM alarm_events ae
LEFT JOIN alarm_events ae_clear
ON ae.eventid = ae_clear.eventid AND ae_clear.eventtype = 1
JOIN alarm_event_data aed
ON aed.id = ae.id AND aed.propname = 'myLocation'
WHERE ae.eventtype = 0
AND ae.source LIKE '%Jammed%'
AND ae.source LIKE '%Chute%'
AND ae.eventtime BETWEEN :startDate AND :endDate
GROUP BY aed.strValue
),
-- Combine Full and Jammed
Aggregated AS (
SELECT
dl.lane_number,
COALESCE(f.FullCount, 0) AS FullCount,
COALESCE(j.JamCount, 0) AS JamCount,
COALESCE(f.FullDuration, 0) AS FullDuration,
COALESCE(j.JamDuration, 0) AS JamDuration
FROM DesiredLanes dl
LEFT JOIN FullAlarms f ON f.myLocation = CONCAT('S03_CH', dl.lane_number)
LEFT JOIN JammedAlarms j ON j.myLocation = CONCAT('S03_CH', dl.lane_number)
)
SELECT
CONCAT('S03_CH', lane_number) AS Lane,
FullCount,
JamCount,
FullDuration,
JamDuration
FROM Aggregated
ORDER BY lane_number;