2024-02-09 10:40:20 +00:00
|
|
|
DELIMITER $$
|
2024-02-14 10:05:16 +00:00
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`XDiario_check`()
|
2024-02-09 10:40:20 +00:00
|
|
|
BEGIN
|
|
|
|
/**
|
2024-02-14 10:05:16 +00:00
|
|
|
* Realiza la revisión diaria de los asientos contables,
|
2024-02-09 10:40:20 +00:00
|
|
|
* identificando y notificando los asientos descuadrados
|
|
|
|
* y ajustando los saldos en caso necesario.
|
|
|
|
*/
|
|
|
|
INSERT INTO mail (receiver, subject, body)
|
|
|
|
SELECT 'cau@verdnatura.es',
|
|
|
|
'Asientos descuadrados',
|
|
|
|
GROUP_CONCAT(CONCAT(' Asiento: ', ASIEN, ' - Importe:', recon) SEPARATOR ' | \n')
|
|
|
|
FROM (
|
|
|
|
SELECT ASIEN,
|
|
|
|
SUM(IFNULL(ROUND(Eurodebe, 2), 0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0)) recon
|
|
|
|
FROM XDiario
|
|
|
|
WHERE NOT enlazado
|
|
|
|
GROUP BY ASIEN
|
|
|
|
HAVING ABS(SUM(IFNULL(ROUND(Eurodebe, 2), 0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0))) > 0.01
|
|
|
|
) sub
|
|
|
|
HAVING COUNT(*);
|
|
|
|
|
|
|
|
UPDATE XDiario xd
|
|
|
|
JOIN (
|
|
|
|
SELECT xd.id, SUBCTA, recon
|
|
|
|
FROM XDiario xd
|
|
|
|
JOIN (
|
|
|
|
SELECT ASIEN,
|
|
|
|
SUM(IFNULL(ROUND(Eurodebe, 2), 0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0)) recon
|
|
|
|
FROM XDiario
|
|
|
|
WHERE NOT enlazado
|
|
|
|
GROUP BY ASIEN
|
|
|
|
HAVING recon
|
|
|
|
) sub ON sub.ASIEN = xd.ASIEN
|
|
|
|
WHERE xd.SUBCTA > '5999999999'
|
|
|
|
GROUP BY xd.ASIEN
|
|
|
|
) sub ON sub.id = xd.id
|
|
|
|
SET xd.Eurohaber = IF(IFNULL(xd.Eurohaber, 0) = 0, xd.Eurohaber, xd.Eurohaber + sub.recon),
|
|
|
|
xd.Eurodebe = IF(IFNULL(xd.Eurodebe, 0) = 0, xd.Eurodebe, xd.Eurodebe - sub.recon);
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|