Optimize recipe ingredient costs/calories calculation when only_check_single_unit_in_stock is used (closes #780)

This commit is contained in:
Bernd Bestel 2022-12-26 19:48:26 +01:00
parent 3f2ad17460
commit 76500c57bd
No known key found for this signature in database
GPG Key ID: 71BD34C0D4891300
3 changed files with 137 additions and 1 deletions

View File

@ -18,6 +18,7 @@
- Will be used/selected as the default quantity unit on the consume page
- The product's "Quick consume amount" is now displayed related to this quantity unit ("quick consume/open buttons" on the stock overview page)
- Defaults to the product's "Quantity unit stock" (so no changed behavior when not configured)
- Changed that when the ingredient option "Only check if any amount is in stock" is enabled, costs and calories are now based on the original entered amount instead of an "virtual" fixed amount of `1`
- Fixed that hiding the "Purchased date" column (table options) on the stock entries page didn't work
- Fixed that the consumed amount was wrong, when consuming multiple substituted subproducts at once and when multiple/different conversion factors were involved

135
migrations/0211.sql Normal file
View File

@ -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 * IFNULL(qucr.factor, 1) 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) * IFNULL(qucr.factor, 1) 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 CASE WHEN rp.product_id != p_effective.id THEN p.qu_id_stock ELSE rp.qu_id END = 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 * IFNULL(qucr.factor, 1) 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) * IFNULL(qucr.factor, 1) 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 CASE WHEN rp.product_id != p_effective.id THEN p.qu_id_stock ELSE rp.qu_id END = 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;

View File

@ -519,7 +519,7 @@
<i class="fa-solid fa-exchange-alt"></i> {{ FindObjectInArrayByPropertyValue($products, 'id', $selectedRecipePosition->product_id_effective)->name }}
</span>
@endif
@if($selectedRecipePosition->need_fulfilled == 1 && GROCY_FEATURE_FLAG_STOCK_PRICE_TRACKING) <span class="float-right font-italic ml-2 locale-number locale-number-currency">{{ $selectedRecipePosition->costs }}</span> @endif
@if(GROCY_FEATURE_FLAG_STOCK_PRICE_TRACKING) <span class="float-right font-italic ml-2 locale-number locale-number-currency">{{ $selectedRecipePosition->costs }}</span> @endif
<span class="float-right font-italic"><span class="locale-number locale-number-generic">{{ $selectedRecipePosition->calories }}</span> {{ $__t('Calories') }}</span>
@if(!empty($selectedRecipePosition->recipe_variable_amount))
<div class="small text-muted font-italic">{{ $__t('Variable amount') }}</div>