-- Migration script: add_character_name_to_notification.sql -- Fügt character_name und character_id zur falukant_log.notification Tabelle hinzu, -- legt Index an, erzeugt die Helper-Funktion und den Trigger. -- Idempotent und mit Down-Schritten zum Entfernen. BEGIN; -- 1) Spalten anlegen ALTER TABLE IF EXISTS falukant_log.notification ADD COLUMN IF NOT EXISTS character_name text; ALTER TABLE IF EXISTS falukant_log.notification ADD COLUMN IF NOT EXISTS character_id integer; -- 2) Index (idempotent) CREATE INDEX IF NOT EXISTS idx_notification_character_id ON falukant_log.notification (character_id); -- 3) Trigger-Funktion anlegen (idempotent) 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 -- prüfen, ob Zielspalte existiert 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 RETURN NEW; END IF; IF NEW.character_name IS NOT NULL THEN RETURN NEW; END IF; v_char_id := NEW.character_id; IF v_char_id IS NULL AND NEW.user_id IS NOT NULL THEN 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 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; -- 4) Trigger anlegen (BEFORE INSERT) 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(); COMMIT; -- Down / Rollback (falls benötigt): -- Die folgenden Statements entfernen Trigger, Funktion, Index und Spalten. -- Hinweis: Ausführbar separat; zur Anwendung einfach die folgenden Zeilen verwenden: -- BEGIN; DROP TRIGGER IF EXISTS trg_populate_notification_character_name ON falukant_log.notification; DROP FUNCTION IF EXISTS falukant_log.populate_notification_character_name(); DROP INDEX IF EXISTS falukant_log.idx_notification_character_id; ALTER TABLE IF EXISTS falukant_log.notification DROP COLUMN IF EXISTS character_name; ALTER TABLE IF EXISTS falukant_log.notification DROP COLUMN IF EXISTS character_id; COMMIT;