DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceIn_booking`( vSelf INT, vBookNumber INT ) BEGIN /** * Genera la contabilidad para una factura y la marca como contabilizada * Cuadra el asiento generado en si encuentra problemas derivados * de los calculos con decimales * * @param vSelf Id invoiceIn * @param vBookEntry Id de asiento, si es NULL se genera uno nuevo */ DECLARE vFiscalYear INT; DECLARE vDistinctTransactions INT; DECLARE vHasRepeatedTransactions BOOL; SELECT COUNT(DISTINCT iit.transactionTypeSageFk) INTO vDistinctTransactions FROM invoiceIn ii JOIN invoiceInTax iit ON iit.invoiceInFk = ii.id JOIN invoiceInSerial iis ON iis.code = ii.serial WHERE iit.invoiceInFk = vSelf AND iis.taxAreaFk = 'CEE' AND iit.transactionTypeSageFk; IF vDistinctTransactions > 1 THEN CALL util.throw ('This invoice does not allow different types of transactions'); END IF; SELECT TRUE INTO vHasRepeatedTransactions FROM invoiceInTax WHERE invoiceInFk = vSelf GROUP BY transactionTypeSageFk HAVING COUNT(transactionTypeSageFk) > 1 LIMIT 1; IF vHasRepeatedTransactions THEN CALL util.throw ('This invoice contains repeated types of transactions'); END IF; CREATE OR REPLACE TEMPORARY TABLE tInvoiceIn ENGINE = MEMORY SELECT ii.bookEntried, iit.foreignValue, ii.companyFk, ii.expenseFkDeductible, iit.taxableBase, iit.transactionTypeSageFk, ii.serial, ii.issued, ii.operated, ii.supplierRef, ii.siiTrascendencyInvoiceInFk, ii.cplusTaxBreakFk, ii.cplusSubjectOpFk, ii.siiTypeInvoiceInFk, ii.cplusRectificationTypeFk, ii.booked, IFNULL(a.isUeeMember, c.isUeeMember) isUeeMember, (c.id = cc.id) isSameCountry, s.account supplierAccount, s.name supplierName, s.nif, s.IsVies, iit.taxTypeSageFk, tt.code taxCode, ti.Iva, ti.CuentaIvaSoportado, ti.PorcentajeIva, ti.CuentaIvaRepercutido, ttr.ClaveOperacionDefecto, iis.cplusTerIdNifFk, cit.id invoicesCount, e.code, e.isWithheld, e.id expenseFk, e.name expenseName FROM invoiceIn ii JOIN supplier s ON s.id = ii.supplierFk LEFT JOIN province p ON p.id = s.provinceFk LEFT JOIN autonomy a ON a.id = p.autonomyFk JOIN country c ON c.id = s.countryFk JOIN supplier sc ON sc.id = ii.companyFk JOIN country cc ON cc.id = sc.countryFk JOIN invoiceInSerial iis ON iis.code = ii.serial JOIN siiTypeInvoiceIn cit ON cit.id = ii.siiTypeInvoiceInFk LEFT JOIN invoiceInTax iit ON iit.invoiceInFk = ii.id LEFT JOIN sage.TiposTransacciones ttr ON ttr.CodigoTransaccion = iit.transactionTypeSageFk LEFT JOIN expense e ON e.id = iit.expenseFk LEFT JOIN sage.TiposIva ti ON ti.CodigoIva = iit.taxTypeSageFk LEFT JOIN sage.taxType tt ON tt.id = ti.CodigoIva WHERE ii.id = vSelf; SELECT YEAR(bookEntried) INTO vFiscalYear FROM tInvoiceIn LIMIT 1; IF vBookNumber IS NULL THEN CALL ledger_nextTx(vFiscalYear, vBookNumber); END IF; -- Apunte del proveedor INSERT INTO XDiario( ASIEN, FECHA, SUBCTA, EUROHABER, CONCEPTO, CAMBIO, HABERME, NFACTICK, CLAVE, empresa_id) SELECT vBookNumber ASIEN, tii.bookEntried FECHA, tii.supplierAccount SUBCTA, SUM(tii.taxableBase * IF(tii.serial= 'R' AND ((tii.taxCode IS NULL OR tii.taxCode <> 'ISP21') AND tii.taxTypeSageFk IS NOT NULL), 1 + (tii.PorcentajeIva / 100), 1)) EUROHABER, CONCAT('s/fra', RIGHT(tii.supplierRef, 8), ':', LEFT(tii.supplierName, 10)) CONCEPTO, CAST(tii.taxableBase / tii.foreignValue AS DECIMAL (10,4)) CAMBIO, SUM(tii.foreignValue * IF(tii.serial = 'R', 1 + (tii.PorcentajeIva / 100), 1)) HABERME, tii.invoicesCount NFACTICK, vSelf CLAVE, tii.companyFk empresa_id FROM tInvoiceIn tii; -- Línea de Gastos INSERT INTO XDiario( ASIEN, FECHA, SUBCTA, CONTRA, EURODEBE, EUROHABER, CONCEPTO, CAMBIO, DEBEME, HABERME, NFACTICK, empresa_id) SELECT vBookNumber ASIEN, tii.bookEntried FECHA, IF(tii.isWithheld, LPAD(RIGHT(tii.supplierAccount, 5), 10, tii.expenseFk),tii.expenseFk) SUBCTA, tii.supplierAccount CONTRA, IF(tii.isWithheld AND tii.taxableBase < 0, NULL, ROUND(SUM(tii.taxableBase),2)) EURODEBE, IF(tii.isWithheld AND tii.taxableBase < 0, ROUND(SUM(-tii.taxableBase), 2), NULL) EUROHABER, CONCAT('s/fra', RIGHT(tii.supplierRef, 8), ':', LEFT(tii.supplierName, 10)) CONCEPTO, CAST(tii.taxableBase / tii.foreignValue AS DECIMAL (10, 4)) CAMBIO, IF(tii.isWithheld, NULL,ABS(ROUND(SUM(tii.foreignValue), 2))) DEBEME, IF(tii.isWithheld, ABS(ROUND(SUM(tii.foreignValue), 2)) ,NULL) HABERME, tii.invoicesCount NFACTICK, tii.companyFk empresa_id FROM tInvoiceIn tii WHERE tii.code IS NULL OR tii.code <> 'suplido' GROUP BY tii.expenseFk; -- Líneas de IVA INSERT INTO XDiario( ASIEN, FECHA, SUBCTA, CONTRA, EURODEBE, BASEEURO, CONCEPTO, FACTURA, IVA, AUXILIAR, SERIE, TIPOOPE, FECHA_EX, FECHA_OP, NFACTICK, FACTURAEX, L340, LRECT349, TIPOCLAVE, TIPOEXENCI, TIPONOSUJE, TIPOFACT, TIPORECTIF, TERIDNIF, TERNIF, TERNOM, FECREGCON, empresa_id) SELECT vBookNumber ASIEN, tii.bookEntried FECHA, IF(tii.expenseFkDeductible>0, tii.expenseFkDeductible, tii.CuentaIvaSoportado) SUBCTA, tii.supplierAccount CONTRA, SUM(ROUND(tii.PorcentajeIva * tii.taxableBase / 100, 2)) EURODEBE, SUM(tii.taxableBase) BASEEURO, GROUP_CONCAT(DISTINCT tii.expenseName SEPARATOR ', ') CONCEPTO, vSelf FACTURA, tii.PorcentajeIva IVA, IF(tii.isUeeMember AND eWithheld.id IS NULL, '', '*') AUXILIAR, tii.serial SERIE, tii.ClaveOperacionDefecto, tii.issued FECHA_EX, tii.operated FECHA_OP, tii.invoicesCount NFACTICK, tii.supplierRef FACTURAEX, TRUE L340, (tii.isSameCountry OR NOT tii.isUeeMember) LRECT349, tii.siiTrascendencyInvoiceInFk TIPOCLAVE, tii.cplusTaxBreakFk TIPOEXENCI, tii.cplusSubjectOpFk TIPONOSUJE, tii.siiTypeInvoiceInFk TIPOFACT, tii.cplusRectificationTypeFk TIPORECTIF, tii.cplusTerIdNifFk TERIDNIF, tii.nif TERNIF, tii.supplierName TERNOM, tii.booked FECREGCON, tii.companyFk FROM tInvoiceIn tii LEFT JOIN ( SELECT e.id FROM tInvoiceIn tii JOIN expense e ON e.id = tii.expenseFk WHERE e.isWithheld LIMIT 1 ) eWithheld ON TRUE WHERE tii.taxTypeSageFk IS NOT NULL AND (tii.taxCode IS NULL OR tii.taxCode NOT IN ('import10', 'import21')) GROUP BY tii.PorcentajeIva, tii.expenseFk; -- Línea iva inversor sujeto pasivo INSERT INTO XDiario( ASIEN, FECHA, SUBCTA, CONTRA, EUROHABER, BASEEURO, CONCEPTO, FACTURA, IVA, AUXILIAR, SERIE, TIPOOPE, FECHA_EX, FECHA_OP, NFACTICK, FACTURAEX, L340, LRECT349, TIPOCLAVE, TIPOEXENCI, TIPONOSUJE, TIPOFACT, TIPORECTIF, TERIDNIF, TERNIF, TERNOM, empresa_id) SELECT vBookNumber ASIEN, tii.bookEntried FECHA, tii.CuentaIvaRepercutido SUBCTA, tii.supplierAccount CONTRA, SUM(ROUND(tii.PorcentajeIva * tii.taxableBase / 100,2)) EUROHABER, ROUND(SUM(tii.taxableBase),2) BASEEURO, GROUP_CONCAT(DISTINCT tii.expenseName SEPARATOR ', ') CONCEPTO, vSelf FACTURA, tii.PorcentajeIva IVA, '*' AUXILIAR, tii.serial SERIE, tii.ClaveOperacionDefecto, tii.issued FECHA_EX, tii.operated FECHA_OP, tii.invoicesCount NFACTICK, tii.supplierRef FACTURAEX, FALSE L340, (tii.isSameCountry OR NOT tii.isUeeMember) LRECT349, 1 TIPOCLAVE, tii.cplusTaxBreakFk TIPOEXENCI, tii.cplusSubjectOpFk TIPONOSUJE, tii.siiTypeInvoiceInFk TIPOFACT, tii.cplusRectificationTypeFk TIPORECTIF, tii.cplusTerIdNifFk TERIDNIF, tii.nif TERNIF, tii.supplierName TERNOM, tii.companyFk FROM tInvoiceIn tii JOIN sage.config c WHERE tii.taxCode = 'ISP21' OR MID(tii.supplierAccount, 4, 1) = '1' AND tii.taxTypeSageFk IS NOT NULL AND NOT(tii.isVies AND c.nontaxableTransactionTypeFk = tii.transactionTypeSageFk AND tii.taxCode = 'nonTaxable') GROUP BY tii.PorcentajeIva, tii.expenseFk; -- Actualización del registro original UPDATE invoiceIn ii SET ii.isBooked = TRUE WHERE ii.id = vSelf; -- Problemas derivados de la precisión en los decimales al calcular los impuestos UPDATE XDiario SET EURODEBE = EURODEBE - (SELECT IF(ABS(sub.difference) = 0.01, sub.difference, 0) FROM( SELECT SUM(IFNULL(ROUND(EURODEBE, 2),0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0)) difference FROM XDiario WHERE ASIEN = vBookNumber )sub ) WHERE ASIEN = vBookNumber AND EURODEBE <> 0 ORDER BY id DESC LIMIT 1; DROP TEMPORARY TABLE tInvoiceIn; END$$ DELIMITER ;