salix/services/db/install/changes/1.2-CHECK/04-ticketGetTax.sql

99 lines
3.9 KiB
SQL

USE `vn`;
DROP procedure IF EXISTS `ticketGetTax`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketGetTax`()
READS SQL DATA
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
* @return tmp.ticketTax 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 ();
/** 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
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT tmpTicket.ticketFk,
bp.pgcFk,
SUM(s.quantity * s.price * (100 - s.discount)/100 ) AS taxableBase,
pgc.rate,
tc.code
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;
DROP TEMPORARY TABLE IF EXISTS tmp.ticketServiceTax;
CREATE TEMPORARY TABLE tmp.ticketServiceTax
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT tt.ticketFk,
SUM(ts.quantity * ts.price) AS taxableBase,
pgc.rate,
tc.code
FROM tmp.ticketTax 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 AND pgc.rate = tt.rate
JOIN taxClass tc ON tc.id = bp.taxClassFk
GROUP BY tt.ticketFk, tt.code,tt.rate
HAVING taxableBase != 0;
UPDATE tmp.ticketTax tt
JOIN tmp.ticketServiceTax ts ON tt.ticketFk = ts.ticketFk AND tt.code = ts.code AND tt.rate = ts.rate
SET tt.taxableBase = tt.taxableBase + ts.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 IF EXISTS tmp.addressCompany;
DROP TEMPORARY TABLE IF EXISTS tmp.addressTaxArea;
END$$
DELIMITER ;