Skip to content

Commit

Permalink
Add migrations to fix shopping list generation
Browse files Browse the repository at this point in the history
  • Loading branch information
TrueDoctor committed May 29, 2024
1 parent 3e2ebda commit 48c752f
Show file tree
Hide file tree
Showing 4 changed files with 111 additions and 2 deletions.
33 changes: 33 additions & 0 deletions foodlib/migrations/20240529202502_fix_shopping_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
CREATE OR REPLACE VIEW public.shopping_list AS
SELECT full_weight.event_id,
full_weight.event_name,
full_weight.ingredient_id,
full_weight.ingredient,
sum(full_weight.weight) AS weight,
round(sum(full_weight.weight) * ingredients.energy * 1000::numeric, 2) AS energy,
sum(full_weight.weight)* COALESCE(price_per_ingredient_weight.price, '-1,00 €'::money) AS price,
full_weight.tour_id
FROM ( SELECT prefetch.event_id,
prefetch.tour_id,
prefetch.event_name,
prefetch.ingredient_id,
prefetch.ingredient,
prefetch.store_id,
prefetch.buy_by,
round(GREATEST(prefetch.weight::double precision - COALESCE(event_storage.amount::double precision, 0::double precision), 0::double precision)::numeric, 2) AS weight
FROM ( SELECT shopping_tour_ingredients.event_id,
shopping_tour_ingredients.tour_id,
shopping_tour_ingredients.event AS event_name,
shopping_tour_ingredients.ingredient_id,
shopping_tour_ingredients.ingredient,
shopping_tour_ingredients.store_id,
shopping_tour_ingredients.buy_by,
sum(shopping_tour_ingredients.weight) AS weight
FROM shopping_tour_ingredients
WHERE shopping_tour_ingredients.tour_id IS NOT NULL
GROUP BY shopping_tour_ingredients.event_id, shopping_tour_ingredients.tour_id, shopping_tour_ingredients.event, shopping_tour_ingredients.ingredient_id, shopping_tour_ingredients.ingredient, shopping_tour_ingredients.buy_by, shopping_tour_ingredients.store_id) prefetch
LEFT JOIN event_storage USING (event_id, ingredient_id)) full_weight
LEFT JOIN best_event_ingredient_sources as price_per_ingredient_weight
USING (ingredient_id)
LEFT JOIN ingredients USING (ingredient_id)
GROUP BY full_weight.event_id, full_weight.tour_id, full_weight.event_name, full_weight.ingredient_id, full_weight.ingredient, ingredients.energy, price_per_ingredient_weight.price
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
CREATE OR REPLACE VIEW public.event_ingredients_before_prep_time_resolve AS
SELECT events.event_id,
events.event_name AS event,
event_meals.recipe_id,
resolved_recipes.recipe,
event_meals.place_id,
places.name AS place,
event_meals.start_time,
event_meals.end_time,
resolved_recipes.ingredient_id,
resolved_recipes.ingredient,
resolved_recipes.weight * recipe_multipliers.recipe_multiplier * ingredient_weight.weight AS weight,
recipe_multipliers.recipe_multiplier * resolved_recipes.weight * ingredients.energy * 1000::numeric AS energy,
ingredient_sources.price * (recipe_multipliers.recipe_multiplier * resolved_recipes.weight / (ingredient_weight.weight * COALESCE(ingredient_sources.package_size, 1::numeric)))::double precision AS price,
event_meals.servings,
event_meals.meal_id,
resolved_recipes.acc AS subrecipe_hierarchy,
event_meals.start_time AS buy_by,
ingredient_sources.store_id
FROM events
LEFT JOIN event_meals USING (event_id)
LEFT JOIN places USING (place_id)
LEFT JOIN resolved_recipes USING (recipe_id)
LEFT JOIN ingredients USING (ingredient_id)
LEFT JOIN best_event_ingredient_sources USING (event_id, ingredient_id)
LEFT JOIN ingredient_sources USING (ingredient_source_id, ingredient_id)
LEFT JOIN ingredient_weight USING (ingredient_id, unit_id)
LEFT JOIN ( SELECT event_meals_1.recipe_id,
event_meals_1.event_id,
event_meals_1.place_id,
event_meals_1.start_time,
event_meals_1.energy_per_serving * event_meals_1.servings::numeric / recipe_stats.energy AS recipe_multiplier
FROM event_meals event_meals_1
JOIN recipe_stats USING (recipe_id)) recipe_multipliers USING (event_id, recipe_id, place_id, start_time);

