DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_getTax`( 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. */ -- Mantengo el drop porque si no da error en los tests de back de salix -- Table 'addressCompany' was locked with a READ lock and can't be updated' 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 CREATE OR REPLACE TEMPORARY TABLE tmp.ticketTax (PRIMARY KEY (ticketFk, code, rate)) ENGINE = MEMORY WITH sales AS ( SELECT s.ticketFk, s.itemFk, s.quantity * s.price * (100 - s.discount) / 100 total, t.companyFk, t.addressFk, su.countryFk, ata.areaFk, itc.taxClassFk FROM vn.sale s JOIN tmp.ticket tmp ON tmp.ticketFk = s.ticketFk JOIN vn.ticket t ON t.id = s.ticketFk JOIN vn.supplier su ON su.id = t.companyFk JOIN tmp.addressTaxArea ata ON ata.addressFk = t.addressFk AND ata.companyFk = t.companyFk JOIN vn.itemTaxCountry itc ON itc.itemFk = s.itemFk AND itc.countryFk = su.countryFk HAVING total ) SELECT s.ticketFk, bp.pgcFk, SUM(s.total) taxableBase, pgc.rate, tc.code, bp.priority FROM sales s JOIN vn.bookingPlanner bp ON bp.countryFk = s.countryFk AND bp.taxAreaFk = s.areaFk AND bp.taxClassFk = s.taxClassFk JOIN vn.pgc ON pgc.code = bp.pgcFk JOIN vn.taxClass tc ON tc.id = bp.taxClassFk GROUP BY s.ticketFk, pgc.code, pgc.rate HAVING taxableBase ORDER BY priority; CREATE OR REPLACE 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; 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 ; CREATE OR REPLACE 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, tmp.addressTaxArea; END$$ DELIMITER ;