feat: refs #8227 Roadmap changes
gitea/salix/pipeline/pr-dev There was a failure building this commit
Details
gitea/salix/pipeline/pr-dev There was a failure building this commit
Details
This commit is contained in:
parent
56b0baebaa
commit
a14d6227a1
|
@ -16,19 +16,46 @@ BEGIN
|
||||||
*/
|
*/
|
||||||
DECLARE vSeconds INT;
|
DECLARE vSeconds INT;
|
||||||
|
|
||||||
WITH wRoadmap AS (
|
WITH wRoadmapStop AS (
|
||||||
SELECT ROW_NUMBER() OVER(PARTITION BY roadmapFk ORDER BY eta) `sequence`,
|
SELECT ROW_NUMBER() OVER(PARTITION BY roadmapFk ORDER BY eta) `sequence`,
|
||||||
roadmapFk,
|
roadmapFk,
|
||||||
roadmapAddressFk,
|
roadmapAddressFk,
|
||||||
eta
|
eta
|
||||||
FROM vn.roadmapStop
|
FROM vn.roadmapStop
|
||||||
|
WHERE roadmapFk IS NOT NULL
|
||||||
|
AND roadmapAddressFk IS NOT NULL
|
||||||
|
AND eta IS NOT NULL
|
||||||
)
|
)
|
||||||
SELECT AVG(TIME_TO_SEC(TIMEDIFF(rTo.eta, rFrom.eta))) INTO vSeconds
|
SELECT AVG(TIME_TO_SEC(TIMEDIFF(rsTo.eta, rsFrom.eta))) INTO vSeconds
|
||||||
FROM wRoadmap rFrom
|
FROM wRoadmapStop rsFrom
|
||||||
JOIN wRoadmap rTo ON rTo.roadmapFk = rFrom.roadmapFk
|
JOIN wRoadmapStop rsTo ON rsTo.roadmapFk = rsFrom.roadmapFk
|
||||||
WHERE rFrom.roadmapAddressFk = vRoadmapAddressFrom
|
WHERE rsFrom.roadmapAddressFk = vRoadmapAddressFrom
|
||||||
AND rTo.roadmapAddressFk = vRoadmapAddressTo
|
AND rsTo.roadmapAddressFk = vRoadmapAddressTo
|
||||||
AND rFrom.`sequence` + 1 = rTo.`sequence`;
|
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;
|
RETURN vSeconds;
|
||||||
END$$
|
END$$
|
||||||
|
|
|
@ -0,0 +1,17 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`roadmap_afterUpdate`
|
||||||
|
AFTER UPDATE ON `roadmap`
|
||||||
|
FOR EACH ROW
|
||||||
|
BEGIN
|
||||||
|
DECLARE vSeconds INT;
|
||||||
|
|
||||||
|
IF NOT (NEW.etd <=> OLD.etd) THEN
|
||||||
|
SET vSeconds = TIME_TO_SEC(TIMEDIFF(NEW.etd, OLD.etd));
|
||||||
|
IF vSeconds IS NOT NULL AND vSeconds <> 0 THEN
|
||||||
|
UPDATE roadmapStop
|
||||||
|
SET eta = eta + INTERVAL vSeconds SECOND
|
||||||
|
WHERE roadmapFk = NEW.id;
|
||||||
|
END IF;
|
||||||
|
END IF;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -4,12 +4,32 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`roadmap_beforeInsert`
|
||||||
FOR EACH ROW
|
FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
SET NEW.editorFk = account.myUser_getId();
|
SET NEW.editorFk = account.myUser_getId();
|
||||||
IF NEW.etd > NEW.eta THEN
|
|
||||||
|
IF NEW.name IS NOT NULL THEN
|
||||||
|
SET NEW.name = UCASE(NEW.name);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NEW.etd > NEW.eta AND NEW.etd IS NOT NULL AND NEW.eta IS NOT NULL THEN
|
||||||
CALL util.throw('Departure time can not be after arrival time');
|
CALL util.throw('Departure time can not be after arrival time');
|
||||||
END IF;
|
END IF;
|
||||||
SET NEW.name = UCASE(NEW.name);
|
|
||||||
IF NEW.`trailerPlate` IS NOT NULL THEN
|
IF NEW.trailerPlate IS NOT NULL THEN
|
||||||
SET NEW.m3 = (SELECT m3 FROM vehicle WHERE numberPlate = NEW.trailerPlate);
|
SET NEW.m3 = (SELECT m3 FROM vehicle WHERE numberPlate = NEW.trailerPlate);
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
|
IF NEW.tugPlate IS NOT NULL THEN
|
||||||
|
SET NEW.m3 = NEW.m3 + (SELECT m3 FROM vehicle WHERE numberPlate = NEW.tugPlate);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NEW.driver1Fk IS NOT NULL THEN
|
||||||
|
SET NEW.driverName = (SELECT CONCAT(w.firstName, ' ', w.lastName)
|
||||||
|
FROM worker w
|
||||||
|
WHERE w.id = NEW.driver1Fk);
|
||||||
|
|
||||||
|
SET NEW.phone = (SELECT COALESCE(w.phone, c.mobile, c.phone, c.mobile)
|
||||||
|
FROM worker w
|
||||||
|
LEFT JOIN client c ON c.id = w.id
|
||||||
|
WHERE w.id = NEW.driver1Fk);
|
||||||
|
END IF;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
|
@ -4,12 +4,51 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`roadmap_beforeUpdate`
|
||||||
FOR EACH ROW
|
FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
SET NEW.editorFk = account.myUser_getId();
|
SET NEW.editorFk = account.myUser_getId();
|
||||||
IF NEW.etd > NEW.eta THEN
|
|
||||||
|
IF NOT (NEW.name <=> OLD.name) THEN
|
||||||
|
SET NEW.name = UCASE(NEW.name);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NEW.etd > NEW.eta AND NEW.etd IS NOT NULL AND NEW.eta IS NOT NULL THEN
|
||||||
CALL util.throw('Departure time can not be after arrival time');
|
CALL util.throw('Departure time can not be after arrival time');
|
||||||
END IF;
|
END IF;
|
||||||
SET NEW.name = UCASE(NEW.name);
|
|
||||||
IF NOT (NEW.`trailerPlate` <=> OLD.`trailerPlate`) THEN
|
IF NOT (NEW.trailerPlate <=> OLD.trailerPlate) THEN
|
||||||
SET NEW.m3 = (SELECT m3 FROM vehicle WHERE numberPlate = NEW.trailerPlate);
|
SET NEW.m3 = (SELECT m3 FROM vehicle WHERE numberPlate = NEW.trailerPlate);
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
|
IF NOT (NEW.tugPlate <=> OLD.tugPlate) THEN
|
||||||
|
SET NEW.m3 = NEW.m3 + (SELECT m3 FROM vehicle WHERE numberPlate = NEW.tugPlate);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NOT (NEW.driverName <=> OLD.driverName) THEN
|
||||||
|
SET NEW.driver1Fk = NULL;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NOT (NEW.driver1Fk <=> OLD.driver1Fk) AND NEW.driver1Fk IS NOT NULL THEN
|
||||||
|
SET NEW.driverName = (SELECT CONCAT(w.firstName, ' ', w.lastName)
|
||||||
|
FROM worker w
|
||||||
|
WHERE w.id = NEW.driver1Fk);
|
||||||
|
|
||||||
|
SET NEW.phone = (SELECT COALESCE(w.phone, c.mobile, c.phone, c.mobile)
|
||||||
|
FROM worker w
|
||||||
|
LEFT JOIN client c ON c.id = w.id
|
||||||
|
WHERE w.id = NEW.driver1Fk);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NOT (NEW.driverChangeName <=> OLD.driverChangeName) THEN
|
||||||
|
SET NEW.driverChangeFk = NULL;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NOT (NEW.driverChangeFk <=> OLD.driverChangeFk) AND NEW.driverChangeFk IS NOT NULL THEN
|
||||||
|
SET NEW.driverChangeName = (SELECT CONCAT(w.firstName, ' ', w.lastName)
|
||||||
|
FROM worker w
|
||||||
|
WHERE w.id = NEW.driverChangeFk);
|
||||||
|
|
||||||
|
SET NEW.phone = (SELECT COALESCE(w.phone, c.mobile, c.phone, c.mobile)
|
||||||
|
FROM worker w
|
||||||
|
LEFT JOIN client c ON c.id = w.id
|
||||||
|
WHERE w.id = NEW.driverChangeFk);
|
||||||
|
END IF;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
|
@ -4,13 +4,17 @@ ALTER TABLE vn.roadmap
|
||||||
MODIFY COLUMN trailerPlate varchar(10) CHARACTER SET utf8mb3 COLLATE utf8mb3_unicode_ci DEFAULT NULL NULL,
|
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',
|
MODIFY COLUMN etd datetime NOT NULL COMMENT 'Tiempo estimado de salida',
|
||||||
MODIFY COLUMN `name` varchar(45) CHARACTER SET utf8mb3 COLLATE utf8mb3_unicode_ci NULL,
|
MODIFY COLUMN `name` varchar(45) CHARACTER SET utf8mb3 COLLATE utf8mb3_unicode_ci NULL,
|
||||||
ADD eta datetime NOT NULL COMMENT 'Tiempo estimado de llegada' AFTER etd,
|
MODIFY COLUMN driver1Fk int(10) unsigned DEFAULT NULL NULL AFTER driverName,
|
||||||
ADD roadmapAddressFk int(11) NOT NULL AFTER `name`;
|
MODIFY COLUMN driver2Fk int(10) unsigned DEFAULT NULL NULL AFTER driver1Fk,
|
||||||
|
ADD eta datetime DEFAULT NULL NULL COMMENT 'Tiempo estimado de llegada' AFTER etd,
|
||||||
|
ADD roadmapAddressFk int(11) DEFAULT NULL NULL AFTER `name`,
|
||||||
|
ADD dollyPlate varchar(10) DEFAULT NULL AFTER trailerPlate,
|
||||||
|
ADD tugPlate varchar(10) DEFAULT NULL AFTER dollyPlate,
|
||||||
|
ADD driverChangeName varchar(45) DEFAULT NULL AFTER driver2Fk,
|
||||||
|
ADD driverChangeFk int(10) unsigned DEFAULT NULL NULL AFTER driverChangeName;
|
||||||
|
|
||||||
-- Separamos los CHANGE por que si no arriba no se aplican
|
-- Separamos los CHANGE por que si no arriba no se aplican
|
||||||
ALTER TABLE vn.roadmap
|
ALTER TABLE vn.roadmap
|
||||||
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;
|
CHANGE userFk editorFk int(10) unsigned DEFAULT NULL NULL AFTER m3;
|
||||||
|
|
||||||
CREATE INDEX roadmap_etd_IDX USING BTREE ON vn.roadmap (etd);
|
CREATE INDEX roadmap_etd_IDX USING BTREE ON vn.roadmap (etd);
|
||||||
|
|
|
@ -5,9 +5,11 @@ UPDATE vn.roadmap
|
||||||
ALTER TABLE vn.roadmap
|
ALTER TABLE vn.roadmap
|
||||||
ADD CONSTRAINT roadmap_roadmapAddress_FK FOREIGN KEY (roadmapAddressFk)
|
ADD CONSTRAINT roadmap_roadmapAddress_FK FOREIGN KEY (roadmapAddressFk)
|
||||||
REFERENCES vn.roadmapAddress(addressFk) ON DELETE RESTRICT ON UPDATE CASCADE,
|
REFERENCES vn.roadmapAddress(addressFk) ON DELETE RESTRICT ON UPDATE CASCADE,
|
||||||
ADD CONSTRAINT roadmap_driver_FK FOREIGN KEY (driverFk)
|
ADD CONSTRAINT roadmap_driver_FK FOREIGN KEY (driver1Fk)
|
||||||
REFERENCES vn.worker(id) ON DELETE RESTRICT ON UPDATE CASCADE,
|
REFERENCES vn.worker(id) ON DELETE RESTRICT ON UPDATE CASCADE,
|
||||||
ADD CONSTRAINT roadmap_driver_FK2 FOREIGN KEY (codriverFk)
|
ADD CONSTRAINT roadmap_driver_FK2 FOREIGN KEY (driver2Fk)
|
||||||
|
REFERENCES vn.worker(id) ON DELETE RESTRICT ON UPDATE CASCADE,
|
||||||
|
ADD CONSTRAINT roadmap_driverChange_FK FOREIGN KEY (driverChangeFk)
|
||||||
REFERENCES vn.worker(id) ON DELETE RESTRICT ON UPDATE CASCADE,
|
REFERENCES vn.worker(id) ON DELETE RESTRICT ON UPDATE CASCADE,
|
||||||
ADD CONSTRAINT roadmap_user_Fk FOREIGN KEY (editorFk)
|
ADD CONSTRAINT roadmap_user_Fk FOREIGN KEY (editorFk)
|
||||||
REFERENCES account.user(id) ON DELETE RESTRICT ON UPDATE CASCADE;
|
REFERENCES account.user(id) ON DELETE RESTRICT ON UPDATE CASCADE;
|
||||||
|
|
|
@ -0,0 +1,2 @@
|
||||||
|
ALTER TABLE vn.vehicle
|
||||||
|
ADD typeFk enum('car','van','truck','trailer','tug', 'tugDolly','dolly') DEFAULT 'van' NOT NULL;
|
Loading…
Reference in New Issue