salix/db/routines/edi/procedures/ekt_scan.sql

132 lines
3.3 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `edi`.`ekt_scan`(vBarcode VARCHAR(512))
BEGIN
/**
* Busca transaciones a partir de un código de barras, las marca como escaneadas
* y las devuelve.
* Ver https://wiki.verdnatura.es/index.php/Ekt#Algoritmos_de_lectura
*
* @param vBarcode Código de compra de una etiqueta de subasta
* @param vLabels Cantidad escaneada
* @table tmp.ekt(ektFk) Transacciones escaneadas
*/
DECLARE vIsFound BOOL;
DECLARE vUsefulAuctionLeftSegmentLength INT;
DECLARE vStandardBarcodeLength INT;
DECLARE vFloridayBarcodeLength INT;
DECLARE vFloramondoBarcodeLength INT;
DECLARE vAuction INT;
DECLARE vKlo INT;
DECLARE vFec DATE;
DECLARE vShortAgj INT;
DECLARE vLongAgj INT;
DECLARE vXtraLongAgj INT;
DECLARE vDefaultKlo INT;
SELECT
ec.usefulAuctionLeftSegmentLength,
ec.standardBarcodeLength,
ec.floridayBarcodeLength,
ec.floramondoBarcodeLength,
ec.defaultKlo
INTO
vUsefulAuctionLeftSegmentLength,
vStandardBarcodeLength,
vFloridayBarcodeLength,
vFloramondoBarcodeLength,
vDefaultKlo
FROM edi.ektConfig ec;
DROP TEMPORARY TABLE IF EXISTS tmp.ekt;
CREATE TEMPORARY TABLE tmp.ekt
ENGINE = MEMORY
SELECT id ektFk FROM ekt LIMIT 0;
CASE
WHEN LENGTH(vBarcode) <= vFloridayBarcodeLength THEN
INSERT INTO tmp.ekt
SELECT id
FROM edi.ektRecent e
WHERE e.cps = vBarcode
OR e.batchNumber = vBarcode;
WHEN LENGTH(vBarcode) = vFloramondoBarcodeLength THEN
INSERT INTO tmp.ekt
SELECT e.id
FROM edi.ektRecent e
WHERE e.pro = MID(vBarcode,2,6)
AND CAST(e.ptd AS SIGNED) = MID(vBarcode,8,5);
ELSE
SET vBarcode = LPAD(vBarcode,vStandardBarcodeLength,'0');
SET vAuction = MID(vBarcode, 1, 3);
SET vKlo = MID(vBarcode, 4, 2);
SET vFec = MAKEDATE(YEAR(util.VN_CURDATE()), MID(vBarcode, 6, 3));
SET vShortAgj = MID(vBarcode, 9, 5);
SET vLongAgj = MID(vBarcode, 9, 7);
SET vXtraLongAgj = MID(vBarcode, 9, 8);
-- Clásico de subasta
-- Trade standard
-- Trade que construye como la subasta
-- Trade como el anterior pero sin trade code
INSERT INTO tmp.ekt
SELECT id
FROM ekt
WHERE fec >= vFec - INTERVAL 1 DAY
AND ((
vKlo = vDefaultKlo
AND (klo = vKlo OR klo IS NULL OR klo = 0)
AND agj IN (vShortAgj, vLongAgj, vXtraLongAgj))
OR (klo = vKlo
AND auction = vAuction
AND agj = vShortAgj)
)
ORDER BY agj DESC, fec DESC
LIMIT 1;
SELECT COUNT(*) FROM tmp.ekt INTO vIsFound;
-- BatchNumber largo
IF NOT vIsFound THEN
INSERT INTO tmp.ekt
SELECT id
FROM edi.ektRecent e
WHERE e.batchNumber
= LEFT(vBarcode,vUsefulAuctionLeftSegmentLength)
AND e.batchNumber > 0;
SELECT COUNT(*) FROM tmp.ekt INTO vIsFound;
END IF;
-- Order Number
IF NOT vIsFound THEN
INSERT INTO tmp.ekt
SELECT id
FROM edi.ektRecent e
WHERE e.putOrderFk = vBarcode;
SELECT COUNT(*) FROM tmp.ekt INTO vIsFound;
END IF;
-- deliveryNumber incrustado
IF NOT vIsFound THEN
INSERT INTO tmp.ekt
SELECT id
FROM edi.ektRecent e
WHERE e.deliveryNumber
= MID(vBarcode, 4, 13)
AND e.deliveryNumber > 0;
SELECT COUNT(*) FROM tmp.ekt INTO vIsFound;
END IF;
END CASE;
IF vIsFound THEN
UPDATE ekt e
JOIN tmp.ekt t ON t.ektFk = e.id
SET e.scanned = TRUE;
END IF;
END$$
DELIMITER ;