This commit is contained in:
parent
acf47468c0
commit
7f563f99bb
|
@ -0,0 +1,8 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` EVENT `vn`.`itemShelvingSale_doReserve`
|
||||
ON SCHEDULE EVERY 15 SECOND
|
||||
STARTS '2023-10-16 00:00:00'
|
||||
ON COMPLETION PRESERVE
|
||||
ENABLE
|
||||
DO CALL vn.itemShelvingSale_doReserve$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,87 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_addWithReservation`(
|
||||
vItemFk INT,
|
||||
vQuantity INT,
|
||||
vTicketFk INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* En el ámbito de las colecciones se añade una línea de sale a un ticket
|
||||
* de una colección en caso de tener disponible y se realiza la reserva.
|
||||
*
|
||||
* @param vItemFk id of item
|
||||
* @param vQuantity quantity to be added to the ticket
|
||||
* @param vTicketFk ticket to which the sales line is added
|
||||
*/
|
||||
DECLARE vWarehouseFk INT;
|
||||
DECLARE vCacheAvailableFk INT;
|
||||
DECLARE vAvailable INT;
|
||||
DECLARE vSaleFk INT;
|
||||
DECLARE vConcept VARCHAR(50);
|
||||
DECLARE vItemName VARCHAR(50);
|
||||
DECLARE vHasThrow BOOLEAN DEFAULT FALSE;
|
||||
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
SELECT t.warehouseFk INTO vWarehouseFk
|
||||
FROM ticket t
|
||||
JOIN ticketCollection tc ON tc.ticketFk = t.id
|
||||
WHERE t.id = vTicketFk;
|
||||
|
||||
CALL cache.available_refresh(
|
||||
vCacheAvailableFk,
|
||||
FALSE,
|
||||
vWarehouseFk,
|
||||
util.VN_CURDATE());
|
||||
|
||||
SELECT available INTO vAvailable
|
||||
FROM cache.available
|
||||
WHERE calc_id = vCacheAvailableFk
|
||||
AND item_id = vItemFk;
|
||||
|
||||
IF vAvailable < vQuantity THEN
|
||||
SET vHasThrow = TRUE;
|
||||
SELECT vAvailable, vQuantity;
|
||||
ELSE
|
||||
START TRANSACTION;
|
||||
|
||||
SELECT `name`,
|
||||
CONCAT(getUser(), ' ', DATE_FORMAT(util.VN_NOW(), '%H:%i'), ' ', name)
|
||||
INTO vItemName, vConcept
|
||||
FROM item
|
||||
WHERE id = vItemFk;
|
||||
|
||||
INSERT INTO ticketLog
|
||||
SET originFk = vTicketFk,
|
||||
userFk = getUser(),
|
||||
`action` = 'update',
|
||||
`description` = CONCAT('Añadido articulo ', vItemName, ' cantidad:', vQuantity);
|
||||
|
||||
INSERT INTO sale
|
||||
SET itemFk = vItemFk,
|
||||
ticketFk = vTicketFk,
|
||||
concept = vConcept,
|
||||
quantity = vQuantity,
|
||||
isAdded = TRUE;
|
||||
|
||||
SELECT LAST_INSERT_ID() INTO vSaleFk;
|
||||
|
||||
CALL sale_calculateComponent(vSaleFk, NULL);
|
||||
CALL itemShelvingSale_addBySale(vSaleFk);
|
||||
|
||||
IF NOT EXISTS (SELECT TRUE FROM itemShelvingSale WHERE saleFk = vSaleFk LIMIT 1) THEN
|
||||
SET vHasThrow = TRUE;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF vHasThrow THEN
|
||||
CALL util.throw("No hay disponibilidad para el artículo seleccionado");
|
||||
ELSE
|
||||
COMMIT;
|
||||
END IF;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,77 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getAssigned`(
|
||||
vUserFk INT,
|
||||
OUT vCollectionFk INT)
|
||||
proc:BEGIN
|
||||
/* Comprueba si existen colecciones libres que se ajustan al perfil del usuario
|
||||
* y le asigna la más antigua.
|
||||
* Añade un registro al semillero de colecciones y hace la reserva para la colección
|
||||
* @param vUserFk Id de usuario
|
||||
* @param vCollectionFk Id de colección
|
||||
*/
|
||||
DECLARE vHasTooMuchCollections BOOL;
|
||||
DECLARE vLockTime INT DEFAULT 15;
|
||||
|
||||
-- Si hay colecciones sin terminar, sale del proceso
|
||||
CALL collection_get(vUserFk);
|
||||
|
||||
SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0
|
||||
INTO vHasTooMuchCollections
|
||||
FROM tCollection
|
||||
JOIN productionConfig pc ;
|
||||
|
||||
DROP TEMPORARY TABLE tCollection;
|
||||
|
||||
IF vHasTooMuchCollections THEN
|
||||
CALL util.throw('Hay colecciones pendientes');
|
||||
LEAVE proc;
|
||||
END IF;
|
||||
|
||||
IF NOT GET_LOCK('collection_getAssigned', vLockTime) THEN
|
||||
LEAVE proc;
|
||||
END IF;
|
||||
|
||||
-- Se eliminan las colecciones sin asignar que estan obsoletas
|
||||
INSERT INTO ticketTracking(stateFk, ticketFk)
|
||||
SELECT s.id, tc.ticketFk
|
||||
FROM collection c
|
||||
JOIN ticketCollection tc ON tc.collectionFk = c.id
|
||||
JOIN state s ON s.code = 'PRINTED_AUTO'
|
||||
JOIN productionConfig pc
|
||||
WHERE c.workerFk IS NULL
|
||||
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
||||
|
||||
DELETE c
|
||||
FROM collection c
|
||||
JOIN productionConfig pc
|
||||
WHERE c.workerFk IS NULL
|
||||
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
||||
|
||||
-- Se añade registro al semillero
|
||||
INSERT INTO collectionHotbed
|
||||
SET userFk = vUserFk;
|
||||
|
||||
-- Comprueba si hay colecciones disponibles que se ajustan a su configuracion
|
||||
SELECT MIN(c.id) INTO vCollectionFk
|
||||
FROM collection c
|
||||
JOIN operator o ON (o.itemPackingTypeFk = c.itemPackingTypeFk
|
||||
OR c.itemPackingTypeFk IS NULL)
|
||||
AND o.numberOfWagons = c.wagons
|
||||
AND o.trainFk = c.trainFk
|
||||
AND o.warehouseFk = c.warehouseFk
|
||||
AND c.workerFk IS NULL
|
||||
WHERE o.workerFk = vUserFk;
|
||||
|
||||
IF vCollectionFk IS NULL THEN
|
||||
CALL collection_new(vUserFk, vCollectionFk);
|
||||
END IF;
|
||||
|
||||
UPDATE collection
|
||||
SET workerFk = vUserFk
|
||||
WHERE id = vCollectionFk;
|
||||
|
||||
CALL itemShelvingSale_addByCollection(vCollectionFk);
|
||||
|
||||
DO RELEASE_LOCK('collection_getAssigned');
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,51 @@
|
|||
|
||||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addByCollection`(
|
||||
vCollectionFk INT(11)
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Guarda la ubicación para el contenido de una colección
|
||||
*
|
||||
* @param vCollectionFk Identificador de collection
|
||||
*/
|
||||
DECLARE vDone BOOL DEFAULT FALSE;
|
||||
DECLARE vSaleFk INT;
|
||||
DECLARE vSales CURSOR FOR
|
||||
WITH sales AS (
|
||||
SELECT s.id saleFk, s.quantity, SUM(IFNULL(iss.quantity, 0)) quantityReserved
|
||||
FROM vn.ticketCollection tc
|
||||
JOIN vn.sale s ON s.ticketFk = tc.ticketFk
|
||||
LEFT JOIN vn.itemShelvingSale iss ON iss.saleFk = s.id
|
||||
WHERE tc.collectionFk = vCollectionFk
|
||||
GROUP BY s.id
|
||||
HAVING quantity <> quantityReserved
|
||||
), trackedSales AS (
|
||||
SELECT sa.saleFk
|
||||
FROM sales sa
|
||||
JOIN vn.saleTracking st ON st.saleFk = sa.saleFk
|
||||
JOIN vn.`state` s ON s.id = st.stateFk
|
||||
WHERE st.isChecked
|
||||
AND s.semaphore = 1
|
||||
GROUP BY sa.saleFk
|
||||
) SELECT s.saleFk
|
||||
FROM sales s
|
||||
LEFT JOIN trackedSales ts ON ts.saleFk = s.saleFk
|
||||
WHERE ts.saleFk IS NULL;
|
||||
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||
|
||||
OPEN vSales;
|
||||
l: LOOP
|
||||
SET vDone = FALSE;
|
||||
FETCH vSales INTO vSaleFk;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE l;
|
||||
END IF;
|
||||
|
||||
CALL itemShelvingSale_addBySale(vSaleFk);
|
||||
END LOOP;
|
||||
CLOSE vSales;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,100 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addBySale`(
|
||||
vSaleFk INT
|
||||
)
|
||||
proc: BEGIN
|
||||
/**
|
||||
* Reserva una línea de venta en la ubicación más óptima
|
||||
*
|
||||
* @param vSaleFk Id de sale
|
||||
* @param vItemShelvingSaleFk Id de reserva
|
||||
*/
|
||||
DECLARE vLastPickingOrder INT;
|
||||
DECLARE vDone INT DEFAULT FALSE;
|
||||
DECLARE vItemShelvingFk INT;
|
||||
DECLARE vAvailable INT;
|
||||
DECLARE vReservedQuantity INT;
|
||||
DECLARE vOutStanding INT;
|
||||
DECLARE vUserFk INT;
|
||||
|
||||
DECLARE vItemShelvingAvailable CURSOR FOR
|
||||
SELECT ish.id itemShelvingFk,
|
||||
ish.available
|
||||
FROM sale s
|
||||
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 sector sc ON sc.id = p.sectorFk
|
||||
JOIN productionConfig pc
|
||||
WHERE s.id = vSaleFk
|
||||
AND NOT sc.isHideForPickers
|
||||
ORDER BY s.id,
|
||||
p.pickingOrder >= vLastPickingOrder,
|
||||
sh.priority DESC,
|
||||
ish.available >= s.quantity DESC,
|
||||
s.quantity MOD ish.grouping = 0 DESC,
|
||||
ish.grouping DESC,
|
||||
IF(pc.orderMode = 'Location', p.pickingOrder, ish.created);
|
||||
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||
/* DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
*/
|
||||
SELECT MAX(p.pickingOrder), s.quantity - SUM(IFNULL(iss.quantity, 0))
|
||||
INTO vLastPickingOrder, vOutStanding
|
||||
FROM sale s
|
||||
LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
||||
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 s.id = vSaleFk;
|
||||
|
||||
IF vOutStanding <= 0 THEN
|
||||
LEAVE proc;
|
||||
END IF;
|
||||
|
||||
SELECT getUser() INTO vUserFk;
|
||||
|
||||
OPEN vItemShelvingAvailable;
|
||||
l: LOOP
|
||||
SET vDone = FALSE;
|
||||
FETCH vItemShelvingAvailable INTO vItemShelvingFk, vAvailable;
|
||||
|
||||
IF vOutStanding <= 0 OR vDone THEN
|
||||
LEAVE l;
|
||||
END IF;
|
||||
|
||||
SELECT id INTO vItemShelvingFk
|
||||
FROM itemShelving
|
||||
WHERE id = vItemShelvingFk
|
||||
FOR UPDATE;
|
||||
|
||||
SELECT LEAST(vOutStanding, vAvailable) INTO vReservedQuantity;
|
||||
SET vOutStanding = vOutStanding - vReservedQuantity;
|
||||
|
||||
IF vReservedQuantity > 0 THEN
|
||||
-- START TRANSACTION;
|
||||
|
||||
INSERT INTO itemShelvingSale(
|
||||
itemShelvingFk,
|
||||
saleFk,
|
||||
quantity,
|
||||
userFk)
|
||||
SELECT vItemShelvingFk,
|
||||
vSaleFk,
|
||||
vReservedQuantity,
|
||||
vUserFk;
|
||||
|
||||
UPDATE itemShelving
|
||||
SET available = available - vReservedQuantity
|
||||
WHERE id = vItemShelvingFk;
|
||||
|
||||
-- COMMIT;
|
||||
END IF;
|
||||
END LOOP;
|
||||
CLOSE vItemShelvingAvailable;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,52 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_doReserve`()
|
||||
proc: BEGIN
|
||||
/**
|
||||
* Genera reservas de la tabla itemShelvingSaleReserv
|
||||
*/
|
||||
DECLARE vDone BOOL;
|
||||
DECLARE vSaleFk INT;
|
||||
|
||||
DECLARE vSales CURSOR FOR
|
||||
SELECT DISTINCT saleFk FROM tSale;
|
||||
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
||||
SET vDone = TRUE;
|
||||
|
||||
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
DO RELEASE_LOCK('vn.itemShelvingSale_doReserve');
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
IF !GET_LOCK('vn.itemShelvingSale_doReserve', 0) THEN
|
||||
LEAVE proc;
|
||||
END IF;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tSale
|
||||
ENGINE = MEMORY
|
||||
SELECT id, saleFk FROM itemShelvingSaleReserv;
|
||||
|
||||
OPEN vSales;
|
||||
|
||||
myLoop: LOOP
|
||||
SET vDone = FALSE;
|
||||
FETCH vSales INTO vSaleFk;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE myLoop;
|
||||
END IF;
|
||||
|
||||
CALL itemShelvingSale_addBySale (vSaleFk);
|
||||
END LOOP;
|
||||
|
||||
CLOSE vSales;
|
||||
|
||||
DELETE iss FROM itemShelvingSaleReserv iss JOIN tSale s ON s.id = iss.id;
|
||||
|
||||
DROP TEMPORARY TABLE tSale;
|
||||
|
||||
DO RELEASE_LOCK('vn.itemShelvingSale_doReserve');
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -7,112 +7,120 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_se
|
|||
BEGIN
|
||||
/**
|
||||
* Gestiona la reserva de un itemShelvingFk, actualizando isPicked y quantity
|
||||
* en vn.itemShelvingSale y vn.sale.isPicked en caso necesario.
|
||||
* en itemShelvingSale y 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
|
||||
* @param vIsItemShelvingSaleEmpty determina si la 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 vTotalQuantity INT;
|
||||
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
IF (SELECT isPicked FROM itemShelvingSale WHERE id = vItemShelvingSaleFk) THEN
|
||||
CALL util.throw('Booking completed');
|
||||
CALL util.throw('Reserva completada');
|
||||
END IF;
|
||||
|
||||
SELECT s.itemFk, iss.saleFk, iss.itemShelvingFk
|
||||
INTO vItemFk, vSaleFk, vItemShelvingFk
|
||||
SELECT s.itemFk, iss.saleFk, iss.itemShelvingFk, SUM(IFNULL(iss.quantity,0))
|
||||
INTO vItemFk, vSaleFk, vItemShelvingFk, vReservedQuantity
|
||||
FROM itemShelvingSale iss
|
||||
JOIN sale s ON s.id = iss.saleFk
|
||||
WHERE iss.id = vItemShelvingSaleFk
|
||||
AND NOT iss.isPicked;
|
||||
|
||||
IF vQuantity > vReservedQuantity
|
||||
OR (vQuantity < vReservedQuantity AND
|
||||
(NOT vIsItemShelvingSaleEmpty OR vIsItemShelvingSaleEmpty IS NULL))
|
||||
OR (vIsItemShelvingSaleEmpty IS NOT NULL AND vQuantity = vReservedQuantity) THEN
|
||||
CALL util.throw('La cantidad no puede distinta a la reserva');
|
||||
END IF;
|
||||
|
||||
|
||||
START TRANSACTION;
|
||||
|
||||
|
||||
UPDATE itemShelvingSale
|
||||
SET isPicked = TRUE,
|
||||
quantity = vQuantity
|
||||
WHERE id = vItemShelvingSaleFk;
|
||||
|
||||
SELECT id INTO vItemShelvingFk
|
||||
FROM itemShelving
|
||||
WHERE id = vItemShelvingFk
|
||||
AND FALSE
|
||||
FOR UPDATE;
|
||||
|
||||
UPDATE itemShelving
|
||||
SET visible = IF(vIsItemShelvingSaleEmpty, 0, GREATEST(0,visible - vQuantity))
|
||||
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;
|
||||
COMMIT;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
(INDEX(saleFk, userFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT vCursorSaleFk, vUserFk;
|
||||
IF vIsItemShelvingSaleEmpty AND vQuantity <> vReservedQuantity THEN
|
||||
|
||||
CALL itemShelvingSale_reserveWhitUser();
|
||||
DROP TEMPORARY TABLE tmp.sale;
|
||||
UPDATE itemShelving
|
||||
SET visible = 0,
|
||||
available = 0
|
||||
WHERE id = vItemShelvingFk
|
||||
AND itemFk = vItemFk;
|
||||
|
||||
END LOOP;
|
||||
CLOSE vSales;
|
||||
CALL itemShelvingSale_addBySale(vSaleFk);
|
||||
|
||||
START TRANSACTION;
|
||||
|
||||
INSERT INTO itemShelvingSaleReserv (saleFk)
|
||||
SELECT DISTINCT iss.saleFk
|
||||
FROM itemShelvingSale iss
|
||||
JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||
WHERE iss.itemShelvingFk = vItemShelvingFk
|
||||
AND ish.itemFk = vItemFk
|
||||
AND NOT iss.isPicked;
|
||||
|
||||
DELETE iss
|
||||
FROM itemShelvingSale iss
|
||||
JOIN sale s ON s.id = iss.saleFk
|
||||
WHERE iss.id = vItemShelvingSaleFk
|
||||
AND s.itemFk = vItemFk
|
||||
JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||
WHERE iss.itemShelvingFk = vItemShelvingFk
|
||||
AND ish.itemFk = vItemFk
|
||||
AND NOT iss.isPicked;
|
||||
COMMIT;
|
||||
|
||||
CALL itemShelvingSale_doReserve();
|
||||
END IF;
|
||||
|
||||
SELECT SUM(quantity) INTO vRemainingQuantity
|
||||
SELECT SUM(IF(isPicked, 0, quantity)), SUM(quantity)
|
||||
INTO vRemainingQuantity, vTotalQuantity
|
||||
FROM itemShelvingSale
|
||||
WHERE saleFk = vSaleFk
|
||||
AND NOT isPicked;
|
||||
WHERE saleFk = vSaleFk;
|
||||
|
||||
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;
|
||||
IF vRemainingQuantity = 0 THEN
|
||||
START TRANSACTION;
|
||||
|
||||
CALL saleTracking_new(
|
||||
vSaleFk,
|
||||
TRUE,
|
||||
vReservedQuantity,
|
||||
vTotalQuantity,
|
||||
`account`.`myUser_getId`(),
|
||||
NULL,
|
||||
'PREPARED',
|
||||
TRUE);
|
||||
|
||||
UPDATE sale s
|
||||
SET s.quantity = vReservedQuantity
|
||||
WHERE s.id = vSaleFk ;
|
||||
END IF;
|
||||
SET s.quantity = vTotalQuantity,
|
||||
isPicked = TRUE
|
||||
WHERE s.id = vSaleFk;
|
||||
|
||||
COMMIT;
|
||||
END IF;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,34 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_setSaleGroup`(
|
||||
vSaleGroupFk INT(10)
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Gestiona la reserva de un vn.saleGroup actualizando vn.itemShelvingSale.isPicked
|
||||
* y cambiando el estado de la vn.sale
|
||||
*
|
||||
* @param vSaleGroupFk Id saleGroupFk
|
||||
*/
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
IF NOT (SELECT COUNT(*) FROM saleGroup WHERE id = vSaleGroupFk) THEN
|
||||
CALL util.throw('Sale group not exists');
|
||||
END IF;
|
||||
|
||||
START TRANSACTION;
|
||||
|
||||
UPDATE itemShelvingSale iss
|
||||
JOIN sale s ON s.id = iss.saleFk
|
||||
JOIN saleGroupDetail sg ON sg.saleFk = s.id
|
||||
SET iss.isPicked = TRUE
|
||||
WHERE sg.saleGroupFk = vSaleGroupFk;
|
||||
|
||||
CALL saleTracking_addPreparedSaleGroup(vSaleGroupFk);
|
||||
|
||||
COMMIT;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,60 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_unpicked`(
|
||||
vSelf INT(11)
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Desmarca una línea que ya estaba sacada, devolviendo la cantidad al itemShelving
|
||||
*
|
||||
* @param vSelf Identificador del itemShelvingSale
|
||||
*/
|
||||
DECLARE vSaleFk INT;
|
||||
DECLARE vReservedQuantity INT;
|
||||
DECLARE vIsSaleGroup BOOL;
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
IF (SELECT NOT isPicked FROM itemShelvingSale WHERE id = vSelf) THEN
|
||||
CALL util.throw('Reserva no completada');
|
||||
END IF;
|
||||
|
||||
SELECT ish.saleFk, ish.quantity, IF(sg.id, TRUE, FALSE)
|
||||
INTO vSaleFk, vReservedQuantity, vIsSaleGroup
|
||||
FROM itemShelvingSale ish
|
||||
LEFT JOIN saleGroupDetail sg ON sg.saleFk = ish.saleFk
|
||||
WHERE ish.id = vSelf;
|
||||
|
||||
IF vIsSaleGroup THEN
|
||||
CALL util.throw('Can not unpicked a sale group');
|
||||
END IF;
|
||||
|
||||
START TRANSACTION;
|
||||
|
||||
UPDATE itemShelvingSale
|
||||
SET isPicked = FALSE
|
||||
WHERE id = vSelf;
|
||||
|
||||
UPDATE sale s
|
||||
JOIN itemShelvingSale ish ON ish.saleFk = s.id
|
||||
SET s.isPicked = FALSE
|
||||
WHERE ish.id = vSelf;
|
||||
|
||||
UPDATE itemShelvingSale iss
|
||||
JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||
SET ish.visible = ish.visible + iss.quantity
|
||||
WHERE iss.id = vSelf;
|
||||
|
||||
CALL saleTracking_new(
|
||||
vSaleFk,
|
||||
FALSE,
|
||||
vReservedQuantity,
|
||||
`account`.`myUser_getId`(),
|
||||
NULL,
|
||||
'ON_PREPARATION',
|
||||
TRUE);
|
||||
COMMIT;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -1,5 +1,7 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingTransfer`(vItemShelvingFk INT, vShelvingFk VARCHAR(3))
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingTransfer`(
|
||||
vItemShelvingFk INT,
|
||||
vShelvingFk VARCHAR(3))
|
||||
BEGIN
|
||||
/**
|
||||
* Transfiere producto de una ubicación a otra, fusionando si coincide el
|
||||
|
@ -14,16 +16,14 @@ BEGIN
|
|||
INTO vNewItemShelvingFk
|
||||
FROM itemShelving ish
|
||||
JOIN (
|
||||
SELECT
|
||||
itemFk,
|
||||
SELECT itemFk,
|
||||
packing,
|
||||
created
|
||||
FROM itemShelving
|
||||
WHERE id = vItemShelvingFk
|
||||
) ish2
|
||||
ON ish2.itemFk = ish.itemFk
|
||||
) ish2 ON ish2.itemFk = ish.itemFk
|
||||
AND ish2.packing = ish.packing
|
||||
AND date(ish2.created) = date(ish.created)
|
||||
AND DATE(ish2.created) = DATE(ish.created)
|
||||
WHERE ish.shelvingFk = vShelvingFk COLLATE utf8_unicode_ci;
|
||||
|
||||
IF vNewItemShelvingFk THEN
|
||||
|
@ -39,7 +39,6 @@ BEGIN
|
|||
SET shelvingFk = vShelvingFk
|
||||
WHERE id = vItemShelvingFk;
|
||||
END IF;
|
||||
|
||||
SELECT true;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -1,8 +1,6 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelving_add`(IN vShelvingFk VARCHAR(8), IN vBarcode VARCHAR(22), IN vQuantity INT, IN vPackagingFk VARCHAR(10), IN vGrouping INT, IN vPacking INT, IN vWarehouseFk INT)
|
||||
BEGIN
|
||||
|
||||
|
||||
/**
|
||||
* Añade registro o lo actualiza si ya existe.
|
||||
*
|
||||
|
@ -36,7 +34,7 @@ BEGIN
|
|||
AND packing = vPacking) = 1 THEN
|
||||
|
||||
UPDATE itemShelving
|
||||
SET visible = visible+vQuantity
|
||||
SET visible = visible + vQuantity
|
||||
WHERE shelvingFk COLLATE utf8_unicode_ci = vShelvingFk AND itemFk = vItemFk AND packing = vPacking;
|
||||
|
||||
ELSE
|
||||
|
@ -53,7 +51,8 @@ BEGIN
|
|||
vQuantity,
|
||||
IFNULL(vGrouping, b.grouping),
|
||||
IFNULL(vPacking, b.packing),
|
||||
IFNULL(vPackagingFk, b.packagingFk)
|
||||
IFNULL(vPackagingFk, b.packagingFk),
|
||||
vQuantity
|
||||
FROM item i
|
||||
LEFT JOIN cache.last_buy lb ON i.id = lb.item_id AND lb.warehouse_id = vWarehouseFk
|
||||
LEFT JOIN buy b ON b.id = lb.buy_id
|
||||
|
|
|
@ -0,0 +1,27 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_AFTER_INSERT`
|
||||
AFTER INSERT ON `itemShelving`
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
|
||||
INSERT INTO vn.itemShelvingLog(
|
||||
itemShelvingFk,
|
||||
workerFk,
|
||||
accion,
|
||||
itemFk,
|
||||
shelvingFk,
|
||||
visible,
|
||||
`grouping`,
|
||||
packing,
|
||||
available)
|
||||
VALUES( NEW.id,
|
||||
NEW.userFk,
|
||||
'CREA REGISTRO',
|
||||
NEW.itemFk,
|
||||
NEW.shelvingFk,
|
||||
NEW.visible,
|
||||
NEW.`grouping`,
|
||||
NEW.packing,
|
||||
NEW.available);
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,16 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_AFTER_UPDATE`
|
||||
AFTER UPDATE ON `itemShelving`
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
INSERT INTO itemShelvingLog
|
||||
SET itemShelvingFk = NEW.id,
|
||||
workerFk = account.myUser_getId(),
|
||||
accion = 'CAMBIO',
|
||||
itemFk = NEW.itemFk,
|
||||
shelvingFk = NEW.shelvingFk,
|
||||
visible = NEW.visible,
|
||||
`grouping` = NEW.`grouping`,
|
||||
packing = NEW.packing;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,10 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_BEFORE_INSERT`
|
||||
BEFORE INSERT ON `itemShelving`
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
SET NEW.editorFk = account.myUser_getId();
|
||||
SET NEW.userFk = account.myUser_getId();
|
||||
SET NEW.available = NEW.visible;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,23 @@
|
|||
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';
|
||||
|
||||
ALTER TABLE vn.itemShelving DROP COLUMN IF EXISTS available;
|
||||
|
||||
ALTER TABLE vn.itemShelving ADD available INT NULL;
|
||||
|
||||
UPDATE vn.itemShelving SET available = visible;
|
||||
|
||||
CREATE TABLE vn.itemShelvingSaleReserv (
|
||||
`id` int(11) NOT NULL AUTO_INCREMENT,
|
||||
`saleFk` int(11) NOT NULL,
|
||||
PRIMARY KEY (`id`),
|
||||
KEY `itemShelvingSaleReserv_ibfk_1` (`saleFk`)
|
||||
) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci
|
||||
COMMENT='Queue of changed itemShelvingSale to reserve';
|
Loading…
Reference in New Issue