The trick was to use a helper-field and a (decorated) @post_load method in the model that allows to fill the helper fields with the values (ints) instead of strings for enums. Trouble is: We are parsing strings from API/JSON and want to serialize as int (value in IntEnum). The helper fields also must be skipped when setting up the query. Pretty convoluted, but gets the jon done (finally). Also extended the database by new field 'interval_end' which is a preparation to allow not only timestamps but also intervals when specifying times for participants.
93 lines
3.9 KiB
SQL
93 lines
3.9 KiB
SQL
-- add notification handling columns to shipcall
|
|
-- evaluation_time: Time when the "traffic light" was last changed
|
|
-- evaluation_notifications_sent: Flag to indicate if notifications were sent for the current evaluation
|
|
|
|
ALTER TABLE `bremen_calling_devel`.`shipcall`
|
|
ADD COLUMN `evaluation_time` DATETIME NULL DEFAULT NULL AFTER `evaluation_message`,
|
|
ADD COLUMN `evaluation_notifications_sent` BIT NULL AFTER `evaluation_time`,
|
|
ADD COLUMN `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 `modified`;
|
|
|
|
|
|
-- prepare notification table for historic notification data
|
|
-- removed reference to participant and times and dropped unnecessary columns
|
|
-- added reference to shipcall
|
|
|
|
ALTER TABLE `bremen_calling_devel`.`notification`
|
|
DROP FOREIGN KEY `FK_NOT_TIMES`,
|
|
DROP FOREIGN KEY `FK_NOT_PART`;
|
|
ALTER TABLE `bremen_calling_devel`.`notification`
|
|
DROP COLUMN `deleted`,
|
|
DROP COLUMN `acknowledged`,
|
|
DROP COLUMN `participant_id`,
|
|
DROP COLUMN `times_id`,
|
|
ADD COLUMN `shipcall_id` INT UNSIGNED NULL AFTER `id`,
|
|
ADD INDEX `FK_NOTIFICATION_SHIPCALL_idx` (`shipcall_id` ASC) VISIBLE,
|
|
DROP INDEX `FK_NOT_PART` ,
|
|
DROP INDEX `FK_NOT_TIMES` ;
|
|
;
|
|
ALTER TABLE `bremen_calling_devel`.`notification`
|
|
ADD CONSTRAINT `FK_NOTIFICATION_SHIPCALL`
|
|
FOREIGN KEY (`shipcall_id`)
|
|
REFERENCES `bremen_calling_devel`.`shipcall` (`id`)
|
|
ON DELETE NO ACTION
|
|
ON UPDATE NO ACTION;
|
|
|
|
|
|
-- added notification flags
|
|
-- participant reference is now mandatory
|
|
|
|
ALTER TABLE `bremen_calling_devel`.`user`
|
|
DROP FOREIGN KEY `FK_USER_PART`;
|
|
ALTER TABLE `bremen_calling_devel`.`user`
|
|
ADD COLUMN `notify_email` BIT NULL DEFAULT NULL AFTER `api_key`,
|
|
ADD COLUMN `notify_whatsapp` BIT NULL DEFAULT NULL AFTER `notify_email`,
|
|
ADD COLUMN `notify_signal` BIT NULL DEFAULT NULL AFTER `notify_whatsapp`,
|
|
ADD COLUMN `notify_popup` BIT NULL DEFAULT NULL AFTER `notify_signal`,
|
|
CHANGE COLUMN `participant_id` `participant_id` INT UNSIGNED NOT NULL ;
|
|
ALTER TABLE `bremen_calling_devel`.`user`
|
|
ADD CONSTRAINT `FK_USER_PART`
|
|
FOREIGN KEY (`participant_id`)
|
|
REFERENCES `bremen_calling_devel`.`participant` (`id`);
|
|
|
|
-- History table for change tracking
|
|
|
|
CREATE TABLE `bremen_calling_devel`.`history` (
|
|
`id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
|
|
`participant_id` INT UNSIGNED NOT NULL,
|
|
`user_id` INT UNSIGNED NOT NULL,
|
|
`shipcall_id` INT UNSIGNED NOT NULL,
|
|
`timestamp` DATETIME NOT NULL COMMENT 'Time of saving',
|
|
`eta` DATETIME 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`))
|
|
COMMENT = 'This table stores a history of changes made to shipcalls so that everyone can see who changed what and when';
|
|
|
|
-- and foreign keys
|
|
|
|
ALTER TABLE `bremen_calling_devel`.`history`
|
|
ADD INDEX `FK_HISTORY_PARTICIPANT_idx` (`participant_id` ASC) VISIBLE,
|
|
ADD INDEX `FK_HISTORY_SHIPCALL_idx` (`shipcall_id` ASC) VISIBLE;
|
|
;
|
|
ALTER TABLE `bremen_calling_devel`.`history`
|
|
ADD CONSTRAINT `FK_HISTORY_PARTICIPANT`
|
|
FOREIGN KEY (`participant_id`)
|
|
REFERENCES `bremen_calling_devel`.`participant` (`id`)
|
|
ON DELETE NO ACTION
|
|
ON UPDATE NO ACTION,
|
|
ADD CONSTRAINT `FK_HISTORY_SHIPCALL`
|
|
FOREIGN KEY (`shipcall_id`)
|
|
REFERENCES `bremen_calling_devel`.`shipcall` (`id`)
|
|
ON DELETE NO ACTION
|
|
ON UPDATE NO ACTION,
|
|
ADD CONSTRAINT `FK_HISTORY_USER`
|
|
FOREIGN KEY (`user_id`)
|
|
REFERENCES `bremen_calling_devel`.`user` (`id`)
|
|
ON DELETE NO ACTION
|
|
ON UPDATE NO ACTION;
|
|
|
|
-- add ata_atd field to times
|
|
|
|
ALTER TABLE `bremen_calling_devel`.`times`
|
|
ADD COLUMN `ata_atd` DATETIME NULL DEFAULT NULL COMMENT 'Relevant only for mooring, this field can be used to record actual ATA / ATD' AFTER `participant_type`,
|
|
ADD COLUMN `interval_end` DATETIME NULL 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.' AFTER `ata_atd`; |