ALTER TABLE `vn`.`itemShelvingSale` DROP COLUMN IF EXISTS isPicked; ALTER TABLE`vn`.`itemShelvingSale` ADD isPicked TINYINT(1) DEFAULT FALSE NOT NULL; ALTER TABLE `vn`.`productionConfig` DROP COLUMN IF EXISTS orderMode; ALTER TABLE `vn`.`productionConfig` ADD orderMode ENUM('Location', 'Age') NOT NULL DEFAULT 'Location'; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserveByCollection`( vCollectionFk INT(11) ) BEGIN /** * Reserva cantidades con ubicaciones para el contenido de una colección * * @param vCollectionFk Identificador de collection */ CREATE OR REPLACE TEMPORARY TABLE tmp.sale (INDEX(saleFk)) ENGINE = MEMORY SELECT s.id saleFk, NULL userFk FROM ticketCollection tc JOIN sale s ON s.ticketFk = tc.ticketFk LEFT JOIN ( SELECT DISTINCT saleFk FROM saleTracking st JOIN state s ON s.id = st.stateFk WHERE st.isChecked AND s.semaphore = 1)st ON st.saleFk = s.id WHERE tc.collectionFk = vCollectionFk AND st.saleFk IS NULL AND NOT s.isPicked; CALL itemShelvingSale_reserve(); END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_setQuantity`( vItemShelvingSaleFk INT(10), vQuantity DECIMAL(10,0), vIsItemShelvingSaleEmpty BOOLEAN ) BEGIN /** * Gestiona la reserva de un itemShelvingFk, actualizando isPicked y quantity * en vn.itemShelvingSale y vn.sale.isPicked en caso necesario. * Si la reserva de la ubicación es fallida, se regulariza la situación * * @param vItemShelvingSaleFk Id itemShelvingSaleFK * @param vQuantity Cantidad real que se ha cogido de la ubicación * @param vIsItemShelvingSaleEmpty determina si ka ubicación itemShelvingSale se ha * quedado vacio tras el movimiento */ DECLARE vSaleFk INT; DECLARE vCursorSaleFk INT; DECLARE vItemShelvingFk INT; DECLARE vReservedQuantity INT; DECLARE vRemainingQuantity INT; DECLARE vItemFk INT; DECLARE vUserFk INT; DECLARE vDone BOOLEAN DEFAULT FALSE; DECLARE vSales CURSOR FOR SELECT iss.saleFk, iss.userFk FROM itemShelvingSale iss JOIN sale s ON s.id = iss.saleFk WHERE iss.id = vItemShelvingSaleFk AND s.itemFk = vItemFk AND NOT iss.isPicked; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; IF (SELECT isPicked FROM itemShelvingSale WHERE id = vItemShelvingSaleFk) THEN CALL util.throw('Booking completed'); END IF; SELECT s.itemFk, iss.saleFk, iss.itemShelvingFk INTO vItemFk, vSaleFk, vItemShelvingFk FROM itemShelvingSale iss JOIN sale s ON s.id = iss.saleFk WHERE iss.id = vItemShelvingSaleFk AND NOT iss.isPicked; UPDATE itemShelvingSale SET isPicked = TRUE, quantity = vQuantity WHERE id = vItemShelvingSaleFk; UPDATE itemShelving SET visible = IF(vIsItemShelvingSaleEmpty, 0, GREATEST(0,visible - vQuantity)) WHERE id = vItemShelvingFk; IF vIsItemShelvingSaleEmpty THEN OPEN vSales; l: LOOP SET vDone = FALSE; FETCH vSales INTO vCursorSaleFk, vUserFk; IF vDone THEN LEAVE l; END IF; CREATE OR REPLACE TEMPORARY TABLE tmp.sale (INDEX(saleFk, userFk)) ENGINE = MEMORY SELECT vCursorSaleFk, vUserFk; CALL itemShelvingSale_reserveWhitUser(); DROP TEMPORARY TABLE tmp.sale; END LOOP; CLOSE vSales; DELETE iss FROM itemShelvingSale iss JOIN sale s ON s.id = iss.saleFk WHERE iss.id = vItemShelvingSaleFk AND s.itemFk = vItemFk AND NOT iss.isPicked; END IF; SELECT SUM(quantity) INTO vRemainingQuantity FROM itemShelvingSale WHERE saleFk = vSaleFk AND NOT isPicked; IF vRemainingQuantity THEN CALL itemShelvingSale_reserveBySale (vSaleFk, vRemainingQuantity, NULL); SELECT SUM(quantity) INTO vRemainingQuantity FROM itemShelvingSale WHERE saleFk = vSaleFk AND NOT isPicked; IF NOT vRemainingQuantity <=> 0 THEN SELECT SUM(iss.quantity) INTO vReservedQuantity FROM itemShelvingSale iss WHERE iss.saleFk = vSaleFk; CALL saleTracking_new( vSaleFk, TRUE, vReservedQuantity, `account`.`myUser_getId`(), NULL, 'PREPARED', TRUE); UPDATE sale s SET s.quantity = vReservedQuantity WHERE s.id = vSaleFk ; END IF; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserve`() BEGIN /** * Reserva cantidades con ubicaciones para un conjunto de sales del mismo wareHouse * * @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 ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserveBySale`( vSelf INT , vQuantity INT, vUserFk INT ) BEGIN /** * Reserva cantida y ubicación para una saleFk * * @param vSelf Identificador de la venta * @param vQuantity Cantidad a reservar * @param vUserFk Id de usuario que realiza la reserva */ CREATE OR REPLACE TEMPORARY TABLE tmp.sale ENGINE = MEMORY SELECT vSelf saleFk, vUserFk userFk; CALL itemShelvingSale_reserve(); END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelvingSale_AFTER_INSERT` AFTER INSERT ON `itemShelvingSale` FOR EACH ROW BEGIN UPDATE vn.sale SET isPicked = TRUE WHERE id = NEW.saleFk; END$$ DELIMITER ;