93 lines
2.7 KiB
MySQL
93 lines
2.7 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserve`()
|
||
|
BEGIN
|
||
|
/**
|
||
|
* Reserva cantidades con ubicaciones para un conjunto de sales del mismo
|
||
|
* almacen.
|
||
|
*
|
||
|
* @table tmp.sale(saleFk, userFk)
|
||
|
*/
|
||
|
DECLARE vCalcFk INT;
|
||
|
DECLARE vWarehouseFk INT;
|
||
|
DECLARE vCurrentYear INT DEFAULT YEAR(util.VN_NOW());
|
||
|
DECLARE vLastPickingOrder INT;
|
||
|
|
||
|
SELECT t.warehouseFk, MAX(p.pickingOrder)
|
||
|
INTO vWarehouseFk, vLastPickingOrder
|
||
|
FROM ticket t
|
||
|
JOIN sale s ON s.ticketFk = t.id
|
||
|
JOIN tmp.sale ts ON ts.saleFk = s.id
|
||
|
LEFT JOIN itemShelvingSale iss ON iss.saleFk = ts.saleFk
|
||
|
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||
|
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
|
||
|
LEFT JOIN parking p ON p.id = sh.parkingFk
|
||
|
WHERE t.warehouseFk IS NOT NULL;
|
||
|
|
||
|
IF vWarehouseFk IS NULL THEN
|
||
|
CALL util.throw('Warehouse not set');
|
||
|
END IF;
|
||
|
|
||
|
CALL cache.visible_refresh(vCalcFk, FALSE, vWarehouseFk);
|
||
|
|
||
|
SET @outstanding = 0;
|
||
|
SET @oldsaleFk = 0;
|
||
|
|
||
|
CREATE OR REPLACE TEMPORARY TABLE tSalePlacementQuantity
|
||
|
(INDEX(saleFk))
|
||
|
ENGINE = MEMORY
|
||
|
SELECT saleFk, userFk, quantityToReserve, itemShelvingFk
|
||
|
FROM( SELECT saleFk,
|
||
|
sub.userFk,
|
||
|
itemShelvingFk ,
|
||
|
IF(saleFk <> @oldsaleFk, @outstanding := quantity, @outstanding),
|
||
|
@qtr := LEAST(@outstanding, available) quantityToReserve,
|
||
|
@outStanding := @outStanding - @qtr,
|
||
|
@oldsaleFk := saleFk
|
||
|
FROM(
|
||
|
SELECT ts.saleFk,
|
||
|
ts.userFk,
|
||
|
s.quantity,
|
||
|
ish.id itemShelvingFk,
|
||
|
ish.visible - IFNULL(ishr.reservedQuantity, 0) available
|
||
|
FROM tmp.sale ts
|
||
|
JOIN sale s ON s.id = ts.saleFk
|
||
|
JOIN itemShelving ish ON ish.itemFk = s.itemFk
|
||
|
LEFT JOIN (
|
||
|
SELECT itemShelvingFk, SUM(quantity) reservedQuantity
|
||
|
FROM itemShelvingSale
|
||
|
WHERE NOT isPicked
|
||
|
GROUP BY itemShelvingFk) ishr ON ishr.itemShelvingFk = ish.id
|
||
|
JOIN shelving sh ON sh.code = ish.shelvingFk
|
||
|
JOIN parking p ON p.id = sh.parkingFk
|
||
|
JOIN sector sc ON sc.id = p.sectorFk
|
||
|
JOIN warehouse w ON w.id = sc.warehouseFk
|
||
|
JOIN productionConfig pc
|
||
|
WHERE w.id = vWarehouseFk
|
||
|
AND NOT sc.isHideForPickers
|
||
|
ORDER BY
|
||
|
s.id,
|
||
|
p.pickingOrder >= vLastPickingOrder,
|
||
|
sh.priority DESC,
|
||
|
ish.visible >= s.quantity DESC,
|
||
|
s.quantity MOD ish.grouping = 0 DESC,
|
||
|
ish.grouping DESC,
|
||
|
IF(pc.orderMode = 'Location', p.pickingOrder, ish.created)
|
||
|
)sub
|
||
|
)sub2
|
||
|
WHERE quantityToReserve > 0;
|
||
|
|
||
|
INSERT INTO itemShelvingSale(
|
||
|
itemShelvingFk,
|
||
|
saleFk,
|
||
|
quantity,
|
||
|
userFk)
|
||
|
SELECT itemShelvingFk,
|
||
|
saleFk,
|
||
|
quantityToReserve,
|
||
|
IFNULL(userFk, getUser())
|
||
|
FROM tSalePlacementQuantity spl;
|
||
|
|
||
|
DROP TEMPORARY TABLE tmp.sale;
|
||
|
END$$
|
||
|
DELIMITER ;
|