75 lines
2.3 KiB
MySQL
75 lines
2.3 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`supplier_checkBalance`(IN vDateTo DATETIME, IN vIsConciliated BOOL)
|
||
|
BEGIN
|
||
|
/**
|
||
|
* Compara los datos de nuestros proveedores 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);
|
||
|
SET vDateTo = TIMESTAMP(vDateTo,'23:59:59');
|
||
|
SELECT util.firstDayOfYear(vDateTo) INTO vDateFrom;
|
||
|
SELECT maxTolerance INTO vMaxTolerance
|
||
|
FROM vn.ledgerConfig;
|
||
|
|
||
|
SELECT c.code,
|
||
|
s.id supplierFk,
|
||
|
s.account,
|
||
|
sub1.mysql,
|
||
|
sub1.sage,
|
||
|
sub1.mysql - sub1.sage difference,
|
||
|
sub1.companyFk,
|
||
|
s.name
|
||
|
FROM supplier s
|
||
|
JOIN (SELECT companyFk,
|
||
|
supplierFk,
|
||
|
CAST(ROUND(SUM(mysql),2) AS DECIMAL(10,2)) mysql,
|
||
|
CAST(ROUND(SUM(sage),2) AS DECIMAL(10,2)) sage
|
||
|
FROM (SELECT companyFk,
|
||
|
supplierFk,
|
||
|
- SUM(iid.amount) mysql,
|
||
|
0 sage
|
||
|
FROM invoiceInDueDay iid
|
||
|
JOIN invoiceIn ii ON ii.id = iid.invoiceInFk
|
||
|
WHERE IFNULL(ii.bookEntried, ii.issued) BETWEEN vDateFrom AND vDateTo
|
||
|
AND ii.isBooked
|
||
|
GROUP BY ii.id
|
||
|
UNION ALL
|
||
|
SELECT p.companyFk,
|
||
|
p.supplierFk,
|
||
|
p.amount,
|
||
|
0
|
||
|
FROM payment p
|
||
|
JOIN payMethod pm ON pm.id = p.payMethodFk
|
||
|
WHERE p.received BETWEEN vDateFrom AND vDateTo
|
||
|
AND IF(vIsConciliated, p.isConciliated, TRUE) = TRUE
|
||
|
AND NOT pm.code <=>'previousBalance'
|
||
|
UNION ALL
|
||
|
SELECT se.companyFk,
|
||
|
se.supplierFk,
|
||
|
- se.amount,
|
||
|
0
|
||
|
FROM supplierExpense se
|
||
|
WHERE se.dated BETWEEN vDateFrom AND vDateTo
|
||
|
AND IF(vIsConciliated, se.isConciliated, TRUE) = TRUE
|
||
|
UNION ALL
|
||
|
SELECT lc.companyFk,
|
||
|
s.id,
|
||
|
0,
|
||
|
- (NZ(lc.debit) - NZ(lc.credit))
|
||
|
FROM tmp.ledgerComparative lc
|
||
|
JOIN supplier s ON s.account = lc.account
|
||
|
WHERE lc.`date` BETWEEN vDateFrom AND vDateTo
|
||
|
) sub
|
||
|
GROUP BY companyFk, supplierFk
|
||
|
) sub1 ON sub1.supplierFk = s.id
|
||
|
JOIN company c ON c.id = sub1.companyFk
|
||
|
HAVING ABS(difference) > vMaxTolerance
|
||
|
ORDER BY s.name;
|
||
|
END$$
|
||
|
DELIMITER ;
|