DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`Greuge_Evolution_Add`()
BEGIN
/*
	Inserta en la tabla Greuge_Evolution el saldo acumulado de cada cliente,
	así como las ventas acumuladas en los ultimos 365 dias, para poder controlar
	su evolucion.
*/
	DECLARE datFEC DATE;
	DECLARE datFEC_TOMORROW DATE;
	DECLARE datFEC_LASTYEAR DATE;
   
    DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN 
	    
		GET DIAGNOSTICS CONDITION 2 @errno = MYSQL_ERRNO, @text = MESSAGE_TEXT;
		SELECT CONCAT('ERROR ', IFNULL(@errno,0), ': ', ifnull(@text,'texto'));
		CALL vn.mail_insert(
			'jgallego@verdnatura.es,pako@verdnatura.es',
			'noreply@verdnatura.es',
			'Greuge_Evolution_Add',
			CONCAT('ERROR ', IFNULL(@errno, 0), ': ', ifnull(@text, 'texto'))
		);
	
	END;
  
	SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;

	DELETE FROM bi.Greuge_Evolution WHERE Fecha >= TIMESTAMPADD(MONTH,-1,util.VN_CURDATE());

	SELECT 	TIMESTAMPADD(DAY,1,MAX(Fecha)),
			TIMESTAMPADD(DAY,2,MAX(Fecha))
		INTO  datFEC,
				datFEC_TOMORROW
		FROM bi.Greuge_Evolution;

	SET datFEC_LASTYEAR = TIMESTAMPADD(YEAR,-1,datFEC);

	DELETE FROM bi.Greuge_Evolution WHERE Fecha >= datFEC;
    
	DROP TEMPORARY TABLE IF EXISTS maxInvoice;
    
	CREATE TEMPORARY TABLE maxInvoice
		(PRIMARY KEY (Id_Cliente))
		ENGINE = MEMORY
		SELECT DISTINCT clientFk Id_Cliente, max(issued) as maxFecha
			   FROM vn.invoiceOut
			   GROUP BY clientFk
			   HAVING maxFecha < timestampadd(month,-2,datFEC);
    
	WHILE datFEC < util.VN_CURDATE() DO

		REPLACE bi.Greuge_Evolution(Id_Cliente, Fecha, Greuge, Ventas, Fosil)

		SELECT Id_Cliente, datFEC as Fecha, Greuge, Ventas, 0
			FROM (
				SELECT clientFk Id_Cliente, sum(amount) as Greuge
					FROM vn.greuge
						where shipped <= datFEC
						group by clientFk
			) sub
			RIGHT JOIN
			
				(
				
					SELECT Id_Cliente, sum(Ventas) as Ventas
					FROM
					(
					
						SELECT Id_Cliente, IF (fecha != datFEC, -1,1) * (importe + recargo) as Ventas
							FROM bs.ventas
							WHERE fecha = datFEC or fecha = datFEC_LASTYEAR
						
						UNION ALL
						
						SELECT Id_Cliente, Ventas
							FROM bi.Greuge_Evolution
							WHERE Fecha = TIMESTAMPADD(DAY, -1, datFEC)
						
					) sub
					group by Id_Cliente
					
				) v using(Id_Cliente) 
			;
			
		-- Ahora calcularemos el greuge muerto
		UPDATE bi.Greuge_Evolution ge 
				JOIN maxInvoice m using(Id_Cliente)
			SET FOSIL = GREUGE
			WHERE m.maxFecha < TIMESTAMPADD(MONTH,-2,ge.Fecha);

		-- Recobro
		UPDATE bi.Greuge_Evolution ge 
			JOIN (
				   SELECT a.clientFk Id_Cliente, sum(sc.value * s.quantity) as Importe
					   FROM vn.ticket t
					   JOIN vn.address a on a.id = t.addressFk
					   JOIN vn.sale s on s.ticketFk = t.id
					   JOIN vn.saleComponent sc on sc.saleFk = s.id
				   WHERE t.shipped >= datFEC 
					   AND t.shipped < datFEC_TOMORROW
					   AND sc.componentFk = 17 -- Recobro
				   GROUP BY a.clientFk
				 ) sub using(Id_Cliente)
			SET Recobro = Importe
			WHERE ge.Fecha = datFEC;
        
		SET datFEC = datFEC_TOMORROW;
		SET datFEC_TOMORROW = TIMESTAMPADD(DAY,1,datFEC_TOMORROW);
		SET datFEC_LASTYEAR = TIMESTAMPADD(YEAR,-1,datFEC);
        
	END WHILE;

	DROP TEMPORARY TABLE IF EXISTS maxInvoice;
END$$
DELIMITER ;