167 lines
5.2 KiB
SQL
167 lines
5.2 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`claim_ratio_routine`()
|
|
BEGIN
|
|
DECLARE vMonthToRefund INT DEFAULT 4;
|
|
|
|
/*
|
|
* 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
|
|
*/
|
|
|
|
-- Reclamaciones demasiado sensibles
|
|
|
|
INSERT INTO vn.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 vn.sale s
|
|
JOIN vn.claimEnd ce ON ce.saleFk = s.id
|
|
JOIN vn.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 vn.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 vn.sale s
|
|
JOIN vn.claimEnd ce ON ce.saleFk = s.id
|
|
JOIN vn.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 vn.claimEnd ce
|
|
JOIN vn.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
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket_list;
|
|
CREATE TEMPORARY TABLE tmp.ticket_list
|
|
(PRIMARY KEY (Id_Ticket))
|
|
SELECT DISTINCT t.id Id_Ticket
|
|
FROM vn.saleComponent sc
|
|
JOIN vn.sale s ON sc.saleFk = s.id
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
JOIN vn.ticketLastState ts ON ts.ticketFk = t.id
|
|
JOIN vn.ticketTracking tt ON tt.id = ts.ticketTrackingFk
|
|
JOIN vn.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 vn.greuge g
|
|
JOIN tmp.ticket_list t ON g.ticketFk = t.Id_Ticket
|
|
WHERE g.greugeTypeFk = 2;
|
|
|
|
INSERT INTO vn.greuge(clientFk, description, amount,shipped,
|
|
greugeTypeFk, ticketFk)
|
|
SELECT t.clientFk
|
|
,concat('recobro ', s.ticketFk), - round(SUM(sc.value*s.quantity),2)
|
|
AS dif,
|
|
date(t.shipped)
|
|
, 2
|
|
,tt.Id_Ticket
|
|
FROM vn.sale s
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
JOIN tmp.ticket_list tt ON tt.Id_Ticket = t.id
|
|
JOIN vn.saleComponent sc
|
|
ON sc.saleFk = s.id AND sc.componentFk = 17
|
|
GROUP BY t.id
|
|
HAVING ABS(dif) > 1;
|
|
|
|
UPDATE vn.saleComponent sc
|
|
JOIN vn.sale s ON s.id = sc.saleFk
|
|
JOIN tmp.ticket_list tt ON tt.Id_Ticket = s.ticketFk
|
|
SET sc.isGreuge = 1
|
|
WHERE sc.componentFk = 17;
|
|
|
|
/*
|
|
* Recalculamos la ratio de las reclamaciones, que luego
|
|
* se va a utilizar en el recobro
|
|
*/
|
|
|
|
REPLACE bi.claims_ratio(Id_Cliente, Consumo, Reclamaciones, Ratio, recobro)
|
|
SELECT id, 0,0,0,0
|
|
FROM vn.client;
|
|
|
|
REPLACE bi.claims_ratio(Id_Cliente, Consumo, Reclamaciones, Ratio, recobro)
|
|
SELECT fm.Id_Cliente, 12 * fm.Consumo, Reclamaciones,
|
|
round(Reclamaciones / (12*fm.Consumo),4), 0
|
|
FROM bi.facturacion_media_anual fm
|
|
LEFT JOIN(
|
|
SELECT c.clientFk, round(sum(-1 * ((c.responsibility -1)/4) *
|
|
s.quantity * s.price * (100 - s.discount) / 100))
|
|
AS Reclamaciones
|
|
FROM vn.sale s
|
|
JOIN vn.claimEnd ce ON ce.saleFk = s.id
|
|
JOIN vn.claim c ON c.id = ce.claimFk
|
|
WHERE ce.claimDestinationFk NOT IN (1,5)
|
|
AND c.claimStateFk = 3
|
|
AND c.ticketCreated >= TIMESTAMPADD(YEAR, -1, util.VN_CURDATE())
|
|
GROUP BY c.clientFk
|
|
) claims ON claims.clientFk = fm.Id_Cliente;
|
|
|
|
|
|
-- Calculamos el porcentaje del recobro para añadirlo al precio de venta
|
|
UPDATE bi.claims_ratio cr
|
|
JOIN (
|
|
SELECT clientFk Id_Cliente, IFNULL(SUM(amount), 0) AS Greuge
|
|
FROM vn.greuge
|
|
WHERE shipped <= util.VN_CURDATE()
|
|
GROUP BY clientFk
|
|
) g ON g.Id_Cliente = cr.Id_Cliente
|
|
SET recobro = GREATEST(0,round(IFNULL(Greuge, 0) /
|
|
(IFNULL(Consumo, 0) * vMonthToRefund / 12 ) ,3));
|
|
|
|
-- Protección neonatos
|
|
UPDATE bi.claims_ratio cr
|
|
JOIN vn.firstTicketShipped fts ON fts.clientFk = cr.Id_Cliente
|
|
SET recobro = 0, Ratio = 0
|
|
WHERE fts.shipped > TIMESTAMPADD(MONTH,-1,util.VN_CURDATE());
|
|
|
|
-- CLIENTE 7983, JULIAN SUAU
|
|
UPDATE bi.claims_ratio SET recobro = LEAST(0.05, recobro) WHERE Id_Cliente = 7983;
|
|
|
|
-- CLIENTE 4358
|
|
UPDATE bi.claims_ratio SET recobro = GREATEST(0.05, recobro) WHERE Id_Cliente = 4358;
|
|
|
|
-- CLIENTE 5523, VERDECORA
|
|
UPDATE bi.claims_ratio SET recobro = GREATEST(0.12, recobro) WHERE Id_Cliente = 5523;
|
|
|
|
-- CLIENTE 15979, SERVEIS VETERINARIS
|
|
UPDATE bi.claims_ratio SET recobro = GREATEST(0.05, recobro) WHERE Id_Cliente = 15979;
|
|
|
|
-- CLIENTE 5189 i 8942, son de CSR i son el mateix client
|
|
UPDATE bi.claims_ratio cr
|
|
JOIN (SELECT sum(Consumo * recobro)/sum(Consumo) as recobro
|
|
FROM bi.claims_ratio
|
|
WHERE Id_Cliente IN ( 5189,8942)
|
|
) sub
|
|
SET cr.recobro = sub.recobro
|
|
WHERE Id_Cliente IN ( 5189,8942);
|
|
END$$
|
|
DELIMITER ;
|