diff --git a/backend/migrations/20251208000000-add-character-name-to-notification.cjs b/backend/migrations/20251208000000-add-character-name-to-notification.cjs new file mode 100644 index 0000000..fa684e8 --- /dev/null +++ b/backend/migrations/20251208000000-add-character-name-to-notification.cjs @@ -0,0 +1,61 @@ +"use strict"; + +module.exports = { + async up(queryInterface, Sequelize) { + // 1) Add character_name column to notification table + await queryInterface.sequelize.query(` + ALTER TABLE IF EXISTS falukant_log.notification + ADD COLUMN IF NOT EXISTS character_name text; + `); + + // 2) Create helper function to populate character_name from character_id + await queryInterface.sequelize.query(` + CREATE OR REPLACE FUNCTION falukant_log.populate_notification_character_name() + RETURNS TRIGGER AS $function$ + DECLARE + v_first_name TEXT; + v_last_name TEXT; + BEGIN + IF NEW.character_name IS NULL AND NEW.character_id IS NOT NULL THEN + SELECT pf.name, pl.name + INTO v_first_name, v_last_name + FROM falukant_data.character c + LEFT JOIN falukant_predefine.firstname pf ON pf.id = c.first_name + LEFT JOIN falukant_predefine.lastname pl ON pl.id = c.last_name + WHERE c.id = NEW.character_id; + + IF v_first_name IS NOT NULL OR v_last_name IS NOT NULL THEN + NEW.character_name := COALESCE(v_first_name, '') || CASE WHEN v_first_name IS NOT NULL AND v_last_name IS NOT NULL THEN ' ' ELSE '' END || COALESCE(v_last_name, ''); + ELSE + -- Fallback to placeholder with id + NEW.character_name := ('#' || NEW.character_id::text); + END IF; + END IF; + RETURN NEW; + END; + $function$ LANGUAGE plpgsql; + `); + + // 3) Create trigger that runs before insert to populate the column + await queryInterface.sequelize.query(` + DROP TRIGGER IF EXISTS trg_populate_notification_character_name ON falukant_log.notification; + CREATE TRIGGER trg_populate_notification_character_name + BEFORE INSERT ON falukant_log.notification + FOR EACH ROW + EXECUTE FUNCTION falukant_log.populate_notification_character_name(); + `); + }, + + async down(queryInterface, Sequelize) { + await queryInterface.sequelize.query(` + DROP TRIGGER IF EXISTS trg_populate_notification_character_name ON falukant_log.notification; + `); + await queryInterface.sequelize.query(` + DROP FUNCTION IF EXISTS falukant_log.populate_notification_character_name(); + `); + await queryInterface.sequelize.query(` + ALTER TABLE IF EXISTS falukant_log.notification + DROP COLUMN IF EXISTS character_name; + `); + } +}; diff --git a/backend/models/falukant/log/notification.js b/backend/models/falukant/log/notification.js index f4bcf6e..71f0c05 100644 --- a/backend/models/falukant/log/notification.js +++ b/backend/models/falukant/log/notification.js @@ -10,6 +10,17 @@ Notification.init({ tr: { type: DataTypes.STRING, allowNull: false}, + character_name: { + type: DataTypes.STRING, + allowNull: true, + field: 'character_name' + }, + characterName: { + type: DataTypes.VIRTUAL, + get() { + return this.getDataValue('character_name') || null; + } + }, shown: { type: DataTypes.BOOLEAN, allowNull: false,