CREATE DATABASE `bremen_calling` /*!40100 DEFAULT CHARACTER SET utf8mb4 */; CREATE TABLE `participant` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `name` varchar(128) DEFAULT NULL, `street` varchar(128) DEFAULT NULL, `postal_code` varchar(5) DEFAULT NULL, `city` varchar(64) DEFAULT NULL, `flags` int(10) unsigned DEFAULT NULL, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='An organization taking part'; CREATE TABLE `user` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `participant_id` int(11) UNSIGNED DEFAULT NULL, `first_name` varchar(45) DEFAULT NULL, `last_name` varchar(45) DEFAULT NULL, `user_name` varchar(45) DEFAULT NULL, `password_hash` varchar(128) DEFAULT NULL, `api_key` varchar(256) DEFAULT NULL, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_USER_PART` (`participant_id`), CONSTRAINT `FK_USER_PART` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='member of a participant'; CREATE TABLE `berth` ( `id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, `name` VARCHAR(128) NULL DEFAULT NULL COMMENT 'Descriptive name', `participant_id` INT(10) UNSIGNED NULL DEFAULT NULL COMMENT 'If berth belongs to a participant, reference it here', `lock` BIT(1) NULL DEFAULT NULL COMMENT 'The lock must be used', `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_BERTH_PART` (`participant_id`), CONSTRAINT `FK_BERTH_PART` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) ) COMMENT='Berth of ship for a ship call' ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE `ship` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `name` varchar(45) DEFAULT NULL, `imo` int(11) DEFAULT NULL, `callsign` varchar(8) DEFAULT NULL, `participant_id` INT(11) UNSIGNED NULL DEFAULT NULL, `length` FLOAT NULL DEFAULT NULL, `width` FLOAT NULL DEFAULT NULL, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_SHIP_PARTICIPANT` (`participant_id`), CONSTRAINT `FK_SHIP_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE `shipcall` ( `id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, `ship_id` INT(11) UNSIGNED NULL DEFAULT NULL, `type` TINYINT(4) NULL DEFAULT NULL, `eta` DATETIME NULL DEFAULT NULL, `voyage` VARCHAR(16) NULL DEFAULT NULL, `etd` DATETIME NULL DEFAULT NULL, `arrival_berth_id` INT(10) UNSIGNED NULL DEFAULT NULL, `departure_berth_id` INT(10) UNSIGNED NULL DEFAULT NULL, `tug_required` BIT(1) NULL DEFAULT NULL, `pilot_required` BIT(1) NULL DEFAULT NULL, `flags` INT(10) UNSIGNED NULL DEFAULT 0, `pier_side` BIT(1) NULL DEFAULT NULL, `bunkering` BIT(1) NULL DEFAULT NULL, `replenishing` BIT(1) NULL DEFAULT NULL, `draft` FLOAT NULL DEFAULT NULL, `tidal_window_from` DATETIME NULL DEFAULT NULL, `tidal_window_to` DATETIME NULL DEFAULT NULL, `rain_sensitive_cargo` BIT(1) NULL DEFAULT b'0', `recommended_tugs` INT(11) NULL DEFAULT 0, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_SHIPCALL_SHIP` (`ship_id`), INDEX `FK_SHIPCALL_BERTH_ARRIVAL` (`arrival_berth_id`), INDEX `FK_SHIPCALL_BERTH_DEPARTURE` (`departure_berth_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_SHIP` FOREIGN KEY (`ship_id`) REFERENCES `ship` (`id`) ) COMMENT='Incoming, outgoing or moving to another berth' ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE `times` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `start_planned` datetime DEFAULT NULL, `end_planned` datetime DEFAULT NULL, `duration_planned` int(11) DEFAULT NULL, `start_actual` datetime DEFAULT NULL, `end_actual` datetime DEFAULT NULL, `duration_actual` int(11) DEFAULT NULL, `shipcall_id` int(11) UNSIGNED DEFAULT NULL, `participant_id` int(11) UNSIGNED DEFAULT NULL, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_TIME_SHIPCALL` (`shipcall_id`), INDEX `FK_TIME_PART` (`participant_id`), CONSTRAINT `FK_TIME_PART` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`), CONSTRAINT `FK_TIME_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='the planned time for the participants work'; CREATE TABLE `shipcall_participant_map` ( `id` int(11) NOT NULL AUTO_INCREMENT, `shipcall_id` int(10) unsigned DEFAULT NULL, `participant_id` int(10) unsigned DEFAULT NULL, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_MAP_PARTICIPANT_SHIPCALL` (`shipcall_id`), INDEX `FK_MAP_SHIPCALL_PARTICIPANT` (`participant_id`), CONSTRAINT `FK_MAP_PARTICIPANT_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`), CONSTRAINT `FK_MAP_SHIPCALL_PARTICIPANT` FOREIGN KEY (`participant_id`) REFERENCES `participant` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Associates a participant with a shipcall'; CREATE TABLE `shipcall_tug_map` ( `id` INT(11) NOT NULL AUTO_INCREMENT, `shipcall_id` INT(11) UNSIGNED NOT NULL COMMENT 'Ref to ship call', `ship_id` INT(11) UNSIGNED NOT NULL COMMENT 'Ref to ship (that is a tug)', `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_SCT_SHIP` (`ship_id`), INDEX `FK_SCT_SHIPCALL` (`shipcall_id`), CONSTRAINT `FK_SCT_SHIP` FOREIGN KEY (`ship_id`) REFERENCES `ship` (`id`), CONSTRAINT `FK_SCT_SHIPCALL` FOREIGN KEY (`shipcall_id`) REFERENCES `shipcall` (`id`) ) COMMENT='Mapping table that assigns tugs to a ship call' ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE `notification` ( `id` INT(11) UNSIGNED NOT NULL AUTO_INCREMENT, `times_id` INT(11) UNSIGNED NOT NULL COMMENT 'times record that caused the notification', `participant_id` INT(11) UNSIGNED NOT NULL COMMENT 'participant ref', `acknowledged` BIT(1) NULL DEFAULT b'0' COMMENT 'true if UI acknowledged', `level` TINYINT(4) NULL DEFAULT NULL COMMENT 'severity of the notification', `type` TINYINT(4) NULL DEFAULT NULL COMMENT 'Email/UI/Other', `message` VARCHAR(256) NULL DEFAULT NULL COMMENT 'individual message', `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_NOT_TIMES` (`times_id`), INDEX `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`) ) COMMENT='An entry corresponds to an alarm given by a violated rule during times update' ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE `role` ( `id` INT(11) UNSIGNED NOT NULL AUTO_INCREMENT, `name` VARCHAR(50) NOT NULL DEFAULT '0' COMMENT 'unique role name', `description` VARCHAR(255) NULL DEFAULT '0' COMMENT 'role description', `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), UNIQUE INDEX `name` (`name`) ) COMMENT='logical group of securables for one or more user' DEFAULT CHARSET=utf8mb4 ENGINE=InnoDB; CREATE TABLE `securable` ( `id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, `name` VARCHAR(50) NOT NULL DEFAULT '', `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), UNIQUE INDEX `name` (`name`) ) COMMENT='Actual permission on a single(!) feature or operation' DEFAULT CHARSET=utf8mb4 ENGINE=InnoDB; CREATE TABLE `user_role_map` ( `id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, `user_id` INT(10) UNSIGNED NOT NULL DEFAULT 0, `role_id` INT(10) UNSIGNED NOT NULL DEFAULT 0, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_USER_ROLE` (`user_id`), INDEX `FK_ROLE_USER` (`role_id`), CONSTRAINT `FK_ROLE_USER` FOREIGN KEY (`role_id`) REFERENCES `role` (`id`), CONSTRAINT `FK_USER_ROLE` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) COMMENT='Assigns a user to a role' DEFAULT CHARSET=utf8mb4 ENGINE=InnoDB; CREATE TABLE `role_securable_map` ( `id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, `role_id` INT(10) UNSIGNED NOT NULL, `securable_id` INT(10) UNSIGNED NOT NULL, `created` DATETIME NULL DEFAULT current_timestamp(), `modified` DATETIME NULL DEFAULT NULL ON UPDATE current_timestamp(), PRIMARY KEY (`id`), INDEX `FK_ROLE_SECURABLE` (`role_id`), INDEX `FK_SECURABLE_ROLE` (`securable_id`), CONSTRAINT `FK_ROLE_SECURABLE` FOREIGN KEY (`role_id`) REFERENCES `role` (`id`), CONSTRAINT `FK_SECURABLE_ROLE` FOREIGN KEY (`securable_id`) REFERENCES `securable` (`id`) ) COMMENT='Assigns securables to roles' DEFAULT CHARSET=utf8mb4 ENGINE=InnoDB;