// File: politics_worker.h #ifndef POLITICS_WORKER_H #define POLITICS_WORKER_H #include "worker.h" #include #include #include class PoliticsWorker : public Worker { public: PoliticsWorker(ConnectionPool &pool, MessageBroker &broker); ~PoliticsWorker() override; protected: void run() override; private: void performDailyPoliticsTask(); void evaluatePoliticalPositions( std::unordered_map& requiredPerRegion, std::unordered_map& occupiedPerRegion ); std::vector> scheduleElections(); std::vector> processExpiredOfficesAndFill(); std::vector getUserIdsInCitiesOfRegions(const std::vector& regionIds); void notifyOfficeExpirations(); void notifyElectionCreated(const std::vector>& elections); void notifyOfficeFilled(const std::vector>& newOffices); std::vector > processElections(); // ------------------------------------------------------------ // QUERY: Zähle pro Region, wie viele Sitze vorgesehen vs. besetzt sind // ------------------------------------------------------------ static constexpr const char* QUERY_COUNT_OFFICES_PER_REGION = R"( WITH seats_per_region AS ( SELECT pot.id AS office_type_id, rt.id AS region_id, pot.seats_per_region AS seats_total FROM falukant_type.political_office_type AS pot JOIN falukant_type.region AS rt ON pot.region_type = rt.label_tr ), occupied AS ( SELECT po.office_type_id, po.region_id, COUNT(*) AS occupied_count FROM falukant_data.political_office AS po GROUP BY po.office_type_id, po.region_id ), combined AS ( SELECT spr.region_id, spr.seats_total AS required_count, COALESCE(o.occupied_count, 0) AS occupied_count FROM seats_per_region AS spr LEFT JOIN occupied AS o ON spr.office_type_id = o.office_type_id AND spr.region_id = o.region_id ) SELECT region_id, SUM(required_count) AS required_count, SUM(occupied_count) AS occupied_count FROM combined GROUP BY region_id; )"; // ------------------------------------------------------------ // STEP 1: Erzeuge nur diejenigen Wahlen, bei denen noch keine Election // für denselben Termin (NOW()+2 Tage) existiert. // ------------------------------------------------------------ static constexpr const char* QUERY_SELECT_NEEDED_ELECTIONS = R"( WITH -- 1) Definiere das heutige Datum einmal als Referenz target_date AS ( SELECT NOW()::date AS election_date ), -- 2) Lösche nur diejenigen Ämter, deren Ablaufdatum heute erreicht ist, -- und merke deren (office_type_id, region_id) expired_today AS ( DELETE FROM falukant_data.political_office AS po USING falukant_type.political_office_type AS pot WHERE po.office_type_id = pot.id AND (po.created_at + (pot.term_length * INTERVAL '1 day'))::date = (SELECT election_date FROM target_date) RETURNING pot.id AS office_type_id, po.region_id AS region_id ), -- 3) Gruppiere nach Typ+Region und zähle, wie viele Sitze heute frei geworden sind gaps_per_region AS ( SELECT office_type_id, region_id, COUNT(*) AS gaps FROM expired_today GROUP BY office_type_id, region_id ), -- 4) Filtere nur diejenigen Typ+Region‐Kombinationen, für die noch **keine** Election -- mit genau demselben Datum angelegt wurde to_schedule AS ( SELECT g.office_type_id, g.region_id, g.gaps, td.election_date FROM gaps_per_region AS g CROSS JOIN target_date AS td WHERE NOT EXISTS ( SELECT 1 FROM falukant_data.election AS e WHERE e.office_type_id = g.office_type_id AND e.region_id = g.region_id AND e."date"::date = td.election_date ) ), -- 5) Lege für jede so gefilterte Kombination genau eine Election an new_elections AS ( INSERT INTO falukant_data.election (office_type_id, "date", posts_to_fill, created_at, updated_at, region_id) SELECT ts.office_type_id, ts.election_date AS "date", ts.gaps AS posts_to_fill, NOW() AS created_at, NOW() AS updated_at, ts.region_id FROM to_schedule AS ts RETURNING id AS election_id, region_id, posts_to_fill ) -- 6) Gib alle neu angelegten Wahlen zurück SELECT ne.election_id, ne.region_id, ne.posts_to_fill FROM new_elections AS ne ORDER BY ne.region_id, ne.election_id; )"; // ----------------------------------------------------------------------- // 2) Fügt für eine gegebene Election genau LIMIT = ($3 * 2) Kandidaten ein: // $1 = election_id, $2 = region_id, $3 = Anzahl der Sitze (posts_to_fill) // ----------------------------------------------------------------------- static constexpr const char* QUERY_INSERT_CANDIDATES = R"( INSERT INTO falukant_data.candidate (election_id, character_id, created_at, updated_at) SELECT $1 AS election_id, sub.id AS character_id, NOW() AS created_at, NOW() AS updated_at FROM ( WITH RECURSIVE region_tree AS ( SELECT r.id FROM falukant_data.region AS r WHERE r.id = $2 UNION ALL SELECT r2.id FROM falukant_data.region AS r2 JOIN region_tree AS rt ON r2.parent_id = rt.id ) SELECT ch.id FROM falukant_data."character" AS ch JOIN region_tree AS rt2 ON ch.region_id = rt2.id WHERE ch.user_id IS NULL AND ch.birthdate <= NOW() - INTERVAL '21 days' AND ch.title_of_nobility IN ( SELECT id FROM falukant_type.title WHERE label_tr != 'noncivil' ) ORDER BY RANDOM() LIMIT ($3 * 2) ) AS sub(id); )"; // ------------------------------------------------------------ // STEP 2: Füge eine einzelne neue Election ein und liefere die neue election_id // $1 = office_type_id // $2 = gaps (posts_to_fill) // ------------------------------------------------------------ static constexpr const char* QUERY_INSERT_ELECTION = R"( INSERT INTO falukant_data.election (office_type_id, "date", posts_to_fill, created_at, updated_at) VALUES ( $1, NOW() + INTERVAL '2 days', $2, NOW(), NOW() ) RETURNING id; )"; // ------------------------------------------------------------ // QUERY: Process Expired Offices & Refill (Winner + Random) // ------------------------------------------------------------ static constexpr const char* QUERY_PROCESS_EXPIRED_AND_FILL = R"( WITH expired_offices AS ( DELETE FROM falukant_data.political_office AS po USING falukant_type.political_office_type AS pot WHERE po.office_type_id = pot.id AND (po.created_at + (pot.term_length * INTERVAL '1 day')) <= NOW() RETURNING pot.id AS office_type_id, po.region_id AS region_id ), distinct_types AS ( SELECT DISTINCT office_type_id, region_id FROM expired_offices ), votes_per_candidate AS ( SELECT dt.office_type_id, dt.region_id, c.character_id, COUNT(v.id) AS vote_count FROM distinct_types AS dt JOIN falukant_data.election AS e ON e.office_type_id = dt.office_type_id JOIN falukant_data.vote AS v ON v.election_id = e.id JOIN falukant_data.candidate AS c ON c.election_id = e.id AND c.id = v.candidate_id WHERE e."date" >= (NOW() - INTERVAL '30 days') GROUP BY dt.office_type_id, dt.region_id, c.character_id ), ranked_winners AS ( SELECT vpc.office_type_id, vpc.region_id, vpc.character_id, ROW_NUMBER() OVER ( PARTITION BY vpc.office_type_id, vpc.region_id ORDER BY vpc.vote_count DESC ) AS rn FROM votes_per_candidate AS vpc ), selected_winners AS ( SELECT rw.office_type_id, rw.region_id, rw.character_id FROM ranked_winners AS rw JOIN falukant_type.political_office_type AS pot ON pot.id = rw.office_type_id WHERE rw.rn <= pot.seats_per_region ), insert_winners AS ( INSERT INTO falukant_data.political_office (office_type_id, character_id, created_at, updated_at, region_id) SELECT sw.office_type_id, sw.character_id, NOW() AS created_at, NOW() AS updated_at, sw.region_id FROM selected_winners AS sw RETURNING id AS new_office_id, office_type_id, character_id, region_id ), count_inserted AS ( SELECT office_type_id, region_id, COUNT(*) AS inserted_count FROM insert_winners GROUP BY office_type_id, region_id ), needed_to_fill AS ( SELECT dt.office_type_id, dt.region_id, (pot.seats_per_region - COALESCE(ci.inserted_count, 0)) AS gaps FROM distinct_types AS dt JOIN falukant_type.political_office_type AS pot ON pot.id = dt.office_type_id LEFT JOIN count_inserted AS ci ON ci.office_type_id = dt.office_type_id AND ci.region_id = dt.region_id WHERE (pot.seats_per_region - COALESCE(ci.inserted_count, 0)) > 0 ), random_candidates AS ( SELECT rtf.office_type_id, rtf.region_id, ch.id AS character_id, ROW_NUMBER() OVER ( PARTITION BY rtf.office_type_id, rtf.region_id ORDER BY RANDOM() ) AS rn FROM needed_to_fill AS rtf JOIN falukant_data."character" AS ch ON ch.region_id = rtf.region_id AND ch.user_id IS NULL AND ch.birthdate <= NOW() - INTERVAL '21 days' AND ch.title_of_nobility IN ( SELECT id FROM falukant_type.title WHERE label_tr != 'noncivil' ) AND NOT EXISTS ( SELECT 1 FROM falukant_data.political_office AS po2 JOIN falukant_type.political_office_type AS pot2 ON pot2.id = po2.office_type_id WHERE po2.character_id = ch.id AND (po2.created_at + (pot2.term_length * INTERVAL '1 day')) > NOW() + INTERVAL '2 days' ) ), insert_random AS ( INSERT INTO falukant_data.political_office (office_type_id, character_id, created_at, updated_at, region_id) SELECT rc.office_type_id, rc.character_id, NOW() AS created_at, NOW() AS updated_at, rc.region_id FROM random_candidates AS rc JOIN needed_to_fill AS rtf ON rtf.office_type_id = rc.office_type_id AND rtf.region_id = rc.region_id WHERE rc.rn <= rtf.gaps RETURNING id AS new_office_id, office_type_id, character_id, region_id ) SELECT new_office_id AS office_id, office_type_id, character_id, region_id FROM insert_winners UNION ALL SELECT new_office_id AS office_id, office_type_id, character_id, region_id FROM insert_random; )"; // ------------------------------------------------------------ // QUERY: Hole User-IDs in allen Cities untergeordneter Regionen: // ------------------------------------------------------------ static constexpr const char* QUERY_USERS_IN_CITIES_OF_REGIONS = R"( WITH RECURSIVE region_tree AS ( SELECT id FROM falukant_data.region WHERE id = $1 UNION ALL SELECT r2.id FROM falukant_data.region AS r2 JOIN region_tree AS rt ON r2.parent_id = rt.id ) SELECT DISTINCT ch.user_id FROM falukant_data."character" AS ch JOIN region_tree AS rt2 ON ch.region_id = rt2.id WHERE ch.user_id IS NOT NULL; )"; // ------------------------------------------------------------ // QUERY: Benachrichtige User, deren Amt in 2 Tagen abläuft // ------------------------------------------------------------ static constexpr const char* QUERY_NOTIFY_OFFICE_EXPIRATION = R"( INSERT INTO falukant_log.notification (user_id, tr, created_at, updated_at) SELECT po.character_id, 'notify_office_expiring', NOW(), NOW() FROM falukant_data.political_office AS po JOIN falukant_type.political_office_type AS pot ON po.office_type_id = pot.id WHERE (po.created_at + (pot.term_length * INTERVAL '1 day')) BETWEEN (NOW() + INTERVAL '2 days') AND (NOW() + INTERVAL '2 days' + INTERVAL '1 second'); )"; // ------------------------------------------------------------ // QUERY: Benachrichtige User, wenn Election angelegt wurde // ------------------------------------------------------------ static constexpr const char* QUERY_NOTIFY_ELECTION_CREATED = R"( INSERT INTO falukant_log.notification (user_id, tr, created_at, updated_at) VALUES ($1, 'notify_election_created', NOW(), NOW()); )"; // ------------------------------------------------------------ // QUERY: Benachrichtige User, wenn Amt neu besetzt wurde // ------------------------------------------------------------ static constexpr const char* QUERY_NOTIFY_OFFICE_FILLED = R"( INSERT INTO falukant_log.notification (user_id, tr, created_at, updated_at) VALUES ($1, 'notify_office_filled', NOW(), NOW()); )"; // ------------------------------------------------------------ // QUERY: Hole alle Benutzer, deren Amt in 2 Tagen abläuft // ------------------------------------------------------------ static constexpr const char* QUERY_GET_USERS_WITH_EXPIRING_OFFICES = R"( SELECT DISTINCT ch.user_id FROM falukant_data.political_office AS po JOIN falukant_type.political_office_type AS pot ON po.office_type_id = pot.id JOIN falukant_data."character" AS ch ON po.character_id = ch.id WHERE ch.user_id IS NOT NULL AND (po.created_at + (pot.term_length * INTERVAL '1 day')) BETWEEN (NOW() + INTERVAL '2 days') AND (NOW() + INTERVAL '2 days' + INTERVAL '1 second'); )"; // ------------------------------------------------------------ // QUERY: Hole alle Benutzer in Regionen mit neuen Wahlen // ------------------------------------------------------------ static constexpr const char* QUERY_GET_USERS_IN_REGIONS_WITH_ELECTIONS = R"( SELECT DISTINCT ch.user_id FROM falukant_data.election AS e JOIN falukant_data."character" AS ch ON ch.region_id = e.region_id WHERE ch.user_id IS NOT NULL AND e."date" >= NOW() - INTERVAL '1 day'; )"; // ------------------------------------------------------------ // QUERY: Hole alle Benutzer, deren Amt neu besetzt wurde // ------------------------------------------------------------ static constexpr const char* QUERY_GET_USERS_WITH_FILLED_OFFICES = R"( SELECT DISTINCT ch.user_id FROM falukant_data.political_office AS po JOIN falukant_data."character" AS ch ON po.character_id = ch.id WHERE ch.user_id IS NOT NULL AND po.created_at >= NOW() - INTERVAL '1 minute'; )"; static constexpr const char* QUERY_PROCESS_ELECTIONS = R"( SELECT office_id, office_type_id, character_id, region_id FROM falukant_data.process_elections(); )"; }; #endif // POLITICS_WORKER_H