Some fixes and additions
This commit is contained in:
@@ -241,6 +241,180 @@ export async function createTriggers() {
|
||||
$$ LANGUAGE plpgsql VOLATILE;
|
||||
`;
|
||||
|
||||
// process_elections–Stored-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);
|
||||
@@ -257,6 +431,7 @@ export async function createTriggers() {
|
||||
await sequelize.query(createChildRelationNameFunction);
|
||||
await sequelize.query(createChildRelationNameTrigger);
|
||||
await sequelize.query(createRandomMoodUpdateMethod);
|
||||
await sequelize.query(createProcessElectionsFunction);
|
||||
await initializeCharacterTraitTrigger();
|
||||
|
||||
console.log('Triggers created successfully');
|
||||
|
||||
Reference in New Issue
Block a user