grocy/migrations/0179.sql

171 lines
7.7 KiB
SQL

CREATE VIEW stock_next_use
AS
/*
The default consume rule is:
Opened first, then first due first, then first in first out
This orders the stock entries by that
=> Highest "priority" per product = the stock entry to use next
*/
SELECT
-1 AS id, -- Dummy
(ROW_NUMBER() OVER(PARTITION BY product_id ORDER BY open DESC, best_before_date ASC, purchased_date ASC)) * -1 AS priority,
product_id,
stock_id,
price
FROM stock;
CREATE VIEW products_current_price
AS
/*
Current price per product,
based on the stock entry to use next,
or on the last price if the product is currently not in stock
*/
SELECT
-1 AS id, -- Dummy,
p.id AS product_id,
IFNULL(snu.price, plp.price) AS price
FROM products p
LEFT JOIN (
SELECT
product_id,
MAX(priority),
price -- Bare column, ref https://www.sqlite.org/lang_select.html#bare_columns_in_an_aggregate_query
FROM stock_next_use
GROUP BY product_id
) snu
ON p.id = snu.product_id
LEFT JOIN products_last_purchased plp
ON p.id = plp.product_id;
DROP VIEW products_oldest_stock_unit_price;
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.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
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_price pcp
ON rp.product_id = pcp.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
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.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
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_price pcp
ON rp.product_id = pcp.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
WHERE rp.not_check_stock_fulfillment = 1;