salix/db/routines/vn/procedures/sale_getBoxPickingList.sql

77 lines
2.4 KiB
MySQL
Raw Normal View History

DELIMITER $$
2024-08-20 08:06:10 +00:00
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getBoxPickingList`(vSectorFk INT, vDated DATE)
BEGIN
2024-01-25 16:33:54 +00:00
/**
* Returns a suitable boxPicking sales list
*
* @param vSectorFk Identifier for vn.sector table
* @param vDated Date for vn.tickets.shipping
*
2024-01-25 16:33:54 +00:00
* @return tmp.sale
*/
DECLARE vWarehouseFk INT;
SELECT warehouseFk INTO vWarehouseFk
FROM sector
WHERE id = vSectorFk;
CALL productionControl(vWarehouseFk, 0);
2024-01-25 16:33:54 +00:00
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
(saleFk INT PRIMARY KEY)
2024-07-12 10:10:43 +00:00
SELECT s.ticketFk,
s.id saleFk,
s.itemFk,
s.concept,
s.quantity,
MAKETIME(pb.HH,pb.mm,0) etd,
pb.routeFk,
FLOOR(s.quantity / IF(i.isBoxPickingMode, ish.packing, i.packingOut)) stickers,
IF(i.isBoxPickingMode, ish.packing, i.packingOut) packing,
2024-07-14 07:08:14 +00:00
IF(pa.isPackageReturnable, pc.defaultBigPackageFk, b.packagingFk) packagingFk
2024-01-25 16:33:54 +00:00
FROM sale s
JOIN item i ON i.id = s.itemFk
JOIN itemShelving ish ON ish.itemFk = s.itemFk
2024-07-12 10:10:43 +00:00
LEFT JOIN ( SELECT iss.itemShelvingFk,
2024-01-25 16:33:54 +00:00
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
2024-03-25 12:03:11 +00:00
JOIN agency a ON a .id = am.agencyFk
2024-01-25 16:33:54 +00:00
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
2024-07-12 10:10:43 +00:00
LEFT JOIN packaging pa ON pa.id = b.packagingFk
JOIN packagingConfig pc
2024-02-16 11:05:47 +00:00
WHERE IF(i.isBoxPickingMode, ish.packing, i.packingOut)
<= LEAST(s.quantity, ish.visible - IFNULL(tISS.reserve,0))
2024-01-25 16:33:54 +00:00
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
2024-03-25 12:03:11 +00:00
AND a.isOwn
2024-01-25 16:33:54 +00:00
GROUP BY s.id
ORDER BY etd;
2024-02-16 11:05:47 +00:00
SELECT *
FROM tmp.sale
WHERE stickers;
2024-01-25 16:33:54 +00:00
DROP TEMPORARY TABLE tmp.productionBuffer;
2024-01-25 16:33:54 +00:00
DROP TEMPORARY TABLE tmp.sale;
END$$
DELIMITER ;