salix/db/routines/vn/procedures/client_getDebt.sql

63 lines
1.7 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`client_getDebt`(vDate DATE)
BEGIN
/**
* Calculates the risk for active clients
*
* @table tmp.clientGetDebt(clientFk)
* @param vDate Maximum date of records
* @return tmp.risk
*/
DECLARE vStarted DATETIME;
DECLARE vEnded DATETIME;
SELECT util.VN_CURDATE() - INTERVAL riskScope MONTH INTO vStarted
FROM clientConfig;
SET vEnded = util.dayEnd(IFNULL(vDate, util.VN_CURDATE()));
CREATE OR REPLACE TEMPORARY TABLE tClientRisk
ENGINE = MEMORY
SELECT cr.clientFk, SUM(cr.amount) amount
FROM clientRisk cr
JOIN tmp.clientGetDebt c ON c.clientFk = cr.clientFk
GROUP BY cr.clientFk;
INSERT INTO tClientRisk
SELECT c.clientFk, SUM(r.amountPaid)
FROM receipt r
JOIN tmp.clientGetDebt c ON c.clientFk = r.clientFk
WHERE r.payed > vEnded
GROUP BY c.clientFk;
INSERT INTO tClientRisk
SELECT t.clientFk, CAST(-SUM(t.amount) / 100 AS DECIMAL(10,2))
FROM hedera.tpvTransaction t
JOIN tmp.clientGetDebt c ON c.clientFk = t.clientFk
WHERE t.receiptFk IS NULL
AND t.status = 'ok'
GROUP BY t.clientFk;
INSERT INTO tClientRisk
SELECT t.clientFk, SUM(totalWithVat)
FROM ticket t
JOIN tmp.clientGetDebt c ON c.clientFk = t.clientFk
WHERE refFk IS NULL
AND shipped BETWEEN vStarted AND vEnded
GROUP BY t.clientFk;
-- refs #6351 BUG: No cambiar a CREATE OR REPLACE
DROP TEMPORARY TABLE IF EXISTS tmp.risk;
CREATE TEMPORARY TABLE tmp.risk
(PRIMARY KEY (clientFk))
ENGINE = MEMORY
SELECT clientFk, SUM(amount) risk
FROM client c
JOIN tClientRisk cr ON cr.clientFk = c.id
GROUP BY c.id;
DROP TEMPORARY TABLE tClientRisk;
END$$
DELIMITER ;