DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setRisk`( vClientFk INT) BEGIN /** * Update the risk for a client with pending tickets * * @param vClientFk Id 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, companyFk, DATE(shipped) dated FROM vn.ticket t WHERE clientFk = vClientFk AND refFk IS NULL AND NOT isDeleted AND totalWithoutVat <> 0 ), dated AS( SELECT t.companyFk, MIN(DATE(t.dated) - INTERVAL cc.riskScope MONTH) started, MAX(DATE(t.dated)) ended FROM ticket t JOIN vn.clientConfig cc GROUP BY t.companyFk ), balance AS( SELECT SUM(amount)amount, companyFk FROM ( SELECT amount, companyFk FROM vn.clientRisk WHERE clientFk = vClientFk UNION ALL SELECT -(SUM(amount) / 100) amount, tm.companyFk FROM hedera.tpvTransaction t JOIN hedera.tpvMerchant tm ON t.id = t.merchantFk WHERE clientFk = vClientFk AND receiptFk IS NULL AND status = 'ok' ) sub WHERE companyFk GROUP BY companyFk ), uninvoiced AS( SELECT t.companyFk, DATE(t.shipped) dated, SUM(IFNULL(t.totalWithVat, 0)) 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 t.companyFk, DATE(t.shipped) ), receipt AS( SELECT companyFk,DATE(payed) dated, SUM(amountPaid) amount FROM vn.receipt WHERE clientFk = vClientFk AND payed > util.VN_CURDATE() GROUP BY companyFk, DATE(payed) ), risk AS( SELECT b.companyFk, ui.dated, SUM(ui.amount) OVER (PARTITION BY b.companyFk ORDER BY ui.dated ) + b.amount + SUM(IFNULL(r.amount, 0)) amount FROM balance b JOIN uninvoiced ui ON ui.companyFk = b.companyFk LEFT JOIN receipt r ON r.dated > ui.dated AND r.companyFk = ui.companyFk GROUP BY b.companyFk, ui.dated ) SELECT ti.ticketFk, r.amount FROM ticket ti JOIN risk r ON r.dated = ti.dated AND r.companyFk = ti.companyFk; UPDATE ticket t JOIN tTicketRisk tr ON tr.ticketFk = t.id SET t.risk = tr.amount; DROP TEMPORARY TABLE tTicketRisk; END IF; END$$ DELIMITER ;