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 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Port as reference for shipcalls and berths'; -- Add default port to table INSERT INTO port (id, name, locode) VALUES (1, 'Bremen', 'DEBRE'); -- Adding new ref column to berth ALTER TABLE `bremen_calling_devel`.`berth` ADD COLUMN `port_id` INT UNSIGNED DEFAULT NULL AFTER `authority_id`; ALTER TABLE `bremen_calling_devel`.`berth` ALTER INDEX `FK_AUTHORITY_PART_idx` INVISIBLE; -- adding a foreign key berth.port_id -> port.id ALTER TABLE `bremen_calling_devel`.`berth` ADD INDEX `FK_PORT_PART_idx` (`port_id` ASC) VISIBLE; ALTER TABLE `bremen_calling_devel`.`berth` ADD CONSTRAINT `FK_PORT` FOREIGN KEY (`port_id`) REFERENCES `bremen_calling_devel`.`port` (`id`) ON DELETE RESTRICT ON UPDATE RESTRICT; -- adding new ref column to shipcall incl. foreign key ALTER TABLE `bremen_calling_devel`.`shipcall` ADD COLUMN `port_id` INT UNSIGNED NOT NULL DEFAULT 1 COMMENT 'Selected port for this shipcall' AFTER `evaluation_notifications_sent`, CHANGE COLUMN `time_ref_point` `time_ref_point` INT NULL DEFAULT '0' COMMENT 'Index of a location which is the reference point for all time value entries, e.g. berth or Geeste' AFTER `port_id`, ADD INDEX `FK_SHIPCALL_PORT_idx` (`port_id` ASC) VISIBLE; ; ALTER TABLE `bremen_calling_devel`.`shipcall` ADD CONSTRAINT `FK_SHIPCALL_PORT` FOREIGN KEY (`port_id`) REFERENCES `bremen_calling_devel`.`port` (`id`) ON DELETE RESTRICT ON UPDATE RESTRICT; 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 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci COMMENT='Mapping table that assigns participants to a port'; -- all existing berths shall default to "bremen" UPDATE berth SET port_id = 1;