DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_risk`(vClientFk INT) BEGIN /** * Actualiza el riesgo de los tickets pendientes de un cliente * * @param vClientFk Id del cliente */ DECLARE vHasDebt BOOL; SELECT COUNT(*) INTO vHasDebt FROM `client` WHERE id = vClientFk AND typeFk = 'normal'; IF vHasDebt THEN CREATE OR REPLACE TEMPORARY TABLE tTicketRisk (KEY (ticketFk)) ENGINE = MEMORY WITH ticket AS( SELECT id ticketFk, DATE(shipped) dated FROM vn.ticket t WHERE clientFk = vClientFk AND refFk IS NULL AND NOT isDeleted AND totalWithoutVat <> 0 ), dated AS( SELECT MIN(DATE(t.dated) - INTERVAL cc.riskScope MONTH) started, MAX(DATE(t.dated)) ended FROM ticket t JOIN vn.clientConfig cc ), balance AS( SELECT SUM(amount)amount FROM ( SELECT SUM(amount) amount FROM vn.clientRisk WHERE clientFk = vClientFk UNION ALL SELECT -(SUM(amount) / 100) amount FROM hedera.tpvTransaction t WHERE clientFk = vClientFk AND receiptFk IS NULL AND status = 'ok' ) sub ), uninvoiced AS( SELECT DATE(t.shipped) dated, SUM(t.totalWithVat)amount FROM vn.ticket t JOIN dated d WHERE t.clientFk = vClientFk AND t.refFk IS NULL AND t.shipped BETWEEN d.started AND d.ended GROUP BY DATE(t.shipped) ), receipt AS( SELECT DATE(payed) dated, SUM(amountPaid) amount FROM vn.receipt WHERE clientFk = vClientFk AND payed > util.VN_CURDATE() GROUP BY DATE(payed) ), risk AS( SELECT ui.dated, SUM(ui.amount) OVER (ORDER BY ui.dated) + b.amount + SUM(IFNULL(r.amount, 0)) amount FROM balance b JOIN uninvoiced ui LEFT JOIN receipt r ON r.dated > ui.dated GROUP BY ui.dated ) SELECT ti.ticketFk, r.amount FROM ticket ti JOIN risk r ON r.dated = ti.dated; UPDATE ticket t JOIN tTicketRisk tr ON tr.ticketFk = t.id SET t.risk = tr.amount; DROP TEMPORARY TABLE IF EXISTS tTicketRisk; END IF; END$$ DELIMITER ;