ALTER TABLE products ADD parent_product_id INT; CREATE VIEW products_resolved AS SELECT p.parent_product_id parent_product_id, p.id as sub_product_id FROM products p WHERE p.parent_product_id IS NOT NULL UNION SELECT p.id parent_product_id, p.id as sub_product_id FROM products p WHERE p.parent_product_id IS NULL; DROP VIEW stock_current; CREATE VIEW stock_current AS SELECT pr.parent_product_id AS product_id, IFNULL((SELECT SUM(amount) FROM stock WHERE product_id = pr.parent_product_id), 0) AS amount, SUM(s.amount) AS amount_aggregated, MIN(s.best_before_date) AS best_before_date, IFNULL((SELECT SUM(amount) FROM stock WHERE product_id = pr.parent_product_id AND open = 1), 0) AS amount_opened, IFNULL((SELECT SUM(amount) FROM stock WHERE product_id IN (SELECT sub_product_id FROM products_resolved WHERE parent_product_id = pr.parent_product_id) AND open = 1), 0) AS amount_opened_aggregated, CASE WHEN p.parent_product_id IS NOT NULL THEN 1 ELSE 0 END AS is_aggregated_amount FROM products_resolved pr JOIN stock s ON pr.sub_product_id = s.product_id JOIN products p ON pr.sub_product_id = p.id GROUP BY pr.parent_product_id HAVING SUM(s.amount) > 0 UNION -- This is the same as above but sub products not rolled up (column is_aggregated_amount = 0 here) SELECT pr.sub_product_id AS product_id, SUM(s.amount) AS amount, SUM(s.amount) AS amount_aggregated, MIN(s.best_before_date) AS best_before_date, IFNULL((SELECT SUM(amount) FROM stock WHERE product_id = s.product_id AND open = 1), 0) AS amount_opened, IFNULL((SELECT SUM(amount) FROM stock WHERE product_id = s.product_id AND open = 1), 0) AS amount_opened_aggregated, 0 AS is_aggregated_amount FROM products_resolved pr JOIN stock s ON pr.sub_product_id = s.product_id WHERE pr.parent_product_id != pr.sub_product_id GROUP BY pr.sub_product_id HAVING SUM(s.amount) > 0; DROP VIEW stock_missing_products; CREATE VIEW stock_missing_products AS SELECT p.id, MAX(p.name) AS name, p.min_stock_amount - IFNULL(SUM(s.amount), 0) AS amount_missing, CASE WHEN IFNULL(SUM(s.amount), 0) > 0 THEN 1 ELSE 0 END AS is_partly_in_stock FROM products p LEFT JOIN stock_current s ON p.id = s.product_id WHERE p.min_stock_amount != 0 GROUP BY p.id HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount; 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, rp.amount * (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) 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 1 ELSE rp.amount * (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) 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 1 ELSE rp.amount * (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) END < 0 THEN ABS(IFNULL(sc.amount_aggregated, 0) - (CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 1 ELSE rp.amount * (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) END)) ELSE 0 END AS missing_amount, IFNULL(sl.amount, 0) * p.qu_factor_purchase_to_stock AS amount_on_shopping_list, CASE WHEN 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) >= CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 1 ELSE rp.amount * (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) END THEN 1 ELSE 0 END AS need_fulfilled_with_shopping_list, rp.qu_id, (CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 1 ELSE rp.amount * (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) END / p.qu_factor_purchase_to_stock) * pcp.last_price AS costs, CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN 0 ELSE 1 END AS is_nested_recipe_pos, rp.ingredient_group, rp.id, -- Just a dummy id column rnr.includes_recipe_id as child_recipe_id, rp.note, rp.variable_amount AS recipe_variable_amount, rp.only_check_single_unit_in_stock 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 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_price pcp ON rp.product_id = pcp.product_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, rp.amount * (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) 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, (CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 1 ELSE rp.amount * (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) END / p.qu_factor_purchase_to_stock) * pcp.last_price AS costs, CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN 0 ELSE 1 END AS is_nested_recipe_pos, rp.ingredient_group, rp.id, -- Just a dummy id column rnr.includes_recipe_id as child_recipe_id, rp.note, rp.variable_amount AS recipe_variable_amount, rp.only_check_single_unit_in_stock 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 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_price pcp ON rp.product_id = pcp.product_id WHERE rp.not_check_stock_fulfillment = 1;