Files
yourpart3/backend/models/trigger.js
2025-07-09 14:28:35 +02:00

492 lines
17 KiB
JavaScript
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
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;
`;
// process_electionsStored-Procedure anlegen
const createProcessElectionsFunction = `
CREATE OR REPLACE FUNCTION falukant_data.process_elections()
RETURNS TABLE (
office_id INTEGER,
office_type_id INTEGER,
character_id INTEGER,
region_id INTEGER
)
AS $$
BEGIN
RETURN QUERY
WITH
-- 1) Alle Wahlen, die vor mindestens 3 Tagen erstellt wurden
to_process AS (
SELECT
e.id AS election_id,
e.office_type_id AS tp_office_type_id,
e.region_id AS tp_region_id,
e.posts_to_fill AS tp_posts_to_fill,
e.date AS tp_election_date
FROM falukant_data.election e
WHERE (e.created_at::date + INTERVAL '3 days') <= NOW()::date
),
-- 2) Stimmen pro Kandidat zählen
votes AS (
SELECT
tp.election_id,
tp.tp_posts_to_fill AS posts_to_fill,
c.character_id,
COUNT(v.*) AS votes_received
FROM to_process tp
JOIN falukant_data.candidate c
ON c.election_id = tp.election_id
LEFT JOIN falukant_data.vote v
ON v.election_id = c.election_id
AND v.candidate_id = c.id
GROUP BY tp.election_id, tp.tp_posts_to_fill, c.character_id
),
-- 3) Ranking nach Stimmen
ranked AS (
SELECT
v.election_id,
v.character_id,
v.votes_received,
ROW_NUMBER() OVER (
PARTITION BY v.election_id
ORDER BY v.votes_received DESC, RANDOM()
) AS rn
FROM votes v
),
-- 4) Top-N (posts_to_fill) sind Gewinner
winners AS (
SELECT
r.election_id,
r.character_id
FROM ranked r
JOIN to_process tp
ON tp.election_id = r.election_id
WHERE r.rn <= tp.tp_posts_to_fill
),
-- 5) Verbleibende Kandidaten ohne Gewinner
remaining AS (
SELECT
tp.election_id,
c.character_id
FROM to_process tp
JOIN falukant_data.candidate c
ON c.election_id = tp.election_id
WHERE c.character_id NOT IN (
SELECT w.character_id
FROM winners w
WHERE w.election_id = tp.election_id
)
),
-- 6) Zufalls-Nachrücker bis alle Plätze gefüllt sind
random_fill AS (
SELECT
rp.election_id,
rp.character_id
FROM remaining rp
JOIN to_process tp
ON tp.election_id = rp.election_id
JOIN LATERAL (
SELECT r2.character_id
FROM remaining r2
WHERE r2.election_id = rp.election_id
ORDER BY RANDOM()
LIMIT GREATEST(
0,
tp.tp_posts_to_fill
- (SELECT COUNT(*) FROM winners w2 WHERE w2.election_id = tp.election_id)
)
) sub
ON sub.character_id = rp.character_id
),
-- 7) Finale Gewinner (Winners random_fill)
final_winners AS (
SELECT * FROM winners
UNION ALL
SELECT * FROM random_fill
),
-- 8) Neue Ämter anlegen und sofort zurückliefern
created_offices AS (
INSERT INTO falukant_data.political_office
(office_type_id, character_id, created_at, updated_at, region_id)
SELECT
tp.tp_office_type_id,
fw.character_id,
NOW() AS created_at,
NOW() AS updated_at,
tp.tp_region_id
FROM final_winners fw
JOIN to_process tp
ON tp.election_id = fw.election_id
RETURNING
id AS co_office_id,
falukant_data.political_office.office_type_id AS co_office_type_id,
falukant_data.political_office.character_id AS co_character_id,
falukant_data.political_office.region_id AS co_region_id
),
-- 9) election_history befüllen
_hist AS (
INSERT INTO falukant_log.election_history
(election_id, political_office_type_id, election_date, election_result, created_at, updated_at)
SELECT
tp.election_id,
tp.tp_office_type_id,
tp.tp_election_date,
(
SELECT json_agg(vr)
FROM votes vr
WHERE vr.election_id = tp.election_id
),
NOW() AS created_at,
NOW() AS updated_at
FROM to_process tp
),
-- 10) Cleanup: Stimmen, Kandidaten und Wahlen löschen
_del_votes AS (
DELETE FROM falukant_data.vote
WHERE election_id IN (SELECT election_id FROM to_process)
),
_del_candidates AS (
DELETE FROM falukant_data.candidate
WHERE election_id IN (SELECT election_id FROM to_process)
),
_del_elections AS (
DELETE FROM falukant_data.election
WHERE id IN (SELECT election_id FROM to_process)
)
-- 11) Ergebnis wirklich zurückliefern
SELECT
co.co_office_id AS office_id,
co.co_office_type_id,
co.co_character_id,
co.co_region_id
FROM created_offices co
ORDER BY co.co_region_id, co.co_office_id;
END;
$$ LANGUAGE plpgsql;
`;
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 sequelize.query(createProcessElectionsFunction);
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);
}
};