97 lines
2.3 KiB
Plaintext
97 lines
2.3 KiB
Plaintext
SELECT
|
|
jd.Name,
|
|
ROUND((jd.Jam_count / totals.Total_jams) * 100, 2) AS Jam_percentage
|
|
FROM
|
|
(
|
|
/* ---------------------------
|
|
TRUE JAM COUNTS PER DEVICE
|
|
--------------------------- */
|
|
SELECT
|
|
Name,
|
|
COUNT(*) AS Jam_count
|
|
FROM
|
|
(
|
|
/* AREA JAMS */
|
|
SELECT
|
|
Name,
|
|
t_stamp
|
|
FROM jam_area
|
|
WHERE t_stamp BETWEEN :starttime AND :endtime
|
|
|
|
UNION ALL
|
|
|
|
/* DEVICE JAMS — EDGE DETECT */
|
|
SELECT
|
|
Name,
|
|
t_stamp
|
|
FROM
|
|
(
|
|
SELECT
|
|
Name,
|
|
t_stamp,
|
|
Jam,
|
|
IF(@lastName = Name, @prevJam, 0) AS prevJam,
|
|
@prevJam := Jam,
|
|
@lastName := Name
|
|
FROM lane_data
|
|
JOIN (SELECT @prevJam := 0, @lastName := '') AS vars
|
|
WHERE t_stamp BETWEEN :starttime AND :endtime
|
|
ORDER BY Name, t_stamp
|
|
) AS x
|
|
WHERE Jam = 1 AND prevJam = 0
|
|
|
|
) AS all_jams
|
|
GROUP BY Name
|
|
) AS jd
|
|
|
|
CROSS JOIN
|
|
(
|
|
/* ---------------------------
|
|
TOTAL JAM COUNT FOR PERCENT
|
|
--------------------------- */
|
|
SELECT
|
|
SUM(Jam_count) AS Total_jams
|
|
FROM
|
|
(
|
|
/* repeat jam count block */
|
|
SELECT
|
|
Name,
|
|
COUNT(*) AS Jam_count
|
|
FROM
|
|
(
|
|
/* AREA JAMS */
|
|
SELECT
|
|
Name,
|
|
t_stamp
|
|
FROM jam_area
|
|
WHERE t_stamp BETWEEN :starttime AND :endtime
|
|
|
|
UNION ALL
|
|
|
|
/* DEVICE JAMS — EDGE DETECT */
|
|
SELECT
|
|
Name,
|
|
t_stamp
|
|
FROM
|
|
(
|
|
SELECT
|
|
Name,
|
|
t_stamp,
|
|
Jam,
|
|
IF(@lastName2 = Name, @prevJam2, 0) AS prevJam,
|
|
@prevJam2 := Jam,
|
|
@lastName2 := Name
|
|
FROM lane_data
|
|
JOIN (SELECT @prevJam2 := 0, @lastName2 := '') AS v2
|
|
WHERE t_stamp BETWEEN :starttime AND :endtime
|
|
ORDER BY Name, t_stamp
|
|
) AS x2
|
|
WHERE Jam = 1 AND prevJam = 0
|
|
|
|
) AS all_jams2
|
|
GROUP BY Name
|
|
) AS summed
|
|
) AS totals
|
|
|
|
ORDER BY Jam_percentage DESC;
|