salix/db/routines/bs/procedures/clientDied_recalc.sql

61 lines
2.0 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`clientDied_recalc`(
vDays INT,
vCountryCode VARCHAR(2)
)
BEGIN
/**
* Recalcula los clientes inactivos y hace insert en la tabla clientDied
* estableciendo hasta 3 avisos en función del periodo y el código de país.
*
* @param vDays El número de días a considerar para la inactividad del cliente
* @param vCountryCode El código del país para filtrar los clientes
*/
DECLARE vFirstPeriod , vSecondPeriod, vThridPeriod DATE;
SET vFirstPeriod = util.VN_CURDATE() - INTERVAL vDays DAY;
SET vSecondPeriod = util.VN_CURDATE() - INTERVAL vDays * 2 DAY;
SET vThridPeriod = util.VN_CURDATE() - INTERVAL vDays * 3 DAY;
DELETE cd.* FROM clientDied cd
JOIN (
SELECT c.id FROM vn.client c
JOIN vn.country co ON co.id = c.countryFk
WHERE co.code = vCountryCode
) sub ON sub.id = cd.clientFk;
INSERT INTO clientDied (clientFk, lastInvoiced, warning)
SELECT c.id,
sub.lastShipped,
CASE
WHEN lastShipped < vThridPeriod OR lastShipped IS NULL THEN 'third'
WHEN lastShipped < vSecondPeriod THEN 'second'
WHEN lastShipped < vFirstPeriod THEN 'first'
END
FROM vn.client c
JOIN vn.country co ON co .id = c.countryFk
JOIN vn.departmentMana dm ON dm.salesDepartmentFk = c.salesDepartmentFk
LEFT JOIN (
SELECT c.id, DATE(MAX(t.shipped)) lastShipped
FROM vn.client c
LEFT JOIN vn.ticket t ON t.clientFk = c.id
LEFT JOIN vn.country co ON co.id = c.countryFk
WHERE co.code = vCountryCode
AND (t.shipped <= util.VN_CURDATE() OR t.shipped IS NULL)
GROUP BY c.id
) sub ON sub.id = c.id
LEFT JOIN vn.clientObservation cob ON cob.clientFk = c.id
AND cob.created > vThridPeriod
WHERE (sub.lastShipped < vFirstPeriod OR sub.lastShipped IS NULL)
AND c.created < vThridPeriod
AND co.code = vCountryCode
AND cob.`text` IS NULL
AND c.id NOT IN (
SELECT DISTINCT clientFk
FROM vn.ticket
WHERE refFk IS NULL
AND shipped >= vFirstPeriod
)
GROUP BY c.id;
END$$
DELIMITER ;