From 3b8944d61bb2973cd0155bc655a3e953c03f9e10 Mon Sep 17 00:00:00 2001 From: Bernd Bestel Date: Wed, 1 Jun 2022 20:32:31 +0200 Subject: [PATCH] Fixed recipes_pos_resolved.missing_amount calculation (references #1903) --- changelog/68_UNRELEASED_xxxx-xx-xx.md | 1 + migrations/0192.sql | 135 ++++++++++++++++++++++++++ 2 files changed, 136 insertions(+) create mode 100644 migrations/0192.sql diff --git a/changelog/68_UNRELEASED_xxxx-xx-xx.md b/changelog/68_UNRELEASED_xxxx-xx-xx.md index 22feeba1..0687555c 100644 --- a/changelog/68_UNRELEASED_xxxx-xx-xx.md +++ b/changelog/68_UNRELEASED_xxxx-xx-xx.md @@ -21,6 +21,7 @@ ### Recipes - Fixed that when a substituted product is used to display costs and calories (so when a parent product ingredient is currently not in stock itself), no unit conversions were considered for costs/calories calculation +- Fixed that the displayed "already on the shopping list"-amount (for missing ingredients) was wrong when the products "Factor purchase to stock quantity unit" wasn't 1 ### Meal plan diff --git a/migrations/0192.sql b/migrations/0192.sql new file mode 100644 index 00000000..9db07ea2 --- /dev/null +++ b/migrations/0192.sql @@ -0,0 +1,135 @@ +DROP VIEW recipes_pos_resolved; +CREATE VIEW recipes_pos_resolved +AS + +-- Multiplication by 1.0 to force conversion to float (REAL) + +SELECT + r.id AS recipe_id, + rp.id AS recipe_pos_id, + rp.product_id AS product_id, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END AS recipe_amount, + IFNULL(sc.amount_aggregated, 0) AS stock_amount, + CASE WHEN IFNULL(sc.amount_aggregated, 0) >= CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 0.00000001 ELSE CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END END THEN 1 ELSE 0 END AS need_fulfilled, + CASE WHEN IFNULL(sc.amount_aggregated, 0) - CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 0.00000001 ELSE CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END END < 0 THEN ABS(IFNULL(sc.amount_aggregated, 0) - (CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END)) ELSE 0 END AS missing_amount, + IFNULL(sl.amount, 0) AS amount_on_shopping_list, + CASE WHEN ROUND(IFNULL(sc.amount_aggregated, 0) + CASE WHEN r.not_check_shoppinglist = 1 THEN 0 ELSE IFNULL(sl.amount, 0) END, 2) >= ROUND(CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 0.00000001 ELSE CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END END, 2) THEN 1 ELSE 0 END AS need_fulfilled_with_shopping_list, + rp.qu_id, + (r.desired_servings*1.0 / r.base_servings*1.0) * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * rp.amount * IFNULL(pcp.price, 0) * rp.price_factor * CASE WHEN rp.only_check_single_unit_in_stock = 1 OR rp.product_id != p_effective.id THEN IFNULL(qucr.factor, 1) ELSE 1 END AS costs, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN 0 ELSE 1 END AS is_nested_recipe_pos, + rp.ingredient_group, + pg.name as product_group, + rp.id, -- Just a dummy id column + r.type as recipe_type, + rnr.includes_recipe_id as child_recipe_id, + rp.note, + rp.variable_amount AS recipe_variable_amount, + rp.only_check_single_unit_in_stock, + rp.amount / r.base_servings*1.0 * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * IFNULL(p_effective.calories, 0) * CASE WHEN rp.only_check_single_unit_in_stock = 1 OR rp.product_id != p_effective.id THEN IFNULL(qucr.factor, 1) ELSE 1 END AS calories, + p.active AS product_active, + CASE pvs.current_due_status + WHEN 'ok' THEN 0 + WHEN 'due_soon' THEN 1 + WHEN 'overdue' THEN 10 + WHEN 'expired' THEN 20 + END AS due_score, + IFNULL(pcs.product_id_effective, rp.product_id) AS product_id_effective, + p.name AS product_name +FROM recipes r +JOIN recipes_nestings_resolved rnr + ON r.id = rnr.recipe_id +JOIN recipes rnrr + ON rnr.includes_recipe_id = rnrr.id +JOIN recipes_pos rp + ON rnr.includes_recipe_id = rp.recipe_id +JOIN products p + ON rp.product_id = p.id +JOIN products_volatile_status pvs + ON rp.product_id = pvs.product_id +LEFT JOIN product_groups pg + ON p.product_group_id = pg.id +LEFT JOIN ( + SELECT product_id, SUM(amount) AS amount + FROM shopping_list + GROUP BY product_id) sl + ON rp.product_id = sl.product_id +LEFT JOIN stock_current sc + ON rp.product_id = sc.product_id +LEFT JOIN products_current_substitutions pcs + ON rp.product_id = pcs.parent_product_id +LEFT JOIN products_current_price pcp + ON IFNULL(pcs.product_id_effective, rp.product_id) = pcp.product_id +LEFT JOIN products p_effective + ON IFNULL(pcs.product_id_effective, rp.product_id) = p_effective.id +LEFT JOIN quantity_unit_conversions_resolved qucr + ON IFNULL(pcs.product_id_effective, rp.product_id) = qucr.product_id + AND rp.qu_id = qucr.from_qu_id + AND IFNULL(p_effective.qu_id_stock, p.qu_id_stock) = qucr.to_qu_id +WHERE rp.not_check_stock_fulfillment = 0 + +UNION + +-- Just add all recipe positions which should not be checked against stock with fulfilled need + +SELECT + r.id AS recipe_id, + rp.id AS recipe_pos_id, + rp.product_id AS product_id, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END AS recipe_amount, + IFNULL(sc.amount_aggregated, 0) AS stock_amount, + 1 AS need_fulfilled, + 0 AS missing_amount, + IFNULL(sl.amount, 0) AS amount_on_shopping_list, + 1 AS need_fulfilled_with_shopping_list, + rp.qu_id, + (r.desired_servings*1.0 / r.base_servings*1.0) * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * rp.amount * IFNULL(pcp.price, 0) * rp.price_factor * CASE WHEN rp.only_check_single_unit_in_stock = 1 OR rp.product_id != p_effective.id THEN IFNULL(qucr.factor, 1) ELSE 1 END AS costs, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN 0 ELSE 1 END AS is_nested_recipe_pos, + rp.ingredient_group, + pg.name as product_group, + rp.id, -- Just a dummy id column + r.type as recipe_type, + rnr.includes_recipe_id as child_recipe_id, + rp.note, + rp.variable_amount AS recipe_variable_amount, + rp.only_check_single_unit_in_stock, + rp.amount / r.base_servings*1.0 * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * IFNULL(p_effective.calories, 0) * CASE WHEN rp.only_check_single_unit_in_stock = 1 OR rp.product_id != p_effective.id THEN IFNULL(qucr.factor, 1) ELSE 1 END AS calories, + p.active AS product_active, + CASE pvs.current_due_status + WHEN 'ok' THEN 0 + WHEN 'due_soon' THEN 1 + WHEN 'overdue' THEN 10 + WHEN 'expired' THEN 20 + END AS due_score, + IFNULL(pcs.product_id_effective, rp.product_id) AS product_id_effective, + p.name AS product_name +FROM recipes r +JOIN recipes_nestings_resolved rnr + ON r.id = rnr.recipe_id +JOIN recipes rnrr + ON rnr.includes_recipe_id = rnrr.id +JOIN recipes_pos rp + ON rnr.includes_recipe_id = rp.recipe_id +JOIN products p + ON rp.product_id = p.id +JOIN products_volatile_status pvs + ON rp.product_id = pvs.product_id +LEFT JOIN product_groups pg + ON p.product_group_id = pg.id +LEFT JOIN ( + SELECT product_id, SUM(amount) AS amount + FROM shopping_list + GROUP BY product_id) sl + ON rp.product_id = sl.product_id +LEFT JOIN stock_current sc + ON rp.product_id = sc.product_id +LEFT JOIN products_current_substitutions pcs + ON rp.product_id = pcs.parent_product_id +LEFT JOIN products_current_price pcp + ON IFNULL(pcs.product_id_effective, rp.product_id) = pcp.product_id +LEFT JOIN products p_effective + ON IFNULL(pcs.product_id_effective, rp.product_id) = p_effective.id +LEFT JOIN quantity_unit_conversions_resolved qucr + ON IFNULL(pcs.product_id_effective, rp.product_id) = qucr.product_id + AND rp.qu_id = qucr.from_qu_id + AND IFNULL(p_effective.qu_id_stock, p.qu_id_stock) = qucr.to_qu_id +WHERE rp.not_check_stock_fulfillment = 1;