BNA8/.resources/c5c41aafa685ad6dd4e4954007f53348d936317ab9d6dd7027cbcfcd57e67c2b

101 lines
2.8 KiB
Plaintext

WITH ev AS (
SELECT
Name,
t_stamp,
'Full' AS sig,
Full AS val
FROM lane_data
WHERE t_stamp BETWEEN :startTime AND :endTime
UNION ALL
SELECT
Name,
t_stamp,
'Half_Full' AS sig,
Half_Full AS val
FROM lane_data
WHERE t_stamp BETWEEN :startTime AND :endTime
UNION ALL
SELECT
Name,
t_stamp,
'Jam' AS sig,
Jam AS val
FROM lane_data
WHERE t_stamp BETWEEN :startTime AND :endTime
UNION ALL
SELECT
Name,
t_stamp,
'No_Container' AS sig,
No_Container AS val
FROM lane_data
WHERE t_stamp BETWEEN :startTime AND :endTime
UNION ALL
SELECT
Name,
t_stamp,
'Block_Operation' AS sig,
Block_Operation AS val
FROM lane_data
WHERE t_stamp BETWEEN :startTime AND :endTime
),
ch AS (
SELECT
Name,
sig,
t_stamp,
val,
LAG(val) OVER (PARTITION BY Name, sig ORDER BY t_stamp) AS prev_val,
LEAD(t_stamp) OVER (PARTITION BY Name, sig ORDER BY t_stamp) AS next_ts,
LEAD(val) OVER (PARTITION BY Name, sig ORDER BY t_stamp) AS next_val
FROM ev
),
intervals AS (
SELECT
Name,
sig,
TIMESTAMPDIFF(SECOND, t_stamp, next_ts) AS duration_sec
FROM ch
WHERE val = 1
AND (prev_val IS NULL OR prev_val <> 1)
AND next_val = 0
),
dur AS (
SELECT
Name,
SUM(CASE WHEN sig = 'Full' THEN duration_sec ELSE 0 END) AS Full_Duration_Sec,
SUM(CASE WHEN sig = 'Half_Full' THEN duration_sec ELSE 0 END) AS Half_Full_Duration_Sec,
SUM(CASE WHEN sig = 'Jam' THEN duration_sec ELSE 0 END) AS Jam_Duration_Sec,
SUM(CASE WHEN sig = 'No_Container' THEN duration_sec ELSE 0 END) AS No_Container_Duration_Sec,
SUM(CASE WHEN sig = 'Block_Operation' THEN duration_sec ELSE 0 END) AS Block_Operation_Duration_Sec
FROM intervals
GROUP BY Name
)
SELECT
:startTime AS `Start Time`,
:endTime AS `End Time`,
d.Name AS `Lane ID`,
'S01' AS `Sorter`,
COALESCE(d.Full_Duration_Sec, 0) AS `Full Duration (Sec)`,
COALESCE(d.Half_Full_Duration_Sec, 0) AS `Half Full Duration (Sec)`,
COALESCE(d.Jam_Duration_Sec, 0) AS `Jam Duration (Sec)`,
COALESCE(d.No_Container_Duration_Sec, 0) AS `No Container Duration (Sec)`,
COALESCE(d.Block_Operation_Duration_Sec, 0) AS `Block Operation Duration (Sec)`
FROM dur d
UNION ALL
SELECT
:startTime AS `Start Time`,
:endTime AS `End Time`,
'N/A' AS `Lane ID`,
'S01' AS `Sorter`,
0 AS `Full Duration (Sec)`,
0 AS `Half Full Duration (Sec)`,
0 AS `Jam Duration (Sec)`,
0 AS `No Container Duration (Sec)`,
0 AS `Block Operation Duration (Sec)`
WHERE NOT EXISTS (SELECT 1 FROM dur)
ORDER BY `Lane ID`;