Refactor SQL query for finished productions: Update to use DISTINCT ON for unique production IDs, change JOINs to LEFT JOINs for character and director relationships, and simplify capacity checks to ensure sufficient storage for productions. Adjust ordering for improved query performance.
This commit is contained in:
@@ -257,12 +257,9 @@ impl ProduceWorker {
|
||||
.get("used_in_stock")
|
||||
.and_then(|v| v.parse::<i32>().ok())
|
||||
.unwrap_or(0);
|
||||
let running_productions_quantity: i32 = row
|
||||
.get("running_productions_quantity")
|
||||
.and_then(|v| v.parse::<i32>().ok())
|
||||
.unwrap_or(0);
|
||||
|
||||
let free_capacity = stock_size - used_in_stock - running_productions_quantity;
|
||||
// Freier Platz = aktuell befüllte Kapazität; laufende Produktionen belegen noch keinen Lagerplatz
|
||||
let free_capacity = stock_size - used_in_stock;
|
||||
free_capacity >= required_quantity
|
||||
}
|
||||
|
||||
|
||||
@@ -1382,7 +1382,7 @@ WHERE b.falukant_user_id = $1 AND s.stock_type_id = $2;
|
||||
"#;
|
||||
// Produce worker queries
|
||||
pub const QUERY_GET_FINISHED_PRODUCTIONS: &str = r#"
|
||||
SELECT
|
||||
SELECT DISTINCT ON (p.id)
|
||||
p.id AS production_id,
|
||||
p.branch_id,
|
||||
p.product_id,
|
||||
@@ -1409,13 +1409,13 @@ 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
|
||||
JOIN falukant_data.character c
|
||||
LEFT 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
|
||||
LEFT JOIN falukant_data.director d
|
||||
ON d.employer_user_id = c.user_id
|
||||
ON d.employer_user_id = br.falukant_user_id
|
||||
LEFT JOIN falukant_data.knowledge k2
|
||||
ON k2.character_id = d.director_character_id
|
||||
AND k2.product_id = p.product_id
|
||||
@@ -1424,29 +1424,22 @@ pub const QUERY_GET_FINISHED_PRODUCTIONS: &str = r#"
|
||||
LEFT JOIN falukant_type.product_weather_effect pwe
|
||||
ON pwe.product_id = p.product_id
|
||||
AND pwe.weather_type_id = w.weather_type_id
|
||||
-- Prüfe, ob genug freier Lagerplatz vorhanden ist
|
||||
-- Prüfe, ob genug freier Lagerplatz vorhanden ist (korrelierte Subqueries, keine JOIN-Multiplikation)
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
SELECT
|
||||
br2.id AS branch_id,
|
||||
COALESCE(SUM(fds.quantity), 0) AS stock_size,
|
||||
COALESCE(SUM(COALESCE(fdi.quantity, 0)), 0) AS used_in_stock,
|
||||
COALESCE(SUM(COALESCE(fdp2.quantity, 0)), 0) AS running_productions_quantity
|
||||
(SELECT COALESCE(SUM(quantity), 0) FROM falukant_data.stock WHERE branch_id = br2.id) AS stock_size,
|
||||
(SELECT COALESCE(SUM(fdi.quantity), 0) FROM falukant_data.stock fds
|
||||
JOIN falukant_data.inventory fdi ON fdi.stock_id = fds.id WHERE fds.branch_id = br2.id) AS used_in_stock,
|
||||
(SELECT COALESCE(SUM(quantity), 0) FROM falukant_data.production WHERE branch_id = br2.id) AS running_productions_quantity
|
||||
FROM falukant_data.branch br2
|
||||
LEFT JOIN falukant_data.stock fds ON fds.branch_id = br2.id
|
||||
LEFT JOIN falukant_data.inventory fdi ON fdi.stock_id = fds.id
|
||||
LEFT JOIN falukant_data.production fdp2 ON fdp2.branch_id = br2.id
|
||||
GROUP BY br2.id
|
||||
) capacity ON capacity.branch_id = p.branch_id
|
||||
-- Wetter-Effekte derzeit aus der Qualitätsberechnung entfernt
|
||||
WHERE p.start_timestamp + INTERVAL '1 minute' * pr.production_time <= NOW()
|
||||
-- Nur Produktionen zurückgeben, für die genug Lagerplatz vorhanden ist
|
||||
-- running_productions_quantity enthält bereits p.quantity
|
||||
-- Nach dem Abschluss von p muss Platz sein: stock_size - used_in_stock - (running_productions_quantity - p.quantity) >= p.quantity
|
||||
-- Vereinfacht: stock_size - used_in_stock - running_productions_quantity + p.quantity >= p.quantity
|
||||
-- Oder: stock_size - used_in_stock - running_productions_quantity >= 0
|
||||
-- ABER: Wir müssen sicherstellen, dass p.quantity auch wirklich Platz hat
|
||||
AND (capacity.stock_size - capacity.used_in_stock - capacity.running_productions_quantity + p.quantity) >= p.quantity
|
||||
ORDER BY p.start_timestamp;
|
||||
-- Freier Platz = stock_size - used_in_stock; laufende Produktionen belegen noch keinen Platz.
|
||||
-- Es muss genug Platz für p.quantity sein: (stock_size - used_in_stock) >= p.quantity
|
||||
AND (capacity.stock_size - capacity.used_in_stock) >= p.quantity
|
||||
ORDER BY p.id, p.start_timestamp;
|
||||
"#;
|
||||
|
||||
pub const QUERY_DELETE_PRODUCTION: &str = r#"
|
||||
|
||||
Reference in New Issue
Block a user