diff --git a/db/routines/vn/functions/getTimeBetweenRoadmapAddresses.sql b/db/routines/vn/functions/getTimeBetweenRoadmapAddresses.sql new file mode 100644 index 000000000..5a647d51b --- /dev/null +++ b/db/routines/vn/functions/getTimeBetweenRoadmapAddresses.sql @@ -0,0 +1,35 @@ +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 wRoadmap AS ( + SELECT ROW_NUMBER() OVER(PARTITION BY roadmapFk ORDER BY eta) `sequence`, + roadmapFk, + roadmapAddressFk, + eta + FROM vn.roadmapStop + ) + SELECT AVG(TIME_TO_SEC(TIMEDIFF(rTo.eta, rFrom.eta))) INTO vSeconds + FROM wRoadmap rFrom + JOIN wRoadmap rTo ON rTo.roadmapFk = rFrom.roadmapFk + WHERE rFrom.roadmapAddressFk = vRoadmapAddressFrom + AND rTo.roadmapAddressFk = vRoadmapAddressTo + AND rFrom.`sequence` + 1 = rTo.`sequence`; + + RETURN vSeconds; +END$$ +DELIMITER ; diff --git a/db/routines/vn/triggers/roadmap_beforeInsert.sql b/db/routines/vn/triggers/roadmap_beforeInsert.sql index 118653d44..884fe0bbc 100644 --- a/db/routines/vn/triggers/roadmap_beforeInsert.sql +++ b/db/routines/vn/triggers/roadmap_beforeInsert.sql @@ -4,6 +4,10 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`roadmap_beforeInsert` FOR EACH ROW BEGIN SET NEW.editorFk = account.myUser_getId(); + IF NEW.etd > NEW.eta THEN + CALL util.throw('Departure time can not be after arrival time'); + END IF; + IF NEW.tractorPlate IS NOT NULL THEN CALL vehicle_checkNumberPlate(NEW.tractorPlate, NULL); END IF; diff --git a/db/routines/vn/triggers/roadmap_beforeUpdate.sql b/db/routines/vn/triggers/roadmap_beforeUpdate.sql index a60b1e892..96eec2aaf 100644 --- a/db/routines/vn/triggers/roadmap_beforeUpdate.sql +++ b/db/routines/vn/triggers/roadmap_beforeUpdate.sql @@ -4,6 +4,10 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`roadmap_beforeUpdate` FOR EACH ROW BEGIN SET NEW.editorFk = account.myUser_getId(); + IF NEW.etd > NEW.eta THEN + CALL util.throw('Departure time can not be after arrival time'); + END IF; + IF NEW.tractorPlate IS NOT NULL THEN CALL vehicle_checkNumberPlate(NEW.tractorPlate, NULL); END IF; diff --git a/db/versions/11416-goldenTulip/00-firstScript.sql b/db/versions/11416-goldenTulip/00-firstScript.sql index d06f25493..e2962592c 100644 --- a/db/versions/11416-goldenTulip/00-firstScript.sql +++ b/db/versions/11416-goldenTulip/00-firstScript.sql @@ -1,5 +1,10 @@ ALTER TABLE vn.roadmap + COMMENT='Rutas troncales (trailers)', MODIFY COLUMN m3 int(10) unsigned DEFAULT NULL NULL COMMENT 'Capacidad máxima del remolque', + MODIFY COLUMN trailerPlate varchar(10) CHARACTER SET utf8mb3 COLLATE utf8mb3_unicode_ci DEFAULT NULL NULL, + MODIFY COLUMN etd datetime NOT NULL COMMENT 'Tiempo estimado de salida', CHANGE driver1Fk driverFk int(10) unsigned DEFAULT NULL NULL COMMENT 'Conductor principal' AFTER driverName, CHANGE driver2Fk codriverFk int(10) unsigned DEFAULT NULL NULL COMMENT 'Copiloto' AFTER driverFk, - CHANGE userFk editorFk int(10) unsigned DEFAULT NULL NULL AFTER m3; \ No newline at end of file + CHANGE userFk editorFk int(10) unsigned DEFAULT NULL NULL AFTER m3, + ADD eta datetime NOT NULL AFTER etd COMMENT 'Tiempo estimado de llegada', + ADD roadmapAddressFk int(11) NOT NULL AFTER `name`; diff --git a/db/versions/11416-goldenTulip/01-firstScript.sql b/db/versions/11416-goldenTulip/01-firstScript.sql index 76b69387c..58cd44f0d 100644 --- a/db/versions/11416-goldenTulip/01-firstScript.sql +++ b/db/versions/11416-goldenTulip/01-firstScript.sql @@ -1 +1,7 @@ -ALTER TABLE vn.roadmapStop CHANGE userFk editorFk int(10) unsigned DEFAULT NULL NULL; \ No newline at end of file +UPDATE vn.roadmap + SET roadmapAddressFk = (SELECT MIN(addressFk) FROM vn.roadmapAddress), + eta = etd + INTERVAL 1 DAY; + +ALTER TABLE vn.roadmap + ADD CONSTRAINT roadmap_roadmapAddress_FK FOREIGN KEY (roadmapAddressFk) + REFERENCES vn.roadmapAddress(addressFk) ON DELETE RESTRICT ON UPDATE CASCADE; diff --git a/db/versions/11416-goldenTulip/02-firstScript.sql b/db/versions/11416-goldenTulip/02-firstScript.sql index 89833fe8b..8713c5090 100644 --- a/db/versions/11416-goldenTulip/02-firstScript.sql +++ b/db/versions/11416-goldenTulip/02-firstScript.sql @@ -1,4 +1,3 @@ -ALTER TABLE vn.route - ADD roadmapStopFk int(11) NULL, - ADD CONSTRAINT route_roadmapStop_FK FOREIGN KEY (roadmapStopFk) REFERENCES vn.roadmapStop(id) ON DELETE RESTRICT ON UPDATE CASCADE, - CHANGE editorFk editorFk int(10) unsigned DEFAULT NULL NULL AFTER roadmapStopFk; +ALTER TABLE vn.roadmapStop + CHANGE userFk editorFk int(10) unsigned DEFAULT NULL NULL, + CHANGE addressFk roadmapAddressFk int(11) DEFAULT NULL NULL; diff --git a/db/versions/11416-goldenTulip/03-firstScript.sql b/db/versions/11416-goldenTulip/03-firstScript.sql new file mode 100644 index 000000000..89833fe8b --- /dev/null +++ b/db/versions/11416-goldenTulip/03-firstScript.sql @@ -0,0 +1,4 @@ +ALTER TABLE vn.route + ADD roadmapStopFk int(11) NULL, + ADD CONSTRAINT route_roadmapStop_FK FOREIGN KEY (roadmapStopFk) REFERENCES vn.roadmapStop(id) ON DELETE RESTRICT ON UPDATE CASCADE, + CHANGE editorFk editorFk int(10) unsigned DEFAULT NULL NULL AFTER roadmapStopFk; diff --git a/db/versions/11416-goldenTulip/04-firstScript.sql b/db/versions/11416-goldenTulip/04-firstScript.sql new file mode 100644 index 000000000..588810ded --- /dev/null +++ b/db/versions/11416-goldenTulip/04-firstScript.sql @@ -0,0 +1,2 @@ +ALTER TABLE vn.roadmapAddress + COMMENT='Direcciones de los troncales o también llamados puntos de distribución';