124 lines
3.0 KiB
SQL
124 lines
3.0 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`expeditionPallet_build`(
|
|
vExpeditions JSON,
|
|
vArcId INT,
|
|
vWorkerFk INT,
|
|
OUT vPalletFk INT
|
|
)
|
|
proc: BEGIN
|
|
/**
|
|
* Builds an expedition pallet.
|
|
*
|
|
* First, it checks if these expeditions already belong to another pallet,
|
|
* in which case it returns an error.
|
|
*
|
|
* @param vExpeditions JSON_ARRAY with this structure [exp1, exp2, exp3, ...]
|
|
* @param vArcId INT Identifier of arcRead
|
|
* @param vWorkerFk INT Identifier of worker
|
|
* @param out vPalletFk Identifier of expeditionPallet
|
|
*/
|
|
|
|
DECLARE vCounter INT;
|
|
DECLARE vExpeditionFk INT;
|
|
DECLARE vTruckFk INT;
|
|
DECLARE vPrinterFk INT;
|
|
DECLARE vExpeditionStateTypeFk INT;
|
|
DECLARE vFreeExpeditionCount INT;
|
|
DECLARE vExpeditionWithPallet 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 COUNT(expeditionFk) INTO vFreeExpeditionCount
|
|
FROM tExpedition
|
|
WHERE palletFk IS NULL;
|
|
|
|
SELECT COUNT(expeditionFk) INTO vExpeditionWithPallet
|
|
FROM tExpedition
|
|
WHERE palletFk;
|
|
|
|
IF vExpeditionWithPallet THEN
|
|
UPDATE arcRead
|
|
SET error = (
|
|
SELECT GROUP_CONCAT(expeditionFk SEPARATOR ', ')
|
|
FROM tExpedition
|
|
WHERE palletFk
|
|
)
|
|
WHERE id = vArcId;
|
|
LEAVE proc;
|
|
END IF;
|
|
|
|
IF NOT vFreeExpeditionCount THEN
|
|
CALL util.throw ('NO_FREE_EXPEDITIONS');
|
|
END IF;
|
|
|
|
SELECT roadmapStopFk INTO vTruckFk
|
|
FROM (
|
|
SELECT rm.roadmapStopFk, count(*) n
|
|
FROM routesMonitor rm
|
|
JOIN tExpedition e ON e.routeFk = rm.routeFk
|
|
WHERE e.palletFk IS NULL
|
|
GROUP BY roadmapStopFk
|
|
ORDER BY n DESC
|
|
LIMIT 1
|
|
) sub;
|
|
|
|
IF vTruckFk IS NULL THEN
|
|
CALL util.throw ('TRUCK_NOT_AVAILABLE');
|
|
END IF;
|
|
|
|
INSERT INTO expeditionPallet SET truckFk = vTruckFk;
|
|
|
|
SET vPalletFk = LAST_INSERT_ID();
|
|
|
|
INSERT INTO expeditionScan(expeditionFk, palletFk, workerFk)
|
|
SELECT expeditionFk, vPalletFk, vWorkerFk
|
|
FROM tExpedition
|
|
WHERE palletFk IS NULL;
|
|
|
|
SELECT id INTO vExpeditionStateTypeFk
|
|
FROM expeditionStateType
|
|
WHERE code = 'PALLETIZED';
|
|
|
|
INSERT INTO expeditionState(expeditionFk, typeFk)
|
|
SELECT expeditionFk, vExpeditionStateTypeFk
|
|
FROM tExpedition
|
|
WHERE palletFk IS NULL;
|
|
|
|
UPDATE arcRead SET error = NULL WHERE id = vArcId;
|
|
|
|
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 ;
|