1863 lines
66 KiB
Rust
1863 lines
66 KiB
Rust
// Centralized SQL strings for workers.
|
||
|
||
pub const QUERY_UPDATE_MONEY: &str = r#"
|
||
SELECT falukant_data.update_money($1, $2, $3);
|
||
"#;
|
||
|
||
pub const QUERY_GET_MONEY: &str = r#"
|
||
SELECT money FROM falukant_data.falukant_user WHERE id = $1;
|
||
"#;
|
||
|
||
|
||
pub const QUERY_GET_RANDOM_USER: &str = r#"
|
||
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
|
||
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;
|
||
"#;
|
||
|
||
pub const QUERY_GET_RANDOM_CITY: &str = r#"
|
||
SELECT 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' ORDER BY RANDOM() LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_AFFECTED_USERS: &str = r#"
|
||
SELECT DISTINCT b.falukant_user_id AS user_id FROM falukant_data.branch b WHERE b.region_id = $1 AND b.falukant_user_id IS NOT NULL;
|
||
"#;
|
||
|
||
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
|
||
)
|
||
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;
|
||
"#;
|
||
|
||
/// 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());
|
||
"#;
|
||
|
||
// 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;
|
||
"#;
|
||
|
||
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
|
||
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
|
||
JOIN falukant_data.branch b ON b.region_id = c.region_id AND b.falukant_user_id = fu.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
|
||
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;
|
||
"#;
|
||
|
||
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;
|
||
"#;
|
||
|
||
// Character creation related queries (missing from earlier extraction)
|
||
pub const QUERY_IS_PREVIOUS_DAY_CHARACTER_CREATED: &str = r#"
|
||
SELECT created_at
|
||
FROM falukant_data."character"
|
||
WHERE user_id IS NULL
|
||
AND created_at::date = CURRENT_DATE
|
||
ORDER BY created_at DESC
|
||
LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_TOWN_REGION_IDS: &str = r#"
|
||
SELECT fdr.id
|
||
FROM falukant_data.region fdr
|
||
JOIN falukant_type.region ftr ON fdr.region_type_id = ftr.id
|
||
WHERE ftr.label_tr = 'city';
|
||
"#;
|
||
|
||
pub const QUERY_LOAD_FIRST_NAMES: &str = r#"
|
||
SELECT id, gender
|
||
FROM falukant_predefine.firstname;
|
||
"#;
|
||
|
||
pub const QUERY_LOAD_LAST_NAMES: &str = r#"
|
||
SELECT id
|
||
FROM falukant_predefine.lastname;
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_CHARACTER: &str = r#"
|
||
INSERT INTO falukant_data.character(
|
||
user_id,
|
||
region_id,
|
||
first_name,
|
||
last_name,
|
||
birthdate,
|
||
gender,
|
||
created_at,
|
||
updated_at,
|
||
title_of_nobility
|
||
) VALUES (
|
||
NULL,
|
||
$1,
|
||
$2,
|
||
$3,
|
||
NOW(),
|
||
$4,
|
||
NOW(),
|
||
NOW(),
|
||
$5
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_GET_ELIGIBLE_NPC_FOR_DEATH: &str = r#"
|
||
WITH aged AS (
|
||
SELECT
|
||
c.id,
|
||
(current_date - c.birthdate::date) AS age,
|
||
c.user_id
|
||
FROM
|
||
falukant_data.character c
|
||
WHERE
|
||
c.user_id IS NULL
|
||
AND (current_date - c.birthdate::date) > 60
|
||
),
|
||
always_sel AS (
|
||
SELECT *
|
||
FROM aged
|
||
WHERE age > 85
|
||
),
|
||
random_sel AS (
|
||
SELECT *
|
||
FROM aged
|
||
WHERE age <= 85
|
||
ORDER BY random()
|
||
LIMIT 10
|
||
)
|
||
SELECT *
|
||
FROM always_sel
|
||
UNION ALL
|
||
SELECT *
|
||
FROM random_sel;
|
||
"#;
|
||
|
||
pub const QUERY_MARK_CHARACTER_DECEASED: &str = r#"
|
||
DELETE FROM falukant_data.character
|
||
WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_BRANCH_CAPACITY: &str = r#"
|
||
SELECT (SELECT SUM(quantity) FROM falukant_data.stock fds WHERE fds.branch_id = $1) 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 = $1), 0) AS used_in_stock,
|
||
(SELECT COUNT(id) FROM falukant_data.production WHERE branch_id = $1) AS running_productions,
|
||
COALESCE((SELECT SUM(COALESCE(fdp.quantity, 0)) quantity FROM falukant_data.production fdp WHERE fdp.branch_id = $1), 0) AS running_productions_quantity;
|
||
"#;
|
||
|
||
pub const QUERY_GET_INVENTORY: &str = r#"
|
||
SELECT i.id, i.product_id, i.quantity, i.quality, p.sell_cost, fu.id AS user_id, b.region_id, b.id AS branch_id, COALESCE(tpw.worth_percent, 100.0) AS worth_percent
|
||
FROM falukant_data.inventory i
|
||
JOIN falukant_data.stock s ON s.id = i.stock_id
|
||
JOIN falukant_data.branch b ON b.id = s.branch_id
|
||
JOIN falukant_data.falukant_user fu ON fu.id = b.falukant_user_id
|
||
JOIN falukant_data.director d ON d.employer_user_id = fu.id
|
||
JOIN falukant_type.product p ON p.id = i.product_id
|
||
LEFT JOIN falukant_data.town_product_worth tpw ON tpw.region_id = b.region_id AND tpw.product_id = i.product_id
|
||
WHERE d.id = $1 AND b.id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_REMOVE_INVENTORY: &str = r#"
|
||
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());
|
||
"#;
|
||
pub const QUERY_GET_ARRIVED_TRANSPORTS: &str = r#"
|
||
SELECT
|
||
t.id,
|
||
t.product_id,
|
||
t.size,
|
||
t.vehicle_id,
|
||
t.source_region_id,
|
||
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,
|
||
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
|
||
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())
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_GET_AVAILABLE_STOCKS: &str = r#"
|
||
SELECT
|
||
stock.id,
|
||
stock.quantity AS total_capacity,
|
||
(
|
||
SELECT COALESCE(SUM(inventory.quantity), 0)
|
||
FROM falukant_data.inventory
|
||
WHERE inventory.stock_id = stock.id
|
||
) AS filled
|
||
FROM falukant_data.stock stock
|
||
JOIN falukant_data.branch branch
|
||
ON stock.branch_id = branch.id
|
||
WHERE branch.id = $1
|
||
ORDER BY total_capacity DESC;
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_INVENTORY: &str = r#"
|
||
INSERT INTO falukant_data.inventory (stock_id, product_id, quantity, quality, produced_at)
|
||
VALUES ($1, $2, $3, $4, NOW())
|
||
RETURNING id;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_INVENTORY_BY_STOCK_PRODUCT: &str = r#"
|
||
UPDATE falukant_data.inventory
|
||
SET quantity = quantity + $3,
|
||
quality = LEAST(
|
||
100,
|
||
ROUND(
|
||
((quantity * quality) + ($3 * $4))::numeric / NULLIF(quantity + $3, 0)
|
||
)
|
||
)
|
||
WHERE stock_id = $1 AND product_id = $2
|
||
RETURNING id;
|
||
"#;
|
||
|
||
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;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_TRANSPORT_SIZE: &str = r#"
|
||
UPDATE falukant_data.transport
|
||
SET size = $2,
|
||
updated_at = NOW()
|
||
WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_REGION_WORTH_FOR_PRODUCT: &str = r#"
|
||
SELECT tpw.region_id, tpw.product_id, tpw.worth_percent FROM falukant_data.town_product_worth tpw JOIN falukant_data.branch b ON b.region_id = tpw.region_id WHERE b.falukant_user_id = $1 AND tpw.product_id = $2;
|
||
"#;
|
||
|
||
// Political offices and cumulative tax
|
||
pub const QUERY_GET_USER_OFFICES: &str = r#"
|
||
SELECT po.id AS office_id, pot.name AS office_name, po.region_id, rt.label_tr AS region_type
|
||
FROM falukant_data.political_office po
|
||
JOIN falukant_type.political_office_type pot ON pot.id = po.office_type_id
|
||
JOIN falukant_data.region r ON r.id = po.region_id
|
||
JOIN falukant_type.region rt ON rt.id = r.region_type_id
|
||
JOIN falukant_data.character ch ON ch.id = po.character_id
|
||
WHERE ch.user_id = $1
|
||
AND (po.created_at + (pot.term_length * INTERVAL '1 day')) > NOW();
|
||
"#;
|
||
|
||
pub const QUERY_CUMULATIVE_TAX_NO_EXEMPT: &str = r#"
|
||
WITH RECURSIVE ancestors AS (
|
||
SELECT id, parent_id, COALESCE(tax_percent,0.0) AS tax_percent FROM falukant_data.region WHERE id = $1
|
||
UNION ALL
|
||
SELECT r.id, r.parent_id, COALESCE(r.tax_percent,0.0) FROM falukant_data.region r JOIN ancestors a ON r.id = a.parent_id
|
||
)
|
||
SELECT COALESCE(SUM(tax_percent),0.0) AS total_percent FROM ancestors;
|
||
"#;
|
||
|
||
pub const QUERY_CUMULATIVE_TAX_WITH_EXEMPT: &str = r#"
|
||
WITH RECURSIVE ancestors AS (
|
||
SELECT r.id, r.parent_id, CASE WHEN rt.label_tr = ANY($2::text[]) THEN 0.0 ELSE COALESCE(r.tax_percent,0.0) END AS tax_percent
|
||
FROM falukant_data.region r JOIN falukant_type.region rt ON rt.id = r.region_type_id WHERE r.id = $1
|
||
UNION ALL
|
||
SELECT r.id, r.parent_id, CASE WHEN rt.label_tr = ANY($2::text[]) THEN 0.0 ELSE COALESCE(r.tax_percent,0.0) END
|
||
FROM falukant_data.region r JOIN falukant_type.region rt ON rt.id = r.region_type_id JOIN ancestors a ON r.id = a.parent_id
|
||
)
|
||
SELECT COALESCE(SUM(tax_percent),0.0) AS total_percent FROM ancestors;
|
||
"#;
|
||
|
||
pub const QUERY_GET_TRANSPORT_VEHICLES_FOR_ROUTE: &str = r#"
|
||
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
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_TRANSPORT: &str = r#"
|
||
INSERT INTO falukant_data.transport (source_region_id, target_region_id, product_id, size, vehicle_id, created_at, updated_at) VALUES ($1, $2, $3, $4, $5, NOW(), NOW());
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_EMPTY_TRANSPORT: &str = r#"
|
||
INSERT INTO falukant_data.transport (source_region_id, target_region_id, product_id, size, vehicle_id, created_at, updated_at) VALUES ($1, $2, NULL, 0, $3, NOW(), NOW());
|
||
"#;
|
||
|
||
pub const QUERY_GET_USER_BRANCHES: &str = r#"
|
||
SELECT DISTINCT b.region_id, b.id AS branch_id FROM falukant_data.branch b WHERE b.falukant_user_id = $1 AND b.region_id != $2;
|
||
"#;
|
||
|
||
pub const QUERY_GET_FREE_VEHICLES_IN_REGION: &str = r#"
|
||
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 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);
|
||
"#;
|
||
|
||
pub const QUERY_GET_SALARY_TO_PAY: &str = r#"
|
||
SELECT d.id, d.employer_user_id, d.income FROM falukant_data.director d WHERE DATE(d.last_salary_payout) < DATE(NOW());
|
||
"#;
|
||
|
||
pub const QUERY_SET_SALARY_PAYED: &str = r#"
|
||
UPDATE falukant_data.director SET last_salary_payout = NOW() WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_SATISFACTION: &str = r#"
|
||
WITH new_sats AS (
|
||
SELECT d.id, ROUND(d.income::numeric / (c.title_of_nobility * POWER(1.231, AVG(k.knowledge) / 1.5)) * 100) AS new_satisfaction
|
||
FROM falukant_data.director d
|
||
JOIN falukant_data.knowledge k ON d.director_character_id = k.character_id
|
||
JOIN falukant_data.character c ON c.id = d.director_character_id
|
||
GROUP BY d.id, c.title_of_nobility, d.income
|
||
)
|
||
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_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;
|
||
"#;
|
||
|
||
pub const QUERY_COUNT_VEHICLES_IN_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;
|
||
"#;
|
||
|
||
pub const QUERY_CHECK_ROUTE: &str = r#"
|
||
SELECT 1 FROM falukant_data.region_distance rd WHERE (rd.source_region_id = $1 AND rd.target_region_id = $2) OR (rd.source_region_id = $2 AND rd.target_region_id = $1) LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_BRANCH_REGION: &str = r#"
|
||
SELECT region_id FROM falukant_data.branch WHERE id = $1 LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_AVERAGE_WORTH: &str = r#"
|
||
SELECT AVG(tpw.worth_percent) AS avg_worth FROM falukant_data.town_product_worth tpw WHERE tpw.product_id = $1 AND tpw.region_id IN (SELECT region_id FROM falukant_data.branch WHERE falukant_user_id = $2);
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_INVENTORY_QTY: &str = r#"
|
||
UPDATE falukant_data.inventory SET quantity = $1 WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_GET_USER_STOCKS: &str = r#"
|
||
SELECT s.id AS stock_id, s.quantity AS current_capacity
|
||
FROM falukant_data.stock s
|
||
JOIN falukant_data.branch b ON s.branch_id = b.id
|
||
WHERE b.falukant_user_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_STOCK_CAPACITY: &str = r#"
|
||
UPDATE falukant_data.stock
|
||
SET quantity = GREATEST(1, ROUND(quantity * (1 + $1 / 100.0)))
|
||
WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_GET_REGION_STOCKS: &str = r#"
|
||
SELECT s.id AS stock_id, s.quantity AS current_capacity
|
||
FROM falukant_data.stock s
|
||
JOIN falukant_data.branch b ON s.branch_id = b.id
|
||
WHERE b.region_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_STOCK_CAPACITY_REGIONAL: &str = r#"
|
||
UPDATE falukant_data.stock
|
||
SET quantity = GREATEST(1, ROUND(quantity * (1 + $1 / 100.0)))
|
||
WHERE id = $2;
|
||
"#;
|
||
|
||
// Stockage manager specific queries
|
||
pub const QUERY_GET_TOWNS: &str = r#"
|
||
SELECT fdr.id
|
||
FROM falukant_data.region fdr
|
||
JOIN falukant_type.region ftr
|
||
ON ftr.id = fdr.region_type_id
|
||
WHERE ftr.label_tr = 'city';
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_STOCK: &str = r#"
|
||
INSERT INTO falukant_data.buyable_stock (region_id, stock_type_id, quantity)
|
||
SELECT
|
||
$1 AS region_id,
|
||
s.id AS stock_type_id,
|
||
GREATEST(1, ROUND(RANDOM() * 5 * COUNT(br.id))) AS quantity
|
||
FROM falukant_data.branch AS br
|
||
CROSS JOIN falukant_type.stock AS s
|
||
WHERE br.region_id = $1
|
||
GROUP BY s.id
|
||
ORDER BY RANDOM()
|
||
LIMIT GREATEST(
|
||
ROUND(RANDOM() * (SELECT COUNT(id) FROM falukant_type.stock)),
|
||
1
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_CLEANUP_STOCK: &str = r#"
|
||
DELETE FROM falukant_data.buyable_stock
|
||
WHERE quantity <= 0;
|
||
"#;
|
||
|
||
pub const QUERY_GET_REGION_USERS: &str = r#"
|
||
SELECT c.user_id
|
||
FROM falukant_data.character c
|
||
WHERE c.region_id = $1
|
||
AND c.user_id IS NOT NULL;
|
||
"#;
|
||
|
||
pub const QUERY_GET_REGION_HOUSES: &str = r#"
|
||
SELECT uh.id AS house_id, uh.roof_condition, uh.floor_condition, uh.wall_condition, uh.window_condition
|
||
FROM falukant_data.user_house uh
|
||
JOIN falukant_data.character c ON c.user_id = uh.user_id
|
||
WHERE c.region_id = $1
|
||
AND uh.house_type_id NOT IN (
|
||
SELECT id FROM falukant_type.house h WHERE h.label_tr = 'under_bridge'
|
||
);
|
||
"#;
|
||
|
||
// House worker queries
|
||
pub const QUERY_GET_NEW_HOUSE_DATA: &str = r#"
|
||
SELECT
|
||
h.id AS house_id
|
||
FROM
|
||
falukant_type.house AS h
|
||
WHERE
|
||
random() < 0.0001
|
||
AND label_tr <> 'under_bridge';
|
||
"#;
|
||
|
||
pub const QUERY_ADD_NEW_BUYABLE_HOUSE: &str = r#"
|
||
INSERT INTO falukant_data.buyable_house (house_type_id)
|
||
VALUES ($1);
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_BUYABLE_HOUSE_STATE: &str = r#"
|
||
UPDATE falukant_data.buyable_house
|
||
SET roof_condition = ROUND(roof_condition - random() * (3 + 0 * id)),
|
||
floor_condition = ROUND(floor_condition - random() * (3 + 0 * id)),
|
||
wall_condition = ROUND(wall_condition - random() * (3 + 0 * id)),
|
||
window_condition = ROUND(window_condition - random() * (3 + 0 * id));
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_USER_HOUSE_STATE: &str = r#"
|
||
UPDATE falukant_data.user_house
|
||
SET roof_condition = ROUND(roof_condition - random() * (3 + 0 * id)),
|
||
floor_condition = ROUND(floor_condition - random() * (3 + 0 * id)),
|
||
wall_condition = ROUND(wall_condition - random() * (3 + 0 * id)),
|
||
window_condition = ROUND(window_condition - random() * (3 + 0 * id))
|
||
WHERE house_type_id NOT IN (
|
||
SELECT id
|
||
FROM falukant_type.house h
|
||
WHERE h.label_tr = 'under_bridge'
|
||
);
|
||
"#;
|
||
|
||
// 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)),
|
||
floor_condition = GREATEST(0, LEAST(100, floor_condition + $1)),
|
||
wall_condition = GREATEST(0, LEAST(100, wall_condition + $1)),
|
||
window_condition = GREATEST(0, LEAST(100, window_condition + $1))
|
||
WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_CHANGE_WEATHER: &str = r#"
|
||
UPDATE falukant_data.weather
|
||
SET weather_type_id = (
|
||
SELECT id FROM falukant_type.weather ORDER BY RANDOM() LIMIT 1
|
||
)
|
||
WHERE region_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_RANDOM_CHARACTER: &str = r#"
|
||
SELECT id, health, first_name, last_name
|
||
FROM falukant_data."character"
|
||
WHERE user_id = $1 AND health > 0
|
||
ORDER BY RANDOM() LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_HEALTH: &str = r#"
|
||
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;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_DIRECTOR: &str = r#"
|
||
DELETE FROM falukant_data.director WHERE director_character_id = $1 RETURNING employer_user_id;
|
||
"#;
|
||
|
||
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
|
||
)
|
||
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#"
|
||
SELECT user_id FROM falukant_data.character WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_CHILD_RELATION: &str = r#"
|
||
WITH deleted AS (
|
||
DELETE FROM falukant_data.child_relation WHERE child_character_id = $1 RETURNING father_character_id, mother_character_id
|
||
)
|
||
SELECT cf.user_id AS father_user_id, cm.user_id AS mother_user_id FROM deleted d JOIN falukant_data.character cf ON cf.id = d.father_character_id JOIN falukant_data.character cm ON cm.id = d.mother_character_id;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_CHARACTER: &str = r#"
|
||
DELETE FROM falukant_data.character WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_HEIR: &str = r#"
|
||
SELECT child_character_id FROM falukant_data.child_relation WHERE father_character_id = $1 OR mother_character_id = $1 ORDER BY (is_heir IS TRUE) DESC, updated_at DESC LIMIT 1;
|
||
"#;
|
||
|
||
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;
|
||
"#;
|
||
|
||
pub const QUERY_GET_HOUSE_VALUE: &str = r#"
|
||
SELECT COALESCE(SUM(h.cost), 0) AS sum FROM falukant_data.user_house AS uh JOIN falukant_type.house AS h ON uh.house_type_id = h.id WHERE uh.user_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_SETTLEMENT_VALUE: &str = r#"
|
||
SELECT COALESCE(SUM(b.base_cost), 0) AS sum FROM falukant_data.branch AS br JOIN falukant_type.branch AS b ON br.branch_type_id = b.id WHERE br.falukant_user_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_INVENTORY_VALUE: &str = r#"
|
||
SELECT COALESCE(SUM(i.quantity * p.sell_cost), 0) AS sum FROM falukant_data.inventory AS i JOIN falukant_type.product AS p ON i.product_id = p.id JOIN falukant_data.stock AS s ON i.stock_id = s.id JOIN falukant_data.branch AS br ON s.branch_id = br.id WHERE br.falukant_user_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_CREDIT_DEBT: &str = r#"
|
||
SELECT COALESCE(SUM(remaining_amount), 0) AS sum FROM falukant_data.credit WHERE falukant_user_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_COUNT_CHILDREN: &str = r#"
|
||
SELECT COUNT(*) AS cnt FROM falukant_data.child_relation WHERE (father_character_id = $1 OR mother_character_id = $1) AND child_character_id != $2;
|
||
"#;
|
||
|
||
// user_character worker queries
|
||
pub const QUERY_GET_USERS_TO_UPDATE: &str = r#"
|
||
SELECT id, CURRENT_DATE - birthdate::date AS age, health
|
||
FROM falukant_data."character"
|
||
WHERE user_id IS NOT NULL;
|
||
"#;
|
||
|
||
// politics worker queries
|
||
pub const QUERY_COUNT_OFFICES_PER_REGION: &str = 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;
|
||
"#;
|
||
|
||
pub const QUERY_FIND_OFFICE_GAPS: &str = r#"
|
||
WITH
|
||
seats 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
|
||
)
|
||
SELECT
|
||
s.office_type_id,
|
||
s.region_id,
|
||
(s.seats_total - COALESCE(o.occupied_count, 0)) AS gaps
|
||
FROM seats AS s
|
||
LEFT JOIN occupied AS o
|
||
ON s.office_type_id = o.office_type_id
|
||
AND s.region_id = o.region_id
|
||
WHERE (s.seats_total - COALESCE(o.occupied_count, 0)) > 0;
|
||
"#;
|
||
|
||
pub const QUERY_SELECT_NEEDED_ELECTIONS: &str = r#"
|
||
WITH
|
||
target_date AS (
|
||
SELECT NOW()::date AS election_date
|
||
),
|
||
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
|
||
),
|
||
gaps_per_region AS (
|
||
SELECT
|
||
office_type_id,
|
||
region_id,
|
||
COUNT(*) AS gaps
|
||
FROM expired_today
|
||
GROUP BY office_type_id, region_id
|
||
),
|
||
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
|
||
)
|
||
),
|
||
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,
|
||
ts.gaps,
|
||
NOW(),
|
||
NOW(),
|
||
ts.region_id
|
||
FROM to_schedule AS ts
|
||
RETURNING
|
||
id AS election_id,
|
||
region_id,
|
||
posts_to_fill
|
||
)
|
||
SELECT
|
||
ne.election_id,
|
||
ne.region_id,
|
||
ne.posts_to_fill
|
||
FROM new_elections AS ne
|
||
ORDER BY ne.region_id, ne.election_id;
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_CANDIDATES: &str = 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);
|
||
"#;
|
||
|
||
pub const QUERY_SELECT_ELECTIONS_NEEDING_CANDIDATES: &str = r#"
|
||
SELECT
|
||
e.id AS election_id,
|
||
e.region_id AS region_id,
|
||
e.posts_to_fill
|
||
FROM falukant_data.election AS e
|
||
WHERE e.region_id IS NOT NULL
|
||
AND e.posts_to_fill > 0
|
||
AND e.date::date >= CURRENT_DATE
|
||
AND NOT EXISTS (
|
||
SELECT 1
|
||
FROM falukant_data.candidate AS c
|
||
WHERE c.election_id = e.id
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_PROCESS_EXPIRED_AND_FILL: &str = 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,
|
||
COALESCE(ch.reputation, 0) AS reputation
|
||
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
|
||
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
|
||
),
|
||
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, vpc.reputation DESC, vpc.character_id ASC
|
||
) 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(),
|
||
NOW(),
|
||
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(),
|
||
NOW(),
|
||
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;
|
||
"#;
|
||
|
||
pub const QUERY_USERS_IN_CITIES_OF_REGIONS: &str = 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;
|
||
"#;
|
||
|
||
pub const QUERY_NOTIFY_OFFICE_EXPIRATION: &str = r#"
|
||
INSERT INTO falukant_log.notification
|
||
(user_id, tr, created_at, updated_at)
|
||
SELECT
|
||
ch.user_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
|
||
JOIN falukant_data.character AS ch
|
||
ON ch.id = po.character_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');
|
||
"#;
|
||
|
||
pub const QUERY_NOTIFY_ELECTION_CREATED: &str = r#"
|
||
INSERT INTO falukant_log.notification
|
||
(user_id, tr, created_at, updated_at)
|
||
VALUES
|
||
($1, 'notify_election_created', NOW(), NOW());
|
||
"#;
|
||
|
||
pub const QUERY_NOTIFY_OFFICE_FILLED: &str = r#"
|
||
INSERT INTO falukant_log.notification
|
||
(user_id, tr, created_at, updated_at)
|
||
VALUES
|
||
((SELECT user_id FROM falukant_data.character WHERE id = $1), 'notify_office_filled', NOW(), NOW());
|
||
"#;
|
||
|
||
pub const QUERY_GET_USERS_WITH_EXPIRING_OFFICES: &str = 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');
|
||
"#;
|
||
|
||
pub const QUERY_GET_USERS_IN_REGIONS_WITH_ELECTIONS: &str = 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';
|
||
"#;
|
||
|
||
pub const QUERY_GET_USERS_WITH_FILLED_OFFICES: &str = 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';
|
||
"#;
|
||
|
||
pub const QUERY_PROCESS_ELECTIONS: &str = r#"
|
||
SELECT office_id, office_type_id, character_id, region_id
|
||
FROM falukant_data.process_elections();
|
||
"#;
|
||
|
||
pub const QUERY_TRIM_EXCESS_OFFICES_GLOBAL: &str = r#"
|
||
WITH seats 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
|
||
),
|
||
ranked AS (
|
||
SELECT
|
||
po.id,
|
||
po.office_type_id,
|
||
po.region_id,
|
||
s.seats_total,
|
||
ROW_NUMBER() OVER (
|
||
PARTITION BY po.office_type_id, po.region_id
|
||
ORDER BY po.created_at DESC
|
||
) AS rn
|
||
FROM falukant_data.political_office AS po
|
||
JOIN seats AS s
|
||
ON s.office_type_id = po.office_type_id
|
||
AND s.region_id = po.region_id
|
||
),
|
||
to_delete AS (
|
||
SELECT id
|
||
FROM ranked
|
||
WHERE rn > seats_total
|
||
)
|
||
DELETE FROM falukant_data.political_office
|
||
WHERE id IN (SELECT id FROM to_delete);
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_CHARACTERS_HEALTH: &str = r#"
|
||
UPDATE falukant_data."character"
|
||
SET health = $1
|
||
WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_MOOD: &str = r#"
|
||
UPDATE falukant_data."character" AS c
|
||
SET mood_id = falukant_data.get_random_mood_id()
|
||
WHERE c.health > 0
|
||
AND random() < (1.0 / 50.0);
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_GET_ITEMS_TO_UPDATE: &str = r#"
|
||
SELECT id, product_id, producer_id, quantity
|
||
FROM falukant_log.production p
|
||
WHERE p.production_timestamp::date < current_date;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_GET_CHARACTER_IDS: &str = r#"
|
||
SELECT fu.id AS user_id,
|
||
c.id AS character_id,
|
||
c2.id AS director_id
|
||
FROM falukant_data.falukant_user fu
|
||
JOIN falukant_data.character c
|
||
ON c.user_id = fu.id
|
||
LEFT JOIN falukant_data.director d
|
||
ON d.employer_user_id = fu.id
|
||
LEFT JOIN falukant_data.character c2
|
||
ON c2.id = d.director_character_id
|
||
WHERE fu.id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_KNOWLEDGE: &str = r#"
|
||
UPDATE falukant_data.knowledge
|
||
SET knowledge = LEAST(knowledge + $3, 100)
|
||
WHERE character_id = $1
|
||
AND product_id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_LOG_ENTRY: &str = r#"
|
||
DELETE FROM falukant_log.production
|
||
WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_OPEN_CREDITS: &str = r#"
|
||
SELECT
|
||
c.id AS credit_id,
|
||
c.amount,
|
||
c.remaining_amount,
|
||
c.interest_rate,
|
||
fu.id AS user_id,
|
||
fu.money,
|
||
c2.id AS character_id,
|
||
dp.created_at AS debitor_prism_start,
|
||
dp.created_at::date < current_date AS prism_started_previously
|
||
FROM falukant_data.credit c
|
||
JOIN falukant_data.falukant_user fu
|
||
ON fu.id = c.falukant_user_id
|
||
JOIN falukant_data.character c2
|
||
ON c2.user_id = c.falukant_user_id
|
||
LEFT JOIN falukant_data.debtors_prism dp
|
||
ON dp.character_id = c2.id
|
||
WHERE c.remaining_amount > 0
|
||
AND c.updated_at::date < current_date;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_CREDIT: &str = r#"
|
||
UPDATE falukant_data.credit c
|
||
SET remaining_amount = $1
|
||
WHERE falukant_user_id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_CLEANUP_CREDITS: &str = r#"
|
||
DELETE FROM falukant_data.credit
|
||
WHERE remaining_amount <= 0.01;
|
||
"#;
|
||
|
||
pub const QUERY_ADD_CHARACTER_TO_DEBTORS_PRISM: &str = r#"
|
||
INSERT INTO falukant_data.debtors_prism (character_id)
|
||
VALUES ($1);
|
||
"#;
|
||
|
||
pub const QUERY_RANDOM_HEIR: &str = r#"
|
||
WITH chosen AS (
|
||
SELECT
|
||
cr.id AS relation_id,
|
||
cr.child_character_id
|
||
FROM
|
||
falukant_data.child_relation AS cr
|
||
JOIN
|
||
falukant_data.character AS ch
|
||
ON ch.id = cr.child_character_id
|
||
WHERE
|
||
(cr.father_character_id = $1 OR cr.mother_character_id = $1)
|
||
AND ch.region_id = (
|
||
SELECT region_id
|
||
FROM falukant_data.character
|
||
WHERE id = $1
|
||
)
|
||
AND ch.birthdate >= NOW() - INTERVAL '10 days'
|
||
AND ch.title_of_nobility = (
|
||
SELECT id
|
||
FROM falukant_type.title
|
||
WHERE label_tr = 'noncivil'
|
||
)
|
||
ORDER BY RANDOM()
|
||
LIMIT 1
|
||
)
|
||
UPDATE
|
||
falukant_data.child_relation AS cr2
|
||
SET
|
||
is_heir = TRUE,
|
||
updated_at = NOW()
|
||
FROM
|
||
chosen
|
||
WHERE
|
||
cr2.id = chosen.relation_id
|
||
RETURNING
|
||
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,
|
||
updated_at = NOW()
|
||
WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_GET_FALUKANT_USER_ID: &str = r#"
|
||
SELECT user_id
|
||
FROM falukant_data.character
|
||
WHERE id = $1
|
||
LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_AUTOBATISM: &str = r#"
|
||
UPDATE falukant_data.child_relation
|
||
SET name_set = TRUE
|
||
WHERE id IN (
|
||
SELECT cr.id
|
||
FROM falukant_data.child_relation cr
|
||
JOIN falukant_data.character c
|
||
ON c.id = cr.child_character_id
|
||
WHERE cr.name_set = FALSE
|
||
AND c.birthdate < current_date - INTERVAL '5 days'
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_GET_PREGNANCY_CANDIDATES: &str = r#"
|
||
SELECT
|
||
r.character1_id AS father_cid,
|
||
r.character2_id AS mother_cid,
|
||
c1.title_of_nobility,
|
||
c1.last_name,
|
||
c1.region_id,
|
||
fu1.id AS father_uid,
|
||
fu2.id AS mother_uid,
|
||
((CURRENT_DATE - c1.birthdate::date)
|
||
+ (CURRENT_DATE - c2.birthdate::date)) / 2 AS avg_age_days,
|
||
100.0 /
|
||
(1 + EXP(
|
||
0.0647 * (
|
||
((CURRENT_DATE - c1.birthdate::date)
|
||
+ (CURRENT_DATE - c2.birthdate::date)) / 2
|
||
) - 0.0591
|
||
)) AS prob_pct
|
||
FROM falukant_data.relationship r
|
||
JOIN falukant_type.relationship r2
|
||
ON r2.id = r.relationship_type_id
|
||
AND r2.tr = 'married'
|
||
JOIN falukant_data.character c1
|
||
ON c1.id = r.character1_id
|
||
JOIN falukant_data.character c2
|
||
ON c2.id = r.character2_id
|
||
LEFT JOIN falukant_data.falukant_user fu1
|
||
ON fu1.id = c1.user_id
|
||
LEFT JOIN falukant_data.falukant_user fu2
|
||
ON fu2.id = c2.user_id
|
||
WHERE random() * 100 < (
|
||
100.0 /
|
||
(1 + EXP(
|
||
0.11166347 * (
|
||
((CURRENT_DATE - c1.birthdate::date)
|
||
+ (CURRENT_DATE - c2.birthdate::date)) / 2
|
||
) - 2.638267
|
||
))
|
||
) / 2;
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_CHILD: &str = r#"
|
||
INSERT INTO falukant_data.character (
|
||
user_id,
|
||
region_id,
|
||
first_name,
|
||
last_name,
|
||
birthdate,
|
||
gender,
|
||
title_of_nobility,
|
||
mood_id,
|
||
created_at,
|
||
updated_at
|
||
) VALUES (
|
||
NULL,
|
||
$1::int,
|
||
(
|
||
SELECT id
|
||
FROM falukant_predefine.firstname
|
||
WHERE gender = $2
|
||
ORDER BY RANDOM()
|
||
LIMIT 1
|
||
),
|
||
$3::int,
|
||
NOW(),
|
||
$2::varchar,
|
||
$4::int,
|
||
(
|
||
SELECT id
|
||
FROM falukant_type.mood
|
||
ORDER BY RANDOM()
|
||
LIMIT 1
|
||
),
|
||
NOW(),
|
||
NOW()
|
||
)
|
||
RETURNING id AS child_cid;
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_CHILD_RELATION: &str = r#"
|
||
INSERT INTO falukant_data.child_relation (
|
||
father_character_id,
|
||
mother_character_id,
|
||
child_character_id,
|
||
name_set,
|
||
created_at,
|
||
updated_at
|
||
)
|
||
VALUES (
|
||
$1::int,
|
||
$2::int,
|
||
$3::int,
|
||
FALSE,
|
||
NOW(), NOW()
|
||
);
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_KNOWLEDGE: &str = r#"
|
||
DELETE FROM falukant_data.knowledge
|
||
WHERE character_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_DEBTORS_PRISM: &str = r#"
|
||
DELETE FROM falukant_data.debtors_prism
|
||
WHERE character_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_POLITICAL_OFFICE: &str = r#"
|
||
WITH removed AS (
|
||
DELETE FROM falukant_data.political_office
|
||
WHERE character_id = $1
|
||
RETURNING office_type_id, region_id
|
||
),
|
||
affected AS (
|
||
SELECT DISTINCT office_type_id, region_id
|
||
FROM removed
|
||
),
|
||
seats 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
|
||
JOIN affected AS a
|
||
ON a.office_type_id = pot.id
|
||
AND a.region_id = rt.id
|
||
),
|
||
ranked AS (
|
||
SELECT
|
||
po.id,
|
||
po.office_type_id,
|
||
po.region_id,
|
||
s.seats_total,
|
||
ROW_NUMBER() OVER (
|
||
PARTITION BY po.office_type_id, po.region_id
|
||
ORDER BY po.created_at DESC
|
||
) AS rn
|
||
FROM falukant_data.political_office AS po
|
||
JOIN seats AS s
|
||
ON s.office_type_id = po.office_type_id
|
||
AND s.region_id = po.region_id
|
||
),
|
||
to_delete AS (
|
||
SELECT id
|
||
FROM ranked
|
||
WHERE rn > seats_total
|
||
)
|
||
DELETE FROM falukant_data.political_office
|
||
WHERE id IN (SELECT id FROM to_delete);
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_ELECTION_CANDIDATE: &str = r#"
|
||
DELETE FROM falukant_data.election_candidate
|
||
WHERE character_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_STOCK_TYPE_ID: &str = r#"
|
||
SELECT id FROM falukant_type.stock WHERE label_tr = $1 LIMIT 1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_INVENTORY_ITEMS: &str = r#"
|
||
SELECT i.id AS inventory_id, i.quantity AS inventory_quantity, i.stock_id FROM falukant_data.inventory i JOIN falukant_data.stock s ON i.stock_id = s.id JOIN falukant_data.branch b ON s.branch_id = b.id WHERE b.region_id = $1 AND s.stock_type_id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_REDUCE_INVENTORY: &str = r#"
|
||
UPDATE falukant_data.inventory SET quantity = $1 WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_INVENTORY: &str = r#"
|
||
DELETE FROM falukant_data.inventory WHERE stock_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_STOCK: &str = r#"
|
||
DELETE FROM falukant_data.stock WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_GET_STOCK_INVENTORY: &str = r#"
|
||
SELECT id, quantity FROM falukant_data.inventory WHERE stock_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_CAP_INVENTORY: &str = r#"
|
||
UPDATE falukant_data.inventory SET quantity = $1 WHERE id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_GET_USER_INVENTORY_ITEMS: &str = r#"
|
||
SELECT i.id AS inventory_id, i.quantity AS inventory_quantity, i.stock_id
|
||
FROM falukant_data.inventory i
|
||
JOIN falukant_data.stock s ON i.stock_id = s.id
|
||
JOIN falukant_data.branch b ON s.branch_id = b.id
|
||
WHERE b.falukant_user_id = $1 AND s.stock_type_id = $2;
|
||
"#;
|
||
// Produce worker queries
|
||
pub const QUERY_GET_FINISHED_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
|
||
-- 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
|
||
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
|
||
-- Wetter-Effekte derzeit aus der Qualitätsberechnung entfernt
|
||
WHERE p.start_timestamp + INTERVAL '1 minute' * pr.production_time <= NOW()
|
||
ORDER BY p.start_timestamp;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_PRODUCTION: &str = r#"
|
||
DELETE FROM falukant_data.production
|
||
WHERE id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_INSERT_UPDATE_PRODUCTION_LOG: &str = r#"
|
||
INSERT INTO falukant_log.production (
|
||
region_id,
|
||
product_id,
|
||
quantity,
|
||
producer_id,
|
||
production_date
|
||
) VALUES ($1, $2, $3, $4, CURRENT_DATE)
|
||
ON CONFLICT (producer_id, product_id, region_id, production_date)
|
||
DO UPDATE
|
||
SET quantity = falukant_log.production.quantity + EXCLUDED.quantity;
|
||
"#;
|
||
|
||
// 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;
|
||
pub const QUERY_DELETE_STOCK_PERSONAL: &str = QUERY_DELETE_STOCK;
|
||
pub const QUERY_GET_STOCK_INVENTORY_PERSONAL: &str = QUERY_GET_STOCK_INVENTORY;
|
||
pub const QUERY_CAP_INVENTORY_PERSONAL: &str = QUERY_CAP_INVENTORY;
|
||
|
||
// value_recalculation worker queries
|
||
pub const QUERY_UPDATE_PRODUCT_KNOWLEDGE_USER: &str = r#"
|
||
UPDATE falukant_data.knowledge k
|
||
SET knowledge = LEAST(100, k.knowledge + 1)
|
||
FROM falukant_data.character c
|
||
JOIN falukant_log.production p
|
||
ON DATE(p.production_timestamp) = CURRENT_DATE - INTERVAL '1 day'
|
||
WHERE c.id = k.character_id
|
||
AND c.user_id = 18
|
||
AND k.product_id = 10;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_OLD_PRODUCTIONS: &str = r#"
|
||
DELETE FROM falukant_log.production flp
|
||
WHERE DATE(flp.production_timestamp) < CURRENT_DATE;
|
||
"#;
|
||
|
||
pub const QUERY_GET_PRODUCERS_LAST_DAY: &str = r#"
|
||
SELECT p.producer_id
|
||
FROM falukant_log.production p
|
||
WHERE DATE(p.production_timestamp) = CURRENT_DATE - INTERVAL '1 day'
|
||
GROUP BY producer_id;
|
||
"#;
|
||
|
||
pub const QUERY_UPDATE_REGION_SELL_PRICE: &str = r#"
|
||
UPDATE falukant_data.town_product_worth tpw
|
||
SET worth_percent =
|
||
GREATEST(
|
||
0,
|
||
LEAST(
|
||
CASE
|
||
WHEN s.quantity > COALESCE(s.avg_sells, 0) * 1.05 THEN tpw.worth_percent + 1
|
||
WHEN s.quantity < COALESCE(s.avg_sells, 0) * 0.95 THEN tpw.worth_percent - 1
|
||
ELSE tpw.worth_percent
|
||
END,
|
||
100
|
||
)
|
||
)
|
||
FROM (
|
||
SELECT region_id,
|
||
product_id,
|
||
quantity,
|
||
(SELECT AVG(quantity)
|
||
FROM falukant_log.sell avs
|
||
WHERE avs.product_id = s.product_id) AS avg_sells
|
||
FROM falukant_log.sell s
|
||
WHERE DATE(s.sell_timestamp) = CURRENT_DATE - INTERVAL '1 day'
|
||
) s
|
||
WHERE tpw.region_id = s.region_id
|
||
AND tpw.product_id = s.product_id;
|
||
"#;
|
||
|
||
pub const QUERY_DELETE_REGION_SELL_PRICE: &str = r#"
|
||
DELETE FROM falukant_log.sell s
|
||
WHERE DATE(s.sell_timestamp) < CURRENT_DATE;
|
||
"#;
|
||
|
||
pub const QUERY_GET_SELL_REGIONS: &str = r#"
|
||
SELECT s.region_id
|
||
FROM falukant_log.sell s
|
||
WHERE DATE(s.sell_timestamp) = CURRENT_DATE - INTERVAL '1 day'
|
||
GROUP BY region_id;
|
||
"#;
|
||
|
||
pub const QUERY_HOURLY_PRICE_RECALCULATION: &str = r#"
|
||
WITH city_sales AS (
|
||
SELECT s.region_id, s.product_id, SUM(s.quantity) AS total_sold
|
||
FROM falukant_log.sell s
|
||
WHERE s.sell_timestamp >= NOW() - INTERVAL '1 hour'
|
||
GROUP BY s.region_id, s.product_id
|
||
),
|
||
world_avg AS (
|
||
SELECT product_id, AVG(total_sold) AS avg_sold
|
||
FROM city_sales
|
||
GROUP BY product_id
|
||
),
|
||
adjustments AS (
|
||
SELECT
|
||
cs.region_id,
|
||
cs.product_id,
|
||
CASE
|
||
WHEN cs.total_sold > COALESCE(wa.avg_sold, 0) * 1.05 THEN 1.10
|
||
WHEN cs.total_sold < COALESCE(wa.avg_sold, 0) * 0.95 THEN 0.90
|
||
ELSE 1.00
|
||
END AS factor
|
||
FROM city_sales cs
|
||
JOIN world_avg wa ON wa.product_id = cs.product_id
|
||
)
|
||
UPDATE falukant_data.town_product_worth tpw
|
||
SET worth_percent = GREATEST(0, LEAST(100, tpw.worth_percent * adj.factor))
|
||
FROM adjustments adj
|
||
WHERE tpw.region_id = adj.region_id
|
||
AND tpw.product_id = adj.product_id;
|
||
"#;
|
||
|
||
pub const QUERY_SET_MARRIAGES_BY_PARTY: &str = r#"
|
||
WITH updated_relations AS (
|
||
UPDATE falukant_data.relationship AS rel
|
||
SET relationship_type_id = (
|
||
SELECT id
|
||
FROM falukant_type.relationship AS rt
|
||
WHERE rt.tr = 'married'
|
||
)
|
||
WHERE rel.id IN (
|
||
SELECT rel2.id
|
||
FROM falukant_data.party AS p
|
||
JOIN falukant_type.party AS pt
|
||
ON pt.id = p.party_type_id
|
||
AND pt.tr = 'wedding'
|
||
JOIN falukant_data.falukant_user AS fu
|
||
ON fu.id = p.falukant_user_id
|
||
JOIN falukant_data.character AS c
|
||
ON c.user_id = fu.id
|
||
JOIN falukant_data.relationship AS rel2
|
||
ON rel2.character1_id = c.id
|
||
OR rel2.character2_id = c.id
|
||
JOIN falukant_type.relationship AS rt2
|
||
ON rt2.id = rel2.relationship_type_id
|
||
AND rt2.tr = 'engaged'
|
||
WHERE p.created_at <= NOW() - INTERVAL '1 day'
|
||
)
|
||
RETURNING character1_id, character2_id
|
||
)
|
||
SELECT
|
||
c1.user_id AS character1_user,
|
||
c2.user_id AS character2_user
|
||
FROM updated_relations AS ur
|
||
JOIN falukant_data.character AS c1
|
||
ON c1.id = ur.character1_id
|
||
JOIN falukant_data.character AS c2
|
||
ON c2.id = ur.character2_id;
|
||
"#;
|
||
|
||
pub const QUERY_GET_STUDYINGS_TO_EXECUTE: &str = r#"
|
||
SELECT
|
||
l.id,
|
||
l.associated_falukant_user_id,
|
||
l.associated_learning_character_id,
|
||
l.learn_all_products,
|
||
l.learning_recipient_id,
|
||
l.product_id,
|
||
lr.tr
|
||
FROM falukant_data.learning l
|
||
JOIN falukant_type.learn_recipient lr
|
||
ON lr.id = l.learning_recipient_id
|
||
WHERE l.learning_is_executed = FALSE
|
||
AND l.created_at + INTERVAL '1 day' < NOW();
|
||
"#;
|
||
|
||
pub const QUERY_GET_OWN_CHARACTER_ID: &str = r#"
|
||
SELECT id
|
||
FROM falukant_data.character c
|
||
WHERE c.user_id = $1;
|
||
"#;
|
||
|
||
pub const QUERY_INCREASE_ONE_PRODUCT_KNOWLEDGE: &str = r#"
|
||
UPDATE falukant_data.knowledge k
|
||
SET knowledge = LEAST(100, k.knowledge + $1)
|
||
WHERE k.character_id = $2
|
||
AND k.product_id = $3;
|
||
"#;
|
||
|
||
pub const QUERY_INCREASE_ALL_PRODUCTS_KNOWLEDGE: &str = r#"
|
||
UPDATE falukant_data.knowledge k
|
||
SET knowledge = LEAST(100, k.knowledge + $1)
|
||
WHERE k.character_id = $2;
|
||
"#;
|
||
|
||
pub const QUERY_SET_LEARNING_DONE: &str = r#"
|
||
UPDATE falukant_data.learning
|
||
SET learning_is_executed = TRUE,
|
||
updated_at = NOW()
|
||
WHERE id = $1;
|
||
"#;
|
||
|
||
|
||
|