mirror of
https://github.com/grocy/grocy.git
synced 2025-04-29 17:45:39 +00:00
173 lines
8.5 KiB
SQL
173 lines
8.5 KiB
SQL
CREATE VIEW products_current_substitutions
|
|
AS
|
|
|
|
/*
|
|
When a parent product is not in-stock itself,
|
|
any sub product (the next based on the default consume rule) should be used
|
|
|
|
This view lists all parent products and in the column "product_id_effective" either itself,
|
|
when the corresponding parent product is currently in-stock itself, or otherwise the next sub product to use
|
|
*/
|
|
|
|
SELECT
|
|
-1, -- Dummy
|
|
p_sub.id AS parent_product_id,
|
|
CASE WHEN p_sub.has_sub_products = 1 THEN
|
|
CASE WHEN IFNULL(sc.amount, 0) = 0 THEN -- Parent product itself is currently not in stock => use the next sub product
|
|
(
|
|
SELECT x_snu.product_id
|
|
FROM products_resolved x_pr
|
|
JOIN stock_next_use x_snu
|
|
ON x_pr.sub_product_id = x_snu.product_id
|
|
WHERE x_pr.parent_product_id = p_sub.id
|
|
AND x_pr.parent_product_id != x_pr.sub_product_id
|
|
ORDER BY x_snu.priority DESC
|
|
LIMIT 1
|
|
)
|
|
ELSE -- Parent product itself is currently in stock => use it
|
|
p_sub.id
|
|
END
|
|
END AS product_id_effective
|
|
FROM products_view p
|
|
JOIN products_resolved pr
|
|
ON p.id = pr.parent_product_id
|
|
JOIN products_view p_sub
|
|
ON pr.sub_product_id = p_sub.id
|
|
JOIN stock_current sc
|
|
ON p_sub.id = sc.product_id
|
|
WHERE p_sub.has_sub_products = 1;
|
|
|
|
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) * p.qu_factor_purchase_to_stock 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 * p.qu_factor_purchase_to_stock), 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 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 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
|
|
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 quantity_unit_conversions_resolved qucr
|
|
ON rp.product_id = qucr.product_id
|
|
AND rp.qu_id = qucr.from_qu_id
|
|
AND p.qu_id_stock = qucr.to_qu_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
|
|
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) * p.qu_factor_purchase_to_stock 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 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 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
|
|
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 quantity_unit_conversions_resolved qucr
|
|
ON rp.product_id = qucr.product_id
|
|
AND rp.qu_id = qucr.from_qu_id
|
|
AND p.qu_id_stock = qucr.to_qu_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
|
|
WHERE rp.not_check_stock_fulfillment = 1;
|