master #2823
|
@ -1,94 +1,78 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setRisk`(
|
||||
vClientFk INT)
|
||||
vClientFk INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Update the risk for a client with pending tickets
|
||||
* Update the risk for a client with pending tickets.
|
||||
*
|
||||
* @param vClientFk Id cliente
|
||||
*/
|
||||
DECLARE vHasDebt BOOL;
|
||||
DECLARE vStarted DATETIME;
|
||||
|
||||
SELECT COUNT(*) INTO vHasDebt
|
||||
FROM `client`
|
||||
WHERE id = vClientFk
|
||||
AND typeFk = 'normal';
|
||||
|
||||
IF vHasDebt THEN
|
||||
|
||||
SELECT util.VN_CURDATE() - INTERVAL riskScope MONTH INTO vStarted
|
||||
FROM clientConfig;
|
||||
|
||||
IF (SELECT COUNT(*) FROM client WHERE id = vClientFk AND typeFk = 'normal') THEN
|
||||
CREATE OR REPLACE TEMPORARY TABLE tTicketRisk
|
||||
(KEY (ticketFk))
|
||||
(PRIMARY KEY (ticketFk))
|
||||
ENGINE = MEMORY
|
||||
WITH ticket AS(
|
||||
SELECT id ticketFk,
|
||||
companyFk,
|
||||
DATE(shipped) dated,
|
||||
totalWithVat,
|
||||
ticket_isProblemCalcNeeded(id) isProblemCalcNeeded
|
||||
FROM vn.ticket
|
||||
WHERE clientFk = vClientFk
|
||||
AND refFk IS NULL
|
||||
AND NOT isDeleted
|
||||
AND IFNULL(totalWithVat, 0) <> 0
|
||||
AND shipped > vStarted
|
||||
), 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 companyFk, dated, SUM(totalWithVat) amount
|
||||
FROM ticket
|
||||
GROUP BY companyFk, dated
|
||||
), 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, ti.isProblemCalcNeeded
|
||||
FROM ticket ti
|
||||
JOIN risk r ON r.dated = ti.dated AND r.companyFk = ti.companyFk;
|
||||
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)
|
||||
), 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 companyFk, dated, SUM(totalWithVat) amount
|
||||
FROM ticket
|
||||
GROUP BY companyFk, dated
|
||||
), 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, 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 = tr.amount
|
||||
WHERE tr.isProblemCalcNeeded
|
||||
ORDER BY t.id;
|
||||
|
||||
UPDATE ticket t
|
||||
JOIN tTicketRisk tr ON tr.ticketFk = t.id
|
||||
SET t.risk = NULL
|
||||
WHERE NOT tr.isProblemCalcNeeded
|
||||
ORDER BY t.id;
|
||||
SET t.risk = IF(tr.isProblemCalcNeeded, tr.amount, NULL);
|
||||
|
||||
DROP TEMPORARY TABLE tTicketRisk;
|
||||
END IF;
|
||||
END IF;
|
||||
END$$
|
||||
DELIMITER ;
|
Loading…
Reference in New Issue