diff --git a/misc/check_clear_double_times_entries.sql b/misc/check_clear_double_times_entries.sql new file mode 100644 index 0000000..cdea5b4 --- /dev/null +++ b/misc/check_clear_double_times_entries.sql @@ -0,0 +1,46 @@ +-- Inspect duplicates first +WITH duplicate_participants AS ( + SELECT + shipcall_id, + participant_type, + COUNT(*) AS cnt + FROM times + GROUP BY shipcall_id, participant_type + HAVING COUNT(*) > 1 +) +SELECT + t.* +FROM times AS t +JOIN duplicate_participants AS d + ON d.shipcall_id = t.shipcall_id + AND (d.participant_type <=> t.participant_type) +ORDER BY t.shipcall_id, t.participant_type, t.id; + +-- Delete all but the highest-id entry per (shipcall_id, participant_type) +WITH ordered_times AS ( + SELECT + id, + ROW_NUMBER() OVER ( + PARTITION BY shipcall_id, participant_type + ORDER BY id DESC + ) AS rn + FROM times +) +DELETE FROM times +WHERE id IN ( + SELECT id + FROM ordered_times + WHERE rn > 1 +); + +-- Optional: re-check that no duplicates remain +WITH duplicate_participants AS ( + SELECT + shipcall_id, + participant_type, + COUNT(*) AS cnt + FROM times + GROUP BY shipcall_id, participant_type + HAVING COUNT(*) > 1 +) +SELECT COUNT(*) AS remaining_duplicates FROM duplicate_participants; diff --git a/misc/create_schema.sql b/misc/create_schema.sql index 5f9764c..66a2b9c 100644 --- a/misc/create_schema.sql +++ b/misc/create_schema.sql @@ -1,8 +1,8 @@ --- MySQL dump 10.13 Distrib 8.0.33, for Win64 (x86_64) +-- MySQL dump 10.13 Distrib 8.0.43, for Win64 (x86_64) -- -- Host: localhost Database: bremen_calling_test -- ------------------------------------------------------ --- Server version 8.0.34-0ubuntu0.22.04.1 +-- Server version 8.0.42-0ubuntu0.24.10.1 /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; @@ -28,15 +28,44 @@ CREATE TABLE `berth` ( `lock` bit(1) DEFAULT NULL COMMENT 'The lock must be used', `owner_id` int unsigned DEFAULT NULL, `authority_id` int unsigned DEFAULT NULL, + `port_id` int unsigned DEFAULT NULL, `created` datetime DEFAULT CURRENT_TIMESTAMP, `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, `deleted` bit(1) DEFAULT b'0', PRIMARY KEY (`id`), KEY `FK_OWNER_PART_idx` (`owner_id`), - KEY `FK_AUTHORITY_PART_idx` (`authority_id`), + KEY `FK_AUTHORITY_PART_idx` (`authority_id`) /*!80000 INVISIBLE */, + KEY `FK_PORT_PART_idx` (`port_id`), CONSTRAINT `FK_AUTHORITY_PART` FOREIGN KEY (`authority_id`) REFERENCES `participant` (`id`), - CONSTRAINT `FK_OWNER_PART` FOREIGN KEY (`owner_id`) REFERENCES `participant` (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=195 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Berth of ship for a ship call'; + CONSTRAINT `FK_OWNER_PART` FOREIGN KEY (`owner_id`) REFERENCES `participant` (`id`), + CONSTRAINT `FK_PORT` FOREIGN KEY (`port_id`) REFERENCES `port` (`id`) ON DELETE RESTRICT ON UPDATE RESTRICT +) ENGINE=InnoDB AUTO_INCREMENT=205 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Berth of ship for a ship call'; +/*!40101 SET character_set_client = @saved_cs_client */; + +-- +-- Table structure for table `history` +-- + +DROP TABLE IF EXISTS `history`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!50503 SET character_set_client = utf8mb4 */; +CREATE TABLE `history` ( + `id` int unsigned NOT NULL AUTO_INCREMENT, + `participant_id` int unsigned NOT NULL, + `user_id` int unsigned DEFAULT NULL, + `shipcall_id` int unsigned NOT NULL, + `timestamp` datetime NOT NULL COMMENT 'Time of saving', + `eta` datetime DEFAULT NULL COMMENT 'Current ETA / ETD value (depends if shipcall or times were saved)', + `type` int NOT NULL COMMENT 'shipcall or times', + `operation` int NOT NULL COMMENT 'insert, update or delete', + PRIMARY KEY (`id`), + KEY `FK_HISTORY_PARTICIPANT_idx` (`participant_id`), + KEY `FK_HISTORY_SHIPCALL_idx` (`shipcall_id`), + KEY `FK_HISTORY_USER` (`user_id`), + CONSTRAINT `FK_HISTORY_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`), + CONSTRAINT `FK_HISTORY_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`), + CONSTRAINT `FK_HISTORY_USER` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) +) ENGINE=InnoDB AUTO_INCREMENT=23537 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='This table stores a history of changes made to shipcalls so that everyone can see who changed what and when'; /*!40101 SET character_set_client = @saved_cs_client */; CREATE TABLE `history` ( @@ -67,20 +96,19 @@ DROP TABLE IF EXISTS `notification`; /*!50503 SET character_set_client = utf8mb4 */; CREATE TABLE `notification` ( `id` int unsigned NOT NULL AUTO_INCREMENT, - `times_id` int unsigned NOT NULL COMMENT 'times record that caused the notification', - `participant_id` int unsigned NOT NULL COMMENT 'participant ref', - `acknowledged` bit(1) DEFAULT b'0' COMMENT 'true if UI acknowledged', + `shipcall_id` int unsigned DEFAULT NULL, + `participant_id` int unsigned DEFAULT NULL, `level` tinyint DEFAULT NULL COMMENT 'severity of the notification', `type` tinyint DEFAULT NULL COMMENT 'Email/UI/Other', - `message` varchar(256) DEFAULT NULL COMMENT 'individual message', + `message` varchar(512) DEFAULT NULL COMMENT 'individual message', `created` datetime DEFAULT CURRENT_TIMESTAMP, `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), - KEY `FK_NOT_TIMES` (`times_id`), - KEY `FK_NOT_PART` (`participant_id`), - CONSTRAINT `FK_NOT_PART` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`), - CONSTRAINT `FK_NOT_TIMES` FOREIGN KEY (`times_id`) REFERENCES `times` (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='An entry corresponds to an alarm given by a violated rule during times update'; + KEY `FK_NOTIFICATION_SHIPCALL_idx` (`shipcall_id`), + KEY `FK_NOTIFICATION_PARTICIPANT_idx` (`participant_id`), + CONSTRAINT `FK_NOTIFICATION_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) ON DELETE RESTRICT ON UPDATE RESTRICT, + CONSTRAINT `FK_NOTIFICATION_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`) +) ENGINE=InnoDB AUTO_INCREMENT=10398 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='An entry corresponds to an alarm given by a violated rule during times update'; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -102,7 +130,46 @@ CREATE TABLE `participant` ( `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, `deleted` bit(1) DEFAULT b'0', PRIMARY KEY (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=137 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='An organization taking part'; +) ENGINE=InnoDB AUTO_INCREMENT=160 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='An organization taking part'; +/*!40101 SET character_set_client = @saved_cs_client */; + +-- +-- Table structure for table `participant_port_map` +-- + +DROP TABLE IF EXISTS `participant_port_map`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!50503 SET character_set_client = utf8mb4 */; +CREATE TABLE `participant_port_map` ( + `id` int NOT NULL AUTO_INCREMENT, + `participant_id` int unsigned NOT NULL COMMENT 'Ref to participant', + `port_id` int unsigned NOT NULL COMMENT 'Ref to port', + `created` datetime DEFAULT CURRENT_TIMESTAMP, + `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, + PRIMARY KEY (`id`), + KEY `FK_PP_PARTICIPANT` (`participant_id`), + KEY `FK_PP_PORT` (`port_id`), + CONSTRAINT `FK_PP_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`), + CONSTRAINT `FK_PP_PORT` FOREIGN KEY (`port_id`) REFERENCES `port` (`id`) +) ENGINE=InnoDB AUTO_INCREMENT=86 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Mapping table that assigns participants to a port'; +/*!40101 SET character_set_client = @saved_cs_client */; + +-- +-- Table structure for table `port` +-- + +DROP TABLE IF EXISTS `port`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!50503 SET character_set_client = utf8mb4 */; +CREATE TABLE `port` ( + `id` int unsigned NOT NULL AUTO_INCREMENT, + `name` varchar(128) NOT NULL COMMENT 'Name of port', + `locode` char(5) DEFAULT NULL COMMENT 'UNECE locode', + `created` datetime DEFAULT CURRENT_TIMESTAMP, + `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, + `deleted` bit(1) DEFAULT b'0', + PRIMARY KEY (`id`) +) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Port as reference for shipcalls and berths'; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -185,7 +252,7 @@ CREATE TABLE `ship` ( PRIMARY KEY (`id`), KEY `FK_SHIP_PARTICIPANT` (`participant_id`), CONSTRAINT `FK_SHIP_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=14 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci; +) ENGINE=InnoDB AUTO_INCREMENT=485 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -221,16 +288,25 @@ CREATE TABLE `shipcall` ( `canceled` bit(1) DEFAULT NULL, `evaluation` int unsigned DEFAULT NULL, `evaluation_message` varchar(512) DEFAULT NULL, + `evaluation_time` datetime DEFAULT NULL, + `evaluation_notifications_sent` bit(1) DEFAULT NULL, + `port_id` int unsigned NOT NULL DEFAULT '1' COMMENT 'Selected port for this shipcall', + `time_ref_point` int DEFAULT '0' COMMENT 'Index of a location which is the reference point for all time value entries, e.g. berth or Geeste', `created` datetime DEFAULT CURRENT_TIMESTAMP, `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `FK_SHIPCALL_SHIP` (`ship_id`), KEY `FK_SHIPCALL_BERTH_ARRIVAL` (`arrival_berth_id`), KEY `FK_SHIPCALL_BERTH_DEPARTURE` (`departure_berth_id`), + KEY `idx_shipcall_type` (`type`), + KEY `idx_shipcall_eta` (`eta`), + KEY `idx_shipcall_etd` (`etd`), + KEY `FK_SHIPCALL_PORT_idx` (`port_id`), CONSTRAINT `FK_SHIPCALL_BERTH_ARRIVAL` FOREIGN KEY (`arrival_berth_id`) REFERENCES `berth` (`id`), CONSTRAINT `FK_SHIPCALL_BERTH_DEPARTURE` FOREIGN KEY (`departure_berth_id`) REFERENCES `berth` (`id`), + CONSTRAINT `FK_SHIPCALL_PORT` FOREIGN KEY (`port_id`) REFERENCES `port` (`id`) ON DELETE RESTRICT ON UPDATE RESTRICT, CONSTRAINT `FK_SHIPCALL_SHIP` FOREIGN KEY (`ship_id`) REFERENCES `ship` (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=23 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Incoming, outgoing or moving to another berth'; +) ENGINE=InnoDB AUTO_INCREMENT=2789 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Incoming, outgoing or moving to another berth'; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -244,15 +320,15 @@ CREATE TABLE `shipcall_participant_map` ( `id` int NOT NULL AUTO_INCREMENT, `shipcall_id` int unsigned DEFAULT NULL, `participant_id` int unsigned DEFAULT NULL, - `type` int unsigned DEFAULT NULL COMMENT 'Type of participant role', + `type` int unsigned DEFAULT NULL, `created` datetime DEFAULT CURRENT_TIMESTAMP, `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `FK_MAP_PARTICIPANT_SHIPCALL` (`shipcall_id`), KEY `FK_MAP_SHIPCALL_PARTICIPANT` (`participant_id`), - CONSTRAINT `FK_MAP_PARTICIPANT_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`), + CONSTRAINT `FK_MAP_PARTICIPANT_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`) ON DELETE SET NULL, CONSTRAINT `FK_MAP_SHIPCALL_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=128 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Associates a participant with a shipcall'; +) ENGINE=InnoDB AUTO_INCREMENT=8933 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Associates a participant with a shipcall'; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -304,13 +380,20 @@ CREATE TABLE `times` ( `berth_info` varchar(512) DEFAULT NULL, `pier_side` bit(1) DEFAULT NULL, `participant_type` int unsigned DEFAULT NULL, + `ata` datetime DEFAULT NULL COMMENT 'Relevant only for mooring, this field can be used to record actual ATA', + `atd` datetime DEFAULT NULL COMMENT 'Relevant only for mooring, this field can be used to record actual ATD', + `eta_interval_end` datetime DEFAULT NULL COMMENT 'If this value is set the times are given as interval instead of a single point in time. The start time value depends on the participant type.', + `etd_interval_end` datetime DEFAULT NULL COMMENT 'If this value is set the times are given as interval instead of a single point in time. The start time value depends on the participant type.', PRIMARY KEY (`id`), + UNIQUE KEY `uniq_shipcall_participant` (`shipcall_id`,`participant_type`), KEY `FK_TIME_SHIPCALL` (`shipcall_id`), KEY `FK_TIME_PART` (`participant_id`) /*!80000 INVISIBLE */, KEY `FK_TIME_BERTH` (`berth_id`) /*!80000 INVISIBLE */, + KEY `idx_times_eta_berth` (`eta_berth`), + KEY `idx_times_etd_berth` (`etd_berth`), CONSTRAINT `FK_TIME_BERTH` FOREIGN KEY (`berth_id`) REFERENCES `berth` (`id`) ON DELETE RESTRICT ON UPDATE RESTRICT, CONSTRAINT `FK_TIME_PART` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=44 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='the planned time for the participants work'; +) ENGINE=InnoDB AUTO_INCREMENT=7863 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='the planned time for the participants work'; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -322,7 +405,7 @@ DROP TABLE IF EXISTS `user`; /*!50503 SET character_set_client = utf8mb4 */; CREATE TABLE `user` ( `id` int unsigned NOT NULL AUTO_INCREMENT, - `participant_id` int unsigned DEFAULT NULL, + `participant_id` int unsigned NOT NULL, `first_name` varchar(45) DEFAULT NULL, `last_name` varchar(45) DEFAULT NULL, `user_name` varchar(45) DEFAULT NULL, @@ -330,12 +413,17 @@ CREATE TABLE `user` ( `user_phone` varchar(128) DEFAULT NULL, `password_hash` varchar(128) DEFAULT NULL, `api_key` varchar(256) DEFAULT NULL, + `notify_email` bit(1) DEFAULT NULL, + `notify_whatsapp` bit(1) DEFAULT NULL, + `notify_signal` bit(1) DEFAULT NULL, + `notify_popup` bit(1) DEFAULT NULL, + `notify_event` int DEFAULT NULL COMMENT 'Bitflag of selected notification event types that the user wants to be notified of', `created` datetime DEFAULT CURRENT_TIMESTAMP, `modified` datetime DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `FK_USER_PART` (`participant_id`), CONSTRAINT `FK_USER_PART` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) -) ENGINE=InnoDB AUTO_INCREMENT=30 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='member of a participant'; +) ENGINE=InnoDB AUTO_INCREMENT=55 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='member of a participant'; /*!40101 SET character_set_client = @saved_cs_client */; -- @@ -358,6 +446,57 @@ CREATE TABLE `user_role_map` ( CONSTRAINT `FK_USER_ROLE` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Assigns a user to a role'; /*!40101 SET character_set_client = @saved_cs_client */; + +-- +-- Dumping routines for database 'bremen_calling_test' +-- +/*!50003 DROP PROCEDURE IF EXISTS `delete_data` */; +/*!50003 SET @saved_cs_client = @@character_set_client */ ; +/*!50003 SET @saved_cs_results = @@character_set_results */ ; +/*!50003 SET @saved_col_connection = @@collation_connection */ ; +/*!50003 SET character_set_client = utf8mb4 */ ; +/*!50003 SET character_set_results = utf8mb4 */ ; +/*!50003 SET collation_connection = utf8mb4_0900_ai_ci */ ; +/*!50003 SET @saved_sql_mode = @@sql_mode */ ; +/*!50003 SET sql_mode = 'ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_ENGINE_SUBSTITUTION' */ ; +DELIMITER ;; +CREATE DEFINER=`ds`@`localhost` PROCEDURE `delete_data`() +BEGIN + DECLARE shipcall_id_var int; + DECLARE done INT DEFAULT FALSE; + + DECLARE shipcall_iter CURSOR FOR + SELECT shipcall.id FROM shipcall + LEFT JOIN times ON + times.shipcall_id = shipcall.id AND times.participant_type = 8 + WHERE + -- ARRIVAL + (type = 1 AND GREATEST(shipcall.eta, COALESCE(times.eta_berth, 0)) <= CURRENT_DATE() - INTERVAL 1 MONTH) OR + -- DEPARTURE / SHIFTING + (type != 1 AND GREATEST(shipcall.etd, COALESCE(times.etd_berth, 0)) <= CURRENT_DATE() - INTERVAL 1 MONTH); + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; + + OPEN shipcall_iter; + + delete_loop: LOOP + FETCH shipcall_iter INTO shipcall_id_var; + IF done THEN + LEAVE delete_loop; + END IF; + DELETE FROM shipcall_participant_map WHERE shipcall_id = shipcall_id_var; + DELETE FROM shipcall_tug_map WHERE shipcall_id = shipcall_id_var; + DELETE FROM times WHERE shipcall_id = shipcall_id_var; + DELETE FROM history WHERE shipcall_id = shipcall_id_var; + DELETE FROM shipcall WHERE id = shipcall_id_var; + END LOOP; + CLOSE shipcall_iter; +END ;; +DELIMITER ; +/*!50003 SET sql_mode = @saved_sql_mode */ ; +/*!50003 SET character_set_client = @saved_cs_client */ ; +/*!50003 SET character_set_results = @saved_cs_results */ ; +/*!50003 SET collation_connection = @saved_col_connection */ ; /*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */; /*!40101 SET SQL_MODE=@OLD_SQL_MODE */; @@ -368,4 +507,4 @@ CREATE TABLE `user_role_map` ( /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; /*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */; --- Dump completed on 2023-10-06 14:52:04 +-- Dump completed on 2025-11-17 8:26:36