salix/db/routines/vn/procedures/claimRatio_add.sql

155 lines
4.5 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`claimRatio_add`()
BEGIN
/*
* PAK 2015-11-20
* Se trata de añadir a la tabla Greuges todos los
* cargos que luego vamos a utilizar para calcular el recobro
*/
DECLARE vMonthToRefund INT DEFAULT 4;
DECLARE vRecoveryGreugeType INT;
SELECT id INTO vRecoveryGreugeType
FROM greugeType
WHERE code = 'recovery';
-- Reclamaciones demasiado sensibles
INSERT INTO greuge(shipped, clientFk, description,
amount, greugeTypeFk, ticketFk)
SELECT c.ticketCreated
, c.clientFk
, concat('Claim ', c.id,' : ', s.concept)
,round( -1 * ((c.responsibility -1)/4) * s.quantity *
s.price * (100 - s.discount) / 100, 2)
, 4
, s.ticketFk
FROM sale s
JOIN claimEnd ce ON ce.saleFk = s.id
JOIN claim c ON c.id = ce.claimFk
WHERE ce.claimDestinationFk NOT IN (1,5)
AND NOT ce.isGreuge
AND c.claimStateFk = 3;
-- Reclamaciones que pasan a Maná
INSERT INTO greuge(shipped,
clientFk,
`description`,
amount,
greugeTypeFk,
ticketFk)
SELECT c.ticketCreated,
c.clientFk,
concat('Claim_mana ',c.id,' : ', s.concept),
round( ((c.responsibility -1)/4) * s.quantity * s.price * (100 - s.discount) / 100, 2),
3,
s.ticketFk
FROM sale s
JOIN claimEnd ce ON ce.saleFk = s.id
JOIN claim c ON c.id = ce.claimFk
WHERE ce.claimDestinationFk NOT IN (1,5)
AND NOT ce.isGreuge
AND c.claimStateFk = 3
AND c.isChargedToMana;
-- Marcamos para no repetir
UPDATE claimEnd ce
JOIN claim c ON c.id = ce.claimFk
SET c.isChargedToMana = TRUE
WHERE ce.claimDestinationFk NOT IN (1,5)
AND NOT ce.isGreuge
AND c.claimStateFk = 3;
-- Recobros
CREATE OR REPLACE TEMPORARY TABLE tTicketList
(PRIMARY KEY (ticketFk))
SELECT DISTINCT s.ticketFk
FROM saleComponent sc
JOIN sale s ON sc.saleFk = s.id
JOIN ticket t ON t.id = s.ticketFk
JOIN ticketLastState ts ON ts.ticketFk = t.id
JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk
JOIN state st ON st.id = tt.stateFk
WHERE sc.componentFk = 17
AND sc.isGreuge = 0
AND t.shipped >= '2016-10-01'
AND t.shipped < util.VN_CURDATE()
AND st.alertLevel >= 3;
DELETE g.*
FROM greuge g
JOIN tTicketList t ON t.ticketFk = g.ticketFk
WHERE g.greugeTypeFk = vRecoveryGreugeType;
INSERT INTO greuge(clientFk,
`description`,
amount,
shipped,
greugeTypeFk,
ticketFk)
SELECT t.clientFk,
'Recobro',
- ROUND(SUM(sc.value * s.quantity), 2) dif,
DATE(t.shipped),
vRecoveryGreugeType,
tl.ticketFk
FROM sale s
JOIN ticket t ON t.id = s.ticketFk
JOIN tTicketList tl ON tl.ticketFk = t.id
JOIN saleComponent sc ON sc.saleFk = s.id
AND sc.componentFk = 17
GROUP BY t.id
HAVING ABS(dif) > 1;
UPDATE saleComponent sc
JOIN sale s ON s.id = sc.saleFk
JOIN tTicketList tl ON tl.ticketFk = s.ticketFk
SET sc.isGreuge = TRUE
WHERE sc.componentFk = 17;
/*
* Recalculamos la ratio de las reclamaciones, que luego
* se va a utilizar en el recobro
*/
REPLACE claimRatio(clientFk, yearSale, claimAmount, claimingRate, priceIncreasing)
SELECT id, 0, 0, 0, 0
FROM client;
REPLACE claimRatio(clientFk, yearSale, claimAmount, claimingRate, priceIncreasing)
SELECT cac.clientFk, 12 * cac.invoiced, totalClaims,
ROUND(totalClaims / (12 * cac.invoiced), 4), 0
FROM bs.clientAnnualConsumption cac
LEFT JOIN(
SELECT c.clientFk, round(sum(-1 * ((c.responsibility -1)/4) *
s.quantity * s.price * (100 - s.discount) / 100))
totalClaims
FROM sale s
JOIN claimEnd ce ON ce.saleFk = s.id
JOIN claim c ON c.id = ce.claimFk
WHERE ce.claimDestinationFk NOT IN (1,5)
AND c.claimStateFk = 3
AND c.ticketCreated >= util.VN_CURDATE() - INTERVAL 1 YEAR
GROUP BY c.clientFk
) claims ON claims.clientFk = fm.Id_Cliente;
-- Calculamos el porcentaje del recobro para añadirlo al precio de venta
UPDATE claimRatio cr
JOIN (
SELECT clientFk, IFNULL(SUM(amount), 0) AS Greuge
FROM greuge
WHERE shipped <= util.VN_CURDATE()
GROUP BY clientFk
) g ON g.clientFk = cr.clientFk
SET cr.priceIncreasing = GREATEST(0, round(IFNULL(Greuge, 0) /
(IFNULL(Consumo, 0) * vMonthToRefund / 12 ), 3));
-- Protección neonatos
UPDATE claimRatio cr
JOIN firstTicketShipped fts ON fts.clientFk = cr.clientFk
SET cr.priceIncreasing = 0,
cr.claimingRate = 0
WHERE fts.shipped > util.VN_CURDATE() - INTERVAL 1 MONTH;
DROP TEMPORARY TABLE tTicketList;
END$$
DELIMITER ;