113 lines
4.1 KiB
SQL
113 lines
4.1 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`bancos_evolution_add`(vStartingDate DATE)
|
|
BEGIN
|
|
/**
|
|
* Inserta en la tabla bancos_evolution los saldos acumulados de cada banco
|
|
*
|
|
* @param vStartingDate Fecha desde la cual se recalculan la tabla bs.bancos_evolution
|
|
*/
|
|
DECLARE vCurrentDate DATE;
|
|
DECLARE vMaxDate DATE DEFAULT TIMESTAMPADD(MONTH, 7, util.VN_CURDATE());
|
|
IF IFNULL(vStartingDate,0) < TIMESTAMPADD(YEAR, -5, util.VN_CURDATE()) THEN
|
|
CALL util.throw('invalid date');
|
|
END IF;
|
|
DELETE FROM bs.bancos_evolution WHERE Fecha >= vStartingDate;
|
|
|
|
SET vCurrentDate = vStartingDate;
|
|
|
|
INSERT INTO bs.bancos_evolution(Fecha, Id_Banco, saldo)
|
|
SELECT vCurrentDate, Id_Banco, deuda
|
|
FROM bs.bancos_evolution
|
|
WHERE Fecha = TIMESTAMPADD(DAY,-1,vCurrentDate);
|
|
|
|
WHILE vCurrentDate < vMaxDate DO
|
|
-- insertar solo el dia de ayer
|
|
INSERT INTO bs.bancos_evolution(Fecha ,Id_Banco, saldo)
|
|
SELECT vCurrentDate, Id_Banco, SUM(saldo)
|
|
FROM (
|
|
SELECT Id_Banco ,saldo
|
|
FROM bs.bancos_evolution
|
|
WHERE Fecha = TIMESTAMPADD(DAY,-1,vCurrentDate) -- los saldos acumulados del dia anterior
|
|
UNION ALL
|
|
|
|
SELECT c.Id_Banco, IFNULL(SUM(Entrada),0) - IFNULL(SUM(Salida),0) as saldo
|
|
FROM vn2008.Cajas c
|
|
JOIN vn2008.Bancos b using(Id_Banco) -- saldos de las cajas
|
|
JOIN vn.accountingType at2 ON at2.id = b.cash
|
|
WHERE at2.code IN ('wireTransfer','fundingLine')
|
|
AND Cajafecha = vCurrentDate
|
|
AND (Serie = 'MB' OR at2.code = 'fundingLine')
|
|
GROUP BY Id_Banco
|
|
)sub
|
|
GROUP BY Id_Banco
|
|
ON DUPLICATE KEY UPDATE saldo = saldo + VALUES(saldo);
|
|
|
|
SET vCurrentDate = TIMESTAMPADD(DAY,1,vCurrentDate);
|
|
|
|
END WHILE;
|
|
|
|
-- Ahora actualizamos la quilla
|
|
UPDATE bs.bancos_evolution be
|
|
JOIN
|
|
(
|
|
SELECT bp.Id_Banco, - sum(bp.importe) as quilla, t.dated
|
|
FROM vn.time t
|
|
JOIN vn2008.Bancos_poliza bp ON t.dated between apertura AND IFNULL(cierre, t.dated)
|
|
WHERE t.dated BETWEEN vStartingDate AND vMaxDate
|
|
GROUP BY Id_Banco, t.dated
|
|
) sub ON be.Id_Banco = sub.Id_Banco AND sub.dated = be.Fecha
|
|
SET be.quilla = sub.quilla;
|
|
|
|
-- pagos futuros no concilidados
|
|
INSERT INTO bs.bancos_evolution(Fecha, Id_Banco, saldo)
|
|
SELECT t.dated, p.id_banco, - importe
|
|
FROM vn.time t
|
|
join vn2008.pago p ON p.fecha <= t.dated
|
|
WHERE t.dated BETWEEN util.VN_CURDATE() AND vMaxDate
|
|
AND p.fecha BETWEEN util.VN_CURDATE() AND vMaxDate
|
|
AND NOT conciliado
|
|
ON DUPLICATE KEY UPDATE saldo = saldo + VALUES(saldo);
|
|
|
|
-- cobros futuros
|
|
INSERT INTO bs.bancos_evolution(Fecha, Id_Banco, saldo)
|
|
SELECT t.dated, r.Id_Banco, SUM(Entregado)
|
|
FROM vn.time t
|
|
JOIN vn2008.Recibos r ON r.Fechacobro <= t.dated
|
|
WHERE r.Fechacobro > util.VN_CURDATE() AND r.Fechacobro <= vMaxDate
|
|
AND t.dated BETWEEN util.VN_CURDATE() AND vMaxDate
|
|
GROUP BY t.dated, r.Id_Banco
|
|
ON DUPLICATE KEY UPDATE saldo = saldo + VALUES(saldo);
|
|
|
|
-- saldos de la tabla prevision
|
|
INSERT INTO bs.bancos_evolution(Fecha, Id_Banco, saldo)
|
|
SELECT t.dated, sp.Id_Banco, SUM(Importe)
|
|
FROM vn.time t
|
|
JOIN vn2008.Saldos_Prevision sp ON sp.Fecha <= t.dated
|
|
JOIN vn2008.Bancos b ON sp.Id_Banco = b.Id_Banco
|
|
JOIN vn.accountingType at2 ON at2.id = b.cash
|
|
WHERE at2.code IN ('wireTransfer','fundingLine')
|
|
AND t.dated BETWEEN vStartingDate AND vMaxDate
|
|
GROUP BY t.dated, sp.Id_Banco
|
|
ON DUPLICATE KEY UPDATE saldo = saldo + VALUES(saldo);
|
|
|
|
-- Utilizamos el saldo_auxiliar para calcular lo dispuesto en las polizas
|
|
UPDATE bs.bancos_evolution be
|
|
SET saldo_aux = saldo
|
|
WHERE Fecha >= vStartingDate;
|
|
|
|
-- Deuda
|
|
UPDATE bs.bancos_evolution be
|
|
JOIN vn2008.Bancos b using(Id_Banco)
|
|
JOIN vn.accountingType at2 ON at2.id = b.cash
|
|
SET be.deuda = IF(at2.code = 'fundingLine', be.saldo_aux, 0)
|
|
, be.saldo = IF(at2.code = 'fundingLine', 0, be.saldo_aux)
|
|
WHERE Fecha >= vStartingDate;
|
|
|
|
-- Liquidez
|
|
update bs.bancos_evolution set liquidez = saldo - quilla + deuda WHERE Fecha >= vStartingDate;
|
|
-- Disponibilidad
|
|
update bs.bancos_evolution set `disponibilidad ajena` = - quilla + deuda WHERE Fecha >= vStartingDate;
|
|
|
|
END$$
|
|
DELIMITER ;
|