salix/db/routines/vn2008/procedures/CalculoRemesas.sql

67 lines
2.1 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`CalculoRemesas`(IN vFechaRemesa DATE)
BEGIN
DROP TEMPORARY TABLE IF EXISTS TMP_REMESAS;
CREATE TEMPORARY TABLE TMP_REMESAS
SELECT
CONCAT(p.NIF,REPEAT('0', 12-LENGTH(p.NIF))) as CIF1,
cli.Id_Cliente,
cli.Cliente,
cli.`IF` as NIF,
c.PaymentDate as Vencimiento,
0 ImporteFac,
cast(c.Recibo as decimal(10,2)) as ImporteRec,
0 as ImporteActual,
c.companyFk empresa_id,
cli.RazonSocial,
cast(c.Recibo as decimal(10,2)) as ImporteTotal,
cast(c.Recibo as decimal(10,2)) as Saldo,
p.Proveedor as Empresa,
e.abbreviation as EMP,
cli.cuenta,
iban AS Iban,
CONVERT(SUBSTRING(iban,5,4),UNSIGNED INT) AS nrbe,
sepavnl as SEPA,
corevnl as RecibidoCORE,
hasLcr,
be.bic,
be.`name` entityName
FROM Clientes cli
JOIN
(SELECT risk.companyFk,
c.Id_Cliente,
sum(risk.amount) as Recibo,
IF((c.Vencimiento + graceDays) mod 30.001 <= day(vFechaRemesa)
,TIMESTAMPADD(DAY, (c.Vencimiento + graceDays) MOD 30.001, LAST_DAY(TIMESTAMPADD(MONTH,-1,vFechaRemesa)))
,TIMESTAMPADD(DAY, (c.Vencimiento + graceDays) MOD 30.001, LAST_DAY(TIMESTAMPADD(MONTH,-2,vFechaRemesa)))
) as PaymentDate
FROM Clientes c
JOIN pay_met pm on pm.id = pay_met_id
JOIN
(
SELECT companyFk, clientFk, amount
FROM Clientes c
JOIN vn.clientRisk cr ON cr.clientFk = c.Id_Cliente
WHERE pay_met_id = 4
UNION ALL
SELECT d.companyFk, f.clientFk Id_Cliente, - f.amount
FROM vn.invoiceOut f
JOIN Clientes c ON c.Id_Cliente = f.clientFk
JOIN pay_met pm on pm.id = pay_met_id
WHERE f.dued > vFechaRemesa
AND pay_met_id = 4 AND pm.deudaviva
AND f.amount > 0
) risk ON c.Id_Cliente = risk.clientFk
GROUP BY risk.companyFk, Id_Cliente
HAVING Recibo > 10
) c on c.Id_Cliente = cli.Id_Cliente
JOIN Proveedores p on p.Id_Proveedor = c.companyFk
JOIN empresa e on e.id = c.companyFk
LEFT JOIN vn.bankEntity be ON be.id = cli.bankEntityFk;
END$$
DELIMITER ;