DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_getBoxPickingList`(vSectorFk INT, vDated DATE) BEGIN /** * Returns a suitable boxPicking sales list * * @param vSectorFk Identifier for vn.sector table * @param vDated Date for vn.tickets.shipping * * @return tmp.sale */ DECLARE vWarehouseFk INT; SELECT warehouseFk INTO vWarehouseFk FROM sector WHERE id = vSectorFk; CALL productionControl(vWarehouseFk, 0); -- Products with vn.item.isBoxPickingMode = TRUE, pay atention to vn.itemShelving.packing CREATE OR REPLACE TEMPORARY TABLE tmp.sale (saleFk INT PRIMARY KEY) SELECT s.ticketFk, s.id saleFk, s.itemFk, s.concept, s.quantity, MAKETIME(pb.HH,pb.mm,0) etd, pb.routeFk, FLOOR(s.quantity / ish.packing) stickers, ish.packing, b.packagingFk FROM sale s JOIN item i ON i.id = s.itemFk JOIN itemShelving ish ON ish.itemFk = s.itemFk LEFT JOIN ( SELECT iss.itemShelvingFk, s.itemFk, SUM(iss.quantity) reserve FROM itemShelvingSale iss JOIN sale s ON s.id = iss.saleFk WHERE iss.isPicked = FALSE AND iss.created >= vDated GROUP BY iss.itemShelvingFk, s.itemFk) tISS ON tISS.itemFk = ish.itemFk AND tISS.itemShelvingFk = ish.id JOIN shelving sh ON sh.code = ish.shelvingFk JOIN parking p ON p.id = sh.parkingFk JOIN tmp.productionBuffer pb ON pb.ticketFk = s.ticketFk JOIN agencyMode am ON am.id = pb.agencyModeFk LEFT JOIN routesMonitor rm ON rm.routeFk = pb.routeFk LEFT JOIN saleGroupDetail sgd ON sgd.saleFk = s.id LEFT JOIN ticketState ts ON ts.ticketFk = s.ticketFk LEFT JOIN cache.last_buy lb ON lb.item_id = i.id AND lb.warehouse_id = vWarehouseFk LEFT JOIN buy b ON b.id = lb.buy_id WHERE s.quantity BETWEEN ish.packing AND (ish.visible - IFNULL(tISS.reserve,0)) AND i.isBoxPickingMode AND NOT pb.problem AND sgd.saleFk IS NULL AND p.sectorFk = vSectorFk AND ts.isPreviousPreparable AND ((rm.bufferFk AND rm.isPickingAllowed) OR am.code = 'REC_ALG') AND pb.shipped = vDated GROUP BY s.id ORDER BY etd; -- Remaining products, vn.item.packingOut INSERT IGNORE INTO tmp.sale SELECT s.ticketFk, s.id saleFk, s.itemFk, s.concept, s.quantity, MAKETIME(pb.HH,pb.mm,0) etd, pb.routeFk, s.quantity / i.packingOut stickers, i.packingOut, pc.defaultBigPackageFk FROM sale s JOIN item i ON i.id = s.itemFk JOIN itemShelving ish ON ish.itemFk = s.itemFk JOIN shelving sh ON sh.code = ish.shelvingFk JOIN parking p ON p.id = sh.parkingFk JOIN tmp.productionBuffer pb ON pb.ticketFk = s.ticketFk JOIN agencyMode am ON am.id = pb.agencyModeFk JOIN packagingConfig pc LEFT JOIN routesMonitor rm ON rm.routeFk = pb.routeFk LEFT JOIN itemShelvingStock iss ON iss.itemFk = s.itemFk AND iss.sectorFk = p.sectorFk LEFT JOIN saleGroupDetail sgd ON sgd.saleFk = s.id LEFT JOIN ticketState ts ON ts.ticketFk = s.ticketFk WHERE s.quantity >= i.packingOut AND NOT pb.problem AND s.quantity > 0 AND sgd.saleFk IS NULL AND p.sectorFk = vSectorFk AND ts.isPreviousPreparable AND iss.visible >= s.quantity AND ((rm.bufferFk AND rm.isPickingAllowed) OR am.code = 'REC_ALG') AND pb.shipped = vDated GROUP BY s.id ORDER BY etd; SELECT * FROM tmp.sale; DROP TEMPORARY TABLE tmp.productionBuffer; DROP TEMPORARY TABLE tmp.sale; END$$ DELIMITER ;