137 lines
6.0 KiB
SQL
137 lines
6.0 KiB
SQL
WITH DesiredLanes AS (
|
|
SELECT lane_number
|
|
FROM (
|
|
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 UNION SELECT 3) b
|
|
) numbers WHERE n <= 29 -- 101 to 130
|
|
UNION
|
|
SELECT 201 + n 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 UNION SELECT 3) b
|
|
) numbers WHERE n <= 29 -- 201 to 230
|
|
) lanes
|
|
),
|
|
AlarmData AS (
|
|
SELECT DISTINCT
|
|
ae.id AS record_id,
|
|
ae.eventid AS event_uuid,
|
|
ae.source,
|
|
ae.eventtime AS active_time,
|
|
(SELECT MIN(eventtime)
|
|
FROM alarm_events ae2
|
|
WHERE ae2.eventid = ae.eventid
|
|
AND ae2.eventtype = 1
|
|
AND ae2.eventtime >= ae.eventtime
|
|
) AS clear_time
|
|
FROM alarm_events ae
|
|
WHERE
|
|
ae.eventtime BETWEEN :startDate AND :endDate
|
|
AND ae.eventtype = 0
|
|
AND (ae.source LIKE '%Chute%' OR ae.source LIKE '%ChuteStatus%')
|
|
),
|
|
LaneMapping AS (
|
|
SELECT
|
|
id AS record_id,
|
|
strvalue AS tag_value,
|
|
CASE
|
|
WHEN strvalue LIKE '%Chute[%' THEN
|
|
CAST(SUBSTRING(strvalue, LOCATE('Chute[', strvalue) + 6,
|
|
LOCATE(']', strvalue, LOCATE('Chute[', strvalue)) - LOCATE('Chute[', strvalue) - 6) AS UNSIGNED)
|
|
WHEN strvalue LIKE '%Chute[_%' THEN
|
|
CAST(SUBSTRING(strvalue, LOCATE('Chute_', strvalue) + 6) AS UNSIGNED)
|
|
WHEN strvalue LIKE '%Chute%' THEN
|
|
CAST(REGEXP_SUBSTR(strvalue, '[0-9]+') AS UNSIGNED)
|
|
ELSE NULL
|
|
END AS plc_index,
|
|
CASE
|
|
WHEN strvalue LIKE '%Chute[%' THEN
|
|
CASE
|
|
WHEN CAST(SUBSTRING(strvalue, LOCATE('Chute[', strvalue) + 6,
|
|
LOCATE(']', strvalue, LOCATE('Chute[', strvalue)) - LOCATE('Chute[', strvalue) - 6) AS UNSIGNED) BETWEEN 1 AND 30
|
|
THEN 101 + (CAST(SUBSTRING(strvalue, LOCATE('Chute[', strvalue) + 6,
|
|
LOCATE(']', strvalue, LOCATE('Chute[', strvalue)) - LOCATE('Chute[', strvalue) - 6) AS UNSIGNED) - 1)
|
|
WHEN CAST(SUBSTRING(strvalue, LOCATE('Chute[', strvalue) + 6,
|
|
LOCATE(']', strvalue, LOCATE('Chute[', strvalue)) - LOCATE('Chute[', strvalue) - 6) AS UNSIGNED) BETWEEN 31 AND 60
|
|
THEN 201 + (CAST(SUBSTRING(strvalue, LOCATE('Chute[', strvalue) + 6,
|
|
LOCATE(']', strvalue, LOCATE('Chute[', strvalue)) - LOCATE('Chute[', strvalue) - 6) AS UNSIGNED) - 31)
|
|
ELSE NULL
|
|
END
|
|
WHEN strvalue LIKE '%Chute[_%' THEN
|
|
CASE
|
|
WHEN CAST(SUBSTRING(strvalue, LOCATE('Chute_', strvalue) + 6) AS UNSIGNED) BETWEEN 1 AND 30
|
|
THEN 101 + (CAST(SUBSTRING(strvalue, LOCATE('Chute_', strvalue) + 6) AS UNSIGNED) - 1)
|
|
WHEN CAST(SUBSTRING(strvalue, LOCATE('Chute_', strvalue) + 6) AS UNSIGNED) BETWEEN 31 AND 60
|
|
THEN 201 + (CAST(SUBSTRING(strvalue, LOCATE('Chute_', strvalue) + 6) AS UNSIGNED) - 31)
|
|
ELSE NULL
|
|
END
|
|
WHEN strvalue LIKE '%Chute%' THEN
|
|
CASE
|
|
WHEN CAST(REGEXP_SUBSTR(strvalue, '[0-9]+') AS UNSIGNED) BETWEEN 1 AND 30
|
|
THEN 101 + (CAST(REGEXP_SUBSTR(strvalue, '[0-9]+') AS UNSIGNED) - 1)
|
|
WHEN CAST(REGEXP_SUBSTR(strvalue, '[0-9]+') AS UNSIGNED) BETWEEN 31 AND 60
|
|
THEN 201 + (CAST(REGEXP_SUBSTR(strvalue, '[0-9]+') AS UNSIGNED) - 31)
|
|
ELSE NULL
|
|
END
|
|
ELSE NULL
|
|
END AS lane_number
|
|
FROM alarm_event_data
|
|
WHERE propname = 'Tag' AND strvalue LIKE '%Chute%'
|
|
),
|
|
JamEvents AS (
|
|
SELECT DISTINCT
|
|
lm.lane_number,
|
|
ad.event_uuid,
|
|
ad.active_time,
|
|
ad.clear_time
|
|
FROM LaneMapping lm
|
|
INNER JOIN AlarmData ad ON lm.record_id = ad.record_id
|
|
INNER JOIN alarm_event_data aed ON ad.record_id = aed.id
|
|
WHERE aed.propname = 'Jam' AND aed.strvalue = '1'
|
|
),
|
|
FullEvents AS (
|
|
SELECT DISTINCT
|
|
lm.lane_number,
|
|
ad.event_uuid,
|
|
ad.active_time,
|
|
ad.clear_time
|
|
FROM LaneMapping lm
|
|
INNER JOIN AlarmData ad ON lm.record_id = ad.record_id
|
|
INNER JOIN alarm_event_data aed ON ad.record_id = aed.id
|
|
WHERE aed.propname = 'Full' AND aed.strvalue = '1'
|
|
),
|
|
Aggregated AS (
|
|
SELECT
|
|
CONCAT('S02_', dl.lane_number, 'CH') AS lane,
|
|
COALESCE(j.jam_count, 0) AS jam_count,
|
|
COALESCE(f.full_count, 0) AS full_count,
|
|
COALESCE(j.jam_duration_seconds, 0) AS jam_duration_seconds,
|
|
COALESCE(f.full_duration_seconds, 0) AS full_duration_seconds
|
|
FROM DesiredLanes dl
|
|
LEFT JOIN (
|
|
SELECT
|
|
lane_number,
|
|
COUNT(DISTINCT event_uuid) AS jam_count,
|
|
SUM(TIMESTAMPDIFF(SECOND, active_time, COALESCE(clear_time, NOW()))) AS jam_duration_seconds
|
|
FROM JamEvents
|
|
GROUP BY lane_number
|
|
) j ON dl.lane_number = j.lane_number
|
|
LEFT JOIN (
|
|
SELECT
|
|
lane_number,
|
|
COUNT(DISTINCT event_uuid) AS full_count,
|
|
SUM(TIMESTAMPDIFF(SECOND, active_time, COALESCE(clear_time, NOW()))) AS full_duration_seconds
|
|
FROM FullEvents
|
|
GROUP BY lane_number
|
|
) f ON dl.lane_number = f.lane_number
|
|
)
|
|
SELECT
|
|
lane AS Lane,
|
|
jam_count AS JamCount,
|
|
full_count AS FullCount,
|
|
COALESCE(SEC_TO_TIME(jam_duration_seconds), '00:00:00') AS JamDuration,
|
|
COALESCE(SEC_TO_TIME(full_duration_seconds), '00:00:00') AS FullDuration
|
|
FROM Aggregated
|
|
ORDER BY lane; |