36 lines
1.6 KiB
Plaintext
36 lines
1.6 KiB
Plaintext
-- Hourly Scanner Rate Query (Table Display)
|
|
-- Returns up to 24 time buckets with scanner read statistics as rates (items per hour)
|
|
-- Automatically scales interval size based on date range (min 1 hour)
|
|
|
|
SELECT
|
|
DATE_FORMAT(roundtime, '%Y-%m-%d %H:%i:00') AS StartTimestamp,
|
|
CONCAT('H', TIMESTAMPDIFF(HOUR, roundtime, NOW())) AS Hour,
|
|
CONCAT(ROUND(COALESCE(Total, 0) * 3600 / GREATEST(bucket_size, 1), 2), ' pph') AS Total,
|
|
CONCAT(ROUND(COALESCE(GoodRead, 0) * 3600 / GREATEST(bucket_size, 1), 2), ' pph') AS GoodRead,
|
|
CONCAT(ROUND(COALESCE(NoRead, 0) * 3600 / GREATEST(bucket_size, 1), 2), ' pph') AS NoRead,
|
|
CONCAT(ROUND(COALESCE(MultiRead, 0) * 3600 / GREATEST(bucket_size, 1), 2), ' pph') AS MultiRead,
|
|
CONCAT(ROUND(COALESCE(NoCode, 0) * 3600 / GREATEST(bucket_size, 1), 2), ' pph') AS NoCode
|
|
FROM (
|
|
SELECT
|
|
FROM_UNIXTIME(
|
|
CEIL(UNIX_TIMESTAMP(t_stamp) / bucket_size) * bucket_size
|
|
) AS roundtime,
|
|
bucket_size,
|
|
COUNT(*) AS Total,
|
|
SUM(DivertStatus NOT IN (8, 9, 10)) AS GoodRead,
|
|
SUM(DivertStatus = 8) AS NoRead,
|
|
SUM(DivertStatus = 10) AS MultiRead,
|
|
SUM(DivertStatus = 9) AS NoCode
|
|
FROM
|
|
alltable
|
|
CROSS JOIN (
|
|
-- Calculate dynamic bucket size: date range divided by 24, minimum 1 hour (3600 seconds)
|
|
SELECT GREATEST(3600, CEIL((UNIX_TIMESTAMP(:endtime) - UNIX_TIMESTAMP(:starttime)) / 24)) AS bucket_size
|
|
) AS intervals
|
|
WHERE
|
|
t_stamp BETWEEN :starttime AND :endtime
|
|
GROUP BY
|
|
roundtime, bucket_size
|
|
) counts
|
|
ORDER BY
|
|
roundtime ASC; |