Update dependencies and enhance WebSocket server logging: Add 'chrono' and 'android_system_properties' to Cargo.lock, improve error handling and logging in websocket_server.rs, and streamline character creation notifications in worker modules for better clarity and maintainability.
This commit is contained in:
@@ -14,12 +14,7 @@ SELECT id FROM falukant_data.falukant_user ORDER BY RANDOM() LIMIT 1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_RANDOM_INFANT: &str = r#"
|
||||
SELECT
|
||||
c.id AS character_id,
|
||||
c.user_id,
|
||||
c.first_name,
|
||||
c.last_name,
|
||||
CURRENT_DATE - c.birthdate::date AS age_days
|
||||
SELECT c.id AS character_id, c.user_id, CURRENT_DATE - c.birthdate::date AS age_days
|
||||
FROM falukant_data."character" c
|
||||
WHERE c.user_id IS NOT NULL AND c.health > 0 AND CURRENT_DATE - c.birthdate::date <= 730
|
||||
ORDER BY RANDOM() LIMIT 1;
|
||||
@@ -35,62 +30,25 @@ SELECT DISTINCT b.falukant_user_id AS user_id FROM falukant_data.branch b WHERE
|
||||
|
||||
pub const QUERY_UPDATE_WEATHER: &str = r#"
|
||||
WITH all_regions AS (
|
||||
SELECT DISTINCT r.id AS region_id
|
||||
FROM falukant_data.region r
|
||||
JOIN falukant_type.region tr ON r.region_type_id = tr.id
|
||||
WHERE tr.label_tr = 'city'
|
||||
),
|
||||
random_weather AS (
|
||||
SELECT
|
||||
ar.region_id,
|
||||
(
|
||||
SELECT wt.id
|
||||
FROM falukant_type.weather wt
|
||||
ORDER BY RANDOM()
|
||||
LIMIT 1
|
||||
) AS weather_type_id
|
||||
FROM all_regions ar
|
||||
SELECT DISTINCT r.id AS region_id FROM falukant_data.region r JOIN falukant_type.region tr ON r.region_type_id = tr.id WHERE tr.label_tr = 'city'
|
||||
)
|
||||
INSERT INTO falukant_data.weather (region_id, weather_type_id)
|
||||
SELECT rw.region_id, rw.weather_type_id
|
||||
FROM random_weather rw
|
||||
ON CONFLICT (region_id)
|
||||
DO UPDATE SET weather_type_id = EXCLUDED.weather_type_id;
|
||||
SELECT ar.region_id, (SELECT wt.id FROM falukant_type.weather wt ORDER BY random() + ar.region_id * 0 LIMIT 1) FROM all_regions ar
|
||||
ON CONFLICT (region_id) DO UPDATE SET weather_type_id = EXCLUDED.weather_type_id;
|
||||
"#;
|
||||
|
||||
/// Vollständige Notification-Insert-Query (inkl. `character_id`), damit Trigger/Schemaänderungen
|
||||
/// nicht an fehlenden Spalten scheitern.
|
||||
pub const QUERY_INSERT_NOTIFICATION_FULL: &str = r#"
|
||||
INSERT INTO falukant_log.notification (
|
||||
user_id,
|
||||
tr,
|
||||
character_id,
|
||||
shown,
|
||||
created_at,
|
||||
updated_at
|
||||
) VALUES ($1, $2, $3, FALSE, NOW(), NOW());
|
||||
"#;
|
||||
|
||||
/// Löscht alte Notifications (älter als 30 Tage)
|
||||
pub const QUERY_DELETE_OLD_NOTIFICATIONS: &str = r#"
|
||||
DELETE FROM falukant_log.notification
|
||||
WHERE created_at < NOW() - INTERVAL '30 days';
|
||||
pub const QUERY_INSERT_NOTIFICATION: &str = r#"
|
||||
INSERT INTO falukant_log.notification (user_id, tr, shown, created_at, updated_at)
|
||||
VALUES ($1, $2, FALSE, NOW(), NOW());
|
||||
"#;
|
||||
|
||||
// Product pricing
|
||||
pub const QUERY_GET_PRODUCT_COST: &str = r#"
|
||||
SELECT sell_cost, sell_cost AS original_sell_cost FROM falukant_type.product WHERE id = $1;
|
||||
SELECT original_sell_cost, sell_cost FROM falukant_type.product WHERE id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_DIRECTORS: &str = r#"
|
||||
SELECT
|
||||
d.may_produce,
|
||||
d.may_sell,
|
||||
d.may_start_transport,
|
||||
d.may_repair_vehicles,
|
||||
b.id AS branch_id,
|
||||
fu.id AS falukant_user_id,
|
||||
d.id
|
||||
SELECT d.may_produce, d.may_sell, d.may_start_transport, b.id AS branch_id, fu.id AS falukantUserId, d.id
|
||||
FROM falukant_data.director d
|
||||
JOIN falukant_data.falukant_user fu ON fu.id = d.employer_user_id
|
||||
JOIN falukant_data.character c ON c.id = d.director_character_id
|
||||
@@ -98,116 +56,27 @@ JOIN falukant_data.branch b ON b.region_id = c.region_id AND b.falukant_user_id
|
||||
WHERE current_time BETWEEN '08:00:00' AND '17:00:00';
|
||||
"#;
|
||||
|
||||
// Director: vehicle repair automation
|
||||
pub const QUERY_GET_VEHICLES_TO_REPAIR_IN_REGION: &str = r#"
|
||||
SELECT
|
||||
v.id AS vehicle_id,
|
||||
v.condition,
|
||||
vt.cost,
|
||||
COALESCE(vt.build_time_minutes, 0) AS build_time_minutes
|
||||
FROM falukant_data.vehicle v
|
||||
JOIN falukant_type.vehicle vt ON vt.id = v.vehicle_type_id
|
||||
WHERE v.falukant_user_id = $1
|
||||
AND v.region_id = $2
|
||||
AND v.condition < 10
|
||||
AND v.condition < 100
|
||||
AND v.available_from <= NOW()
|
||||
AND NOT EXISTS (
|
||||
SELECT 1 FROM falukant_data.transport t WHERE t.vehicle_id = v.id
|
||||
)
|
||||
ORDER BY v.condition ASC, v.id ASC;
|
||||
"#;
|
||||
|
||||
pub const QUERY_REPAIR_VEHICLE: &str = r#"
|
||||
UPDATE falukant_data.vehicle v
|
||||
SET condition = 100,
|
||||
available_from = NOW() + (COALESCE(vt.build_time_minutes, 0) * INTERVAL '1 minute'),
|
||||
updated_at = NOW()
|
||||
FROM falukant_type.vehicle vt
|
||||
WHERE vt.id = v.vehicle_type_id
|
||||
AND v.id = $1
|
||||
AND v.condition < 100
|
||||
AND v.available_from <= NOW()
|
||||
AND NOT EXISTS (SELECT 1 FROM falukant_data.transport t WHERE t.vehicle_id = v.id)
|
||||
RETURNING v.id AS vehicle_id, v.available_from, COALESCE(vt.build_time_minutes, 0) AS build_time_minutes;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_BEST_PRODUCTION: &str = r#"
|
||||
SELECT
|
||||
fdu.id AS falukant_user_id,
|
||||
CAST(fdu.money AS text) AS money,
|
||||
fdu.certificate,
|
||||
ftp.id AS product_id,
|
||||
ftp.label_tr,
|
||||
fdb.region_id,
|
||||
(SELECT SUM(quantity) FROM falukant_data.stock fds WHERE fds.branch_id = fdb.id) AS stock_size,
|
||||
COALESCE(
|
||||
(SELECT SUM(COALESCE(fdi.quantity, 0))
|
||||
FROM falukant_data.stock fds
|
||||
JOIN falukant_data.inventory fdi ON fdi.stock_id = fds.id
|
||||
WHERE fds.branch_id = fdb.id),
|
||||
0
|
||||
) AS used_in_stock,
|
||||
(
|
||||
ftp.sell_cost
|
||||
* (
|
||||
COALESCE(tpw.worth_percent, 100.0)
|
||||
+ (
|
||||
(COALESCE(k_char.knowledge, 0) * 2 + COALESCE(k_dir.knowledge, 0))::double precision / 3.0
|
||||
)
|
||||
) / 100.0
|
||||
- 6 * ftp.category
|
||||
) / (300.0 * GREATEST(1, ftp.production_time)) AS worth,
|
||||
fdb.id AS branch_id,
|
||||
(SELECT COUNT(id) FROM falukant_data.production WHERE branch_id = fdb.id) AS running_productions,
|
||||
COALESCE(
|
||||
(SELECT SUM(COALESCE(fdp.quantity, 0))
|
||||
FROM falukant_data.production fdp
|
||||
WHERE fdp.branch_id = fdb.id),
|
||||
0
|
||||
) AS running_productions_quantity
|
||||
SELECT fdu.id falukant_user_id, CAST(fdu.money AS text) AS money, fdu.certificate, ftp.id product_id, ftp.label_tr, fdb.region_id,
|
||||
(SELECT SUM(quantity) FROM falukant_data.stock fds WHERE fds.branch_id = fdb.id) AS stock_size,
|
||||
COALESCE((SELECT SUM(COALESCE(fdi.quantity, 0)) FROM falukant_data.stock fds JOIN falukant_data.inventory fdi ON fdi.stock_id = fds.id WHERE fds.branch_id = fdb.id), 0) AS used_in_stock,
|
||||
(ftp.sell_cost * (fdtpw.worth_percent + (fdk_character.knowledge * 2 + fdk_director.knowledge) / 3) / 100 - 6 * ftp.category) / (300.0 * ftp.production_time) AS worth,
|
||||
fdb.id AS branch_id, (SELECT COUNT(id) FROM falukant_data.production WHERE branch_id = fdb.id) AS running_productions,
|
||||
COALESCE((SELECT SUM(COALESCE(fdp.quantity, 0)) quantity FROM falukant_data.production fdp WHERE fdp.branch_id = fdb.id), 0) AS running_productions_quantity
|
||||
FROM falukant_data.director fdd
|
||||
JOIN falukant_data."character" fdc
|
||||
ON fdc.id = fdd.director_character_id
|
||||
JOIN falukant_data.falukant_user fdu
|
||||
ON fdd.employer_user_id = fdu.id
|
||||
LEFT JOIN falukant_data."character" user_character
|
||||
ON user_character.user_id = fdu.id
|
||||
AND user_character.health > 0
|
||||
JOIN falukant_data.branch fdb
|
||||
ON fdb.falukant_user_id = fdu.id
|
||||
AND fdb.region_id = fdc.region_id
|
||||
JOIN falukant_type.product ftp
|
||||
ON ftp.category <= fdu.certificate
|
||||
LEFT JOIN falukant_data.town_product_worth tpw
|
||||
ON tpw.region_id = fdb.region_id
|
||||
AND tpw.product_id = ftp.id
|
||||
LEFT JOIN falukant_data.knowledge k_char
|
||||
ON k_char.product_id = ftp.id
|
||||
AND user_character.id IS NOT NULL
|
||||
AND k_char.character_id = user_character.id
|
||||
LEFT JOIN falukant_data.knowledge k_dir
|
||||
ON k_dir.product_id = ftp.id
|
||||
AND k_dir.character_id = fdd.director_character_id
|
||||
WHERE fdd.id = $1
|
||||
AND fdb.id = $2
|
||||
ORDER BY worth DESC
|
||||
LIMIT 1;
|
||||
JOIN falukant_data.character fdc ON fdc.id = fdd.director_character_id
|
||||
JOIN falukant_data.falukant_user fdu ON fdd.employer_user_id = fdu.id
|
||||
JOIN falukant_data.character user_character ON user_character.user_id = fdu.id
|
||||
JOIN falukant_data.branch fdb ON fdb.falukant_user_id = fdu.id AND fdb.region_id = fdc.region_id
|
||||
JOIN falukant_data.town_product_worth fdtpw ON fdtpw.region_id = fdb.region_id
|
||||
JOIN falukant_data.knowledge fdk_character ON fdk_character.product_id = fdtpw.product_id AND fdk_character.character_id = user_character.id
|
||||
JOIN falukant_data.knowledge fdk_director ON fdk_director.product_id = fdtpw.product_id AND fdk_director.character_id = fdd.director_character_id
|
||||
JOIN falukant_type.product ftp ON ftp.id = fdtpw.product_id AND ftp.category <= fdu.certificate
|
||||
WHERE fdd.id = $1 AND fdb.id = $2 ORDER BY worth DESC LIMIT 1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_INSERT_PRODUCTION: &str = r#"
|
||||
INSERT INTO falukant_data.production (branch_id, product_id, quantity, weather_type_id, start_timestamp)
|
||||
VALUES ($1, $2, $3, (SELECT weather_type_id FROM falukant_data.weather WHERE region_id = $4), NOW());
|
||||
"#;
|
||||
|
||||
// Reparatur: falls Produktionen ohne start_timestamp angelegt wurden, werden sie so gesetzt,
|
||||
// dass sie sofort als „fertig“ gelten (start = NOW() - production_time Minuten).
|
||||
pub const QUERY_FIX_NULL_PRODUCTION_START: &str = r#"
|
||||
UPDATE falukant_data.production p
|
||||
SET start_timestamp = NOW() - (INTERVAL '1 minute' * pr.production_time)
|
||||
FROM falukant_type.product pr
|
||||
WHERE p.start_timestamp IS NULL
|
||||
AND pr.id = p.product_id;
|
||||
INSERT INTO falukant_data.production (branch_id, product_id, quantity, weather_type_id) VALUES ($1, $2, $3, (SELECT weather_type_id FROM falukant_data.weather WHERE region_id = $4));
|
||||
"#;
|
||||
|
||||
// Character creation related queries (missing from earlier extraction)
|
||||
@@ -321,12 +190,8 @@ DELETE FROM falukant_data.inventory WHERE id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_ADD_SELL_LOG: &str = r#"
|
||||
INSERT INTO falukant_log.sell (region_id, product_id, quantity, seller_id, sell_timestamp)
|
||||
VALUES ($1, $2, $3, $4, NOW())
|
||||
ON CONFLICT (seller_id, product_id, region_id)
|
||||
DO UPDATE SET
|
||||
quantity = falukant_log.sell.quantity + EXCLUDED.quantity,
|
||||
sell_timestamp = COALESCE(EXCLUDED.sell_timestamp, NOW());
|
||||
INSERT INTO falukant_log.sell (region_id, product_id, quantity, seller_id) VALUES ($1, $2, $3, $4)
|
||||
ON CONFLICT (region_id, product_id, seller_id) DO UPDATE SET quantity = falukant_log.sell.quantity + EXCLUDED.quantity;
|
||||
"#;
|
||||
pub const QUERY_GET_ARRIVED_TRANSPORTS: &str = r#"
|
||||
SELECT
|
||||
@@ -338,37 +203,15 @@ SELECT
|
||||
t.target_region_id,
|
||||
b_target.id AS target_branch_id,
|
||||
b_source.id AS source_branch_id,
|
||||
COALESCE(rd.distance, 0.0) AS distance,
|
||||
rd.distance AS distance,
|
||||
v.falukant_user_id AS user_id
|
||||
FROM falukant_data.transport AS t
|
||||
JOIN falukant_data.vehicle AS v ON v.id = t.vehicle_id
|
||||
JOIN falukant_type.vehicle AS vt ON vt.id = v.vehicle_type_id
|
||||
LEFT JOIN LATERAL (
|
||||
SELECT rd.distance
|
||||
FROM falukant_data.region_distance AS rd
|
||||
WHERE (
|
||||
(rd.source_region_id = t.source_region_id AND rd.target_region_id = t.target_region_id)
|
||||
OR (rd.source_region_id = t.target_region_id AND rd.target_region_id = t.source_region_id)
|
||||
)
|
||||
AND (
|
||||
rd.transport_mode = vt.transport_mode
|
||||
OR rd.transport_mode IS NULL
|
||||
OR vt.transport_mode IS NULL
|
||||
)
|
||||
ORDER BY
|
||||
(rd.transport_mode = vt.transport_mode) DESC,
|
||||
(rd.transport_mode IS NULL) DESC
|
||||
LIMIT 1
|
||||
) AS rd ON TRUE
|
||||
JOIN falukant_data.region_distance AS rd ON ((rd.source_region_id = t.source_region_id AND rd.target_region_id = t.target_region_id) OR (rd.source_region_id = t.target_region_id AND rd.target_region_id = t.source_region_id)) AND (rd.transport_mode = vt.transport_mode OR rd.transport_mode IS NULL)
|
||||
LEFT JOIN falukant_data.branch AS b_target ON b_target.region_id = t.target_region_id AND b_target.falukant_user_id = v.falukant_user_id
|
||||
LEFT JOIN falukant_data.branch AS b_source ON b_source.region_id = t.source_region_id AND b_source.falukant_user_id = v.falukant_user_id
|
||||
WHERE (
|
||||
-- Transport ist angekommen basierend auf Distanz und Geschwindigkeit (wenn speed > 0)
|
||||
(vt.speed > 0 AND rd.distance IS NOT NULL AND t.created_at + (rd.distance / vt.speed::double precision) * INTERVAL '1 minute' <= NOW())
|
||||
OR
|
||||
-- Fallback: Transport ist länger als 24 Stunden unterwegs (falls keine Distanz gefunden wurde oder speed = 0/NULL)
|
||||
(t.created_at + INTERVAL '24 hours' <= NOW())
|
||||
);
|
||||
WHERE vt.speed > 0 AND t.created_at + (rd.distance / vt.speed::double precision) * INTERVAL '1 minute' <= NOW();
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_AVAILABLE_STOCKS: &str = r#"
|
||||
@@ -410,25 +253,16 @@ pub const QUERY_UPDATE_VEHICLE_AFTER_TRANSPORT: &str = r#"
|
||||
UPDATE falukant_data.vehicle SET region_id = $2, condition = GREATEST(0, condition - $3::int), available_from = NOW(), updated_at = NOW() WHERE id = $1;
|
||||
"#;
|
||||
|
||||
// Vehicle maintenance (TransportWorker)
|
||||
pub const QUERY_GET_BROKEN_VEHICLES: &str = r#"
|
||||
SELECT id AS vehicle_id, falukant_user_id AS user_id
|
||||
FROM falukant_data.vehicle
|
||||
WHERE condition <= 0;
|
||||
"#;
|
||||
|
||||
pub const QUERY_DELETE_TRANSPORTS_BY_VEHICLE: &str = r#"
|
||||
DELETE FROM falukant_data.transport WHERE vehicle_id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_DELETE_VEHICLE: &str = r#"
|
||||
DELETE FROM falukant_data.vehicle WHERE id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_DELETE_TRANSPORT: &str = r#"
|
||||
DELETE FROM falukant_data.transport WHERE id = $1;
|
||||
"#;
|
||||
|
||||
#[allow(dead_code)]
|
||||
pub const QUERY_ADD_TRANSPORT_WAITING_NOTIFICATION: &str = r#"
|
||||
INSERT INTO falukant_log.notification (user_id, tr, shown, created_at, updated_at)
|
||||
VALUES ((SELECT c.user_id FROM falukant_data.character c WHERE c.user_id = $1 LIMIT 1), $2, FALSE, NOW(), NOW());
|
||||
"#;
|
||||
|
||||
pub const QUERY_UPDATE_TRANSPORT_SIZE: &str = r#"
|
||||
UPDATE falukant_data.transport
|
||||
SET size = $2,
|
||||
@@ -477,13 +311,7 @@ SELECT v.id AS vehicle_id, vt.capacity AS capacity
|
||||
FROM falukant_data.vehicle v
|
||||
JOIN falukant_type.vehicle vt ON vt.id = v.vehicle_type_id
|
||||
JOIN falukant_data.region_distance rd ON ((rd.source_region_id = v.region_id AND rd.target_region_id = $3) OR (rd.source_region_id = $3 AND rd.target_region_id = v.region_id)) AND (rd.transport_mode = vt.transport_mode OR rd.transport_mode IS NULL)
|
||||
WHERE v.falukant_user_id = $1
|
||||
AND v.region_id = $2
|
||||
AND v.id NOT IN (
|
||||
SELECT DISTINCT t.vehicle_id
|
||||
FROM falukant_data.transport t
|
||||
WHERE t.vehicle_id IS NOT NULL
|
||||
);
|
||||
WHERE v.falukant_user_id = $1 AND v.region_id = $2;
|
||||
"#;
|
||||
|
||||
pub const QUERY_INSERT_TRANSPORT: &str = r#"
|
||||
@@ -521,6 +349,10 @@ WITH new_sats AS (
|
||||
UPDATE falukant_data.director dir SET satisfaction = ns.new_satisfaction FROM new_sats ns WHERE dir.id = ns.id AND dir.satisfaction IS DISTINCT FROM ns.new_satisfaction RETURNING dir.employer_user_id;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_DIRECTOR_USER: &str = r#"
|
||||
SELECT fu.id AS falukant_user_id FROM falukant_data.director d JOIN falukant_data.falukant_user fu ON fu.id = d.employer_user_id WHERE d.id = $1 LIMIT 1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_COUNT_VEHICLES_IN_BRANCH_REGION: &str = r#"
|
||||
SELECT COUNT(v.id) AS cnt FROM falukant_data.vehicle v WHERE v.falukant_user_id = $1 AND v.region_id = $2;
|
||||
"#;
|
||||
@@ -656,36 +488,6 @@ pub const QUERY_UPDATE_USER_HOUSE_STATE: &str = r#"
|
||||
);
|
||||
"#;
|
||||
|
||||
// Haus-Zusammenfall: Sobald eine Komponente <= 0 ist, wird das Haus entfernt.
|
||||
// Gilt sowohl für kaufbare Häuser als auch für Häuser im Besitz.
|
||||
pub const QUERY_DELETE_COLLAPSED_BUYABLE_HOUSES: &str = r#"
|
||||
WITH deleted AS (
|
||||
DELETE FROM falukant_data.buyable_house
|
||||
WHERE LEAST(
|
||||
roof_condition,
|
||||
floor_condition,
|
||||
wall_condition,
|
||||
window_condition
|
||||
) <= 0
|
||||
RETURNING id
|
||||
)
|
||||
SELECT id AS house_id FROM deleted;
|
||||
"#;
|
||||
|
||||
pub const QUERY_DELETE_COLLAPSED_USER_HOUSES: &str = r#"
|
||||
WITH deleted AS (
|
||||
DELETE FROM falukant_data.user_house
|
||||
WHERE LEAST(
|
||||
roof_condition,
|
||||
floor_condition,
|
||||
wall_condition,
|
||||
window_condition
|
||||
) <= 0
|
||||
RETURNING id, user_id
|
||||
)
|
||||
SELECT id AS house_id, user_id FROM deleted;
|
||||
"#;
|
||||
|
||||
pub const QUERY_UPDATE_HOUSE_QUALITY: &str = r#"
|
||||
UPDATE falukant_data.user_house
|
||||
SET roof_condition = GREATEST(0, LEAST(100, roof_condition + $1)),
|
||||
@@ -704,7 +506,7 @@ WHERE region_id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_RANDOM_CHARACTER: &str = r#"
|
||||
SELECT id, health, first_name, last_name
|
||||
SELECT id, health
|
||||
FROM falukant_data."character"
|
||||
WHERE user_id = $1 AND health > 0
|
||||
ORDER BY RANDOM() LIMIT 1;
|
||||
@@ -715,7 +517,7 @@ UPDATE falukant_data."character" SET health = $1 WHERE id = $2;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_REGION_CHARACTERS: &str = r#"
|
||||
SELECT id, health FROM falukant_data."character" WHERE region_id = $1 AND health > 0 AND user_id IS NOT NULL;
|
||||
SELECT id, health FROM falukant_data."character" WHERE region_id = $1 AND health > 0;
|
||||
"#;
|
||||
|
||||
pub const QUERY_DELETE_DIRECTOR: &str = r#"
|
||||
@@ -726,18 +528,9 @@ pub const QUERY_DELETE_RELATIONSHIP: &str = r#"
|
||||
WITH deleted AS (
|
||||
DELETE FROM falukant_data.relationship
|
||||
WHERE character1_id = $1 OR character2_id = $1
|
||||
RETURNING
|
||||
CASE WHEN character1_id = $1 THEN character2_id ELSE character1_id END AS related_character_id,
|
||||
relationship_type_id
|
||||
RETURNING CASE WHEN character1_id = $1 THEN character2_id ELSE character1_id END AS related_character_id, relationship_type_id
|
||||
)
|
||||
SELECT
|
||||
c.user_id AS related_user_id,
|
||||
d.related_character_id,
|
||||
d.relationship_type_id,
|
||||
rt.tr AS relationship_type_tr
|
||||
FROM deleted d
|
||||
LEFT JOIN falukant_data.character c ON c.id = d.related_character_id
|
||||
LEFT JOIN falukant_type.relationship rt ON rt.id = d.relationship_type_id;
|
||||
SELECT c.user_id AS related_user_id FROM deleted d JOIN falukant_data.character c ON c.id = d.related_character_id;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_USER_ID: &str = r#"
|
||||
@@ -763,12 +556,6 @@ pub const QUERY_SET_CHARACTER_USER: &str = r#"
|
||||
UPDATE falukant_data.character SET user_id = $1, updated_at = NOW() WHERE id = $2;
|
||||
"#;
|
||||
|
||||
// Erben-Logik: erst alte User-Zuordnung lösen (für Unique-Constraints auf character.user_id),
|
||||
// dann den Erben übernehmen lassen.
|
||||
pub const QUERY_CLEAR_CHARACTER_USER: &str = r#"
|
||||
UPDATE falukant_data.character SET user_id = NULL, updated_at = NOW() WHERE id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_CURRENT_MONEY: &str = r#"
|
||||
SELECT money FROM falukant_data.falukant_user WHERE id = $1;
|
||||
"#;
|
||||
@@ -1001,8 +788,7 @@ pub const QUERY_PROCESS_EXPIRED_AND_FILL: &str = r#"
|
||||
dt.office_type_id,
|
||||
dt.region_id,
|
||||
c.character_id,
|
||||
COUNT(v.id) AS vote_count,
|
||||
COALESCE(ch.reputation, 0) AS reputation
|
||||
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
|
||||
@@ -1011,10 +797,8 @@ pub const QUERY_PROCESS_EXPIRED_AND_FILL: &str = r#"
|
||||
JOIN falukant_data.candidate AS c
|
||||
ON c.election_id = e.id
|
||||
AND c.id = v.candidate_id
|
||||
JOIN falukant_data."character" AS ch
|
||||
ON ch.id = c.character_id
|
||||
WHERE e.date >= (NOW() - INTERVAL '30 days')
|
||||
GROUP BY dt.office_type_id, dt.region_id, c.character_id, ch.reputation
|
||||
GROUP BY dt.office_type_id, dt.region_id, c.character_id
|
||||
),
|
||||
ranked_winners AS (
|
||||
SELECT
|
||||
@@ -1023,7 +807,7 @@ pub const QUERY_PROCESS_EXPIRED_AND_FILL: &str = r#"
|
||||
vpc.character_id,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY vpc.office_type_id, vpc.region_id
|
||||
ORDER BY vpc.vote_count DESC, vpc.reputation DESC, vpc.character_id ASC
|
||||
ORDER BY vpc.vote_count DESC
|
||||
) AS rn
|
||||
FROM votes_per_candidate AS vpc
|
||||
),
|
||||
@@ -1371,31 +1155,6 @@ pub const QUERY_RANDOM_HEIR: &str = r#"
|
||||
chosen.child_character_id;
|
||||
"#;
|
||||
|
||||
// Fallback-Erbe: Wenn ein Spieler-Character ohne Kinder stirbt, suchen wir einen zufälligen
|
||||
// NPC-Character in derselben Region (Alter 10–14 Tage) und übergeben ihm die user_id.
|
||||
pub const QUERY_GET_RANDOM_HEIR_FROM_REGION: &str = r#"
|
||||
SELECT ch.id AS child_character_id
|
||||
FROM falukant_data.character ch
|
||||
WHERE ch.user_id IS NULL
|
||||
AND ch.health > 0
|
||||
AND ch.id <> $1
|
||||
AND ch.region_id = (
|
||||
SELECT region_id
|
||||
FROM falukant_data.character
|
||||
WHERE id = $1
|
||||
)
|
||||
-- Alter zwischen 10 und 14 Tagen: birthdate in [now-14d, now-10d]
|
||||
AND ch.birthdate <= NOW() - INTERVAL '10 days'
|
||||
AND ch.birthdate >= NOW() - INTERVAL '14 days'
|
||||
AND ch.title_of_nobility = (
|
||||
SELECT id
|
||||
FROM falukant_type.title
|
||||
WHERE label_tr = 'noncivil'
|
||||
)
|
||||
ORDER BY RANDOM()
|
||||
LIMIT 1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_UPDATE_USER_MONEY: &str = r#"
|
||||
UPDATE falukant_data.falukant_user
|
||||
SET money = $1,
|
||||
@@ -1645,16 +1404,8 @@ pub const QUERY_GET_FINISHED_PRODUCTIONS: &str = r#"
|
||||
ON p.product_id = pr.id
|
||||
JOIN falukant_data.branch br
|
||||
ON p.branch_id = br.id
|
||||
-- Es kann vorkommen, dass ein User temporär keinen zugeordneten Character hat
|
||||
-- (z.B. nach Tod/Erbe). Produktionen sollen trotzdem abschließen.
|
||||
-- LATERAL verhindert Duplikate, falls ein User mehrere Characters hat.
|
||||
LEFT JOIN LATERAL (
|
||||
SELECT c.id, c.user_id
|
||||
FROM falukant_data.character c
|
||||
WHERE c.user_id = br.falukant_user_id
|
||||
ORDER BY c.updated_at DESC NULLS LAST, c.id DESC
|
||||
LIMIT 1
|
||||
) c ON TRUE
|
||||
JOIN falukant_data.character c
|
||||
ON c.user_id = br.falukant_user_id
|
||||
LEFT JOIN falukant_data.knowledge k
|
||||
ON p.product_id = k.product_id
|
||||
AND k.character_id = c.id
|
||||
@@ -1670,7 +1421,6 @@ pub const QUERY_GET_FINISHED_PRODUCTIONS: &str = r#"
|
||||
AND pwe.weather_type_id = w.weather_type_id
|
||||
-- Wetter-Effekte derzeit aus der Qualitätsberechnung entfernt
|
||||
WHERE p.start_timestamp + INTERVAL '1 minute' * pr.production_time <= NOW()
|
||||
AND COALESCE(p.sleep, FALSE) = FALSE
|
||||
ORDER BY p.start_timestamp;
|
||||
"#;
|
||||
|
||||
@@ -1679,64 +1429,6 @@ pub const QUERY_DELETE_PRODUCTION: &str = r#"
|
||||
WHERE id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_SET_PRODUCTION_SLEEP: &str = r#"
|
||||
UPDATE falukant_data.production
|
||||
SET sleep = TRUE
|
||||
WHERE id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_SLEEP_PRODUCTIONS: &str = r#"
|
||||
SELECT
|
||||
p.id AS production_id,
|
||||
p.branch_id,
|
||||
p.product_id,
|
||||
p.quantity,
|
||||
p.start_timestamp,
|
||||
pr.production_time,
|
||||
br.region_id,
|
||||
br.falukant_user_id AS user_id,
|
||||
ROUND(
|
||||
GREATEST(
|
||||
0,
|
||||
LEAST(
|
||||
100,
|
||||
(
|
||||
(COALESCE(k.knowledge, 0) * 0.75
|
||||
+ COALESCE(k2.knowledge, 0) * 0.25)
|
||||
* COALESCE(pwe.quality_effect, 100) / 100.0
|
||||
)
|
||||
)
|
||||
)
|
||||
)::int AS quality
|
||||
FROM falukant_data.production p
|
||||
JOIN falukant_type.product pr
|
||||
ON p.product_id = pr.id
|
||||
JOIN falukant_data.branch br
|
||||
ON p.branch_id = br.id
|
||||
LEFT JOIN LATERAL (
|
||||
SELECT c.id, c.user_id
|
||||
FROM falukant_data.character c
|
||||
WHERE c.user_id = br.falukant_user_id
|
||||
ORDER BY c.updated_at DESC NULLS LAST, c.id DESC
|
||||
LIMIT 1
|
||||
) c ON TRUE
|
||||
LEFT JOIN falukant_data.knowledge k
|
||||
ON p.product_id = k.product_id
|
||||
AND k.character_id = c.id
|
||||
LEFT JOIN falukant_data.director d
|
||||
ON d.employer_user_id = c.user_id
|
||||
LEFT JOIN falukant_data.knowledge k2
|
||||
ON k2.character_id = d.director_character_id
|
||||
AND k2.product_id = p.product_id
|
||||
LEFT JOIN falukant_data.weather w
|
||||
ON w.region_id = br.region_id
|
||||
LEFT JOIN falukant_type.product_weather_effect pwe
|
||||
ON pwe.product_id = p.product_id
|
||||
AND pwe.weather_type_id = w.weather_type_id
|
||||
WHERE p.sleep = TRUE
|
||||
ORDER BY p.start_timestamp;
|
||||
"#;
|
||||
|
||||
pub const QUERY_INSERT_UPDATE_PRODUCTION_LOG: &str = r#"
|
||||
INSERT INTO falukant_log.production (
|
||||
region_id,
|
||||
@@ -1750,6 +1442,16 @@ pub const QUERY_INSERT_UPDATE_PRODUCTION_LOG: &str = r#"
|
||||
SET quantity = falukant_log.production.quantity + EXCLUDED.quantity;
|
||||
"#;
|
||||
|
||||
pub const QUERY_ADD_OVERPRODUCTION_NOTIFICATION: &str = r#"
|
||||
INSERT INTO falukant_log.notification (
|
||||
user_id,
|
||||
tr,
|
||||
shown,
|
||||
created_at,
|
||||
updated_at
|
||||
) VALUES ($1, $2, FALSE, NOW(), NOW());
|
||||
"#;
|
||||
|
||||
// Aliases for personal variants (keeps original prepared statement names used in events.worker)
|
||||
pub const QUERY_REDUCE_INVENTORY_PERSONAL: &str = QUERY_REDUCE_INVENTORY;
|
||||
pub const QUERY_DELETE_INVENTORY_PERSONAL: &str = QUERY_DELETE_INVENTORY;
|
||||
@@ -1932,5 +1634,202 @@ pub const QUERY_SET_LEARNING_DONE: &str = r#"
|
||||
WHERE id = $1;
|
||||
"#;
|
||||
|
||||
// Church Office Queries
|
||||
pub const QUERY_FIND_AVAILABLE_CHURCH_OFFICES: &str = r#"
|
||||
SELECT
|
||||
cot.id AS office_type_id,
|
||||
cot.name AS office_type_name,
|
||||
cot.seats_per_region,
|
||||
cot.region_type,
|
||||
r.id AS region_id,
|
||||
COUNT(co.id) AS occupied_seats
|
||||
FROM falukant_type.church_office_type cot
|
||||
CROSS JOIN falukant_data.region r
|
||||
JOIN falukant_type.region tr ON r.region_type_id = tr.id
|
||||
LEFT JOIN falukant_data.church_office co
|
||||
ON cot.id = co.office_type_id
|
||||
AND co.region_id = r.id
|
||||
WHERE tr.label_tr = cot.region_type
|
||||
GROUP BY cot.id, cot.name, cot.seats_per_region, cot.region_type, r.id
|
||||
HAVING COUNT(co.id) < cot.seats_per_region
|
||||
ORDER BY cot.hierarchy_level ASC, r.id;
|
||||
"#;
|
||||
|
||||
pub const QUERY_FIND_CHURCH_SUPERVISOR: &str = r#"
|
||||
SELECT
|
||||
co.id AS office_id,
|
||||
co.character_id AS supervisor_character_id,
|
||||
co.region_id,
|
||||
cot.hierarchy_level
|
||||
FROM falukant_data.church_office co
|
||||
JOIN falukant_type.church_office_type cot ON co.office_type_id = cot.id
|
||||
WHERE co.region_id = $1
|
||||
AND cot.hierarchy_level > (
|
||||
SELECT hierarchy_level
|
||||
FROM falukant_type.church_office_type
|
||||
WHERE id = $2
|
||||
)
|
||||
ORDER BY cot.hierarchy_level ASC
|
||||
LIMIT 1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_CHURCH_OFFICE_REQUIREMENTS: &str = r#"
|
||||
SELECT
|
||||
id,
|
||||
office_type_id,
|
||||
prerequisite_office_type_id,
|
||||
min_title_level
|
||||
FROM falukant_predefine.church_office_requirement
|
||||
WHERE office_type_id = $1;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_PENDING_CHURCH_APPLICATIONS: &str = r#"
|
||||
SELECT
|
||||
ca.id AS application_id,
|
||||
ca.office_type_id,
|
||||
ca.character_id AS applicant_character_id,
|
||||
ca.region_id,
|
||||
ca.supervisor_id,
|
||||
cot.name AS office_type_name,
|
||||
cot.hierarchy_level
|
||||
FROM falukant_data.church_application ca
|
||||
JOIN falukant_type.church_office_type cot ON ca.office_type_id = cot.id
|
||||
WHERE ca.status = 'pending'
|
||||
AND ca.supervisor_id = $1
|
||||
ORDER BY cot.hierarchy_level ASC, ca.created_at ASC;
|
||||
"#;
|
||||
|
||||
pub const QUERY_CHECK_CHARACTER_ELIGIBILITY: &str = r#"
|
||||
WITH character_info AS (
|
||||
SELECT
|
||||
c.id AS character_id,
|
||||
c.title_of_nobility,
|
||||
t.level AS title_level,
|
||||
EXISTS(
|
||||
SELECT 1
|
||||
FROM falukant_data.church_office co2
|
||||
WHERE co2.character_id = c.id
|
||||
) AS has_office
|
||||
FROM falukant_data.character c
|
||||
LEFT JOIN falukant_type.title t ON c.title_of_nobility = t.id
|
||||
WHERE c.id = $1
|
||||
),
|
||||
prerequisite_check AS (
|
||||
SELECT
|
||||
CASE
|
||||
WHEN $2::int IS NULL THEN TRUE
|
||||
ELSE EXISTS(
|
||||
SELECT 1
|
||||
FROM falukant_data.church_office co
|
||||
WHERE co.character_id = $1
|
||||
AND co.office_type_id = $2::int
|
||||
)
|
||||
END AS has_prerequisite
|
||||
)
|
||||
SELECT
|
||||
ci.character_id,
|
||||
ci.title_level,
|
||||
ci.has_office,
|
||||
pc.has_prerequisite,
|
||||
CASE
|
||||
WHEN $3::int IS NULL THEN TRUE
|
||||
ELSE COALESCE(ci.title_level, 0) >= $3::int
|
||||
END AS meets_title_requirement
|
||||
FROM character_info ci
|
||||
CROSS JOIN prerequisite_check pc;
|
||||
"#;
|
||||
|
||||
pub const QUERY_APPROVE_CHURCH_APPLICATION: &str = r#"
|
||||
WITH updated_application AS (
|
||||
UPDATE falukant_data.church_application
|
||||
SET status = 'approved',
|
||||
decision_date = NOW(),
|
||||
updated_at = NOW()
|
||||
WHERE id = $1
|
||||
AND status = 'pending'
|
||||
RETURNING
|
||||
office_type_id,
|
||||
character_id,
|
||||
region_id,
|
||||
supervisor_id
|
||||
),
|
||||
inserted_office AS (
|
||||
INSERT INTO falukant_data.church_office
|
||||
(office_type_id, character_id, region_id, supervisor_id, created_at, updated_at)
|
||||
SELECT
|
||||
office_type_id,
|
||||
character_id,
|
||||
region_id,
|
||||
supervisor_id,
|
||||
NOW(),
|
||||
NOW()
|
||||
FROM updated_application
|
||||
WHERE NOT EXISTS(
|
||||
SELECT 1
|
||||
FROM falukant_data.church_office co
|
||||
WHERE co.office_type_id = updated_application.office_type_id
|
||||
AND co.region_id = updated_application.region_id
|
||||
AND co.character_id = updated_application.character_id
|
||||
)
|
||||
RETURNING id, office_type_id, character_id, region_id
|
||||
)
|
||||
SELECT
|
||||
id AS office_id,
|
||||
office_type_id,
|
||||
character_id,
|
||||
region_id
|
||||
FROM inserted_office;
|
||||
"#;
|
||||
|
||||
pub const QUERY_REJECT_CHURCH_APPLICATION: &str = r#"
|
||||
UPDATE falukant_data.church_application
|
||||
SET status = 'rejected',
|
||||
decision_date = NOW(),
|
||||
updated_at = NOW()
|
||||
WHERE id = $1
|
||||
AND status = 'pending'
|
||||
RETURNING id;
|
||||
"#;
|
||||
|
||||
pub const QUERY_CREATE_CHURCH_APPLICATION_JOB: &str = r#"
|
||||
INSERT INTO falukant_data.church_application
|
||||
(office_type_id, character_id, region_id, supervisor_id, status, created_at, updated_at)
|
||||
SELECT
|
||||
$1::int AS office_type_id,
|
||||
$2::int AS character_id,
|
||||
$3::int AS region_id,
|
||||
$4::int AS supervisor_id,
|
||||
'pending' AS status,
|
||||
NOW() AS created_at,
|
||||
NOW() AS updated_at
|
||||
WHERE NOT EXISTS(
|
||||
SELECT 1
|
||||
FROM falukant_data.church_application ca
|
||||
WHERE ca.office_type_id = $1::int
|
||||
AND ca.character_id = $2::int
|
||||
AND ca.region_id = $3::int
|
||||
AND ca.status = 'pending'
|
||||
)
|
||||
RETURNING id;
|
||||
"#;
|
||||
|
||||
pub const QUERY_GET_CHARACTERS_FOR_CHURCH_OFFICE: &str = r#"
|
||||
SELECT DISTINCT
|
||||
c.id AS character_id,
|
||||
c.user_id,
|
||||
c.region_id,
|
||||
c.title_of_nobility,
|
||||
t.level AS title_level
|
||||
FROM falukant_data.character c
|
||||
LEFT JOIN falukant_type.title t ON c.title_of_nobility = t.id
|
||||
WHERE c.region_id = $1
|
||||
AND c.health > 0
|
||||
AND NOT EXISTS(
|
||||
SELECT 1
|
||||
FROM falukant_data.church_office co
|
||||
WHERE co.character_id = c.id
|
||||
)
|
||||
ORDER BY RANDOM()
|
||||
LIMIT $2;
|
||||
"#;
|
||||
|
||||
|
||||
Reference in New Issue
Block a user