2024-01-15 11:31:03 +00:00
|
|
|
DELIMITER $$
|
2024-08-20 08:06:10 +00:00
|
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`client_checkBalance`(IN vDateTo DATETIME, IN vIsConciliated BOOL)
|
2024-01-15 11:31:03 +00:00
|
|
|
BEGIN
|
|
|
|
/**
|
|
|
|
* Compara los datos de nuestros clientes con
|
|
|
|
* los que hay en la base de datos de sage
|
|
|
|
*
|
|
|
|
* @param vDateTo
|
|
|
|
* @param vIsConciliated
|
|
|
|
* @table tmp.ledgerComparative (id, date, account, debit, credit, companyFk)
|
|
|
|
*/
|
|
|
|
DECLARE vDateFrom DATE;
|
|
|
|
DECLARE vMaxTolerance DECIMAL(10,2);
|
|
|
|
|
|
|
|
SELECT util.firstDayOfYear(vDateTo), util.dayEnd(vDateTo), maxTolerance
|
|
|
|
INTO vDateFrom, vDateTo, vMaxTolerance
|
|
|
|
FROM vn.ledgerConfig;
|
|
|
|
|
|
|
|
SELECT s.nickname,
|
|
|
|
c.id,
|
|
|
|
c.accountingAccount,
|
|
|
|
sub1.mysql,
|
|
|
|
sub1.sage,
|
|
|
|
sub1.mysql - sub1.sage difference,
|
|
|
|
sub1.companyFk,
|
|
|
|
c.name
|
|
|
|
FROM client c
|
|
|
|
JOIN payMethod pm ON pm.id = c.payMethodFk
|
|
|
|
JOIN (SELECT sub.companyFk,
|
|
|
|
sub.clientFk,
|
|
|
|
CAST(ROUND(SUM(sub.mysql), 2) AS DECIMAL(10,2)) mysql,
|
|
|
|
CAST(ROUND(SUM(sub.sage), 2) AS DECIMAL(10,2)) sage
|
|
|
|
FROM(SELECT io.companyFk,
|
|
|
|
io.clientFk,
|
|
|
|
- io.amount mysql,
|
|
|
|
0 sage
|
|
|
|
FROM invoiceOut io
|
|
|
|
WHERE issued BETWEEN vDateFrom AND vDateTo
|
|
|
|
UNION ALL
|
|
|
|
SELECT r.companyFk,
|
|
|
|
r.clientFk,
|
|
|
|
r.amountPaid,
|
|
|
|
0
|
|
|
|
FROM receipt r
|
|
|
|
WHERE payed BETWEEN vDateFrom AND vDateTo
|
|
|
|
AND IF(vIsConciliated,r.isConciliate, TRUE) = TRUE
|
|
|
|
UNION ALL
|
|
|
|
SELECT lc.companyFk,
|
|
|
|
c.id,
|
|
|
|
0,
|
2024-02-12 07:11:49 +00:00
|
|
|
- (IFNULL(lc.credit, 0) - IFNULL(lc.debit, 0))
|
2024-01-15 11:31:03 +00:00
|
|
|
FROM tmp.ledgerComparative lc
|
|
|
|
JOIN client c ON c.accountingAccount = lc.account
|
|
|
|
WHERE lc.`date` BETWEEN vDateFrom AND vDateTo
|
|
|
|
)sub
|
|
|
|
GROUP BY companyFk, clientFk
|
|
|
|
) sub1 ON sub1.clientFk = c.id
|
|
|
|
JOIN supplier s ON s.id = sub1.companyFk
|
|
|
|
JOIN company co ON co.id = sub1.companyFk
|
|
|
|
LEFT JOIN clientUnpaid cu ON cu.clientFk = c.id
|
|
|
|
AND cu.dated BETWEEN vDateFrom AND vDateTo
|
|
|
|
WHERE pm.outstandingDebt
|
|
|
|
AND co.code <> 'BLK'
|
|
|
|
AND cu.clientFk IS NULL
|
|
|
|
HAVING ABS(difference) > vMaxTolerance
|
|
|
|
ORDER BY c.name;
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|