249 lines
6.6 KiB
SQL
249 lines
6.6 KiB
SQL
DROP PROCEDURE IF EXISTS vn.invoiceInBookingMain;
|
|
|
|
DELIMITER $$
|
|
$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`invoiceInBookingMain`(vInvoiceInId INT)
|
|
BEGIN
|
|
DECLARE vTotalAmount,vTotalAmountDivisa DECIMAL(10,2);
|
|
DECLARE vBookNumber,vSerialNumber INT;
|
|
DECLARE vRate DECIMAL(10,4);
|
|
|
|
CALL invoiceInBookingCommon(vInvoiceInId,vSerialNumber);
|
|
|
|
SELECT SUM(iit.taxableBase * IF( i.serial= 'R' AND ti.Iva <> 'HP DEVENGADO 21 ISP', 1 +(ti.PorcentajeIva/100),1)),
|
|
SUM(iit.foreignValue * IF( i.serial= 'R', 1 + (ti.PorcentajeIva/100),1)),
|
|
iit.taxableBase/iit.foreignValue
|
|
INTO vTotalAmount, vTotalAmountDivisa, vRate
|
|
FROM newInvoiceIn i
|
|
JOIN invoiceInTax iit ON iit.invoiceInFk = i.id
|
|
LEFT JOIN sage.TiposIva ti ON ti.CodigoIva = iit.taxTypeSageFk;
|
|
|
|
CALL vn.ledger_next(vBookNumber);
|
|
|
|
-- Apunte del proveedor
|
|
|
|
INSERT INTO XDiario(ASIEN,
|
|
FECHA,
|
|
SUBCTA,
|
|
EUROHABER,
|
|
CONCEPTO,
|
|
CAMBIO,
|
|
HABERME,
|
|
NFACTICK,
|
|
CLAVE,
|
|
empresa_id
|
|
)
|
|
SELECT
|
|
vBookNumber,
|
|
n.bookEntried,
|
|
s.supplierAccount,
|
|
vTotalAmount EUROHABER,
|
|
n.conceptWithSupplier,
|
|
vRate,
|
|
vTotalAmountDivisa,
|
|
n.invoicesCount,
|
|
vInvoiceInId,
|
|
n.companyFk
|
|
FROM newInvoiceIn n
|
|
JOIN newSupplier s;
|
|
|
|
-- Línea de Gastos
|
|
INSERT INTO XDiario ( ASIEN,
|
|
FECHA,
|
|
SUBCTA,
|
|
CONTRA,
|
|
EURODEBE,
|
|
EUROHABER,
|
|
CONCEPTO,
|
|
CAMBIO,
|
|
DEBEME,
|
|
HABERME,
|
|
NFACTICK,
|
|
empresa_id
|
|
)
|
|
SELECT vBookNumber ASIEN,
|
|
n.bookEntried FECHA,
|
|
IF(e.isWithheld , LPAD(RIGHT(s.supplierAccount,5),10,iit.expenceFk),iit.expenceFk) SUBCTA,
|
|
s.supplierAccount CONTRA,
|
|
IF(e.isWithheld AND iit.taxableBase < 0, NULL, ROUND(SUM(iit.taxableBase),2)) EURODEBE,
|
|
IF(e.isWithheld AND iit.taxableBase < 0,ROUND(SUM(-iit.taxableBase),2),NULL) EUROHABER,
|
|
n.conceptWithSupplier CONCEPTO,
|
|
vRate,
|
|
IF(e.isWithheld,NULL,ABS(ROUND(SUM(iit.foreignValue),2))) DEBEME,
|
|
IF(e.isWithheld,ABS(ROUND(SUM(iit.foreignValue),2)),NULL) HABERME,
|
|
n.invoicesCount NFACTICK,
|
|
n.companyFk empresa_id
|
|
FROM newInvoiceIn n
|
|
JOIN newSupplier s
|
|
JOIN invoiceInTax iit ON iit.invoiceInFk = n.id
|
|
JOIN (SELECT * FROM expence e GROUP BY e.id)e ON e.id = iit.expenceFk
|
|
WHERE e.name != 'Suplidos Transitarios nacionales'
|
|
GROUP BY iit.expenceFk;
|
|
|
|
-- 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,
|
|
n.bookEntried FECHA,
|
|
IF(n.expenceFkDeductible>0, n.expenceFkDeductible, ti.CuentaIvaSoportado) SUBCTA,
|
|
s.supplierAccount CONTRA,
|
|
SUM(ROUND(ti.PorcentajeIva * it.taxableBase / 100 /* + 0.0001*/ , 2)) EURODEBE,
|
|
SUM(it.taxableBase) BASEEURO,
|
|
GROUP_CONCAT(DISTINCT e.`name` SEPARATOR ', ') CONCEPTO,
|
|
vSerialNumber FACTURA,
|
|
ti.PorcentajeIva IVA,
|
|
IF(isUeeMember AND eWithheld.id IS NULL,'','*') AUXILIAR,
|
|
n.serial SERIE,
|
|
ttr.ClaveOperacionDefecto,
|
|
n.issued FECHA_EX,
|
|
n.operated FECHA_OP,
|
|
n.invoicesCount NFACTICK,
|
|
n.supplierRef FACTURAEX,
|
|
TRUE L340,
|
|
(isSameCountry OR NOT isUeeMember) LRECT349,
|
|
n.cplusTrascendency472Fk TIPOCLAVE,
|
|
n.cplusTaxBreakFk TIPOEXENCI,
|
|
n.cplusSubjectOpFk TIPONOSUJE,
|
|
n.cplusInvoiceType472Fk TIPOFACT,
|
|
n.cplusRectificationTypeFk TIPORECTIF,
|
|
iis.cplusTerIdNifFk TERIDNIF,
|
|
s.nif AS TERNIF,
|
|
s.name AS TERNOM,
|
|
n.booked FECREGCON,
|
|
n.companyFk
|
|
FROM newInvoiceIn n
|
|
JOIN newSupplier s
|
|
JOIN invoiceInTax it ON n.id = it.invoiceInFk
|
|
JOIN sage.TiposIva ti ON ti.CodigoIva = it.taxTypeSageFk
|
|
JOIN sage.TiposTransacciones ttr ON ttr.CodigoTransaccion = it.transactionTypeSageFk
|
|
JOIN invoiceInSerial iis ON iis.code = n.serial
|
|
JOIN (SELECT * FROM expence e GROUP BY e.id)e ON e.id = it.expenceFk
|
|
LEFT JOIN (
|
|
SELECT eWithheld.id
|
|
FROM invoiceInTax hold
|
|
JOIN expence eWithheld ON eWithheld.id = hold.expenceFk AND eWithheld.isWithheld
|
|
WHERE hold.invoiceInFk = vInvoiceInId LIMIT 1
|
|
) eWithheld ON TRUE
|
|
WHERE it.taxTypeSageFk IS NOT NULL
|
|
AND it.taxTypeSageFk NOT IN (22, 90)
|
|
GROUP BY ti.PorcentajeIva, e.id;
|
|
|
|
-- 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,
|
|
n.bookEntried FECHA,
|
|
ti.CuentaIvaRepercutido SUBCTA,
|
|
s.supplierAccount CONTRA,
|
|
SUM(ROUND(ti.PorcentajeIva * it.taxableBase / 100,2)) EUROHABER,
|
|
ROUND(SUM(it.taxableBase),2) BASEEURO,
|
|
GROUP_CONCAT(DISTINCT e.`name` SEPARATOR ', ') CONCEPTO,
|
|
vSerialNumber FACTURA,
|
|
ti.PorcentajeIva IVA,
|
|
'*' AUXILIAR,
|
|
n.serial SERIE,
|
|
ttr.ClaveOperacionDefecto,
|
|
n.issued FECHA_EX,
|
|
n.operated FECHA_OP,
|
|
n.invoicesCount NFACTICK,
|
|
n.supplierRef FACTURAEX,
|
|
FALSE L340,
|
|
(isSameCountry OR NOT isUeeMember) LRECT349,
|
|
1 TIPOCLAVE,
|
|
n.cplusTaxBreakFk TIPOEXENCI,
|
|
n.cplusSubjectOpFk TIPONOSUJE,
|
|
n.cplusInvoiceType472Fk TIPOFACT,
|
|
n.cplusRectificationTypeFk TIPORECTIF,
|
|
iis.cplusTerIdNifFk TERIDNIF,
|
|
s.nif AS TERNIF,
|
|
s.name AS TERNOM,
|
|
n.companyFk
|
|
FROM newInvoiceIn n
|
|
JOIN newSupplier s
|
|
JOIN invoiceInTax it ON n.id = it.invoiceInFk
|
|
JOIN sage.TiposIva ti ON ti.CodigoIva = it.taxTypeSageFk
|
|
JOIN sage.TiposTransacciones ttr ON ttr.CodigoTransaccion = it.transactionTypeSageFk
|
|
JOIN invoiceInSerial iis ON iis.code = n.serial
|
|
JOIN (SELECT * FROM expence e GROUP BY e.id)e ON e.id = it.expenceFk
|
|
WHERE ti.Iva = 'HP DEVENGADO 21 ISP' OR MID(s.account, 4, 1) = '1'
|
|
GROUP BY ti.PorcentajeIva, e.id;
|
|
|
|
-- Actualización del registro original
|
|
UPDATE invoiceIn ii
|
|
JOIN newInvoiceIn ni ON ii.id = ni.id
|
|
SET ii.serialNumber = vSerialNumber,
|
|
ii.isBooked = TRUE;
|
|
|
|
-- 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;
|
|
|
|
END$$
|
|
DELIMITER ;
|