317 lines
11 KiB
JavaScript
317 lines
11 KiB
JavaScript
import { sequelize } from '../utils/sequelize.js';
|
|
|
|
export async function createTriggers() {
|
|
const createTriggerFunction = `
|
|
CREATE OR REPLACE FUNCTION community.create_user_param_visibility_trigger()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
-- Check if UserParamVisibility already exists for this UserParam
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM community.user_param_visibility
|
|
WHERE param_id = NEW.id
|
|
) THEN
|
|
-- Insert the default visibility (Invisible)
|
|
INSERT INTO community.user_param_visibility (param_id, visibility)
|
|
VALUES (NEW.id, (
|
|
SELECT id FROM type.user_param_visibility WHERE description = 'Invisible'
|
|
));
|
|
END IF;
|
|
|
|
-- If NEW is null, then we have nothing to do
|
|
IF NEW IS NULL THEN
|
|
RETURN NULL;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
|
|
const createInsertTrigger = `
|
|
CREATE OR REPLACE TRIGGER trigger_create_user_param_visibility
|
|
AFTER INSERT ON community.user_param
|
|
FOR EACH ROW
|
|
WHEN (NEW.id IS NOT NULL)
|
|
EXECUTE FUNCTION community.create_user_param_visibility_trigger();
|
|
`;
|
|
|
|
const createUpdateTrigger = `
|
|
CREATE OR REPLACE TRIGGER trigger_update_user_param_visibility
|
|
AFTER UPDATE ON community.user_param
|
|
FOR EACH ROW
|
|
WHEN (NEW.id IS NOT NULL)
|
|
EXECUTE FUNCTION community.create_user_param_visibility_trigger();
|
|
`;
|
|
|
|
const createDiaryHistoryTriggerFunction = `
|
|
CREATE OR REPLACE FUNCTION community.insert_diary_history()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO community.diary_history (diary_id, user_id, old_text, old_created_at, old_updated_at)
|
|
VALUES (OLD.id, OLD.user_id, OLD.text, OLD.created_at, OLD.updated_at);
|
|
|
|
-- If NEW is null, then we have nothing to do
|
|
IF NEW IS NULL THEN
|
|
RETURN NULL;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
|
|
const createDiaryHistoryTrigger = `
|
|
CREATE OR REPLACE TRIGGER diary_update_trigger
|
|
BEFORE UPDATE ON community.diary
|
|
FOR EACH ROW
|
|
WHEN (OLD.id IS NOT NULL)
|
|
EXECUTE FUNCTION community.insert_diary_history();
|
|
`;
|
|
|
|
const createTitleHistoryTriggerFunction = `
|
|
CREATE OR REPLACE FUNCTION forum.insert_title_history()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO forum.title_history (title_id, old_title, changed_by, old_updated_at)
|
|
VALUES (OLD.id, OLD.title, OLD.created_by, OLD.updated_at);
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
|
|
const createTitleHistoryTrigger = `
|
|
CREATE OR REPLACE TRIGGER title_update_trigger
|
|
BEFORE UPDATE ON forum.title
|
|
FOR EACH ROW
|
|
WHEN (OLD.id IS NOT NULL)
|
|
EXECUTE FUNCTION forum.insert_title_history();
|
|
`;
|
|
|
|
const createCharacterCreationTriggerMethod = `
|
|
CREATE OR REPLACE FUNCTION falukant_data.create_character_creation_trigger()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO falukant_data.knowledge (product_id, character_id)
|
|
SELECT id, NEW.id FROM falukant_type.product;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
|
|
const createCharacterCreationTrigger = `
|
|
CREATE OR REPLACE TRIGGER character_creation_trigger
|
|
AFTER INSERT ON falukant_data.character
|
|
FOR EACH ROW
|
|
WHEN (NEW.id IS NOT NULL)
|
|
EXECUTE FUNCTION falukant_data.create_character_creation_trigger();
|
|
`;
|
|
|
|
const createKnowledgeTriggerMethod = `
|
|
CREATE OR REPLACE FUNCTION falukant_data.create_knowledge_trigger()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.knowledge = random() * 61 + 20;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
|
|
const createKnowledgeTrigger = `
|
|
CREATE OR REPLACE TRIGGER knowledge_trigger
|
|
BEFORE INSERT ON falukant_data.knowledge
|
|
FOR EACH ROW
|
|
WHEN (NEW.id IS NOT NULL)
|
|
EXECUTE FUNCTION falukant_data.create_knowledge_trigger();
|
|
`;
|
|
|
|
const updateMoney = `
|
|
CREATE OR REPLACE FUNCTION falukant_data.update_money(
|
|
p_falukant_user_id integer,
|
|
p_money_change numeric,
|
|
p_activity text,
|
|
p_changed_by integer DEFAULT NULL
|
|
)
|
|
RETURNS void
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
DECLARE
|
|
v_money_before numeric(10,2);
|
|
v_money_after numeric(10,2);
|
|
v_moneyflow_id bigint;
|
|
BEGIN
|
|
SELECT money
|
|
INTO v_money_before
|
|
FROM falukant_data.falukant_user
|
|
WHERE id = p_falukant_user_id;
|
|
IF NOT FOUND THEN
|
|
RAISE EXCEPTION 'FalukantUser mit ID % nicht gefunden', p_falukant_user_id;
|
|
END IF;
|
|
v_money_after := v_money_before + p_money_change;
|
|
INSERT INTO falukant_log.moneyflow (
|
|
falukant_user_id,
|
|
activity,
|
|
money_before,
|
|
money_after,
|
|
change_value,
|
|
changed_by,
|
|
time
|
|
)
|
|
VALUES (
|
|
p_falukant_user_id,
|
|
p_activity,
|
|
v_money_before,
|
|
NULL, -- Wird gleich aktualisiert
|
|
p_money_change,
|
|
p_changed_by,
|
|
NOW()
|
|
)
|
|
RETURNING id INTO v_moneyflow_id;
|
|
UPDATE falukant_data.falukant_user
|
|
SET money = v_money_after
|
|
WHERE id = p_falukant_user_id;
|
|
UPDATE falukant_log.moneyflow
|
|
SET money_after = (
|
|
SELECT money
|
|
FROM falukant_data.falukant_user
|
|
WHERE id = p_falukant_user_id
|
|
)
|
|
WHERE id = v_moneyflow_id;
|
|
END;
|
|
$function$;
|
|
`;
|
|
|
|
const createChildRelationNameFunction = `
|
|
CREATE OR REPLACE FUNCTION falukant_data.populate_child_relation_names()
|
|
RETURNS TRIGGER AS $$
|
|
DECLARE
|
|
v_first_name TEXT;
|
|
v_last_name TEXT;
|
|
v_full_father TEXT;
|
|
v_full_mother TEXT;
|
|
BEGIN
|
|
-- Vaternamen holen
|
|
SELECT pf.name, pl.name
|
|
INTO v_first_name, v_last_name
|
|
FROM falukant_data.character c
|
|
JOIN falukant_predefine.firstname pf ON pf.id = c.first_name
|
|
JOIN falukant_predefine.lastname pl ON pl.id = c.last_name
|
|
WHERE c.id = NEW.father_character_id;
|
|
|
|
v_full_father := v_first_name || ' ' || v_last_name;
|
|
|
|
-- Mutternamen holen
|
|
SELECT pf.name, pl.name
|
|
INTO v_first_name, v_last_name
|
|
FROM falukant_data.character c
|
|
JOIN falukant_predefine.firstname pf ON pf.id = c.first_name
|
|
JOIN falukant_predefine.lastname pl ON pl.id = c.last_name
|
|
WHERE c.id = NEW.mother_character_id;
|
|
|
|
v_full_mother := v_first_name || ' ' || v_last_name;
|
|
|
|
-- Felder füllen
|
|
NEW.father_name := v_full_father;
|
|
NEW.mother_name := v_full_mother;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
|
|
const createChildRelationNameTrigger = `
|
|
DROP TRIGGER IF EXISTS trg_child_relation_populate_names
|
|
ON falukant_data.child_relation;
|
|
CREATE TRIGGER trg_child_relation_populate_names
|
|
BEFORE INSERT ON falukant_data.child_relation
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION falukant_data.populate_child_relation_names();
|
|
`;
|
|
|
|
const createRandomMoodUpdateMethod = `
|
|
CREATE OR REPLACE FUNCTION falukant_data.get_random_mood_id()
|
|
RETURNS INTEGER AS $$
|
|
BEGIN
|
|
RETURN (
|
|
SELECT id
|
|
FROM falukant_type.mood
|
|
ORDER BY random()
|
|
LIMIT 1
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql VOLATILE;
|
|
`;
|
|
|
|
try {
|
|
await sequelize.query(createTriggerFunction);
|
|
await sequelize.query(createInsertTrigger);
|
|
await sequelize.query(createUpdateTrigger);
|
|
await sequelize.query(createDiaryHistoryTriggerFunction);
|
|
await sequelize.query(createDiaryHistoryTrigger);
|
|
await sequelize.query(createTitleHistoryTriggerFunction);
|
|
await sequelize.query(createTitleHistoryTrigger);
|
|
await sequelize.query(createCharacterCreationTriggerMethod);
|
|
await sequelize.query(createCharacterCreationTrigger);
|
|
await sequelize.query(createKnowledgeTriggerMethod);
|
|
await sequelize.query(createKnowledgeTrigger);
|
|
await sequelize.query(updateMoney);
|
|
await sequelize.query(createChildRelationNameFunction);
|
|
await sequelize.query(createChildRelationNameTrigger);
|
|
await sequelize.query(createRandomMoodUpdateMethod);
|
|
await initializeCharacterTraitTrigger();
|
|
|
|
console.log('Triggers created successfully');
|
|
} catch (error) {
|
|
console.error('Error creating triggers:', error);
|
|
}
|
|
}
|
|
|
|
export const initializeCharacterTraitTrigger = async () => {
|
|
try {
|
|
const triggerCheckQuery = `
|
|
SELECT tgname
|
|
FROM pg_trigger
|
|
WHERE tgname = 'trigger_assign_traits';
|
|
`;
|
|
const [existingTrigger] = await sequelize.query(triggerCheckQuery, { type: sequelize.QueryTypes.SELECT });
|
|
if (!existingTrigger) {
|
|
console.log('⚡ Erstelle den Trigger für zufällige Traits...');
|
|
const createTriggerFunctionQuery = `
|
|
CREATE OR REPLACE FUNCTION falukant_data.assign_random_traits()
|
|
RETURNS TRIGGER AS $$
|
|
DECLARE
|
|
trait_ids INTEGER[];
|
|
i INTEGER;
|
|
BEGIN
|
|
-- Zufällig 5 Trait-IDs auswählen
|
|
SELECT ARRAY(
|
|
SELECT id FROM falukant_type.character_trait
|
|
ORDER BY RANDOM()
|
|
LIMIT 5
|
|
) INTO trait_ids;
|
|
|
|
-- Die 5 Traits dem neuen Charakter zuweisen
|
|
FOR i IN 1..array_length(trait_ids, 1) LOOP
|
|
INSERT INTO falukant_data.falukant_character_trait (character_id, trait_id)
|
|
VALUES (NEW.id, trait_ids[i]);
|
|
END LOOP;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`;
|
|
const createTriggerQuery = `
|
|
CREATE TRIGGER trigger_assign_traits
|
|
AFTER INSERT ON falukant_data.character
|
|
FOR EACH ROW EXECUTE FUNCTION falukant_data.assign_random_traits();
|
|
`;
|
|
await sequelize.query(createTriggerFunctionQuery);
|
|
await sequelize.query(createTriggerQuery);
|
|
console.log('✅ Trigger erfolgreich erstellt.');
|
|
} else {
|
|
console.log('🔹 Trigger existiert bereits. Keine Aktion erforderlich.');
|
|
}
|
|
} catch (error) {
|
|
console.error('❌ Fehler beim Erstellen des Triggers:', error);
|
|
}
|
|
};
|