DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getTax`(IN vTaxArea VARCHAR(25))
BEGIN
/**
 * Calcula la base imponible, el IVA y el recargo de equivalencia para
 * un conjunto de tickets.
 *
 * @table tmp.ticket(ticketFk) Identificadores de los tickets a calcular
 * @return tmp.ticketAmount (ticketFk, taxableBase, tax, code)
 * @return tmp.ticketTax (ticketFk, pgcFk, taxableBase, rate, code) Impuesto desglosado para cada ticket.
 */
	DROP TEMPORARY TABLE IF EXISTS tmp.addressCompany;
	CREATE TEMPORARY TABLE tmp.addressCompany
		(INDEX (addressFk, companyFk))
		ENGINE = MEMORY
		SELECT DISTINCT t.addressFk, t.companyFk
			FROM tmp.ticket tmpTicket
				JOIN ticket t ON t.id = tmpTicket.ticketFk;

	CALL addressTaxArea ();
 
	IF vTaxArea IS NOT NULL THEN
		UPDATE tmp.addressTaxArea
			SET areaFk = vTaxArea;
	END IF;

	/* Solo se calcula la base imponible (taxableBase) y el impuesto se calculará posteriormente
	* No se debería cambiar el sistema por problemas con los decimales
	*/
	DROP TEMPORARY TABLE IF EXISTS tmp.ticketTax;
	CREATE TEMPORARY TABLE tmp.ticketTax
		(PRIMARY KEY (ticketFk, code, rate))
		ENGINE = MEMORY
		SELECT * FROM (
			SELECT tmpTicket.ticketFk,
					bp.pgcFk,
					SUM(s.quantity * s.price * (100 - s.discount)/100 ) taxableBase,
					pgc.rate,
					tc.code,
					bp.priority
				FROM tmp.ticket tmpTicket
					JOIN sale s ON s.ticketFk = tmpTicket.ticketFk
					JOIN item i ON i.id = s.itemFk
					JOIN ticket t ON t.id = tmpTicket.ticketFk
					JOIN supplier su ON su.id = t.companyFk
					JOIN tmp.addressTaxArea ata
						ON ata.addressFk = t.addressFk AND ata.companyFk = t.companyFk
					JOIN itemTaxCountry itc
						ON itc.itemFk = i.id AND itc.countryFk = su.countryFk
					JOIN bookingPlanner bp
						ON bp.countryFk = su.countryFk
							AND bp.taxAreaFk = ata.areaFk
							AND bp.taxClassFk = itc.taxClassFk
					JOIN pgc ON pgc.code = bp.pgcFk
					JOIN taxClass tc ON tc.id = bp.taxClassFk
				GROUP BY tmpTicket.ticketFk, pgc.code, pgc.rate
				HAVING taxableBase <> 0) t3
			ORDER BY priority;

	DROP TEMPORARY TABLE IF EXISTS tmp.ticketServiceTax;
	CREATE TEMPORARY TABLE tmp.ticketServiceTax
		(PRIMARY KEY (ticketFk, code, rate))
		ENGINE = MEMORY
		SELECT tt.ticketFk,
				pgc.code pgcFk,
				SUM(ts.quantity * ts.price) taxableBase,
				pgc.rate,
				tc.code
			FROM tmp.ticket tt
				JOIN ticketService ts ON ts.ticketFk = tt.ticketFk
				JOIN ticket t ON t.id = tt.ticketFk
				JOIN supplier su ON su.id = t.companyFk
				JOIN tmp.addressTaxArea ata
					ON ata.addressFk = t.addressFk AND ata.companyFk = t.companyFk
				JOIN bookingPlanner bp
					ON bp.countryFk = su.countryFk
						AND bp.taxAreaFk = ata.areaFk
						AND bp.taxClassFk = ts.taxClassFk
				JOIN pgc ON pgc.code = bp.pgcFk
				JOIN taxClass tc ON tc.id = bp.taxClassFk
			GROUP BY tt.ticketFk, pgc.code
			HAVING taxableBase <> 0;

	INSERT INTO tmp.ticketTax (ticketFk, pgcFk, taxableBase, rate, code)
		SELECT ts.ticketFk, ts.pgcFk, ts.taxableBase, ts.rate, ts.code
			FROM tmp.ticketServiceTax ts
	ON DUPLICATE KEY UPDATE ticketTax.taxableBase = VALUES (taxableBase) + ticketTax.taxableBase ;

	DROP TEMPORARY TABLE IF EXISTS tmp.ticketAmount;
	CREATE TEMPORARY TABLE tmp.ticketAmount
		(INDEX (ticketFk))
		ENGINE = MEMORY
		SELECT ticketFk, 
				taxableBase, 
				SUM(CAST(taxableBase * rate / 100 AS DECIMAL(10, 2))) tax,
				code
			FROM tmp.ticketTax
			GROUP BY ticketFk, code;

	DROP TEMPORARY TABLE tmp.addressCompany;
	DROP TEMPORARY TABLE tmp.addressTaxArea;
END$$
DELIMITER ;