salix/services/db/install/changes/1.1.0/03-clientGetDebtDiary.sql

99 lines
2.1 KiB
SQL

USE `vn`;
DROP procedure IF EXISTS `clientGetDebtDiary`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `clientGetDebtDiary`(vClientFK INT, vCompanyFk INT)
BEGIN
/**
* Devuelve el registro de deuda
*
* @param vClientFK Id del cliente
* @param vCompanyFk Id de la empresa
*/
DECLARE vDate DATETIME DEFAULT CURDATE();
SET @balance:= 0;
SELECT MAX(issued) INTO vDate FROM
(SELECT
created,
issued,
@balance:= ROUND(amount, 2) + @balance AS balance
FROM invoiceOut
WHERE clientFk = vClientFk AND companyFk = vCompanyFk
UNION ALL
SELECT
created,
payed,
@balance:= ROUND(-1 * amountPaid, 2) + @balance AS balance
FROM receipt
WHERE clientFk = vClientFk AND companyFk = vCompanyFk
ORDER BY issued, created) balance
WHERE balance = 0;
SELECT
issued,
CAST(debtOut AS DECIMAL(10,2)) debtOut,
CAST(debtIn AS DECIMAL(10,2)) debtIn,
ref,
companyFk,
priority
FROM
(SELECT
NULL AS issued,
SUM(amountUnpaid) AS debtOut,
NULL AS debtIn,
'Saldo Anterior' AS ref,
companyFk,
0 as priority
FROM
(SELECT SUM(amount) AS amountUnpaid, companyFk, 0
FROM invoiceOut
WHERE clientFk = vClientFK
AND issued < vDate
GROUP BY companyFk
UNION ALL
SELECT SUM(-1 * amountPaid), companyFk, 0
FROM receipt
WHERE clientFk = vClientFK
AND payed < vDate
GROUP BY companyFk) AS transactions
GROUP BY companyFk
UNION ALL
SELECT
issued,
amount as debtOut,
NULL AS debtIn,
id AS ref,
companyFk,
1
FROM invoiceOut
WHERE clientFk = vClientFK
AND issued >= vDate
UNION ALL
SELECT
r.payed,
NULL as debtOut,
r.amountPaid,
r.id,
r.companyFk,
0
FROM receipt r
WHERE r.clientFk = vClientFK
AND r.payed >= vDate) t
INNER JOIN `client` c ON c.id = vClientFK
HAVING debtOut <> 0 OR debtIn <> 0
ORDER BY issued, priority DESC, debtIn;
END$$
DELIMITER ;