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 cm.Fecha , cm.Id_Cliente , concat('Claim ',cm.id,' : ', m.Concepte) ,round( -1 * ((sensib -1)/4) * Cantidad * Preu * (100 - Descuento) / 100, 2) AS Reclamaciones , 4 , m.Id_Ticket FROM vn2008.Movimientos m JOIN vn2008.cl_act ca USING(Id_Movimiento) JOIN vn2008.cl_main cm ON cm.id = ca.cl_main_id WHERE ca.cl_sol_id NOT IN (1,5) AND ca.greuge = 0 AND cm.cl_est_id = 3; -- Reclamaciones que pasan a Maná INSERT INTO vn.greuge(shipped, clientFk, description, amount, greugeTypeFk, ticketFk) SELECT cm.Fecha , cm.Id_Cliente , concat('Claim_mana ',cm.id,' : ', m.Concepte) ,round( ((sensib -1)/4) * Cantidad * Preu * (100 - Descuento) / 100, 2) AS Reclamaciones ,3 ,m.Id_Ticket FROM vn2008.Movimientos m JOIN vn2008.cl_act ca USING(Id_Movimiento) JOIN vn2008.cl_main cm ON cm.id = ca.cl_main_id WHERE ca.cl_sol_id NOT IN (1,5) AND ca.greuge = 0 AND cm.cl_est_id = 3 AND cm.mana; -- Marcamos para no repetir UPDATE vn2008.cl_act ca JOIN vn2008.cl_main cm ON cm.id = ca.cl_main_id SET greuge = 1 WHERE ca.cl_sol_id NOT IN (1,5) AND ca.greuge = 0 AND cm.cl_est_id = 3; -- Recobros DROP TEMPORARY TABLE IF EXISTS tmp.ticket_list; CREATE TEMPORARY TABLE tmp.ticket_list (PRIMARY KEY (Id_Ticket)) SELECT DISTINCT t.Id_Ticket FROM vn2008.Movimientos_componentes mc JOIN vn2008.Movimientos m ON mc.Id_Movimiento = m.Id_Movimiento JOIN vn2008.Tickets t ON t.Id_Ticket = m.Id_Ticket JOIN vn2008.Tickets_state ts ON ts.Id_Ticket = t.Id_Ticket JOIN vn.ticketTracking tt ON tt.id = ts.inter_id JOIN vn2008.state s ON s.id = tt.stateFk WHERE mc.Id_Componente = 17 AND mc.greuge = 0 AND t.Fecha >= '2016-10-01' AND t.Fecha < util.VN_CURDATE() AND s.alert_level >= 3; DELETE g.* FROM vn.greuge g JOIN tmp.ticket_list t ON g.ticketFk = t.Id_Ticket WHERE t.greugeTypeFk = 2; INSERT INTO vn.greuge(clientFk, description, amount,shipped, greugeTypeFk, ticketFk) SELECT Id_Cliente ,concat('recobro ', m.Id_Ticket), - round(SUM(mc.Valor*Cantidad),2) AS dif ,date(t.Fecha) , 2 ,tt.Id_Ticket FROM vn2008.Movimientos m JOIN vn2008.Tickets t ON t.Id_Ticket = m.Id_Ticket JOIN tmp.ticket_list tt ON tt.Id_Ticket = t.Id_Ticket JOIN vn2008.Movimientos_componentes mc ON mc.Id_Movimiento = m.Id_Movimiento AND mc.Id_Componente = 17 GROUP BY t.Id_Ticket HAVING ABS(dif) > 1; UPDATE vn2008.Movimientos_componentes mc JOIN vn2008.Movimientos m ON m.Id_Movimiento = mc.Id_Movimiento JOIN tmp.ticket_list tt ON tt.Id_Ticket = m.Id_Ticket SET greuge = 1 WHERE Id_Componente = 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_Cliente, 0,0,0,0 FROM vn2008.Clientes; REPLACE bi.claims_ratio(Id_Cliente, Consumo, Reclamaciones, Ratio, recobro) SELECT fm.Id_Cliente, 12 * fm.Consumo, Reclamaciones, round(Reclamaciones / (12*fm.Consumo),4) AS Ratio, 0 FROM bi.facturacion_media_anual fm LEFT JOIN( SELECT cm.Id_Cliente, round(sum(-1 * ((sensib -1)/4) * Cantidad * Preu * (100 - Descuento) / 100)) AS Reclamaciones FROM vn2008.Movimientos m JOIN vn2008.cl_act ca ON ca.Id_Movimiento = m.Id_Movimiento JOIN vn2008.cl_main cm ON cm.id = ca.cl_main_id WHERE ca.cl_sol_id NOT IN (1,5) AND cm.cl_est_id = 3 AND cm.Fecha >= TIMESTAMPADD(YEAR, -1, util.VN_CURDATE()) GROUP BY cm.Id_Cliente ) claims ON claims.Id_Cliente = 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, nz(SUM(amount)) 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(nz(Greuge) / (nz(Consumo) * 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 ;