This commit is contained in:
parent
4ee50991d6
commit
efdf62438f
|
@ -0,0 +1,251 @@
|
||||||
|
CREATE TABLE `vn`.`invoiceInCorrection` (
|
||||||
|
`correctingFk` mediumint(8) unsigned NOT NULL COMMENT 'Factura rectificativa',
|
||||||
|
`correctedFk` mediumint(8) unsigned NOT NULL COMMENT 'Factura rectificada',
|
||||||
|
`cplusRectificationTypeFk` int(10) unsigned NOT NULL,
|
||||||
|
`cplusInvoiceType477Fk` int(10) unsigned NOT NULL,
|
||||||
|
`invoiceCorrectionTypeFk` int(11) NOT NULL DEFAULT 3,
|
||||||
|
PRIMARY KEY (`correctingFk`),
|
||||||
|
KEY `invoiceInCorrection_correctedFk` (`correctedFk`),
|
||||||
|
KEY `invoiceInCorrection_cplusRectificationTypeFk` (`cplusRectificationTypeFk`),
|
||||||
|
KEY `invoiceInCorrection_cplusInvoiceType477Fk` (`cplusInvoiceType477Fk`),
|
||||||
|
KEY `invoiceInCorrection_invoiceCorrectionTypeFk` (`invoiceCorrectionTypeFk`),
|
||||||
|
CONSTRAINT `invoiceInCorrection_correctedFk` FOREIGN KEY (`correctedFk`) REFERENCES `invoiceIn` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
|
||||||
|
CONSTRAINT `invoiceInCorrection_correctingFk` FOREIGN KEY (`correctingFk`) REFERENCES `invoiceIn` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
|
||||||
|
CONSTRAINT `invoiceInCorrection_cplusInvoiceType477Fk` FOREIGN KEY (`cplusInvoiceType477Fk`) REFERENCES `cplusInvoiceType477` (`id`) ON UPDATE CASCADE,
|
||||||
|
CONSTRAINT `invoiceInCorrection_invoiceCorrectionTypeFk` FOREIGN KEY (`invoiceCorrectionTypeFk`) REFERENCES `invoiceCorrectionType` (`id`) ON UPDATE CASCADE,
|
||||||
|
CONSTRAINT `invoiceInCorrection_cplusRectificationTypeFk` FOREIGN KEY (`cplusRectificationTypeFk`) REFERENCES `cplusRectificationType` (`id`) ON UPDATE CASCADE
|
||||||
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci COMMENT='Relacion entre las facturas rectificativas y las rectificadas.';
|
||||||
|
|
||||||
|
|
||||||
|
INSERT INTO `salix`.`ACL` (`model`, `property`, `accessType`, `permission`, `principalType`, `principalId`)
|
||||||
|
VALUES
|
||||||
|
('InvoiceInCorrection', '*', '*', 'ALLOW', 'ROLE', 'administrative'),
|
||||||
|
('InvoiceCorrectionType', '*', '*', 'ALLOW', 'ROLE', 'administrative'),
|
||||||
|
('CplusInvoiceType477', '*', '*', 'ALLOW', 'ROLE', 'administrative'),
|
||||||
|
('CplusRectificationType', '*', '*', 'ALLOW', 'ROLE', 'administrative');
|
||||||
|
|
||||||
|
|
||||||
|
DROP PROCEDURE IF EXISTS sage.invoiceIn_add;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
$$
|
||||||
|
CREATE DEFINER=`root`@`localhost` PROCEDURE `sage`.`invoiceIn_add`(vInvoiceInFk INT, vXDiarioFk INT)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Traslada la info de contabilidad relacionada con las facturas recibidas
|
||||||
|
*
|
||||||
|
* @vInvoiceInFk Factura recibida
|
||||||
|
* @vXDiarioFk Id tabla XDiario
|
||||||
|
*/
|
||||||
|
DECLARE vDone BOOL DEFAULT FALSE;
|
||||||
|
DECLARE vBase DOUBLE;
|
||||||
|
DECLARE vVat DOUBLE;
|
||||||
|
DECLARE vRate DOUBLE;
|
||||||
|
DECLARE vTransactionCode INT;
|
||||||
|
DECLARE vCounter INT DEFAULT 0;
|
||||||
|
DECLARE vTransactionCodeOld INT;
|
||||||
|
DECLARE vTaxCode INT;
|
||||||
|
DECLARE vTaxCodeOld INT;
|
||||||
|
DECLARE vOperationCode VARCHAR(1);
|
||||||
|
DECLARE vIsIntracommunity BOOL DEFAULT FALSE;
|
||||||
|
DECLARE vSerialDua VARCHAR(1) DEFAULT 'D';
|
||||||
|
DECLARE vInvoiceTypeReceived VARCHAR(1);
|
||||||
|
DECLARE vInvoiceTypeInformative VARCHAR(1);
|
||||||
|
DECLARE vInvoiceInOriginalFk INT;
|
||||||
|
|
||||||
|
DECLARE vCursor CURSOR FOR
|
||||||
|
SELECT it.taxableBase,
|
||||||
|
CAST((( it.taxableBase / 100) * t.PorcentajeIva) AS DECIMAL (10,2)),
|
||||||
|
t.PorcentajeIva,
|
||||||
|
it.transactionTypeSageFk,
|
||||||
|
it.taxTypeSageFk,
|
||||||
|
t.isIntracommunity,
|
||||||
|
tt.ClaveOperacionDefecto
|
||||||
|
FROM vn.invoiceIn i
|
||||||
|
JOIN vn.invoiceInTax it ON it.InvoiceInFk = i.id
|
||||||
|
JOIN TiposIva t ON t.CodigoIva = it.taxTypeSageFk
|
||||||
|
JOIN TiposTransacciones tt ON tt.CodigoTransaccion = it.transactionTypeSageFk
|
||||||
|
LEFT JOIN vn.dua d ON d.id = vInvoiceInFk
|
||||||
|
WHERE i.id = vInvoiceInFk
|
||||||
|
AND d.id IS NULL;
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||||
|
|
||||||
|
DELETE FROM movContaIVA
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
|
||||||
|
SELECT codeSage INTO vInvoiceTypeReceived
|
||||||
|
FROM invoiceType WHERE code ='received';
|
||||||
|
|
||||||
|
SELECT codeSage INTO vInvoiceTypeInformative
|
||||||
|
FROM invoiceType WHERE code ='informative';
|
||||||
|
|
||||||
|
INSERT INTO movContaIVA(id, LibreA1)
|
||||||
|
VALUES (vXDiarioFk, vInvoiceInFk);
|
||||||
|
|
||||||
|
SELECT invoiceInOriginalFk INTO vInvoiceInOriginalFk
|
||||||
|
FROM vn.invoiceInRefund
|
||||||
|
WHERE invoiceInRefundFk = vInvoiceInFk;
|
||||||
|
|
||||||
|
IF vInvoiceInOriginalFk THEN
|
||||||
|
|
||||||
|
UPDATE movContaIVA mci
|
||||||
|
JOIN vn.invoiceInRefund iir ON iir.invoiceInRefundFk = vInvoiceInFk
|
||||||
|
JOIN (SELECT issued,
|
||||||
|
SUM(sub.taxableBase) taxableBase,
|
||||||
|
SUM(ROUND((sub.taxableBase * sub.PorcentajeIva) / 100 , 2)) vat
|
||||||
|
FROM (SELECT issued,
|
||||||
|
SUM(iit.taxableBase) taxableBase,
|
||||||
|
ti.PorcentajeIva
|
||||||
|
FROM vn.invoiceIn i
|
||||||
|
JOIN vn.invoiceInTax iit ON iit.invoiceInFk = i.id
|
||||||
|
JOIN sage.TiposIva ti ON ti.CodigoIva = iit.taxTypeSageFk
|
||||||
|
WHERE i.id = vInvoiceInOriginalFk
|
||||||
|
GROUP BY ti.CodigoIva)sub
|
||||||
|
) invoiceInOriginal
|
||||||
|
JOIN ClavesOperacion co ON co.Descripcion = 'Factura rectificativa'
|
||||||
|
SET mci.TipoRectificativa = iir.refundCategoryFk,
|
||||||
|
mci.ClaseAbonoRectificativas = iir.refundType,
|
||||||
|
mci.FechaFacturaOriginal = invoiceInOriginal.issued,
|
||||||
|
mci.FechaOperacion = invoiceInOriginal.issued,
|
||||||
|
mci.BaseImponibleOriginal = invoiceInOriginal.taxableBase,
|
||||||
|
mci.CuotaIvaOriginal = invoiceInOriginal.vat,
|
||||||
|
mci.ClaveOperacionFactura = co.ClaveOperacionFactura_
|
||||||
|
WHERE mci.id = vXDiarioFk;
|
||||||
|
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
OPEN vCursor;
|
||||||
|
|
||||||
|
l: LOOP
|
||||||
|
FETCH vCursor INTO vBase,
|
||||||
|
vVat,
|
||||||
|
vRate,
|
||||||
|
vTransactionCode,
|
||||||
|
vTaxCode,
|
||||||
|
vIsIntracommunity,
|
||||||
|
vOperationCode;
|
||||||
|
|
||||||
|
IF vDone THEN
|
||||||
|
LEAVE l;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SET vTransactionCodeOld = vTransactionCode;
|
||||||
|
SET vTaxCodeOld = vTaxCode;
|
||||||
|
|
||||||
|
IF vOperationCode IS NOT NULL THEN
|
||||||
|
UPDATE movContaIVA
|
||||||
|
SET ClaveOperacionFactura = vOperationCode
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SET vCounter = vCounter + 1;
|
||||||
|
CASE vCounter
|
||||||
|
WHEN 1 THEN
|
||||||
|
UPDATE movContaIVA
|
||||||
|
SET BaseIva1 = vBase,
|
||||||
|
PorIva1 = vRate,
|
||||||
|
CuotaIva1 = vVat,
|
||||||
|
CodigoTransaccion1 = vTransactionCode,
|
||||||
|
CodigoIva1 = vTaxCode
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
|
||||||
|
WHEN 2 THEN
|
||||||
|
UPDATE movContaIVA
|
||||||
|
SET BaseIva2 = vBase,
|
||||||
|
PorIva2 = vRate,
|
||||||
|
CuotaIva2 = vVat,
|
||||||
|
CodigoTransaccion2 = vTransactionCode,
|
||||||
|
CodigoIva2 = vTaxCode
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
WHEN 3 THEN
|
||||||
|
UPDATE movContaIVA
|
||||||
|
SET BaseIva3 = vBase,
|
||||||
|
PorIva3 = vRate,
|
||||||
|
CuotaIva3 = vVat,
|
||||||
|
CodigoTransaccion3 = vTransactionCode,
|
||||||
|
CodigoIva3 = vTaxCode
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
WHEN 4 THEN
|
||||||
|
UPDATE movContaIVA
|
||||||
|
SET BaseIva4 = vBase,
|
||||||
|
PorIva4 = vRate,
|
||||||
|
CuotaIva4 = vVat,
|
||||||
|
CodigoTransaccion4 = vTransactionCode,
|
||||||
|
CodigoIva4 = vTaxCode
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
ELSE
|
||||||
|
SELECT vXDiarioFk INTO vXDiarioFk;
|
||||||
|
END CASE;
|
||||||
|
|
||||||
|
IF vIsIntracommunity THEN
|
||||||
|
UPDATE movContaIVA
|
||||||
|
SET Intracomunitaria = TRUE
|
||||||
|
WHERE id = vXDiarioFk;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SET vTransactionCodeOld = vTransactionCode;
|
||||||
|
SET vTaxCodeOld = vTaxCode;
|
||||||
|
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
CLOSE vCursor;
|
||||||
|
|
||||||
|
UPDATE movContaIVA mci
|
||||||
|
JOIN tmp.invoiceIn ii ON ii.id = vInvoiceInFk
|
||||||
|
JOIN vn.XDiario x ON x.id = mci.id
|
||||||
|
LEFT JOIN tmp.invoiceDua id ON id.id = mci.id
|
||||||
|
JOIN vn.supplier s ON s.id = ii.supplierFk
|
||||||
|
JOIN Naciones n ON n.countryFk = s.countryFk
|
||||||
|
SET mci.CodigoDivisa = ii.currencyFk,
|
||||||
|
mci.Año = YEAR(ii.issued),
|
||||||
|
mci.Serie = ii.serial,
|
||||||
|
mci.Factura = ii.serialNumber,
|
||||||
|
mci.FechaFactura = ii.issued,
|
||||||
|
mci.ImporteFactura = IFNULL(mci.BaseIva1, 0) + IFNULL(mci.CuotaIva1, 0) +
|
||||||
|
IFNULL(mci.BaseIva2, 0) + IFNULL(mci.CuotaIva2, 0) +
|
||||||
|
IFNULL(mci.BaseIva3, 0) + IFNULL(mci.CuotaIva3, 0) +
|
||||||
|
IFNULL(mci.BaseIva4, 0) + IFNULL(mci.CuotaIva4, 0),
|
||||||
|
mci.TipoFactura = IF(id.id, IF( ii.serial = vSerialDua COLLATE utf8mb3_unicode_ci, vInvoiceTypeReceived, vInvoiceTypeInformative), vInvoiceTypeReceived),
|
||||||
|
mci.CodigoCuentaFactura = x.SUBCTA,
|
||||||
|
mci.CifDni = IF(LEFT(TRIM(s.nif), 2) = n.SiglaNacion, SUBSTRING(TRIM(s.nif), 3), s.nif),
|
||||||
|
mci.Nombre = s.name,
|
||||||
|
mci.SiglaNacion = n.SiglaNacion,
|
||||||
|
mci.EjercicioFactura = YEAR(ii.issued),
|
||||||
|
mci.FechaOperacion = ii.issued,
|
||||||
|
mci.MantenerAsiento = TRUE,
|
||||||
|
mci.SuFacturaNo = ii.supplierRef,
|
||||||
|
mci.IvaDeducible1 = IF(id.id, FALSE, IF(IFNULL(mci.BaseIva1, FALSE) = FALSE, FALSE, ii.isVatDeductible)),
|
||||||
|
mci.IvaDeducible2 = IF(id.id, FALSE, IF(IFNULL(mci.BaseIva2, FALSE) = FALSE, FALSE, ii.isVatDeductible)),
|
||||||
|
mci.IvaDeducible3 = IF(id.id, FALSE, IF(IFNULL(mci.BaseIva3, FALSE) = FALSE, FALSE, ii.isVatDeductible)),
|
||||||
|
mci.IvaDeducible4 = IF(id.id, FALSE, IF(IFNULL(mci.BaseIva4, FALSE) = FALSE, FALSE, ii.isVatDeductible)),
|
||||||
|
mci.FechaFacturaOriginal = x.FECHA_EX
|
||||||
|
WHERE mci.id = vXDiarioFk;
|
||||||
|
|
||||||
|
-- RETENCIONES
|
||||||
|
UPDATE movContaIVA mci
|
||||||
|
JOIN vn.invoiceIn ii ON ii.id = vInvoiceInFk
|
||||||
|
JOIN vn.XDiario x ON x.id = mci.id
|
||||||
|
JOIN vn.supplier s ON s.id = supplierFk
|
||||||
|
JOIN vn.invoiceInTax iit ON iit.invoiceInFk = ii.id
|
||||||
|
JOIN vn.expence e ON e.id = iit.expenceFk
|
||||||
|
JOIN TiposRetencion t ON t.CodigoRetencion = ii.withholdingSageFk
|
||||||
|
LEFT JOIN tmp.invoiceDua id ON id.id = mci.id
|
||||||
|
JOIN (SELECT SUM(x2.BASEEURO) taxableBase, SUM(x2.EURODEBE) taxBase
|
||||||
|
FROM vn.XDiario x1
|
||||||
|
JOIN vn.XDiario x2 ON x1.ASIEN = x2.ASIEN
|
||||||
|
WHERE x2.BASEEURO <> 0
|
||||||
|
AND x1.id = vXDiarioFk
|
||||||
|
)sub
|
||||||
|
JOIN ClavesOperacion co ON co.Descripcion = 'Arrendamiento de locales de negocio'
|
||||||
|
SET mci.CodigoRetencion = t.CodigoRetencion,
|
||||||
|
mci.ClaveOperacionFactura = IF( t.Retencion = 'ARRENDAMIENTO Y SUBARRENDAMIENTO', co.ClaveOperacionFactura_, mci.ClaveOperacionFactura),
|
||||||
|
mci.BaseRetencion = IF (t.Retencion = 'ACTIVIDADES AGRICOLAS O GANADERAS', sub.taxableBase + sub.taxBase, sub.taxableBase),
|
||||||
|
mci.PorRetencion = t.PorcentajeRetencion,
|
||||||
|
mci.ImporteRetencion = iit.taxableBase * - 1
|
||||||
|
WHERE mci.id = vXDiarioFk
|
||||||
|
AND e.name = 'Retenciones'
|
||||||
|
AND id.id IS NULL;
|
||||||
|
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
Loading…
Reference in New Issue