Refactor hourly price recalculation logic: Implemented a two-tier pricing adjustment system based on sales data, comparing city sales against global and parent-region averages. Updated SQL queries to reflect new pricing rules, ensuring dynamic price adjustments within defined tolerances. Enhanced logging for better tracking of affected regions during recalculation.
This commit is contained in:
@@ -77,8 +77,14 @@ const QUERY_GET_SELL_REGIONS: &str = r#"
|
||||
"#;
|
||||
|
||||
// Stündliche Preisneuberechnung basierend auf Verkäufen der letzten Stunde
|
||||
// Für jedes Produkt in jeder Stadt: Wenn überdurchschnittlich viel verkauft wurde,
|
||||
// sinkt der Preis um 10% (begrenzt auf 0-100)
|
||||
// Zwei Ebenen der Preisberechnung:
|
||||
// 1. Weltweit: Vergleich Stadt-Verkäufe vs. weltweiter Durchschnitt
|
||||
// - ±5% Toleranz: Preis bleibt gleich
|
||||
// - Mehr Verkäufe (>5% über Durchschnitt): Preis +10%
|
||||
// - Weniger Verkäufe (<5% unter Durchschnitt): Preis -10%
|
||||
// 2. Parent-Region: Vergleich Stadt-Verkäufe vs. Durchschnitt der parent-region
|
||||
// - ±5% Toleranz: Preis bleibt gleich
|
||||
// - Abweichung >±5%: Preis ±5%
|
||||
const QUERY_HOURLY_PRICE_RECALCULATION: &str = r#"
|
||||
WITH city_sales AS (
|
||||
SELECT
|
||||
@@ -89,38 +95,120 @@ const QUERY_HOURLY_PRICE_RECALCULATION: &str = r#"
|
||||
WHERE s.sell_timestamp >= NOW() - INTERVAL '1 hour'
|
||||
GROUP BY s.region_id, s.product_id
|
||||
),
|
||||
avg_sales AS (
|
||||
world_avg_sales AS (
|
||||
SELECT
|
||||
product_id,
|
||||
AVG(total_sold) AS avg_sold
|
||||
FROM city_sales
|
||||
GROUP BY product_id
|
||||
),
|
||||
price_updates AS (
|
||||
parent_region_sales AS (
|
||||
SELECT
|
||||
r.parent_region_id,
|
||||
cs.product_id,
|
||||
AVG(cs.total_sold) AS avg_sold
|
||||
FROM city_sales cs
|
||||
JOIN falukant_data.region r ON r.id = cs.region_id
|
||||
WHERE r.parent_region_id IS NOT NULL
|
||||
GROUP BY r.parent_region_id, cs.product_id
|
||||
),
|
||||
price_updates_world AS (
|
||||
SELECT
|
||||
cs.region_id,
|
||||
cs.product_id,
|
||||
cs.total_sold,
|
||||
COALESCE(av.avg_sold, 0) AS avg_sold,
|
||||
tpw.worth_percent AS current_price
|
||||
COALESCE(wa.avg_sold, 0) AS world_avg,
|
||||
tpw.worth_percent AS current_price,
|
||||
CASE
|
||||
-- Mehr als 5% über dem weltweiten Durchschnitt: 10% teurer
|
||||
WHEN cs.total_sold > COALESCE(wa.avg_sold, 0) * 1.05
|
||||
THEN tpw.worth_percent * 1.1
|
||||
-- Weniger als 5% unter dem weltweiten Durchschnitt: 10% billiger
|
||||
WHEN cs.total_sold < COALESCE(wa.avg_sold, 0) * 0.95
|
||||
THEN tpw.worth_percent * 0.9
|
||||
-- Innerhalb ±5%: Preis bleibt gleich
|
||||
ELSE tpw.worth_percent
|
||||
END AS price_after_world
|
||||
FROM city_sales cs
|
||||
JOIN avg_sales av ON av.product_id = cs.product_id
|
||||
JOIN world_avg_sales wa ON wa.product_id = cs.product_id
|
||||
JOIN falukant_data.town_product_worth tpw
|
||||
ON tpw.region_id = cs.region_id
|
||||
AND tpw.product_id = cs.product_id
|
||||
WHERE cs.total_sold > COALESCE(av.avg_sold, 0)
|
||||
-- Nur updaten wenn es eine Änderung gibt (außerhalb der ±5% Toleranz)
|
||||
WHERE cs.total_sold > COALESCE(wa.avg_sold, 0) * 1.05
|
||||
OR cs.total_sold < COALESCE(wa.avg_sold, 0) * 0.95
|
||||
),
|
||||
all_cities_with_prices AS (
|
||||
SELECT
|
||||
cs.region_id,
|
||||
cs.product_id,
|
||||
cs.total_sold,
|
||||
r.parent_region_id,
|
||||
tpw.worth_percent AS original_price,
|
||||
COALESCE(puw.price_after_world, tpw.worth_percent) AS price_after_world
|
||||
FROM city_sales cs
|
||||
JOIN falukant_data.region r ON r.id = cs.region_id
|
||||
JOIN falukant_data.town_product_worth tpw
|
||||
ON tpw.region_id = cs.region_id
|
||||
AND tpw.product_id = cs.product_id
|
||||
LEFT JOIN price_updates_world puw
|
||||
ON puw.region_id = cs.region_id
|
||||
AND puw.product_id = cs.product_id
|
||||
),
|
||||
price_updates_parent AS (
|
||||
SELECT
|
||||
acwp.region_id,
|
||||
acwp.product_id,
|
||||
acwp.total_sold,
|
||||
acwp.parent_region_id,
|
||||
COALESCE(prs.avg_sold, 0) AS parent_avg,
|
||||
acwp.price_after_world AS current_price,
|
||||
CASE
|
||||
-- Mehr als 5% über dem parent-region Durchschnitt: 5% teurer
|
||||
WHEN acwp.total_sold > COALESCE(prs.avg_sold, 0) * 1.05
|
||||
THEN acwp.price_after_world * 1.05
|
||||
-- Weniger als 5% unter dem parent-region Durchschnitt: 5% billiger
|
||||
WHEN acwp.total_sold < COALESCE(prs.avg_sold, 0) * 0.95
|
||||
THEN acwp.price_after_world * 0.95
|
||||
-- Innerhalb ±5%: Preis bleibt gleich (vom world-update)
|
||||
ELSE acwp.price_after_world
|
||||
END AS new_price
|
||||
FROM all_cities_with_prices acwp
|
||||
LEFT JOIN parent_region_sales prs
|
||||
ON prs.parent_region_id = acwp.parent_region_id
|
||||
AND prs.product_id = acwp.product_id
|
||||
WHERE acwp.parent_region_id IS NOT NULL
|
||||
AND (
|
||||
acwp.total_sold > COALESCE(prs.avg_sold, 0) * 1.05
|
||||
OR acwp.total_sold < COALESCE(prs.avg_sold, 0) * 0.95
|
||||
)
|
||||
),
|
||||
final_price_updates AS (
|
||||
SELECT
|
||||
COALESCE(pup.region_id, puw.region_id) AS region_id,
|
||||
COALESCE(pup.product_id, puw.product_id) AS product_id,
|
||||
COALESCE(pup.new_price, puw.price_after_world, acwp.original_price) AS final_price
|
||||
FROM all_cities_with_prices acwp
|
||||
LEFT JOIN price_updates_world puw
|
||||
ON puw.region_id = acwp.region_id
|
||||
AND puw.product_id = acwp.product_id
|
||||
LEFT JOIN price_updates_parent pup
|
||||
ON pup.region_id = acwp.region_id
|
||||
AND pup.product_id = acwp.product_id
|
||||
WHERE puw.region_id IS NOT NULL
|
||||
OR pup.region_id IS NOT NULL
|
||||
)
|
||||
UPDATE falukant_data.town_product_worth tpw
|
||||
SET worth_percent = GREATEST(
|
||||
0,
|
||||
LEAST(
|
||||
100,
|
||||
pu.current_price * 0.9 -- 10% Preisreduktion
|
||||
fpu.final_price
|
||||
)
|
||||
)
|
||||
FROM price_updates pu
|
||||
WHERE tpw.region_id = pu.region_id
|
||||
AND tpw.product_id = pu.product_id;
|
||||
FROM final_price_updates fpu
|
||||
WHERE tpw.region_id = fpu.region_id
|
||||
AND tpw.product_id = fpu.product_id;
|
||||
"#;
|
||||
|
||||
// Ehen / Beziehungen
|
||||
@@ -341,10 +429,10 @@ impl ValueRecalculationWorker {
|
||||
.map_err(|e| DbError::new(format!("DB-Verbindung fehlgeschlagen: {e}")))?;
|
||||
|
||||
conn.prepare("hourly_price_recalculation", QUERY_HOURLY_PRICE_RECALCULATION)?;
|
||||
let updated_rows = conn.execute("hourly_price_recalculation", &[])?;
|
||||
let _updated_rows = conn.execute("hourly_price_recalculation", &[])?;
|
||||
|
||||
// Sammle alle betroffenen Regionen für Event-Benachrichtigungen
|
||||
let mut affected_regions = std::collections::HashSet::new();
|
||||
let mut affected_regions = HashSet::new();
|
||||
|
||||
// Da die Query bereits die Updates durchführt, müssen wir die betroffenen Regionen
|
||||
// separat abfragen. Alternativ können wir auch einfach alle Regionen benachrichtigen,
|
||||
@@ -362,6 +450,9 @@ impl ValueRecalculationWorker {
|
||||
}
|
||||
}
|
||||
|
||||
// Speichere die Anzahl vor der Schleife, da affected_regions in der Schleife bewegt wird
|
||||
let affected_count = affected_regions.len();
|
||||
|
||||
// Benachrichtige alle betroffenen Regionen über Preisänderungen
|
||||
for region_id in affected_regions {
|
||||
let message =
|
||||
@@ -371,7 +462,7 @@ impl ValueRecalculationWorker {
|
||||
|
||||
eprintln!(
|
||||
"[ValueRecalculationWorker] Stündliche Preisneuberechnung abgeschlossen. {} Regionen aktualisiert.",
|
||||
affected_regions.len()
|
||||
affected_count
|
||||
);
|
||||
|
||||
Ok(())
|
||||
|
||||
Reference in New Issue
Block a user