-- Query to get the latest status for each lane for pie chart display -- Total lanes in system: minimum 201, or actual count if more lanes are added WITH latest_records AS ( SELECT Name, Full, Half_Full, Jam, Faulted, No_Container, Block_Operation, ROW_NUMBER() OVER (PARTITION BY Name ORDER BY t_stamp DESC) AS rn FROM lane_data ), totals AS ( SELECT GREATEST(COUNT(*), 201) AS total_lanes, SUM(CASE WHEN Jam = 1 THEN 1 ELSE 0 END) AS jammed_count, SUM(CASE WHEN Faulted = 1 THEN 1 ELSE 0 END) AS faulted_count, SUM(CASE WHEN Full = 1 THEN 1 ELSE 0 END) AS full_count, SUM(CASE WHEN Half_Full = 1 THEN 1 ELSE 0 END) AS half_full_count, SUM(CASE WHEN No_Container = 1 THEN 1 ELSE 0 END) AS no_container_count, SUM(CASE WHEN Block_Operation = 1 THEN 1 ELSE 0 END) AS block_operation_count FROM latest_records WHERE rn = 1 ) SELECT 'Jammed' AS `Status`, COALESCE(jammed_count, 0) AS `Count`, ROUND(COALESCE(jammed_count, 0) * 100.0 / total_lanes, 2) AS `Percentage (%)` FROM totals UNION ALL SELECT '50% Full' AS `Status`, COALESCE(half_full_count, 0) AS `Count`, ROUND(COALESCE(half_full_count, 0) * 100.0 / total_lanes, 2) AS `Percentage (%)` FROM totals UNION ALL SELECT '100% Full' AS `Status`, COALESCE(full_count, 0) AS `Count`, ROUND(COALESCE(full_count, 0) * 100.0 / total_lanes, 2) AS `Percentage (%)` FROM totals UNION ALL SELECT 'Faulted' AS `Status`, COALESCE(faulted_count, 0) AS `Count`, ROUND(COALESCE(faulted_count, 0) * 100.0 / total_lanes, 2) AS `Percentage (%)` FROM totals UNION ALL SELECT 'No Container' AS `Status`, COALESCE(no_container_count, 0) AS `Count`, ROUND(COALESCE(no_container_count, 0) * 100.0 / total_lanes, 2) AS `Percentage (%)` FROM totals UNION ALL SELECT 'Blocked by Operator' AS `Status`, COALESCE(block_operation_count, 0) AS `Count`, ROUND(COALESCE(block_operation_count, 0) * 100.0 / total_lanes, 2) AS `Percentage (%)` FROM totals;