439 lines
14 KiB
MySQL
439 lines
14 KiB
MySQL
|
DROP PROCEDURE IF EXISTS `sage`.`accountingMovements_add`;
|
||
|
|
||
|
DELIMITER $$
|
||
|
$$
|
||
|
CREATE DEFINER=`root`@`localhost` PROCEDURE `sage`.`accountingMovements_add`(vYear INT, vCompanyFk INT)
|
||
|
BEGIN
|
||
|
/**
|
||
|
* Traslada la info de contabilidad generada en base a vn.XDiario a la tabla sage.movConta para poder ejecutar posteriormente el proceso de importación de datos de SQL Server
|
||
|
* Solo traladará los asientos marcados con el campo vn.XDiario.enlazadoSage = FALSE
|
||
|
* @vYear Año contable del que se quiere trasladar la información
|
||
|
* @vCompanyFk Empresa de la que se quiere trasladar datos
|
||
|
*/
|
||
|
DECLARE vDatedFrom DATETIME;
|
||
|
DECLARE vDatedTo DATETIME;
|
||
|
DECLARE vDuaTransactionFk INT;
|
||
|
DECLARE vTaxImportFk INT;
|
||
|
DECLARE vTaxImportReducedFk INT;
|
||
|
DECLARE vTaxImportSuperReducedFk INT;
|
||
|
DECLARE vTransactionExportFk INT;
|
||
|
DECLARE vTransactionExportTaxFreeFk INT;
|
||
|
DECLARE vSerialDua VARCHAR(1) DEFAULT 'D';
|
||
|
DECLARE vInvoiceTypeInformativeCode VARCHAR(1);
|
||
|
DECLARE vCountryCanariasCode, vCountryCeutaMelillaCode VARCHAR(2) ;
|
||
|
DECLARE vBookEntries TEXT;
|
||
|
|
||
|
SELECT SiglaNacion INTO vCountryCanariasCode
|
||
|
FROM Naciones
|
||
|
WHERE Nacion ='ISLAS CANARIAS';
|
||
|
|
||
|
SELECT SiglaNacion INTO vCountryCeutaMelillaCode
|
||
|
FROM Naciones
|
||
|
WHERE Nacion ='CEUTA Y MELILLA';
|
||
|
|
||
|
SELECT CodigoTransaccion INTO vDuaTransactionFk
|
||
|
FROM TiposTransacciones
|
||
|
WHERE Transaccion = 'Import. bienes y serv. corrientes pdte. liquidar';
|
||
|
|
||
|
SELECT CodigoIva INTO vTaxImportFk
|
||
|
FROM TiposIva
|
||
|
WHERE Iva = 'IVA 21% importaciones';
|
||
|
|
||
|
SELECT CodigoIva INTO vTaxImportReducedFk
|
||
|
FROM TiposIva
|
||
|
WHERE Iva = 'IVA 10% importaciones';
|
||
|
|
||
|
SELECT CodigoIva INTO vTaxImportSuperReducedFk
|
||
|
FROM TiposIva
|
||
|
WHERE Iva = 'H.P. IVA Soportado Impor 4%';
|
||
|
|
||
|
SELECT CodigoTransaccion INTO vTransactionExportFk
|
||
|
FROM TiposTransacciones
|
||
|
WHERE Transaccion = 'Exportaciones definitivas';
|
||
|
|
||
|
SELECT CodigoTransaccion INTO vTransactionExportTaxFreeFk
|
||
|
FROM TiposTransacciones
|
||
|
WHERE Transaccion = 'Envíos definitivos a Canarias, Ceuta y Melilla';
|
||
|
|
||
|
SELECT codeSage INTO vInvoiceTypeInformativeCode
|
||
|
FROM invoiceType WHERE code ='informative';
|
||
|
|
||
|
SELECT CAST(CONCAT(vYear, '-01-01') AS DATETIME), util.dayEnd(CAST(CONCAT(vYear, '-12-31') AS DATE))
|
||
|
INTO vDatedFrom, vDatedTo;
|
||
|
|
||
|
TRUNCATE movContaIVA;
|
||
|
|
||
|
DELETE FROM movConta
|
||
|
WHERE enlazadoSage = FALSE
|
||
|
AND Asiento <> 1 ;
|
||
|
|
||
|
CALL clientSupplier_add(vCompanyFk);
|
||
|
CALL pgc_add(vCompanyFk);
|
||
|
CALL invoiceOut_manager(vYear, vCompanyFk);
|
||
|
CALL invoiceIn_manager(vYear, vCompanyFk);
|
||
|
|
||
|
INSERT INTO movConta(TipoEntrada,
|
||
|
Ejercicio,
|
||
|
CodigoEmpresa,
|
||
|
Asiento,
|
||
|
CargoAbono,
|
||
|
CodigoCuenta,
|
||
|
Contrapartida,
|
||
|
FechaAsiento,
|
||
|
Comentario,
|
||
|
ImporteAsiento,
|
||
|
NumeroPeriodo,
|
||
|
FechaGrabacion,
|
||
|
CodigoDivisa,
|
||
|
ImporteCambio,
|
||
|
ImporteDivisa,
|
||
|
FactorCambio,
|
||
|
IdProcesoIME,
|
||
|
TipoCarteraIME,
|
||
|
TipoAnaliticaIME,
|
||
|
StatusTraspasadoIME,
|
||
|
TipoImportacionIME,
|
||
|
Metalico347,
|
||
|
BaseIva1,
|
||
|
PorBaseCorrectora1,
|
||
|
PorIva1,
|
||
|
CuotaIva1,
|
||
|
PorRecargoEquivalencia1,
|
||
|
RecargoEquivalencia1,
|
||
|
CodigoTransaccion1,
|
||
|
BaseIva2,
|
||
|
PorBaseCorrectora2,
|
||
|
PorIva2,
|
||
|
CuotaIva2,
|
||
|
PorRecargoEquivalencia2,
|
||
|
RecargoEquivalencia2,
|
||
|
CodigoTransaccion2,
|
||
|
BaseIva3,
|
||
|
PorBaseCorrectora3,
|
||
|
PorIva3,
|
||
|
CuotaIva3,
|
||
|
PorRecargoEquivalencia3,
|
||
|
RecargoEquivalencia3,
|
||
|
CodigoTransaccion3,
|
||
|
BaseIva4,
|
||
|
PorBaseCorrectora4,
|
||
|
PorIva4,
|
||
|
CuotaIva4,
|
||
|
PorRecargoEquivalencia4,
|
||
|
RecargoEquivalencia4,
|
||
|
CodigoTransaccion4,
|
||
|
Año,
|
||
|
Serie,
|
||
|
Factura,
|
||
|
SuFacturaNo,
|
||
|
FechaFactura,
|
||
|
ImporteFactura,
|
||
|
TipoFactura,
|
||
|
CodigoCuentaFactura,
|
||
|
CifDni,
|
||
|
Nombre,
|
||
|
CodigoRetencion,
|
||
|
BaseRetencion,
|
||
|
PorRetencion,
|
||
|
ImporteRetencion,
|
||
|
SiglaNacion,
|
||
|
EjercicioFactura,
|
||
|
FechaOperacion,
|
||
|
Exclusion347,
|
||
|
MantenerAsiento,
|
||
|
ClaveOperacionFactura_,
|
||
|
TipoRectificativa,
|
||
|
FechaFacturaOriginal,
|
||
|
BaseImponibleOriginal,
|
||
|
CuotaIvaOriginal,
|
||
|
ClaseAbonoRectificativas,
|
||
|
RecargoEquivalenciaOriginal,
|
||
|
LibreA1,
|
||
|
CodigoIva1,
|
||
|
CodigoIva2,
|
||
|
CodigoIva3,
|
||
|
CodigoIva4,
|
||
|
IvaDeducible1,
|
||
|
IvaDeducible2,
|
||
|
IvaDeducible3,
|
||
|
IvaDeducible4,
|
||
|
Intracomunitaria
|
||
|
)
|
||
|
SELECT 'EN' TipoEntrada,
|
||
|
YEAR(x.FECHA) Ejercicio,
|
||
|
company_getCode(vCompanyFk) AS CodigoEmpresa,
|
||
|
x.ASIEN Asiento,
|
||
|
IF(EURODEBE <> 0 OR (EURODEBE = 0 AND EUROHABER IS NULL), 'D', 'H') CargoAbono,
|
||
|
x.SUBCTA CodigoCuenta,
|
||
|
x.CONTRA Contrapartida,
|
||
|
x.FECHA FechaAsiento,
|
||
|
x.CONCEPTO Comentario,
|
||
|
IF(x.EURODEBE, x.EURODEBE, x.EUROHABER) ImporteAsiento,
|
||
|
MONTH(x.FECHA) NumeroPeriodo,
|
||
|
IF(sub2.FECREGCON IS NULL, sub2.FECHA_EX, sub2.FECREGCON) FechaGrabacion,
|
||
|
IF(x.CAMBIO, IFNULL(mci.CodigoDivisa, sub3.code), '') CodigoDivisa,
|
||
|
x.CAMBIO ImporteCambio,
|
||
|
IFNULL(x.DEBEME, x.HABERME) ImporteDivisa,
|
||
|
IF(x.CAMBIO, TRUE, FALSE) FactorCambio,
|
||
|
NULL IdProcesoIME,
|
||
|
0 TipoCarteraIME,
|
||
|
0 TipoAnaliticaIME,
|
||
|
0 StatusTraspasadoIME,
|
||
|
0 TipoImportacionIME,
|
||
|
x.METAL Metalico347,
|
||
|
mci.BaseIva1,
|
||
|
mci.PorBaseCorrectora1,
|
||
|
mci.PorIva1,
|
||
|
mci.CuotaIva1,
|
||
|
mci.PorRecargoEquivalencia1,
|
||
|
mci.RecargoEquivalencia1,
|
||
|
mci.CodigoTransaccion1,
|
||
|
mci.BaseIva2,
|
||
|
mci.PorBaseCorrectora2,
|
||
|
mci.PorIva2,
|
||
|
mci.CuotaIva2,
|
||
|
mci.PorRecargoEquivalencia2,
|
||
|
mci.RecargoEquivalencia2,
|
||
|
mci.CodigoTransaccion2,
|
||
|
mci.BaseIva3,
|
||
|
mci.PorBaseCorrectora3,
|
||
|
mci.PorIva3,
|
||
|
mci.CuotaIva3,
|
||
|
mci.PorRecargoEquivalencia3,
|
||
|
mci.RecargoEquivalencia3,
|
||
|
mci.CodigoTransaccion3,
|
||
|
mci.BaseIva4,
|
||
|
mci.PorBaseCorrectora4,
|
||
|
mci.PorIva4,
|
||
|
mci.CuotaIva4,
|
||
|
mci.PorRecargoEquivalencia4,
|
||
|
mci.RecargoEquivalencia4,
|
||
|
mci.CodigoTransaccion4,
|
||
|
mci.Año,
|
||
|
mci.Serie,
|
||
|
mci.Factura,
|
||
|
mci.SuFacturaNo,
|
||
|
mci.FechaFactura,
|
||
|
mci.ImporteFactura,
|
||
|
mci.TipoFactura,
|
||
|
mci.CodigoCuentaFactura,
|
||
|
mci.CifDni,
|
||
|
mci.Nombre,
|
||
|
mci.CodigoRetencion,
|
||
|
mci.BaseRetencion,
|
||
|
mci.PorRetencion,
|
||
|
mci.ImporteRetencion,
|
||
|
mci.SiglaNacion,
|
||
|
mci.EjercicioFactura,
|
||
|
mci.FechaOperacion,
|
||
|
mci.Exclusion347,
|
||
|
TRUE,
|
||
|
mci.ClaveOperacionFactura,
|
||
|
mci.TipoRectificativa,
|
||
|
mci.FechaFacturaOriginal,
|
||
|
mci.BaseImponibleOriginal,
|
||
|
mci.CuotaIvaOriginal,
|
||
|
mci.ClaseAbonoRectificativas,
|
||
|
mci.RecargoEquivalenciaOriginal,
|
||
|
mci.LibreA1,
|
||
|
mci.CodigoIva1,
|
||
|
mci.CodigoIva2,
|
||
|
mci.CodigoIva3,
|
||
|
mci.CodigoIva4,
|
||
|
mci.IvaDeducible1,
|
||
|
mci.IvaDeducible2,
|
||
|
mci.IvaDeducible3,
|
||
|
mci.IvaDeducible4,
|
||
|
mci.Intracomunitaria
|
||
|
FROM vn.XDiario x
|
||
|
LEFT JOIN movContaIVA mci ON mci.id = x.id
|
||
|
LEFT JOIN (SELECT *
|
||
|
FROM (SELECT DISTINCT ASIEN, FECREGCON, FECHA_EX
|
||
|
FROM vn.XDiario
|
||
|
WHERE enlazadoSage = FALSE
|
||
|
ORDER BY ASIEN, FECREGCON DESC, FECHA_EX DESC
|
||
|
LIMIT 10000000000000000000
|
||
|
) sub GROUP BY ASIEN
|
||
|
)sub2 ON sub2.ASIEN = x.ASIEN
|
||
|
LEFT JOIN ( SELECT DISTINCT(account),cu.code
|
||
|
FROM vn.bank b
|
||
|
JOIN vn.currency cu ON cu.id = b.currencyFk
|
||
|
WHERE cu.code <> 'EUR' -- no se informa cuando la divisa en EUR
|
||
|
)sub3 ON sub3.account = x.SUBCTA
|
||
|
WHERE x.enlazadoSage = FALSE
|
||
|
AND x.empresa_id = vCompanyFk
|
||
|
AND x.FECHA BETWEEN vDatedFrom AND vDatedTo;
|
||
|
|
||
|
-- Metálicos
|
||
|
UPDATE movConta m
|
||
|
JOIN (SELECT Asiento,
|
||
|
c.socialName name,
|
||
|
c.fi,
|
||
|
n.SiglaNacion,
|
||
|
m.CodigoCuenta,
|
||
|
m.Contrapartida
|
||
|
FROM movConta m
|
||
|
LEFT JOIN vn.client c ON c.id = IF(m.CargoAbono = 'H',
|
||
|
CAST(SUBSTRING(m.CodigoCuenta, 3, LENGTH(m.CodigoCuenta)) AS UNSIGNED),
|
||
|
CAST(SUBSTRING(m.Contrapartida, 3, LENGTH(m.Contrapartida)) AS UNSIGNED))
|
||
|
LEFT JOIN Naciones n ON n.countryFk = c.countryFk
|
||
|
WHERE m.Metalico347 = TRUE
|
||
|
AND m.enlazadoSage = FALSE
|
||
|
)sub ON m.Asiento = sub.Asiento
|
||
|
SET m.Metalico347 = TRUE,
|
||
|
m.TipoFactura = vInvoiceTypeInformativeCode,
|
||
|
m.CifDni = sub.fi,
|
||
|
m.Nombre = sub.name,
|
||
|
m.SiglaNacion = sub.SiglaNacion
|
||
|
WHERE m.enlazadoSage = FALSE;
|
||
|
|
||
|
UPDATE movConta m
|
||
|
SET m.Metalico347 = FALSE,
|
||
|
m.TipoFactura = ''
|
||
|
WHERE m.CargoAbono = 'D'
|
||
|
AND m.enlazadoSage = FALSE;
|
||
|
|
||
|
-- Elimina cuentas de cliente/proveedor que no se utilizarán en la importación
|
||
|
DELETE cp
|
||
|
FROM clientesProveedores cp
|
||
|
LEFT JOIN movConta mc ON mc.codigoCuenta = cp.codigoCuenta
|
||
|
AND mc.enlazadoSage = FALSE
|
||
|
WHERE mc.codigoCuenta IS NULL;
|
||
|
|
||
|
-- Elimina cuentas contables que no se utilizarán en la importación
|
||
|
DELETE pc
|
||
|
FROM planCuentasPGC pc
|
||
|
LEFT JOIN movConta mc ON mc.codigoCuenta = pc.codigoCuenta
|
||
|
AND mc.enlazadoSage = FALSE
|
||
|
WHERE mc.codigoCuenta IS NULL;
|
||
|
|
||
|
-- DUAS
|
||
|
UPDATE movConta mci
|
||
|
JOIN vn.XDiario x ON x.ASIEN = mci.Asiento
|
||
|
JOIN TiposIva ti ON ti.CodigoIva = x.IVA
|
||
|
JOIN vn.pgcMaster pm ON pm.code = mci.CodigoCuenta COLLATE utf8mb3_unicode_ci
|
||
|
SET mci.BaseIva1 = x.BASEEURO,
|
||
|
mci.PorIva1 = x.IVA,
|
||
|
mci.CuotaIva1 = CAST((x.IVA / 100) * x.BASEEURO AS DECIMAL(10, 2)),
|
||
|
mci.CodigoTransaccion1 = vDuaTransactionFk,
|
||
|
mci.CodigoIva1 = vTaxImportReducedFk,
|
||
|
mci.IvaDeducible1 = TRUE,
|
||
|
mci.FechaFacturaOriginal = x.FECHA_EX,
|
||
|
mci.SuFacturaNo = x.FACTURAEX,
|
||
|
mci.FechaOperacion = x.FECHA_OP,
|
||
|
mci.ImporteFactura = mci.ImporteFactura + x.BASEEURO + CAST((x.IVA / 100) * x.BASEEURO AS DECIMAL(10, 2))
|
||
|
WHERE pm.description = 'HP Iva pendiente'
|
||
|
AND mci.enlazadoSage = FALSE
|
||
|
AND x.SERIE = vSerialDua COLLATE utf8mb3_unicode_ci
|
||
|
AND ti.Iva = 'I.V.A. 10% Nacional';
|
||
|
|
||
|
UPDATE movConta mci
|
||
|
JOIN vn.XDiario x ON x.ASIEN = mci.Asiento
|
||
|
JOIN TiposIva ti ON ti.CodigoIva = x.IVA
|
||
|
JOIN vn.pgcMaster pm ON pm.code = mci.CodigoCuenta COLLATE utf8mb3_unicode_ci
|
||
|
SET mci.BaseIva2 = x.BASEEURO ,
|
||
|
mci.PorIva2 = x.IVA,
|
||
|
mci.CuotaIva2 = CAST((x.IVA / 100) * x.BASEEURO AS DECIMAL(10,2)),
|
||
|
mci.CodigoTransaccion2 = vDuaTransactionFk ,
|
||
|
mci.CodigoIva2 = vTaxImportFk,
|
||
|
mci.IvaDeducible2 = TRUE,
|
||
|
mci.ImporteFactura = mci.ImporteFactura + x.BASEEURO + CAST((x.IVA / 100) * x.BASEEURO AS DECIMAL(10, 2))
|
||
|
WHERE pm.description = 'HP Iva pendiente'
|
||
|
AND mci.enlazadoSage = FALSE
|
||
|
AND x.SERIE = vSerialDua COLLATE utf8mb3_unicode_ci
|
||
|
AND ti.Iva = 'I.V.A. 21%';
|
||
|
|
||
|
UPDATE movConta mci
|
||
|
JOIN vn.XDiario x ON x.ASIEN = mci.Asiento
|
||
|
JOIN TiposIva ti ON ti.CodigoIva = x.IVA
|
||
|
JOIN vn.pgcMaster pm ON pm.code = mci.CodigoCuenta COLLATE utf8mb3_unicode_ci
|
||
|
SET mci.BaseIva3 = x.BASEEURO ,
|
||
|
mci.PorIva3 = x.IVA,
|
||
|
mci.CuotaIva3 = CAST((x.IVA / 100) * x.BASEEURO AS DECIMAL(10,2)),
|
||
|
mci.CodigoTransaccion3 = vDuaTransactionFk ,
|
||
|
mci.CodigoIva3 = vTaxImportSuperReducedFk,
|
||
|
mci.IvaDeducible3 = TRUE,
|
||
|
mci.ImporteFactura = mci.ImporteFactura + x.BASEEURO + CAST((x.IVA / 100) * x.BASEEURO AS DECIMAL(10, 2))
|
||
|
WHERE pm.description = 'HP Iva pendiente'
|
||
|
AND mci.enlazadoSage = FALSE
|
||
|
AND x.SERIE = vSerialDua COLLATE utf8mb3_unicode_ci
|
||
|
AND ti.Iva = 'I.V.A. 4%';
|
||
|
|
||
|
-- Rectificativas
|
||
|
UPDATE movConta mci
|
||
|
JOIN (SELECT x.ASIEN, x.FECHA_RT, x.SERIE_RT, x.FACTU_RT
|
||
|
FROM movConta mci
|
||
|
JOIN vn.XDiario x ON x.ASIEN = mci.Asiento
|
||
|
WHERE mci.TipoRectificativa > 0
|
||
|
AND mci.enlazadoSage = FALSE
|
||
|
AND x.FACTU_RT IS NOT NULL
|
||
|
GROUP BY x.ASIEN
|
||
|
) sub ON sub.ASIEN = mci.Asiento
|
||
|
SET mci.EjercicioFacturaOriginal = YEAR(sub.FECHA_RT),
|
||
|
mci.SerieFacturaOriginal = sub.SERIE_RT,
|
||
|
mci.NumeroFacturaOriginal = sub.FACTU_RT
|
||
|
WHERE mci.TipoRectificativa > 0 AND
|
||
|
mci.enlazadoSage = FALSE ;
|
||
|
|
||
|
-- Exportaciones Andorras y Canarias cambia TT (la cuenta es compartida)
|
||
|
UPDATE movConta mci
|
||
|
SET CodigoTransaccion1 = vTransactionExportTaxFreeFk,
|
||
|
CodigoTransaccion2 = IF(CodigoTransaccion2 = 0, 0, vTransactionExportTaxFreeFk),
|
||
|
CodigoTransaccion3 = IF(CodigoTransaccion3 = 0, 0, vTransactionExportTaxFreeFk),
|
||
|
CodigoTransaccion4 = IF(CodigoTransaccion4 = 0, 0, vTransactionExportTaxFreeFk)
|
||
|
WHERE enlazadoSage = FALSE
|
||
|
AND (CodigoTransaccion1 = vTransactionExportFk
|
||
|
OR CodigoTransaccion2 = vTransactionExportFk
|
||
|
OR CodigoTransaccion3 = vTransactionExportFk
|
||
|
OR CodigoTransaccion4 = vTransactionExportFk)
|
||
|
AND SiglaNacion IN (vCountryCanariasCode COLLATE utf8mb3_unicode_ci, vCountryCeutaMelillaCode COLLATE utf8mb3_unicode_ci);
|
||
|
|
||
|
UPDATE movConta mc
|
||
|
SET CodigoDivisa = 'USD',
|
||
|
FactorCambio = TRUE,
|
||
|
ImporteCambio = ABS( CAST( IF( ImporteDivisa <> 0 AND ImporteCambio = 0, ImporteAsiento / ImporteDivisa, ImporteCambio) AS DECIMAL( 10, 2)))
|
||
|
WHERE enlazadoSage = FALSE
|
||
|
AND (ImporteCambio <> 0 OR ImporteDivisa <> 0 OR FactorCambio);
|
||
|
|
||
|
UPDATE movConta mc
|
||
|
SET importeDivisa= -importeDivisa
|
||
|
WHERE enlazadoSage = FALSE
|
||
|
AND importeDivisa > 0
|
||
|
AND ImporteAsiento < 0;
|
||
|
|
||
|
-- Comprobación que los importes e ivas sean correctos, avisa vía CAU
|
||
|
SELECT GROUP_CONCAT(Asiento ORDER BY Asiento ASC SEPARATOR ',') INTO vBookEntries
|
||
|
FROM(SELECT sub.Asiento
|
||
|
FROM (SELECT mc.Asiento, SUM(mc.ImporteAsiento) amount
|
||
|
FROM movConta mc
|
||
|
WHERE mc.enlazadoSage = FALSE
|
||
|
GROUP BY mc.Asiento)sub
|
||
|
JOIN (SELECT x.ASIEN, SUM(IFNULL(x.EURODEBE,0) + IFNULL(x.EUROHABER,0)) amount
|
||
|
FROM vn.XDiario x
|
||
|
WHERE x.enlazadoSage = FALSE
|
||
|
GROUP BY ASIEN)sub2 ON sub2.ASIEN = sub.Asiento
|
||
|
WHERE sub.amount <> sub2.amount
|
||
|
UNION ALL
|
||
|
SELECT sub.Asiento
|
||
|
FROM (SELECT Asiento, SUM(BaseIva1 + BaseIva2 + BaseIva3 + BaseIva4) amountTaxableBase
|
||
|
FROM movConta
|
||
|
WHERE TipoFactura <> 'I'
|
||
|
AND enlazadoSage = FALSE
|
||
|
GROUP BY Asiento) sub
|
||
|
JOIN (SELECT ASIEN, SUM(BASEEURO) amountTaxableBase
|
||
|
FROM (SELECT ASIEN, SUM(BASEEURO) BASEEURO
|
||
|
FROM vn.XDiario
|
||
|
WHERE FACTURA
|
||
|
AND auxiliar <> '*'
|
||
|
AND enlazadoSage = FALSE
|
||
|
GROUP BY FACTURA, ASIEN)sub3
|
||
|
GROUP BY ASIEN) sub2 ON sub2.ASIEN = sub.Asiento
|
||
|
WHERE sub.amountTaxableBase<>sub2.amountTaxableBase
|
||
|
AND sub.amountTaxableBase/2 <> sub2.amountTaxableBase) sub;
|
||
|
|
||
|
IF vBookEntries IS NOT NULL THEN
|
||
|
SELECT util.notification_send ("book-entries-imported-incorrectly", CONCAT('{"bookEntries":"', vBookEntries,'"}'), null);
|
||
|
END IF;
|
||
|
END$$
|
||
|
DELIMITER ;
|