/**
 * Creates a buy line from an EDI lot.
 *
 * @param v_edi The EDI id
 */
USE edi;
DROP PROCEDURE IF EXISTS edi_load;
DELIMITER $$
CREATE PROCEDURE edi_load (v_edi INT)
BEGIN
	DECLARE v_ref INT;
	DECLARE v_buy INT;
    DECLARE v_item INT;
	DECLARE v_qty INT;
	DECLARE v_package INT;
    DECLARE v_is_lot BOOLEAN;
    
    -- Carga los datos necesarios del EKT
    
    SELECT ref, qty, package INTO v_ref, v_qty, v_package
		FROM vn2008.buy_edi e
			LEFT JOIN item i ON e.ref = i.id
		WHERE e.id = v_edi;

	-- Inserta el cubo si no existe

	IF v_package = 800 
	THEN
		SET v_package = 800 + v_qty;

		INSERT IGNORE INTO vn2008.Cubos SET
			Id_Cubo = v_package,
            x = 7200 / v_qty,
            y = 1;
	ELSE
		INSERT IGNORE INTO vn2008.Cubos (Id_Cubo, X, Y, Z)
			SELECT bucket_id, ROUND(x_size/10), ROUND(y_size/10), ROUND(z_size/10)
				FROM bucket WHERE bucket_id = v_package;
		
        IF ROW_COUNT() > 0
		THEN
			INSERT INTO vn2008.mail SET
				`subject` = 'Cubo añadido',
				`text` = CONCAT('Se ha añadido el cubo: ', v_package),
				`to` = 'ekt@verdnatura.es';
		END IF;
	END IF;

	-- Intenta obtener el artículo en base a los atributos holandeses
    
    INSERT IGNORE INTO item_track SET
		item_id = v_ref;

	SELECT c.Id_Compra, c.Id_Article INTO v_buy, v_item
		FROM vn2008.buy_edi e 
			JOIN item_track t ON t.item_id = e.ref
			LEFT JOIN vn2008.buy_edi l ON l.ref = e.ref
			LEFT JOIN vn2008.Compres c ON c.buy_edi_id = l.id
            JOIN vn2008.config cfg
		WHERE e.id = v_edi
			AND l.id != v_edi
			AND c.Id_Article != cfg.generic_item
			AND IF(t.s1, l.s1 = e.s1, TRUE)
			AND IF(t.s2, l.s2 = e.s2, TRUE)
			AND IF(t.s3, l.s3 = e.s3, TRUE)
			AND IF(t.s4, l.s4 = e.s4, TRUE)
            AND IF(t.s5, l.s5 = e.s5, TRUE)
            AND IF(t.s6, l.s6 = e.s6, TRUE)
            AND IF(t.kop, l.kop = e.kop, TRUE)
			AND IF(t.pac, l.pac = e.pac, TRUE)
			AND IF(t.cat, l.cat = e.cat, TRUE)
			AND IF(t.ori, l.ori = e.ori, TRUE)
			AND IF(t.pro, l.pro = e.pro, TRUE)
            AND IF(t.sub, l.sub = e.sub, TRUE)
			AND IF(t.package, l.package = e.package, TRUE)
            AND c.Id_Article < 170000
		ORDER BY l.now DESC, c.Id_Compra ASC LIMIT 1;

	-- Determina si el articulo se vende por lotes

	IF v_item
    THEN
		SELECT COUNT(*) > 0 INTO v_is_lot
			FROM vn2008.Articles a
				LEFT JOIN vn2008.Tipos t ON t.tipo_id = a.tipo_id
			WHERE a.Id_Article = v_item
				AND t.`transaction`;

		-- Si el articulo se vende por lotes se inserta un nuevo artículo

		IF v_is_lot
		THEN
			INSERT INTO vn2008.Articles (
				 Article
				,Medida
				,Categoria
				,Id_Origen
				,iva_group_id
				,Foto
				,Color
				,Codintrastat
				,tipo_id
				,Tallos
			)
			SELECT
				 i.`name`
				,IFNULL(e.s1, e.pac)
				,e.cat
				,IFNULL(o.id, 17)
				,IFNULL(a.iva_group_id, 1)
				,a.Foto
				,a.Color
				,a.Codintrastat
				,IFNULL(a.tipo_id, 10)
				,IF(a.tipo_id = 15, 0, 1)
				FROM vn2008.buy_edi e
					LEFT JOIN item i ON i.id = e.ref
					LEFT JOIN vn2008.Origen o ON o.Abreviatura = e.ori
					LEFT JOIN vn2008.Articles a ON a.Id_Article = v_item
				WHERE e.id = v_edi;
					
			SET v_item = LAST_INSERT_ID();
		END IF;
	END IF;

	-- Inserta la compra asociada al EKT

	INSERT INTO vn2008.Compres
	(
		 Id_Entrada
		,buy_edi_id
		,Costefijo
		,Id_Article
		,Nicho
		,grouping
		,caja
		,Packing
		,Cantidad
		,Productor
		,Etiquetas
		,Id_Cubo
	)
	SELECT
		 cfg.edi_entry
		,v_edi
		,(@t := IF(a.Tallos, a.Tallos, 1)) * e.pri
		,IFNULL(v_item, cfg.generic_item)
		,a.Nicho
		,IFNULL(c.grouping, e.pac)
		,IFNULL(c.caja, TRUE)
		,@pac := e.pac / @t
		,@pac * e.qty
		,s.company_name
		,e.qty
		,IFNULL(c.Id_Cubo, e.package)
		FROM vn2008.buy_edi e 
			LEFT JOIN vn2008.Compres c ON c.Id_Compra = v_buy
			LEFT JOIN vn2008.Articles a ON a.Id_Article = c.Id_Article
			LEFT JOIN supplier s ON e.pro = s.supplier_id
            JOIN vn2008.config cfg
		WHERE e.id = v_edi
        LIMIT 1;
END$$
DELIMITER ;