hedera-web/rest/edi/plsql/batch_new.sql

170 lines
3.2 KiB
SQL

/**
* Adds a new lot, generates its barcode
* inserts/updates de record on table #vn2008.buy_edi
**/
USE edi;
DROP PROCEDURE IF EXISTS batch_new;
DELIMITER $$
CREATE PROCEDURE batch_new (
v_message INT
,v_type MEDIUMINT
,v_delivery_number BIGINT
,v_fec DATE
,v_hor TIME
,v_ref INT
,v_agj INT
,v_cat VARCHAR(2)
,v_pac INT
,v_sub MEDIUMINT
,v_kop INT
,v_ptd VARCHAR(6)
,v_pro MEDIUMINT
,v_ori VARCHAR(3)
,v_ptj MEDIUMINT
,v_qty INT
,v_pri DOUBLE
,v_klo SMALLINT
,v_s1 VARCHAR(3)
,v_s2 VARCHAR(3)
,v_s3 VARCHAR(3)
,v_s4 VARCHAR(4)
,v_s5 VARCHAR(3)
,v_s6 VARCHAR(3)
,v_k1 SMALLINT
,v_k2 SMALLINT
,v_p1 TINYINT
,v_p2 TINYINT
,v_auction SMALLINT
,v_package INT
)
BEGIN
DECLARE v_edi INT;
DECLARE v_barcode CHAR(15) DEFAULT NULL;
DECLARE v_is_duplicated BOOLEAN DEFAULT FALSE;
DECLARE v_update_existent BOOLEAN DEFAULT FALSE;
DECLARE CONTINUE HANDLER FOR 1062 -- ER_DUP_KEY
SET v_is_duplicated = TRUE;
-- Genera el código de barras
IF v_agj != 0 AND v_agj IS NOT NULL
THEN
SET v_barcode = CONCAT(
LPAD(v_auction, 2, 0),
LPAD(IFNULL(v_klo, 99), 2, 0),
LPAD(DAYOFYEAR(v_fec), 3, 0),
IF(v_klo IS NULL OR v_klo = 99,
LPAD(v_agj, 7, 0),
CONCAT(LPAD(v_agj, 5, 0), '01')
),
'0'
);
END IF;
IF v_kop IS NULL
THEN
SELECT default_kop INTO v_kop FROM config;
END IF;
-- Inserta el nuevo EKT
INSERT INTO vn2008.buy_edi SET
barcode = IFNULL(v_barcode, barcode)
,delivery_number = v_delivery_number
,entry_year = YEAR(v_fec)
,fec = v_fec
,hor = v_hor
,ref = v_ref
,agj = v_agj
,cat = v_cat
,pac = v_pac
,sub = v_sub
,kop = v_kop
,ptd = v_ptd
,pro = v_pro
,ori = v_ori
,ptj = v_ptj
,qty = v_qty
,pri = v_pri
,klo = v_klo
,s1 = v_s1
,s2 = v_s2
,s3 = v_s3
,s4 = v_s4
,s5 = v_s5
,s6 = v_s6
,k01 = v_k1
,k02 = v_k2
,k03 = v_p1
,k04 = v_p2
,auction = v_auction
,package = v_package;
-- Si el EKT está duplicado y el que habia en la tabla era uno
-- provisional, lo actualiza con los nuevos valores.
IF NOT v_is_duplicated
THEN
SET v_edi = LAST_INSERT_ID();
CALL edi_load (v_edi);
ELSEIF v_delivery_number != 0
AND v_delivery_number IS NOT NULL
THEN
SELECT id INTO v_edi
FROM vn2008.buy_edi
WHERE delivery_number = v_delivery_number;
SELECT COUNT(*) = 0 INTO v_update_existent
FROM vn2008.buy_edi e
JOIN batch b ON b.buy_edi_id = e.id
JOIN config c
WHERE e.delivery_number = v_delivery_number
AND b.type_id != c.presale_id;
END IF;
IF v_update_existent
THEN
UPDATE vn2008.buy_edi SET
barcode = IFNULL(v_barcode, barcode)
,fec = v_fec
,hor = v_hor
,ref = v_ref
,agj = v_agj
,cat = v_cat
,pac = v_pac
,sub = v_sub
,kop = v_kop
,ptd = v_ptd
,pro = v_pro
,ori = v_ori
,ptj = v_ptj
,qty = v_qty
,pri = v_pri
,klo = v_klo
,s1 = v_s1
,s2 = v_s2
,s3 = v_s3
,s4 = v_s4
,s5 = v_s5
,s6 = v_s6
,k01 = v_k1
,k02 = v_k2
,k03 = v_p1
,k04 = v_p2
,auction = v_auction
,package = v_package
WHERE id = v_edi;
END IF;
-- Registra el lote
INSERT INTO batch SET
message_id = v_message
,type_id = v_type
,buy_edi_id = v_edi;
END$$
DELIMITER ;