From 160d72e755ec57372d9b29601910c084f0de19ac Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Thu, 14 Mar 2024 17:02:07 +0100 Subject: [PATCH] hotfix upload invoiceIn_add.sql error --- db/routines/sage/procedures/invoiceIn_add.sql | 96 ++++--- db/routines/vn/procedures/invoiceIn_add.sql | 234 ------------------ 2 files changed, 64 insertions(+), 266 deletions(-) delete mode 100644 db/routines/vn/procedures/invoiceIn_add.sql diff --git a/db/routines/sage/procedures/invoiceIn_add.sql b/db/routines/sage/procedures/invoiceIn_add.sql index a2690deb0..0898d6810 100644 --- a/db/routines/sage/procedures/invoiceIn_add.sql +++ b/db/routines/sage/procedures/invoiceIn_add.sql @@ -3,10 +3,11 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `sage`.`invoiceIn_add`(vI BEGIN /** * Traslada la info de contabilidad relacionada con las facturas recibidas - * + * * @vInvoiceInFk Factura recibida * @vXDiarioFk Id tabla XDiario - */ + */ + DECLARE vInvoiceInOriginalFk INT; DECLARE vDone BOOL DEFAULT FALSE; DECLARE vBase DOUBLE; DECLARE vVat DOUBLE; @@ -23,25 +24,25 @@ BEGIN DECLARE vInvoiceTypeInformative VARCHAR(1); DECLARE vIsInformativeExportation BOOL DEFAULT FALSE; - DECLARE vCursor CURSOR FOR + DECLARE vCursor CURSOR FOR SELECT it.taxableBase, CAST((( it.taxableBase / 100) * t.PorcentajeIva) AS DECIMAL (10,2)), t.PorcentajeIva, it.transactionTypeSageFk, it.taxTypeSageFk, tty.isIntracommunity, - tt.ClaveOperacionDefecto + tt.ClaveOperacionDefecto FROM vn.invoiceIn i JOIN vn.invoiceInTax it ON it.InvoiceInFk = i.id JOIN TiposIva t ON t.CodigoIva = it.taxTypeSageFk JOIN taxType tty ON tty.id = t.CodigoIva JOIN TiposTransacciones tt ON tt.CodigoTransaccion = it.transactionTypeSageFk LEFT JOIN vn.dua d ON d.id = vInvoiceInFk - WHERE i.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; @@ -64,22 +65,22 @@ BEGIN vTaxCode, vIsIntracommunity, vOperationCode; - - IF vDone THEN + + IF vDone THEN LEAVE l; END IF; - SET vTransactionCodeOld = vTransactionCode; - SET vTaxCodeOld = vTaxCode; + SET vTransactionCodeOld = vTransactionCode; + SET vTaxCodeOld = vTaxCode; - IF vOperationCode IS NOT NULL THEN + IF vOperationCode IS NOT NULL THEN UPDATE movContaIVA SET ClaveOperacionFactura = vOperationCode WHERE id = vXDiarioFk; END IF; - + SET vCounter = vCounter + 1; - CASE vCounter + CASE vCounter WHEN 1 THEN UPDATE movContaIVA SET BaseIva1 = vBase, @@ -115,31 +116,31 @@ BEGIN WHERE id = vXDiarioFk; ELSE SELECT vXDiarioFk INTO vXDiarioFk; - END CASE; + END CASE; IF vIsIntracommunity THEN UPDATE movContaIVA SET Intracomunitaria = TRUE WHERE id = vXDiarioFk; END IF; - - SET vTransactionCodeOld = vTransactionCode; - SET vTaxCodeOld = vTaxCode; - + + SET vTransactionCodeOld = vTransactionCode; + SET vTaxCodeOld = vTaxCode; + END LOOP; CLOSE vCursor; SELECT d.ASIEN AND x.ASIEN IS NULL INTO vIsInformativeExportation FROM vn.dua d - LEFT JOIN vn.XDiario x ON x.ASIEN = d.ASIEN + LEFT JOIN vn.XDiario x ON x.ASIEN = d.ASIEN AND x.SERIE = vSerialDua COLLATE utf8mb3_unicode_ci WHERE d.ASIEN = ( SELECT ASIEN - FROM vn.XDiario + FROM vn.XDiario WHERE id = vXDiarioFk) LIMIT 1; - + UPDATE movContaIVA mci JOIN tmp.invoiceIn ii ON ii.id = vInvoiceInFk JOIN vn.XDiario x ON x.id = mci.id @@ -151,13 +152,13 @@ BEGIN mci.Serie = ii.serial, mci.Factura = ii.id, 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) + + 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), - IF(vIsInformativeExportation,vInvoiceTypeInformative, vInvoiceTypeReceived)), + mci.TipoFactura = IF(id.id, + IF( ii.serial = vSerialDua COLLATE utf8mb3_unicode_ci, vInvoiceTypeReceived, vInvoiceTypeInformative), + IF(vIsInformativeExportation,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, @@ -185,7 +186,7 @@ BEGIN 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 + WHERE x2.BASEEURO <> 0 AND x1.id = vXDiarioFk )sub JOIN ClavesOperacion co ON co.Descripcion = 'Arrendamiento de locales de negocio' @@ -193,10 +194,41 @@ BEGIN 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 + mci.ImporteRetencion = iit.taxableBase * - 1 + WHERE mci.id = vXDiarioFk AND e.name = 'Retenciones' AND id.id IS NULL; + SELECT correctedFk INTO vInvoiceInOriginalFk + FROM vn.invoiceInCorrection + WHERE correctingFk = 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; END$$ -DELIMITER ; +DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn/procedures/invoiceIn_add.sql b/db/routines/vn/procedures/invoiceIn_add.sql deleted file mode 100644 index 0898d6810..000000000 --- a/db/routines/vn/procedures/invoiceIn_add.sql +++ /dev/null @@ -1,234 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE 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 vInvoiceInOriginalFk INT; - 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 vIsInformativeExportation BOOL DEFAULT FALSE; - - DECLARE vCursor CURSOR FOR - SELECT it.taxableBase, - CAST((( it.taxableBase / 100) * t.PorcentajeIva) AS DECIMAL (10,2)), - t.PorcentajeIva, - it.transactionTypeSageFk, - it.taxTypeSageFk, - tty.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 taxType tty ON tty.id = t.CodigoIva - 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); - - 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; - - SELECT d.ASIEN AND x.ASIEN IS NULL INTO vIsInformativeExportation - FROM vn.dua d - LEFT JOIN vn.XDiario x ON x.ASIEN = d.ASIEN - AND x.SERIE = vSerialDua COLLATE utf8mb3_unicode_ci - WHERE d.ASIEN = ( - SELECT ASIEN - FROM vn.XDiario - WHERE id = vXDiarioFk) - LIMIT 1; - - 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.id, - 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), - IF(vIsInformativeExportation,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.expense e ON e.id = iit.expenseFk - 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; - - SELECT correctedFk INTO vInvoiceInOriginalFk - FROM vn.invoiceInCorrection - WHERE correctingFk = 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; -END$$ -DELIMITER ; \ No newline at end of file