diff --git a/db/changes/10491-august/00-notificationProc.sql b/db/changes/10491-august/00-notificationProc.sql new file mode 100644 index 0000000000..475b2e3892 --- /dev/null +++ b/db/changes/10491-august/00-notificationProc.sql @@ -0,0 +1,28 @@ +DROP FUNCTION IF EXISTS `util`.`notification_send`; +DELIMITER $$ +CREATE DEFINER=`root`@`localhost` FUNCTION `util`.`notification_send`(vNotificationName VARCHAR(255), vParams TEXT, vAuthorFk INT) + RETURNS INT + MODIFIES SQL DATA +BEGIN +/** + * Sends a notification. + * + * @param vNotificationName The notification name + * @param vParams The notification parameters formatted as JSON + * @param vAuthorFk The notification author or %NULL if there is no author + * @return The notification id + */ + DECLARE vNotificationFk INT; + + SELECT id INTO vNotificationFk + FROM `notification` + WHERE `name` = vNotificationName; + + INSERT INTO notificationQueue + SET notificationFk = vNotificationFk, + params = vParams, + authorFk = vAuthorFk; + + RETURN LAST_INSERT_ID(); +END$$ +DELIMITER ; diff --git a/db/changes/10491-august/00-notificationTables.sql b/db/changes/10491-august/00-notificationTables.sql new file mode 100644 index 0000000000..d5fcf00b20 --- /dev/null +++ b/db/changes/10491-august/00-notificationTables.sql @@ -0,0 +1,63 @@ +USE util; + +CREATE TABLE notification( + id INT PRIMARY KEY, + `name` VARCHAR(255) UNIQUE, + `description` VARCHAR(255) +); + +CREATE TABLE notificationAcl( + notificationFk INT, -- FK notification.id + roleFk INT(10) unsigned, -- FK account.role.id + PRIMARY KEY(notificationFk, roleFk) +); + +ALTER TABLE `util`.`notificationAcl` ADD CONSTRAINT `notificationAcl_ibfk_1` FOREIGN KEY (`notificationFk`) REFERENCES `util`.`notification` (`id`) + ON DELETE CASCADE + ON UPDATE CASCADE; + +ALTER TABLE `util`.`notificationAcl` ADD CONSTRAINT `notificationAcl_ibfk_2` FOREIGN KEY (`roleFk`) REFERENCES `account`.`role`(`id`) + ON DELETE RESTRICT + ON UPDATE CASCADE; + +CREATE TABLE notificationSubscription( + notificationFk INT, -- FK notification.id + userFk INT(10) unsigned, -- FK account.user.id + PRIMARY KEY(notificationFk, userFk) +); + +ALTER TABLE `util`.`notificationSubscription` ADD CONSTRAINT `notificationSubscription_ibfk_1` FOREIGN KEY (`notificationFk`) REFERENCES `util`.`notification` (`id`) + ON DELETE CASCADE + ON UPDATE CASCADE; + +ALTER TABLE `util`.`notificationSubscription` ADD CONSTRAINT `notificationSubscription_ibfk_2` FOREIGN KEY (`userFk`) REFERENCES `account`.`user`(`id`) + ON DELETE CASCADE + ON UPDATE CASCADE; + +CREATE TABLE notificationQueue( + id INT PRIMARY KEY AUTO_INCREMENT, + notificationFk VARCHAR(255), -- FK notification.name + params TEXT, -- JSON + authorFk INT(10) unsigned NULL, -- FK account.user.id + `status` ENUM('pending', 'sent', 'error') NOT NULL DEFAULT 'pending', + created DATETIME DEFAULT CURRENT_TIMESTAMP, + INDEX(notificationFk), + INDEX(authorFk), + INDEX(status) +); + +ALTER TABLE `util`.`notificationQueue` ADD CONSTRAINT `nnotificationQueue_ibfk_1` FOREIGN KEY (`notificationFk`) REFERENCES `util`.`notification` (`name`) + ON DELETE CASCADE + ON UPDATE CASCADE; + +ALTER TABLE `util`.`notificationQueue` ADD CONSTRAINT `notificationQueue_ibfk_2` FOREIGN KEY (`authorFk`) REFERENCES `account`.`user`(`id`) + ON DELETE CASCADE + ON UPDATE CASCADE; + +CREATE TABLE notificationConfig( + id INT PRIMARY KEY AUTO_INCREMENT, + cleanDays MEDIUMINT +); + +INSERT INTO notificationConfig + SET cleanDays = 90; diff --git a/db/changes/10491-august/delete.keep b/db/changes/10491-august/delete.keep deleted file mode 100644 index e69de29bb2..0000000000