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

103 lines
2.6 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`expeditionPallet_build`(
vExpeditions JSON,
vArcId INT,
vWorkerFk INT,
OUT vPalletFk INT
)
BEGIN
/** Construye un pallet de expediciones.
*
* Primero comprueba si esas expediciones ya pertenecen a otro pallet,
* en cuyo caso actualiza ese pallet.
*
* @param vExpeditions JSON_ARRAY con esta estructura [exp1, exp2, exp3, ...]
* @param vArcId INT Identificador de arcRead
* @param vWorkerFk INT Identificador de worker
* @param out vPalletFk Identificador de expeditionPallet
*/
DECLARE vCounter INT;
DECLARE vExpeditionFk INT;
DECLARE vTruckFk INT;
DECLARE vPrinterFk INT;
2024-07-22 07:46:20 +00:00
DECLARE vExpeditionStateTypeFk INT;
CREATE OR REPLACE TEMPORARY TABLE tExpedition (
expeditionFk INT,
routeFk INT,
palletFk INT,
PRIMARY KEY (expeditionFk)
);
SET vCounter = JSON_LENGTH(vExpeditions);
WHILE vCounter DO
SET vCounter = vCounter - 1;
SET vExpeditionFk = JSON_EXTRACT(vExpeditions,CONCAT("$[", vCounter, "]"));
INSERT IGNORE INTO tExpedition(expeditionFk, routeFk, palletFk)
SELECT vExpeditionFk, t.routeFk, es.palletFk
FROM expedition e
LEFT JOIN ticket t ON t.id = e.ticketFk
LEFT JOIN expeditionScan es ON es.expeditionFk = e.id
WHERE e.id = vExpeditionFk;
END WHILE;
SELECT palletFk INTO vPalletFk
FROM (
SELECT palletFk, count(*) n
FROM tExpedition
WHERE palletFk > 0
GROUP BY palletFk
ORDER BY n DESC
LIMIT 100
) sub
LIMIT 1;
IF vPalletFk IS NULL THEN
SELECT roadmapStopFk INTO vTruckFk
FROM (
SELECT rm.roadmapStopFk, count(*) n
FROM routesMonitor rm
JOIN tExpedition e ON e.routeFk = rm.routeFk
GROUP BY roadmapStopFk
ORDER BY n DESC
LIMIT 1
) sub;
IF vTruckFk IS NULL THEN
CALL util.throw ('TRUCK_NOT_AVAILABLE');
END IF;
2024-07-18 13:16:25 +00:00
INSERT INTO expeditionPallet SET truckFk = vTruckFk;
SET vPalletFk = LAST_INSERT_ID();
END IF;
INSERT INTO expeditionScan(expeditionFk, palletFk, workerFk)
SELECT expeditionFk, vPalletFk, vWorkerFk
FROM tExpedition
ON DUPLICATE KEY UPDATE palletFk = vPalletFk, workerFk = vWorkerFk;
2024-07-22 07:46:20 +00:00
SELECT id INTO vExpeditionStateTypeFk FROM expeditionStateType WHERE code = 'PALLETIZED';
INSERT INTO expeditionState(expeditionFk, typeFk)
2024-07-22 07:46:20 +00:00
SELECT expeditionFk, vExpeditionStateTypeFk FROM tExpedition;
SELECT printerFk INTO vPrinterFk FROM arcRead WHERE id = vArcId;
CALL report_print(
'LabelPalletExpedition',
vPrinterFk,
account.myUser_getId(),
JSON_OBJECT('palletFk', vPalletFk, 'userFk', account.myUser_getId()),
'high'
);
UPDATE expeditionPallet SET isPrint = TRUE WHERE id = vPalletFk;
DROP TEMPORARY TABLE tExpedition;
END$$
DELIMITER ;