CREATE OR REPLACE VIEW public.shopping_list AS
SELECT full_weight.event_id,
full_weight.event_name,
full_weight.ingredient_id,
full_weight.ingredient,
sum(full_weight.weight) AS weight,
round(sum(full_weight.weight) * ingredients.energy * 1000::numeric, 2) AS energy,
sum(full_weight.weight)::double precision * COALESCE(price_per_ingredient_weight.price, '-1,00 €'::money) AS price,
full_weight.tour_id
FROM ( SELECT prefetch.event_id,
prefetch.tour_id,
prefetch.event_name,
prefetch.ingredient_id,
prefetch.ingredient,
prefetch.store_id,
prefetch.buy_by,
round(GREATEST(prefetch.weight::double precision - COALESCE(event_storage.amount::double precision, 0::double precision), 0::double precision)::numeric, 2) AS weight
FROM ( SELECT shopping_tour_ingredients.event_id,
shopping_tour_ingredients.tour_id,
shopping_tour_ingredients.event AS event_name,
shopping_tour_ingredients.ingredient_id,
shopping_tour_ingredients.ingredient,
shopping_tour_ingredients.store_id,
shopping_tour_ingredients.buy_by,
sum(shopping_tour_ingredients.weight) AS weight
FROM shopping_tour_ingredients
WHERE shopping_tour_ingredients.tour_id IS NOT NULL
GROUP BY shopping_tour_ingredients.event_id, shopping_tour_ingredients.tour_id, shopping_tour_ingredients.event, shopping_tour_ingredients.ingredient_id, shopping_tour_ingredients.ingredient, shopping_tour_ingredients.buy_by, shopping_tour_ingredients.store_id) prefetch
LEFT JOIN event_storage USING (event_id, ingredient_id)) full_weight
LEFT JOIN best_event_ingredient_sources price_per_ingredient_weight USING (ingredient_id, event_id)
LEFT JOIN ingredients USING (ingredient_id)
GROUP BY full_weight.event_id, full_weight.tour_id, full_weight.event_name, full_weight.ingredient_id, full_weight.ingredient, ingredients.energy, price_per_ingredient_weight.price;
10 changes: 10 additions & 0 deletions foodlib/migrations/20240529211035_fix_best_ingredient_sources.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
CREATE OR REPLACE VIEW public.event_ingredients_with_source_options AS
SELECT events.event_id,
resolved_recipes.ingredient_id,
source_price_per_kilo.price_per_kilo AS price,
source_price_per_kilo.ingredient_source_id
FROM events
LEFT JOIN event_meals USING (event_id)
LEFT JOIN resolved_recipes USING (recipe_id)
LEFT JOIN event_ingredient_sources USING (event_id, ingredient_id)
LEFT JOIN source_price_per_kilo USING (ingredient_source_id)
3 changes: 1 addition & 2 deletions foodlib/src/meals.rs
Original file line number Diff line number Diff line change
Expand Up @@ -54,7 +54,6 @@ impl Default for Meal {
}
}
}
// (CASE WHEN event_meals.servings != 0 THEN round(sum(energy) / event_meals.servings,0) ELSE 0 END) as "energy!",

impl FoodBase {
pub async fn get_event_meals(&self, event_id: i32) -> eyre::Result<Vec<Meal>> {
Expand All @@ -71,7 +70,7 @@ impl FoodBase {
event_meals.start_time as "start_time!",
event_meals.end_time as "end_time!",
round(sum(weight),2) as "weight!",
0 as "energy!",
(CASE WHEN event_meals.servings != 0 THEN round(sum(energy) / event_meals.servings,0) ELSE 0 END) as "energy!",
sum(price) as "price!",
event_meals.servings as "servings!"
Expand Down

0 comments on commit 48c752f

Please sign in to comment.