DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`claimRatio_add`() BEGIN /* * Añade a la tabla greuges todos los cargos necesario y * que luego lo utilizamos para calcular el recobro. */ DECLARE vMonthToRefund INT DEFAULT 4; DECLARE vRecoveryGreugeType INT DEFAULT (SELECT id FROM greugeType WHERE code = 'recovery'); DECLARE vManaGreugeType INT DEFAULT (SELECT id FROM greugeType WHERE code = 'mana'); DECLARE vClaimGreugeType INT DEFAULT (SELECT id FROM greugeType WHERE code = 'claim'); DECLARE vDebtComponentType INT DEFAULT (SELECT id FROM component WHERE code = 'debtCollection'); IF vRecoveryGreugeType IS NULL OR vManaGreugeType IS NULL OR vClaimGreugeType IS NULL OR vDebtComponentType IS NULL THEN CALL util.throw('Required variables not found'); END IF; -- 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), vClaimGreugeType, s.ticketFk FROM sale s JOIN claimEnd ce ON ce.saleFk = s.id JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk WHERE ce.claimDestinationFk NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge AND cs.code = 'resolved'; -- 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), vManaGreugeType, s.ticketFk FROM sale s JOIN claimEnd ce ON ce.saleFk = s.id JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk WHERE cd.description NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge AND cs.code = 'resolved' AND c.isChargedToMana; -- Marcamos para no repetir UPDATE claimEnd ce JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk SET c.isChargedToMana = TRUE WHERE cd.description NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge AND cs.code = 'resolved'; -- 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 JOIN alertLevel al ON al.id = st.alertLevel WHERE sc.componentFk = vDebtComponentType AND NOT sc.isGreuge AND t.shipped >= '2016-10-01' AND t.shipped < util.VN_CURDATE() AND al.code = 'DELIVERED'; 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 = vDebtComponentType 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 = vDebtComponentType; INSERT INTO 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 claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk WHERE ce.claimDestinationFk NOT IN ('Bueno', 'Corregido') AND cs.code = 'resolved' AND c.ticketCreated >= util.VN_CURDATE() - INTERVAL 1 YEAR GROUP BY c.clientFk ) sub ON sub.clientFk = cac.clientFk; -- Calculamos el porcentaje del recobro para añadirlo al precio de venta UPDATE claimRatio cr JOIN ( SELECT clientFk, IFNULL(SUM(amount), 0) greuge FROM greuge WHERE shipped <= util.VN_CURDATE() GROUP BY clientFk ) sub ON sub.clientFk = cr.clientFk SET cr.priceIncreasing = GREATEST(0, ROUND(IFNULL(sub.greuge, 0) / (IFNULL(cr.yearSale, 0) * vMonthToRefund / 12 ), 3)) WHERE cr.dated = util.VN_CURDATE(); -- 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 AND cr.dated = util.VN_CURDATE(); DROP TEMPORARY TABLE tTicketList; END$$ DELIMITER ;