salix/services/db/install/changes/1.1.0/11-clientGetDebt.sql

71 lines
1.9 KiB
SQL

DROP procedure IF EXISTS vn.`clientGetDebt`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE vn.`clientGetDebt`(vDate DATE)
BEGIN
/**
* Calcula el riesgo para los clientes activos
*
* @table tmp.clientGetDebt(clientFk)
* @param vDate Fecha maxima de los registros
* @return tmp.risk
*/
DECLARE vStarted DATETIME DEFAULT TIMESTAMPADD(DAY, - DAYOFMONTH(CURDATE()) - 5, CURDATE());
DECLARE vEnded DATETIME;
SET vEnded = TIMESTAMP(IFNULL(vDate, CURDATE()), '23:59:59');
DROP TEMPORARY TABLE IF EXISTS tmp.ticket;
CREATE TEMPORARY TABLE tmp.ticket
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT id ticketFk, c.clientFk
FROM ticket t
JOIN tmp.clientGetDebt c ON c.clientFk = t.clientFk
WHERE refFk IS NULL
AND shipped BETWEEN vStarted AND vEnded;
CALL ticketGetTotal();
DROP TEMPORARY TABLE IF EXISTS tClientRisk;
CREATE TEMPORARY TABLE tClientRisk
ENGINE = MEMORY
SELECT cr.customer_id clientFk, SUM(cr.amount) amount
FROM bi.customer_risk cr
JOIN tmp.clientGetDebt c ON c.clientFk = cr.customer_id
GROUP BY cr.customer_id;
INSERT INTO tClientRisk
SELECT c.clientFk, SUM(r.amountPaid)
FROM receipt r
JOIN tmp.clientGetDebt c ON c.clientFk = r.clientFk
WHERE r.payed > vStarted
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, total
FROM tmp.ticketTotal tt
JOIN tmp.ticket t ON t.ticketFk = tt.ticketFk;
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
WHERE c.isActive
GROUP BY c.id;
END$$
DELIMITER ;