BNA8/.resources/61f1d12b5e364c065949ca3b6a593989f875469887fc85046d373546cc76acf3

63 lines
3.9 KiB
Plaintext

-- Hourly Lane Graph Query (Rate per hour)
-- Shows every hour in detail with all lane statistics as rates (items per hour) for graphing
-- Rate calculation matches LaneDetails_Rate.sql formula
-- Filtered by specific lane parameter
SELECT
CONCAT('H', TIMESTAMPDIFF(HOUR,
DATE_FORMAT(Startstamp, "%Y-%m-%d %H:00:00"),
DATE_FORMAT(NOW(), "%Y-%m-%d %H:00:00")
)) AS Hour,
ROUND(total_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS Total,
ROUND(success_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS Sorted,
ROUND(unknown_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS Unknown,
ROUND(unexpected_container_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS Unexpected,
ROUND(tracking_error_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS TrackingError,
ROUND(gap_error_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS GapError,
ROUND(destination_full_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DestinationFull,
ROUND(destination_non_operational_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DestinationFault,
ROUND(invalid_destination_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DestinationInvalid,
ROUND(destination_disabled_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DestinationDisabled,
ROUND(throughput_limit_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS ThroughputLimit,
ROUND(failed_to_divert_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DivertFail,
ROUND(no_destination_received_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DestinationNone,
ROUND(lost_container_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS Lost,
ROUND(dimension_error_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DimensionError,
ROUND(weight_error_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS WeightError,
ROUND(container_utilization_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS ContainerUtilization,
ROUND(unable_to_divert_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS UnableToDivert,
ROUND(destination_not_attempted_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS DestinationNotAttempted,
ROUND(scan_error_count * 3600 / TIMESTAMPDIFF(SECOND, Startstamp, Endtstamp), 2) AS ScanError
FROM (
SELECT
DATE(t_stamp) AS date_part,
HOUR(t_stamp) AS hour_part,
MIN(t_stamp) AS Startstamp,
MAX(t_stamp) AS Endtstamp,
COUNT(*) AS total_count,
SUM(DivertStatus = 0) AS success_count,
SUM(DivertStatus = 1) AS unknown_count,
SUM(DivertStatus = 2) AS unexpected_container_count,
SUM(DivertStatus = 3) AS tracking_error_count,
SUM(DivertStatus = 4) AS gap_error_count,
SUM(DivertStatus = 5) AS destination_full_count,
SUM(DivertStatus = 6) AS destination_non_operational_count,
SUM(DivertStatus = 7) AS invalid_destination_count,
SUM(DivertStatus = 12) AS destination_disabled_count,
SUM(DivertStatus = 13) AS throughput_limit_count,
SUM(DivertStatus = 14) AS failed_to_divert_count,
SUM(DivertStatus = 16) AS no_destination_received_count,
SUM(DivertStatus = 17) AS lost_container_count,
SUM(DivertStatus = 18) AS dimension_error_count,
SUM(DivertStatus = 19) AS weight_error_count,
SUM(DivertStatus = 20) AS container_utilization_count,
SUM(DivertStatus = 21) AS unable_to_divert_count,
SUM(DivertStatus = 22) AS destination_not_attempted_count,
SUM(DivertStatus IN (8, 9, 10)) AS scan_error_count
FROM alltable
WHERE DEST_REQ = :lane AND t_stamp BETWEEN :starttime AND :endtime
GROUP BY DATE(t_stamp), HOUR(t_stamp)
) counts
ORDER BY Startstamp ASC;