Actualizar db/routines/vn/procedures/ticket_setRisk.sql
gitea/salix/pipeline/head This commit looks good Details

This commit is contained in:
Carlos Andrés 2024-07-31 17:38:50 +00:00
parent f0598d6cf1
commit 77f6e80066
1 changed files with 59 additions and 54 deletions

View File

@ -13,60 +13,65 @@ BEGIN
(PRIMARY KEY (ticketFk)) (PRIMARY KEY (ticketFk))
ENGINE = MEMORY ENGINE = MEMORY
WITH ticket AS ( WITH ticket AS (
SELECT t.id ticketFk, SELECT t.id ticketFk,
t.companyFk, t.companyFk,
DATE(t.shipped) dated, DATE(t.shipped) dated,
t.totalWithVat, t.totalWithVat,
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
FROM vn.ticket t FROM vn.ticket t
JOIN vn.clientConfig cc JOIN vn.clientConfig cc
WHERE t.clientFk = vClientFk WHERE t.clientFk = vClientFk
AND t.refFk IS NULL AND t.refFk IS NULL
AND NOT t.isDeleted AND NOT t.isDeleted
AND IFNULL(t.totalWithVat, 0) <> 0 AND IFNULL(t.totalWithVat, 0) <> 0
AND t.shipped > (util.VN_CURDATE() - INTERVAL cc.riskScope MONTH) AND t.shipped > (util.VN_CURDATE() - INTERVAL cc.riskScope MONTH)
), balance AS ( ), uninvoiced AS (
SELECT SUM(amount)amount, companyFk SELECT companyFk, dated, SUM(totalWithVat) amount
FROM ( FROM ticket
SELECT amount, companyFk GROUP BY companyFk, dated
FROM vn.clientRisk ), companies AS (
WHERE clientFk = vClientFk SELECT DISTINCT companyFk FROM uninvoiced
UNION ALL ), balance AS (
SELECT -(SUM(amount) / 100) amount, tm.companyFk SELECT SUM(IFNULL(amount, 0))amount, companyFk
FROM hedera.tpvTransaction t FROM (
JOIN hedera.tpvMerchant tm ON t.id = t.merchantFk SELECT cr.amount, c.companyFk
WHERE clientFk = vClientFk FROM companies c
AND receiptFk IS NULL LEFT JOIN vn.clientRisk cr ON cr.companyFk = c.companyFk
AND `status` = 'ok' AND cr.clientFk = vClientFk
) sub UNION ALL
WHERE companyFk SELECT -(SUM(t.amount) / 100) amount, c.companyFk
GROUP BY companyFk FROM companies c
), uninvoiced AS ( LEFT JOIN hedera.tpvMerchant tm ON tm.companyFk = c.companyFk
SELECT companyFk, dated, SUM(totalWithVat) amount LEFT JOIN hedera.tpvTransaction t ON t.merchantFk = tm.id
FROM ticket AND t.clientFk = vClientFk
GROUP BY companyFk, dated AND t.receiptFk IS NULL
), receipt AS ( AND t.`status` = 'ok'
SELECT companyFk, DATE(payed) dated, SUM(amountPaid) amount ) sub
FROM vn.receipt WHERE companyFk
WHERE clientFk = vClientFk GROUP BY companyFk
AND payed > util.VN_CURDATE() ), receipt AS (
GROUP BY companyFk, DATE(payed) SELECT r.companyFk, DATE(r.payed) dated, SUM(r.amountPaid) amount
), risk AS ( FROM vn.receipt r
SELECT b.companyFk, JOIN companies c ON c.companyFk = r.companyFk
ui.dated, WHERE r.clientFk = vClientFk
SUM(ui.amount) OVER (PARTITION BY b.companyFk ORDER BY ui.dated) + AND r.payed > util.VN_CURDATE()
b.amount + GROUP BY r.companyFk, DATE(r.payed)
SUM(IFNULL(r.amount, 0)) amount ), risk AS (
FROM balance b SELECT b.companyFk,
JOIN uninvoiced ui ON ui.companyFk = b.companyFk ui.dated,
LEFT JOIN receipt r ON r.dated > ui.dated SUM(ui.amount) OVER (PARTITION BY b.companyFk ORDER BY ui.dated) +
AND r.companyFk = ui.companyFk b.amount +
GROUP BY b.companyFk, ui.dated SUM(IFNULL(r.amount, 0)) amount
) FROM balance b
SELECT ti.ticketFk, r.amount, ti.isProblemCalcNeeded JOIN uninvoiced ui ON ui.companyFk = b.companyFk
FROM ticket ti LEFT JOIN receipt r ON r.dated > ui.dated
JOIN risk r ON r.dated = ti.dated AND r.companyFk = ui.companyFk
AND r.companyFk = ti.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 UPDATE ticket t
JOIN tTicketRisk tr ON tr.ticketFk = t.id JOIN tTicketRisk tr ON tr.ticketFk = t.id