195 lines
5.8 KiB
SQL
195 lines
5.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `sage`.`invoiceOut_add`(IN vInvoiceOutFk INT, IN vXDiarioFk INT)
|
|
BEGIN
|
|
/**
|
|
* Traslada la info de contabilidad relacionada con las facturas emitidas
|
|
*
|
|
* @vYear Año contable del que se quiere trasladar la información
|
|
* @vCompany Empresa de la que se quiere trasladar datos
|
|
*/
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vMaxLengthName INT DEFAULT 35;
|
|
DECLARE vBase DOUBLE;
|
|
DECLARE vVat DOUBLE;
|
|
DECLARE vRate DOUBLE;
|
|
DECLARE vMod347 DOUBLE;
|
|
DECLARE vTaxEqu DOUBLE;
|
|
DECLARE vRateEqu DOUBLE;
|
|
DECLARE vTransactionCode INT;
|
|
DECLARE vCounter INT DEFAULT 0;
|
|
DECLARE vInvoiceOutCorrectedFk INT;
|
|
DECLARE vTaxCode INT;
|
|
DECLARE vIsIntracommunity BOOL DEFAULT FALSE;
|
|
DECLARE vInvoiceTypeSended VARCHAR(1);
|
|
DECLARE vOperationCode VARCHAR(1);
|
|
DECLARE vHasCustomsAccountingNote BOOL;
|
|
|
|
DECLARE vCursor CURSOR FOR
|
|
SELECT oit.taxableBase,
|
|
oit.vat,
|
|
pgc.rate,
|
|
pgc.mod347,
|
|
pgcRE.rate,
|
|
oitRE.vat,
|
|
tc.transactionCode,
|
|
tc.taxCode,
|
|
tc.isIntracommunity,
|
|
tc.operationcode
|
|
FROM vn.invoiceOutTax oit
|
|
JOIN vn.pgc ON pgc.code = oit.pgcFk
|
|
LEFT JOIN vn.pgcEqu e ON e.vatFk = oit.pgcFk
|
|
LEFT JOIN vn.pgcEqu eRE ON eRE.equFk = oit.pgcFk
|
|
LEFT JOIN vn.invoiceOutTax oitRE ON oitRE.invoiceOutFk = oit.invoiceOutFk
|
|
AND oitRE.pgcFk = e.equFk
|
|
LEFT JOIN vn.pgc pgcRE ON pgcRE.code = oitRE.pgcFk
|
|
LEFT JOIN vn.taxCode tc ON tc.code = pgc.code COLLATE 'utf8mb3_unicode_ci'
|
|
WHERE eRE.equFk IS NULL
|
|
AND oit.invoiceOutFk = vInvoiceOutFk
|
|
GROUP BY pgc.code;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
SELECT COUNT(*) INTO vHasCustomsAccountingNote
|
|
FROM vn.XDiario x
|
|
JOIN config c ON c.pendingTaxAccount = x.SUBCTA
|
|
WHERE ASIEN = (SELECT ASIEN FROM vn.XDiario WHERE id = vXDiarioFk);
|
|
|
|
SELECT codeSage INTO vInvoiceTypeSended
|
|
FROM invoiceType
|
|
WHERE code = IF(vHasCustomsAccountingNote, 'informative', 'sended');
|
|
|
|
DELETE FROM movContaIVA
|
|
WHERE id = vXDiarioFk;
|
|
|
|
INSERT INTO movContaIVA(id) VALUES (vXDiarioFk);
|
|
|
|
OPEN vCursor;
|
|
|
|
l: LOOP
|
|
FETCH vCursor INTO vBase,
|
|
vVat,
|
|
vRate,
|
|
vMod347,
|
|
vTaxEqu,
|
|
vRateEqu,
|
|
vTransactionCode,
|
|
vTaxCode,
|
|
vIsIntracommunity,
|
|
vOperationCode;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
SET vCounter = vCounter + 1;
|
|
|
|
CASE vCounter
|
|
WHEN 1 THEN
|
|
UPDATE movContaIVA
|
|
SET BaseIva1 = vBase,
|
|
PorIva1 = vRate,
|
|
CuotaIva1 = vVat,
|
|
PorRecargoEquivalencia1 = vTaxEqu,
|
|
RecargoEquivalencia1 = vRateEqu,
|
|
CodigoTransaccion1 = vTransactionCode,
|
|
CodigoIva1 = vTaxCode
|
|
WHERE id = vXDiarioFk;
|
|
WHEN 2 THEN
|
|
UPDATE movContaIVA
|
|
SET BaseIva2 = vBase,
|
|
PorIva2 = vRate,
|
|
CuotaIva2 = vVat,
|
|
PorRecargoEquivalencia2 = vTaxEqu,
|
|
RecargoEquivalencia2 =vRateEqu,
|
|
CodigoTransaccion2 = vTransactionCode,
|
|
CodigoIva2 = vTaxCode
|
|
WHERE id = vXDiarioFk;
|
|
WHEN 3 THEN
|
|
UPDATE movContaIVA
|
|
SET BaseIva3 = vBase,
|
|
PorIva3 = vRate,
|
|
CuotaIva3 = vVat,
|
|
PorRecargoEquivalencia3 = vTaxEqu,
|
|
RecargoEquivalencia3 = vRateEqu,
|
|
CodigoTransaccion3 = vTransactionCode,
|
|
CodigoIva3 = vTaxCode
|
|
WHERE id = vXDiarioFk;
|
|
WHEN 4 THEN
|
|
UPDATE movContaIVA
|
|
SET BaseIva4 = vBase,
|
|
PorIva4 = vRate,
|
|
CuotaIva4 = vVat,
|
|
PorRecargoEquivalencia4 = vTaxEqu,
|
|
RecargoEquivalencia4 = vRateEqu,
|
|
CodigoTransaccion4 = vTransactionCode,
|
|
CodigoIva4 = vTaxCode
|
|
WHERE id = vXDiarioFk;
|
|
END CASE;
|
|
|
|
UPDATE movContaIVA
|
|
SET Exclusion347 = NOT vMod347,
|
|
Intracomunitaria = vIsIntracommunity,
|
|
ClaveOperacionFactura = vOperationCode
|
|
WHERE id = vXDiarioFk;
|
|
|
|
END LOOP;
|
|
|
|
CLOSE vCursor;
|
|
|
|
UPDATE movContaIVA mci
|
|
JOIN vn.invoiceOut i ON i.id = vInvoiceOutFk
|
|
LEFT JOIN vn.invoiceCorrection ic ON ic.correctedFk = vInvoiceOutFk
|
|
LEFT JOIN vn.invoiceOut ioc ON ioc.id = ic.correctingFk
|
|
JOIN vn.XDiario x ON x.id = mci.id
|
|
JOIN vn.client c ON c.id = i.clientFk
|
|
JOIN Naciones n ON n.countryFk = c.countryFk
|
|
JOIN vn.invoiceOutSerial ios ON ios.code = i.serial
|
|
JOIN vn.taxArea ta ON ta.code = ios.taxAreaFk
|
|
SET mci.Año = YEAR(i.issued),
|
|
mci.Serie = i.serial,
|
|
mci.Factura = RIGHT(i.ref, LENGTH(i.ref) -1),
|
|
mci.FechaFactura = i.issued,
|
|
mci.ImporteFactura = i.amount,
|
|
mci.TipoFactura = vInvoiceTypeSended,
|
|
mci.CodigoCuentaFactura = x.SUBCTA,
|
|
mci.CifDni = c.fi,
|
|
mci.Nombre = SUBSTR(c.socialName, 1, vMaxLengthName),
|
|
mci.SiglaNacion = n.SiglaNacion,
|
|
mci.EjercicioFactura = YEAR(i.issued),
|
|
mci.FechaOperacion = i.issued,
|
|
mci.MantenerAsiento = TRUE,
|
|
mci.FechaFacturaOriginal = x.FECHA_EX
|
|
WHERE mci.id = vXDiarioFk;
|
|
|
|
SELECT correctedFk INTO vInvoiceOutCorrectedFk
|
|
FROM vn.invoiceCorrection
|
|
WHERE correctingFk = vInvoiceOutFk;
|
|
|
|
IF vInvoiceOutCorrectedFk THEN
|
|
UPDATE movContaIVA mci
|
|
JOIN vn.invoiceOut i ON i.id = vInvoiceOutCorrectedFk
|
|
JOIN vn.invoiceCorrection ic ON ic.correctedFk = vInvoiceOutCorrectedFk
|
|
JOIN (SELECT SUM(IF(IFNULL(e.vatFk, TRUE), iot.taxableBase, 0)) taxableBase,
|
|
SUM(IF(IFNULL(e.vatFk, TRUE), iot.vat, 0)) vat,
|
|
SUM(IF(IFNULL(e.vatFk, TRUE), 0, iot.vat)) equ
|
|
FROM vn.invoiceOutTax iot
|
|
LEFT JOIN vn.pgcEqu e ON e.vatFk = iot.pgcFk
|
|
WHERE iot.invoiceOutFk = vInvoiceOutCorrectedFk
|
|
) tax
|
|
JOIN ClavesOperacion co ON co.Descripcion = 'Factura rectificativa'
|
|
SET mci.TipoRectificativa = 2,
|
|
mci.ClaseAbonoRectificativas = 1,
|
|
mci.FechaFacturaOriginal = i.issued,
|
|
mci.FechaOperacion = i.issued,
|
|
mci.BaseImponibleOriginal = tax.taxableBase,
|
|
mci.CuotaIvaOriginal = tax.vat,
|
|
mci.RecargoEquivalenciaOriginal = tax.equ,
|
|
mci.ClaveOperacionFactura = co.ClaveOperacionFactura_
|
|
WHERE mci.id = vXDiarioFk
|
|
AND i.id = vInvoiceOutCorrectedFk;
|
|
|
|
END IF;
|
|
|
|
END$$
|
|
DELIMITER ;
|