118 lines
2.6 KiB
MySQL
118 lines
2.6 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`clientGetDebtDiary`(vClientFK INT, vCompanyFk INT)
|
||
|
BEGIN
|
||
|
/**
|
||
|
* Devuelve el registro de deuda
|
||
|
*
|
||
|
* @param vClientFK Id del cliente
|
||
|
* @param vCompanyFk Id de la empresa
|
||
|
*/
|
||
|
DECLARE vDone BOOL;
|
||
|
DECLARE vDate DATETIME;
|
||
|
DECLARE vTotalBalance DOUBLE DEFAULT 0.00;
|
||
|
DECLARE vCreated DATETIME;
|
||
|
DECLARE vIssued DATETIME;
|
||
|
DECLARE vBalance DOUBLE DEFAULT 0.00;
|
||
|
DECLARE cur CURSOR FOR
|
||
|
SELECT
|
||
|
created,
|
||
|
issued,
|
||
|
ROUND(amount, 2) AS balance
|
||
|
FROM invoiceOut
|
||
|
WHERE clientFk = vClientFk AND companyFk = vCompanyFk
|
||
|
UNION ALL
|
||
|
SELECT
|
||
|
created,
|
||
|
payed,
|
||
|
ROUND(-1 * amountPaid, 2) AS balance
|
||
|
FROM receipt
|
||
|
WHERE clientFk = vClientFk AND companyFk = vCompanyFk
|
||
|
ORDER BY issued, created;
|
||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||
|
|
||
|
OPEN cur;
|
||
|
|
||
|
proc: LOOP
|
||
|
SET vDone = FALSE;
|
||
|
|
||
|
FETCH cur INTO vCreated, vIssued, vBalance;
|
||
|
|
||
|
IF vDate IS NULL THEN
|
||
|
SET vDate=vIssued;
|
||
|
END IF;
|
||
|
|
||
|
IF vDone THEN
|
||
|
LEAVE proc;
|
||
|
END IF;
|
||
|
|
||
|
SET vTotalBalance = vTotalBalance + vBalance;
|
||
|
|
||
|
IF CAST(ABS(vTotalBalance) AS UNSIGNED) = 0 THEN
|
||
|
SET vDate = vIssued;
|
||
|
SET vDone = TRUE;
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
|
||
|
CLOSE cur;
|
||
|
|
||
|
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,
|
||
|
ref,
|
||
|
companyFk,
|
||
|
1
|
||
|
FROM invoiceOut
|
||
|
WHERE clientFk = vClientFK
|
||
|
AND issued >= vDate
|
||
|
UNION ALL
|
||
|
|
||
|
SELECT
|
||
|
r.payed,
|
||
|
NULL as debtOut,
|
||
|
r.amountPaid,
|
||
|
r.invoiceFk,
|
||
|
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 ;
|