Files
yourpart3/backend/migrations/20251208000000-add-character-name-to-notification.cjs

136 lines
5.1 KiB
JavaScript

"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;
`);
// 1b) Add character_id column so triggers and application can set a reference
await queryInterface.sequelize.query(`
ALTER TABLE IF EXISTS falukant_log.notification
ADD COLUMN IF NOT EXISTS character_id integer;
`);
// Create an index on character_id to speed lookups (if not exists)
await queryInterface.sequelize.query(`
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.relkind = 'i' AND c.relname = 'idx_notification_character_id' AND n.nspname = 'falukant_log'
) THEN
CREATE INDEX idx_notification_character_id ON falukant_log.notification (character_id);
END IF;
END$$;
`);
// 2) Create helper function to populate character_name from character_id or user_id
// - Resolve name via character_id if present
// - Fallback to a character for the same user_id when character_id is NULL
// - Only set NEW.character_name when the column exists and is NULL
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;
v_char_id INTEGER;
v_column_exists BOOLEAN;
BEGIN
-- check if target column exists in the notification table
SELECT EXISTS(
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'falukant_log' AND table_name = 'notification' AND column_name = 'character_name'
) INTO v_column_exists;
IF NOT v_column_exists THEN
-- Nothing to do when target column absent
RETURN NEW;
END IF;
-- only populate when column is NULL
IF NEW.character_name IS NOT NULL THEN
RETURN NEW;
END IF;
-- prefer explicit character_id
v_char_id := NEW.character_id;
-- when character_id is null, try to find a character for the user_id
IF v_char_id IS NULL AND NEW.user_id IS NOT NULL THEN
-- choose a representative character: the one with highest id for this user (change if different policy required)
SELECT id INTO v_char_id
FROM falukant_data.character
WHERE user_id = NEW.user_id
ORDER BY id DESC
LIMIT 1;
END IF;
IF v_char_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 = v_char_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
NEW.character_name := ('#' || v_char_id::text);
END IF;
ELSE
-- last resort fallback: use user_id as identifier if present
IF NEW.user_id IS NOT NULL THEN
NEW.character_name := ('#u' || NEW.user_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(`
-- drop index if exists
DO $$
BEGIN
IF EXISTS (
SELECT 1 FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.relkind = 'i' AND c.relname = 'idx_notification_character_id' AND n.nspname = 'falukant_log'
) THEN
EXECUTE 'DROP INDEX falukant_log.idx_notification_character_id';
END IF;
END$$;
`);
await queryInterface.sequelize.query(`
ALTER TABLE IF EXISTS falukant_log.notification
DROP COLUMN IF EXISTS character_name;
`);
await queryInterface.sequelize.query(`
ALTER TABLE IF EXISTS falukant_log.notification
DROP COLUMN IF EXISTS character_id;
`);
}
};