DELIMITER $$

CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`zone_getCollisions`()
BEGIN
/**
 * Calcula si para un mismo codigo postal y dia
 * hay mas de una zona configurada y manda correo
 *
 */
	DECLARE vGeoFk INT DEFAULT NULL;
	DECLARE vZoneFk INT;
	DECLARE vIsDone INT DEFAULT FALSE;
	DECLARE vTableCollisions TEXT;
    DECLARE json_data JSON;
	DECLARE cur1 CURSOR FOR SELECT zoneFk from tmp.zoneOption;

	DECLARE CONTINUE HANDLER FOR NOT FOUND SET vIsDone = TRUE;

	DROP TEMPORARY TABLE IF EXISTS tmp.zone;
	CREATE TEMPORARY TABLE tmp.zone
		SELECT z.id
			FROM zone z
				JOIN agencyMode am ON am.id = z.agencyModeFk
				JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk
			WHERE dm.code IN ('AGENCY','DELIVERY');

	CALL zone_getOptionsForShipment(util.VN_CURDATE(),FALSE);

	DROP TEMPORARY TABLE IF EXISTS tmp.zoneNodes;
	CREATE TEMPORARY TABLE tmp.zoneNodes (
			geoFk INT,
			name VARCHAR(100),
			parentFk INT,
			sons INT,
			isChecked BOOL DEFAULT 0,
			zoneFk INT,
			PRIMARY KEY zoneFkk (zoneFk, geoFk),
			INDEX(geoFk))
			ENGINE = MyISAM;

	OPEN cur1;
	cur1Loop: LOOP
		SET vIsDone = FALSE;
		FETCH cur1 INTO vZoneFk;
		IF vIsDone THEN
			LEAVE cur1Loop;
	    END IF;

		CALL zone_getLeaves(vZoneFk, NULL, NULL, TRUE);

		myLoop: LOOP
			SET vGeoFk = NULL;
			SELECT geoFk INTO vGeoFk
				FROM tmp.zoneNodes zn
				WHERE NOT isChecked
				LIMIT 1;

			IF vGeoFk IS NULL THEN
				LEAVE myLoop;
			END IF;

			CALL zone_getLeaves(vZoneFk, vGeoFk, NULL, TRUE);
			UPDATE tmp.zoneNodes
				SET isChecked = TRUE
				WHERE geoFk = vGeoFk;
		END LOOP;

	END LOOP;
	CLOSE cur1;
	DELETE FROM tmp.zoneNodes
		WHERE sons > 0;

	DROP TEMPORARY TABLE IF EXISTS geoCollision;
	CREATE TEMPORARY TABLE geoCollision
		SELECT z.agencyModeFk, zn.geoFk, zw.warehouseFk
			FROM tmp.zoneNodes zn
				JOIN zone z ON z.id = zn.zoneFk
				JOIN zoneWarehouse zw ON z.id = zw.zoneFk
	        GROUP BY z.agencyModeFk, zn.geoFk, zw.warehouseFk
	        HAVING count(*) > 1;

    -- Recojo los datos de la zona que ha dado conflicto
    SELECT JSON_ARRAYAGG(
        JSON_OBJECT(
            'zoneFk', zoneFk,
            'zn',  JSON_OBJECT('name', zn.name),
            'z',  JSON_OBJECT('name', z.name,'price', z.price),
            'w',  JSON_OBJECT('name', w.name)
            )
    ) FROM tmp.zoneNodes zn
    JOIN zone z ON z.id = zn.zoneFk
    JOIN geoCollision gc ON gc.agencyModeFk = z.agencyModeFk AND zn.geoFk = gc.geoFk
    JOIN warehouse w ON w.id = gc.warehouseFk
    INTO json_data;

    -- Creo un registro de la notificacion 'zone-included' para reportar via email
    SELECT util.notification_send(
        'zone-included',
            JSON_OBJECT('zoneCollisions',json_data),
        account.myUser_getId()
    );

	DROP TEMPORARY TABLE
		geoCollision,
		tmp.zone,
		tmp.zoneNodes,
		tmp.zoneOption;
END$$
DELIMITER ;