DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblems`( vIsTodayRelative TINYINT(1) ) BEGIN /** * Calcula los problemas para un conjunto de sale * * @param vIsTodayRelative Indica si se calcula el disponible como si todo saliera hoy * @table tmp.sale(saleFk) Identificadores de los sale a calcular * @return tmp.saleProblems */ DECLARE vWarehouseFk INT; DECLARE vDate DATE; DECLARE vAvailableCache INT; DECLARE vVisibleCache INT; DECLARE vDone BOOL; DECLARE vCursor CURSOR FOR SELECT t.warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(t.shipped)) dated FROM tmp.sale ts JOIN sale s ON s.id = ts.saleFk JOIN ticket t ON t.id = s.ticketFk WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY) GROUP BY warehouseFk, dated; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; CREATE OR REPLACE TEMPORARY TABLE tmp.saleProblems( saleFk INT(11), hasItemShortage BOOL DEFAULT FALSE, hasItemLost BOOL DEFAULT FALSE, hasItemDelay BOOL DEFAULT FALSE, hasRounding BOOL DEFAULT FALSE, PRIMARY KEY (saleFk) ) ENGINE = MEMORY; CREATE OR REPLACE TEMPORARY TABLE tItemShelving (INDEX (itemFk, warehouseFk)) ENGINE = MEMORY SELECT ish.itemFk itemFk, SUM(ish.visible) visible, s.warehouseFk warehouseFk FROM itemShelving ish JOIN shelving sh ON sh.id = ish.shelvingFk JOIN parking p ON p.id = sh.parkingFk JOIN sector s ON s.id = p.sectorFk GROUP BY ish.itemFk, s.warehouseFk; -- Disponible, faltas, inventario y retrasos OPEN vCursor; l: LOOP SET vDone = FALSE; FETCH vCursor INTO vWarehouseFk, vDate; IF vDone THEN LEAVE l; END IF; -- Disponible: no va a haber suficiente producto para preparar todos los pedidos CALL cache.available_refresh(vAvailableCache, FALSE, vWarehouseFk, vDate); -- Faltas: visible, disponible y ubicado son menores que la cantidad vendida CALL cache.visible_refresh(vVisibleCache, FALSE, vWarehouseFk); INSERT INTO tmp.saleProblems(saleFk, hasItemShortage) SELECT s.id, TRUE FROM tmp.sale ts JOIN sale s ON s.id = ts.saleFk JOIN ticket t ON t.id = s.ticketFk JOIN item i ON i.id = s.itemFk JOIN itemType it ON it.id = i.typeFk JOIN itemCategory ic ON ic.id = it.categoryFk LEFT JOIN cache.visible v ON v.item_id = i.id AND v.calc_id = vVisibleCache LEFT JOIN cache.available av ON av.item_id = i.id AND av.calc_id = vAvailableCache LEFT JOIN tItemShelving tis ON tis.itemFk = i.id AND tis.warehouseFk = t.warehouseFk WHERE (v.visible < s.quantity AND v.visible IS NOT NULL) AND (av.available < s.quantity AND av.available IS NOT NULL) AND (tis.visible < s.quantity AND tis.visible IS NOT NULL) AND NOT s.isPicked AND NOT s.reserved AND ic.merchandise AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) AND NOT i.generic AND util.VN_CURDATE() = vDate AND t.warehouseFk = vWarehouseFk GROUP BY s.id; -- Inventario: Visible suficiente, pero ubicado menor a la cantidad vendida INSERT INTO tmp.saleProblems(saleFk, hasItemLost) SELECT s.id, TRUE FROM tmp.sale ts JOIN sale s ON s.id = ts.saleFk JOIN ticket t ON t.id = s.ticketFk JOIN item i ON i.id = s.itemFk JOIN itemType it ON it.id = i.typeFk JOIN itemCategory ic ON ic.id = it.categoryFk LEFT JOIN cache.visible v ON v.item_id = s.itemFk AND v.calc_id = vVisibleCache LEFT JOIN tItemShelving tis ON tis.itemFk = i.id AND tis.warehouseFk = t.warehouseFk WHERE (v.visible >= s.quantity AND v.visible IS NOT NULL) AND (tis.visible < s.quantity AND tis.visible IS NOT NULL) AND s.quantity > 0 AND NOT s.isPicked AND NOT s.reserved AND ic.merchandise AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) AND NOT i.generic AND util.VN_CURDATE() = vDate AND t.warehouseFk = vWarehouseFk GROUP BY s.id ON DUPLICATE KEY UPDATE hasItemLost = TRUE; -- Retraso: Disponible suficiente, pero no visible ni ubicado INSERT INTO tmp.saleProblems(saleFk, hasItemDelay) SELECT s.id, TRUE FROM tmp.sale ts JOIN sale s ON s.id = ts.saleFk JOIN ticket t ON t.id = s.ticketFk JOIN item i ON i.id = s.itemFk JOIN itemType it ON it.id = i.typeFk JOIN itemCategory ic ON ic.id = it.categoryFk LEFT JOIN cache.visible v ON v.item_id = s.itemFk AND v.calc_id = vVisibleCache LEFT JOIN cache.available av ON av.item_id = i.id AND av.calc_id = vAvailableCache LEFT JOIN tItemShelving tis ON tis.itemFk = i.id AND tis.warehouseFk = t.warehouseFk WHERE (v.visible < s.quantity AND v.visible IS NOT NULL) AND (av.available < s.quantity AND av.available IS NOT NULL) AND (tis.visible < s.quantity AND tis.visible IS NOT NULL) AND s.quantity > 0 AND NOT s.isPicked AND NOT s.reserved AND ic.merchandise AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) AND NOT i.generic AND util.VN_CURDATE() = vDate AND t.warehouseFk = vWarehouseFk GROUP BY s.id ON DUPLICATE KEY UPDATE hasItemDelay = TRUE; -- Redondeo: cantidad incorrecta con respecto al grouping CALL buy_getUltimate(NULL, vWarehouseFk, vDate); INSERT INTO tmp.saleProblems(saleFk, hasRounding) SELECT s.id, TRUE FROM tmp.sale ts JOIN sale s ON s.id = ts.saleFk JOIN ticket t ON t.id = s.ticketFk AND t.warehouseFk = vWarehouseFk JOIN item i ON i.id = s.itemFk JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk JOIN buy b ON b.id = bu.buyFk WHERE MOD(s.quantity, b.`grouping`) GROUP BY s.id ON DUPLICATE KEY UPDATE hasRounding = TRUE; DROP TEMPORARY TABLE tmp.buyUltimate; END LOOP; CLOSE vCursor; DROP TEMPORARY TABLE tItemShelving; END$$ DELIMITER ;