DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`inventoryDiscrepancyDetail_replace`() BEGIN /** * Replace all records in table inventoryDiscrepancyDetail and insert new * records into inventoryDiscrepancy for all inventory warehouses. */ DECLARE vDone INT DEFAULT FALSE; DECLARE vCalc INT; DECLARE vWarehouseFk INT; DECLARE cWarehouses CURSOR FOR SELECT id FROM vn.warehouse WHERE isInventory; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; TRUNCATE TABLE inventoryDiscrepancyDetail; OPEN cWarehouses; read_loop: LOOP SET vDone = FALSE; FETCH cWarehouses INTO vWarehouseFk; IF vDone THEN LEAVE read_loop; END IF; CALL cache.visible_refresh(vCalc, FALSE, vWarehouseFk); CREATE OR REPLACE TEMPORARY TABLE tVisible SELECT itemFk, SUM(visible) totalVisible FROM vn.itemShelving ish JOIN vn.shelving sh ON sh.code = ish.shelvingFk JOIN vn.parking p ON p.id = sh.parkingFk JOIN vn.sector sc ON sc.id = p.sectorFk WHERE sc.warehouseFk = vWarehouseFk GROUP BY itemFk; INSERT INTO inventoryDiscrepancyDetail( warehouseFk, itemFk, theorical, visible, notPicked, alert) SELECT vWarehouseFk warehouseFk, v.item_id itemFk, v.visible, tv.totalVisible, s.notPicked, CASE WHEN s.notPicked > IFNULL(tv.totalVisible, 0) THEN 0 WHEN v.visible > IFNULL((tv.totalVisible * 2), 0) THEN 1 WHEN v.visible > tv.totalVisible THEN 2 ELSE 3 END alert FROM cache.visible v LEFT JOIN tVisible tv ON tv.itemFk = v.item_id JOIN ( SELECT s.itemFk, SUM(s.quantity) notPicked FROM vn.sale s JOIN vn.ticket t ON t.id = s.ticketFk JOIN vn.ticketState ts ON ts.ticketFk = t.id JOIN vn.alertLevel al ON al.id = ts.alertLevel WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayend(util.VN_CURDATE()) AND s.isPicked = FALSE AND al.code = 'FREE' AND t.warehouseFk = vWarehouseFk GROUP BY s.itemFk HAVING notPicked ) s ON s.itemFk = v.item_id WHERE v.calc_id = vCalc AND NOT v.visible <=> tv.totalVisible; END LOOP; CLOSE cWarehouses; INSERT INTO inventoryDiscrepancy( warehouseFk, alert, quantity) SELECT warehouseFk, alert, COUNT(*) FROM inventoryDiscrepancyDetail GROUP BY warehouseFk, alert; DROP TEMPORARY TABLE IF EXISTS tVisible; END$$ DELIMITER ;