DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`expeditionPallet_build`(IN vExpeditions JSON, IN vArcId INT, IN 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 vn.arcRead * @param vWorkerFk INT Identificador de vn.worker * @param out vPalletFk Identificador de vn.expeditionPallet */ DECLARE vCounter INT; DECLARE vExpeditionFk INT; DECLARE vTruckFk INT; DECLARE vPrinterFk INT; DROP TEMPORARY TABLE IF EXISTS tExpedition; CREATE TEMPORARY TABLE tExpedition SELECT e.id expeditionFk, r.id routeFk, ep.id palletFk FROM vn.expedition e, vn.route r, vn.expeditionPallet ep LIMIT 0; ALTER TABLE tExpedition ADD 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 vn.expedition e LEFT JOIN vn.ticket t ON t.id = e.ticketFk LEFT JOIN vn.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 expeditionTruckFk INTO vTruckFk FROM ( SELECT rm.expeditionTruckFk, count(*) n FROM vn.routesMonitor rm JOIN tExpedition e ON e.routeFk = rm.routeFk GROUP BY expeditionTruckFk ORDER BY n DESC LIMIT 1) sub; IF vTruckFk IS NULL THEN CALL util.throw ('TRUCK_NOT_AVAILABLE'); END IF; INSERT INTO vn.expeditionPallet(truckFk) VALUES(vTruckFk); SET vPalletFk = LAST_INSERT_ID(); END IF; INSERT INTO vn.expeditionScan(expeditionFk, palletFk, workerFk) SELECT expeditionFk, vPalletFk, vWorkerFk FROM tExpedition ON DUPLICATE KEY UPDATE palletFk = vPalletFk, workerFk = vWorkerFk; SELECT printerFk INTO vPrinterFk FROM vn.arcRead WHERE id = vArcId; CALL vn.report_print( 'LabelPalletExpedition', vPrinterFk, account.myUser_getId(), JSON_OBJECT('palletFk', vPalletFk, 'userFk', account.myUser_getId()), 'high' ); UPDATE vn.expeditionPallet SET isPrint = TRUE WHERE id = vPalletFk; DROP TEMPORARY TABLE tExpedition; END$$ DELIMITER ;