DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelving_getSaleDate`(vShelvingFk VARCHAR(3)) BEGIN /* Devuelve la mínima fecha en que se necesita cada producto en esa matrícula. * * @param vShelvingFk Matrícula del carro o pallet */ DECLARE vWarehouseFk INT; DECLARE vStockScopeDays INT; SELECT s.warehouseFk, stockScopeDays INTO vWarehouseFk, vStockScopeDays FROM sector s JOIN operator o ON s.id = o.sectorFk JOIN productionConfig pc WHERE o.workerFk = account.myUser_getId(); IF vWarehouseFk IS NULL THEN CALL util.throw('WarehouseFk not setted'); END IF; IF vStockScopeDays IS NULL THEN CALL util.throw('StockScopeDays not setted'); END IF; CREATE OR REPLACE TEMPORARY TABLE tmp.tItems (PRIMARY KEY (itemFk)) ENGINE = MEMORY SELECT itemFk, SUM(visible) visible FROM itemShelving WHERE shelvingFk = vShelvingFk COLLATE utf8_unicode_ci GROUP BY itemFk; CREATE OR REPLACE TEMPORARY TABLE tmp.tStockByDay (INDEX (itemFk, dated)) ENGINE = MEMORY SELECT dated, SUM(t3.amount) OVER (PARTITION BY t3.itemFk ORDER BY dated) stock, t3.itemFk FROM ( SELECT t.itemFk, dated, SUM(amount) amount FROM ( SELECT t2.itemFk, t2.amount, t2.dated FROM ( SELECT item_id itemFk, amount, util.VN_CURDATE() dated FROM cache.stock s JOIN tmp.tItems i ON i.itemFk = s.item_id WHERE s.warehouse_id = vWarehouseFk UNION ALL SELECT ish.itemFk, - SUM(ish.visible), util.VN_CURDATE() FROM itemShelving ish JOIN tmp.tItems i ON i.itemFk = ish.itemFk JOIN shelving sh ON sh.code = ish.shelvingFk JOIN parking p ON sh.parkingFk = p.id JOIN sector s ON s.id = p.sectorFk WHERE s.isReserve GROUP BY ish.itemFk UNION ALL SELECT iei.itemFk, SUM(quantity), landed FROM itemEntryIn iei JOIN tmp.tItems i ON i.itemFk = iei.itemFk WHERE iei.landed BETWEEN util.VN_CURDATE() AND util.VN_CURDATE() + INTERVAL vStockScopeDays DAY AND iei.warehouseInFk = vWarehouseFk AND NOT isVirtualStock GROUP BY iei.itemFk, iei.landed UNION ALL SELECT ieo.itemFk, SUM(quantity), shipped FROM itemEntryOut ieo JOIN tmp.tItems i ON i.itemFk = ieo.itemFk WHERE ieo.shipped BETWEEN util.VN_CURDATE() AND util.VN_CURDATE() + INTERVAL vStockScopeDays DAY AND ieo.warehouseOutFk = vWarehouseFk GROUP BY ieo.itemFk, ieo.shipped UNION ALL SELECT i.itemFk, SUM(ito.quantity), DATE(ito.shipped) FROM itemTicketOut ito JOIN tmp.tItems i ON i.itemFk = ito.itemFk WHERE ito.shipped BETWEEN util.VN_CURDATE() AND util.VN_CURDATE() + INTERVAL vStockScopeDays DAY AND ito.warehouseFk = vWarehouseFk GROUP BY ito.itemFk, ito.shipped ) t2 JOIN tmp.tItems i ON i.itemFk = t2.itemFk)t GROUP BY t.itemFk, dated ) t3; -- Se restan las entradas de hoy UPDATE tmp.tStockByDay sbd JOIN (SELECT iei.itemFk, SUM(quantity) todayEntry FROM itemEntryIn iei JOIN tmp.tItems i ON i.itemFk = iei.itemFk WHERE iei.landed = util.VN_CURDATE() AND iei.warehouseInFk = vWarehouseFk AND NOT iei.isVirtualStock) sub ON sub.itemFk = sbd.itemFk SET sbd.stock = sbd.stock - sub.todayEntry WHERE sbd.dated = util.VN_CURDATE(); -- Se añaden las lineas de venta servidas UPDATE tmp.tStockByDay sbd JOIN (SELECT s.itemFK, SUM(quantity) amount FROM sale s JOIN ticket t ON t.id = s.ticketFk WHERE t.warehouseFk = vWarehouseFk AND t.shipped BETWEEN util.VN_CURDATE() AND util.midnight() AND s.isPicked GROUP BY s.itemFk) sub ON sub.itemFk = sbd.itemFk SET sbd.stock = sbd.stock + sub.amount; -- Se añaden los items ubicados hoy UPDATE tmp.tStockByDay sbd JOIN (SELECT ish.itemFK, SUM(ish.visible) amount FROM itemShelving ish JOIN shelving sh ON sh.code = ish.shelvingFk JOIN parking p ON p.id = sh.parkingFk JOIN sector s ON s.id = p.sectorFk WHERE s.warehouseFk = vWarehouseFk AND NOT s.isReserve AND ish.created BETWEEN util.VN_CURDATE() AND util.midnight() GROUP BY ish.itemFk) sub ON sub.itemFk = sbd.itemFk SET sbd.stock = sbd.stock + sub.amount; SELECT ts.itemFk, i.longName, IF(ts.stock<=0, ts.dated, NULL) dated, ts.stock, sub4.visible, sub4.shelvingFk FROM( SELECT IFNULL(sub2.minDated, sub.minDated) dated, IFNULL(sub2.itemFk, sub.itemFk) itemFk FROM(SELECT sbd.itemFk, MIN(dated) minDated, sbd.stock FROM tmp.tItems ti LEFT JOIN tmp.tStockByDay sbd ON sbd.itemFk = ti.itemFk GROUP BY itemFk)sub LEFT JOIN ( SELECT sbd.itemFk, MIN(dated) minDated, sbd.stock FROM tmp.tItems ti LEFT JOIN tmp.tStockByDay sbd ON sbd.itemFk = ti.itemFk WHERE sbd.stock <= 0 GROUP BY itemFk)sub2 ON sub2.itemFk =sub.itemFk WHERE sub2.itemFk IS NOT NULL OR (sub2.itemFk IS NULL AND sub.itemFk IS NOT NULL)) sub3 LEFT JOIN tmp.tStockByDay ts ON ts.itemFk = sub3.itemFk AND ts.dated = sub3.dated JOIN (SELECT ish.itemFk, ish.visible, p.sectorFk, ish.shelvingFk FROM itemShelving ish JOIN vn.shelving sh ON sh.code = ish.shelvingFk LEFT JOIN parking p ON p.id = parkingFk LEFT JOIN vn.sector s ON s.id = p.sectorFk WHERE ish.shelvingFk = vShelvingFk COLLATE utf8_unicode_ci ) sub4 ON sub4.itemFk = ts.itemFk LEFT JOIN sector s ON s.id = sub4.sectorFk LEFT JOIN item i ON i.id = ts.itemFk WHERE NOT s.isReserve; DROP TEMPORARY TABLE tmp.tStockByDay, tmp.tItems; END$$ DELIMITER ;