salix/db/routines/vn/functions/getTimeBetweenRoadmapAddres...

63 lines
1.7 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` FUNCTION `vn`.`getTimeBetweenRoadmapAddresses`(
vRoadmapAddressFrom INT,
vRoadmapAddressTo INT
)
RETURNS int(11)
DETERMINISTIC
BEGIN
/**
* Retorna el tiempo en segundos que se suele tardar en ir
* de un punto de distribución a otro en una ruta troncal.
*
* @param vRoadmapAddressFrom Punto de distribución de origen
* @param vRoadmapAddressTo Punto de distribución de destino
* @return Tiempo en segundos
*/
DECLARE vSeconds INT;
WITH wRoadmapStop AS (
SELECT ROW_NUMBER() OVER(PARTITION BY roadmapFk ORDER BY eta) `sequence`,
roadmapFk,
roadmapAddressFk,
eta
FROM vn.roadmapStop
WHERE roadmapFk IS NOT NULL
AND roadmapAddressFk IS NOT NULL
AND eta IS NOT NULL
)
SELECT AVG(TIME_TO_SEC(TIMEDIFF(rsTo.eta, rsFrom.eta))) INTO vSeconds
FROM wRoadmapStop rsFrom
JOIN wRoadmapStop rsTo ON rsTo.roadmapFk = rsFrom.roadmapFk
WHERE rsFrom.roadmapAddressFk = vRoadmapAddressFrom
AND rsTo.roadmapAddressFk = vRoadmapAddressTo
AND rsFrom.`sequence` + 1 = rsTo.`sequence`;
IF NOT IFNULL(vSeconds, 0) THEN
WITH wRoadmap AS (
SELECT id,
roadmapAddressFk,
etd
FROM vn.roadmap
WHERE roadmapAddressFk = vRoadmapAddressFrom
AND etd IS NOT NULL
), wRoadmapStop AS (
SELECT ROW_NUMBER() OVER(PARTITION BY roadmapFk ORDER BY eta) `sequence`,
roadmapFk,
roadmapAddressFk,
eta
FROM vn.roadmapStop
WHERE roadmapFk IS NOT NULL
AND roadmapAddressFk = vRoadmapAddressTo
AND eta IS NOT NULL
)
SELECT AVG(TIME_TO_SEC(TIMEDIFF(rsTo.eta, rFrom.etd))) INTO vSeconds
FROM wRoadmap rFrom
JOIN wRoadmapStop rsTo ON rsTo.roadmapFk = rFrom.id
AND rsTo.`sequence` = 1;
END IF;
RETURN vSeconds;
END$$
DELIMITER ;