salix/db/routines/vn/functions/routeProposal_beta.sql

56 lines
1.8 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`routeProposal_beta`(vTicketFk INT)
RETURNS int(11)
NOT DETERMINISTIC
READS SQL DATA
BEGIN
DECLARE vRouteFk INT;
DECLARE vAddressFk INT;
DECLARE vLanded DATE;
DECLARE vZoneFk INT;
DECLARE vSignificativeFriendship INT DEFAULT 6;
DECLARE vVolumeMax DECIMAL(5,1) DEFAULT 10;
SELECT addressFk, zoneFk, landed INTO vAddressFk, vZoneFk, vLanded
FROM vn.ticket
WHERE id = vTicketFk;
-- Se inicia la selección de rutas posibles con aquellas cuyas agencias alguna vez han estado asociadas con nuestra zona
DROP TEMPORARY TABLE IF EXISTS tmp.route;
CREATE TEMPORARY TABLE tmp.route
SELECT r.id routeFk,
zf.friendship zoneFriendship
FROM vn.route r
JOIN cache.zoneAgencyFriendship zf ON zf.agencyModeFk = r.agencyModeFk
WHERE friendship >= vSignificativeFriendship
AND zf.zoneFk = vZoneFk
AND r.created = vLanded
ORDER BY friendship;
-- Se eliminan aquellas que superan el volumen máximo
DELETE r.*
FROM tmp.route r
JOIN (SELECT routeFk, sum(volume) volume
FROM vn.saleVolume
WHERE landed = vLanded
GROUP BY routeFk) sub ON sub.routeFk = r.routeFk
WHERE sub.volume > vVolumeMax;
-- Se ordenan las que quedan en función con la afinidad del resto de consignatarios de cada ruta
SELECT routeFk INTO vRouteFk
FROM
(SELECT r.routeFk, r.zoneFriendship, sum(af.friendship) friendshipSum
FROM tmp.route r
LEFT JOIN vn.ticket t ON t.routeFk = r.routeFk
LEFT JOIN cache.addressFriendship af ON af.addressFk2 = t.addressFk AND af.addressFk1 = vAddressFk
GROUP BY routeFk
ORDER BY zoneFriendship DESC, friendshipSum DESC
) sub
LIMIT 1;
RETURN vRouteFk;
END$$
DELIMITER ;