83 lines
2.5 KiB
SQL
83 lines
2.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_setRisk`(
|
|
vClientFk INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Update the risk for a client with pending tickets.
|
|
*
|
|
* @param vClientFk Id cliente
|
|
*/
|
|
IF (SELECT COUNT(*) FROM client WHERE id = vClientFk AND typeFk = 'normal') THEN
|
|
CREATE OR REPLACE TEMPORARY TABLE tTicketRisk
|
|
(PRIMARY KEY (ticketFk))
|
|
ENGINE = MEMORY
|
|
WITH ticket AS (
|
|
SELECT t.id ticketFk,
|
|
t.companyFk,
|
|
DATE(t.shipped) dated,
|
|
t.totalWithVat,
|
|
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
|
FROM vn.ticket t
|
|
JOIN vn.clientConfig cc
|
|
WHERE t.clientFk = vClientFk
|
|
AND t.refFk IS NULL
|
|
AND NOT t.isDeleted
|
|
AND IFNULL(t.totalWithVat, 0) <> 0
|
|
AND t.shipped > (util.VN_CURDATE() - INTERVAL cc.riskScope MONTH)
|
|
), uninvoiced AS (
|
|
SELECT companyFk, dated, SUM(totalWithVat) amount
|
|
FROM ticket
|
|
GROUP BY companyFk, dated
|
|
), companies AS (
|
|
SELECT DISTINCT companyFk FROM uninvoiced
|
|
), balance AS (
|
|
SELECT SUM(IFNULL(amount, 0))amount, companyFk
|
|
FROM (
|
|
SELECT cr.amount, c.companyFk
|
|
FROM companies c
|
|
LEFT JOIN vn.clientRisk cr ON cr.companyFk = c.companyFk
|
|
AND cr.clientFk = vClientFk
|
|
UNION ALL
|
|
SELECT -(SUM(t.amount) / 100) amount, c.companyFk
|
|
FROM companies c
|
|
LEFT JOIN hedera.tpvMerchant tm ON tm.companyFk = c.companyFk
|
|
LEFT JOIN hedera.tpvTransaction t ON t.merchantFk = tm.id
|
|
AND t.clientFk = vClientFk
|
|
AND t.receiptFk IS NULL
|
|
AND t.`status` = 'ok'
|
|
) sub
|
|
WHERE companyFk
|
|
GROUP BY companyFk
|
|
), receipt AS (
|
|
SELECT r.companyFk, DATE(r.payed) dated, SUM(r.amountPaid) amount
|
|
FROM vn.receipt r
|
|
JOIN companies c ON c.companyFk = r.companyFk
|
|
WHERE r.clientFk = vClientFk
|
|
AND r.payed > util.VN_CURDATE()
|
|
GROUP BY r.companyFk, DATE(r.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, ti.isProblemCalcNeeded
|
|
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 = IF(tr.isProblemCalcNeeded, tr.amount, NULL);
|
|
|
|
DROP TEMPORARY TABLE tTicketRisk;
|
|
END IF;
|
|
END$$
|
|
DELIMITER ; |