mirror of
https://github.com/grocy/grocy.git
synced 2025-04-29 01:32:38 +00:00
285 lines
13 KiB
SQL
285 lines
13 KiB
SQL
CREATE TABLE cache__quantity_unit_conversions_resolved (
|
|
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE,
|
|
product_id INT,
|
|
from_qu_id INT,
|
|
from_qu_name TEXT,
|
|
from_qu_name_plural TEXT,
|
|
to_qu_id INT,
|
|
to_qu_name TEXT,
|
|
to_qu_name_plural TEXT,
|
|
factor TEXT,
|
|
path TEXT
|
|
);
|
|
|
|
INSERT INTO cache__quantity_unit_conversions_resolved
|
|
(product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path)
|
|
SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path
|
|
FROM quantity_unit_conversions_resolved;
|
|
|
|
CREATE INDEX ix_cache__quantity_unit_conversions_resolved_performance1 ON cache__quantity_unit_conversions_resolved (
|
|
product_id,
|
|
from_qu_id,
|
|
to_qu_id
|
|
);
|
|
|
|
DROP TRIGGER qu_conversions_inverse_INS;
|
|
CREATE TRIGGER quantity_unit_conversions_INS AFTER INSERT ON quantity_unit_conversions
|
|
BEGIN
|
|
-- Create the inverse QU conversion
|
|
INSERT OR REPLACE INTO quantity_unit_conversions
|
|
(from_qu_id, to_qu_id, factor, product_id)
|
|
VALUES
|
|
(NEW.to_qu_id, NEW.from_qu_id, 1 / IFNULL(NEW.factor, 1), NEW.product_id);
|
|
|
|
-- Update quantity_unit_conversions_resolved cache
|
|
DELETE FROM cache__quantity_unit_conversions_resolved
|
|
WHERE path LIKE '%/' || NEW.to_qu_id || '/%'
|
|
OR path LIKE '%/' || NEW.from_qu_id || '/%';
|
|
|
|
INSERT INTO cache__quantity_unit_conversions_resolved
|
|
(product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path)
|
|
SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path
|
|
FROM quantity_unit_conversions_resolved
|
|
WHERE path LIKE '%/' || NEW.to_qu_id || '/%'
|
|
OR path LIKE '%/' || NEW.from_qu_id || '/%';
|
|
END;
|
|
|
|
DROP TRIGGER qu_conversions_inverse_UPD;
|
|
CREATE TRIGGER quantity_unit_conversions_UPD AFTER UPDATE ON quantity_unit_conversions
|
|
BEGIN
|
|
-- Update the inverse QU conversion
|
|
UPDATE quantity_unit_conversions
|
|
SET factor = 1 / IFNULL(NEW.factor, 1),
|
|
from_qu_id = NEW.to_qu_id,
|
|
to_qu_id = NEW.from_qu_id
|
|
WHERE from_qu_id = OLD.to_qu_id
|
|
AND to_qu_id = OLD.from_qu_id
|
|
AND IFNULL(product_id, -1) = IFNULL(NEW.product_id, -1);
|
|
|
|
-- Update quantity_unit_conversions_resolved cache
|
|
DELETE FROM cache__quantity_unit_conversions_resolved
|
|
WHERE path LIKE '%/' || NEW.to_qu_id || '/%'
|
|
OR path LIKE '%/' || NEW.from_qu_id || '/%';
|
|
|
|
INSERT INTO cache__quantity_unit_conversions_resolved
|
|
(product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path)
|
|
SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path
|
|
FROM quantity_unit_conversions_resolved
|
|
WHERE path LIKE '%/' || NEW.to_qu_id || '/%'
|
|
OR path LIKE '%/' || NEW.from_qu_id || '/%';
|
|
END;
|
|
|
|
DROP TRIGGER qu_conversions_inverse_DEL;
|
|
CREATE TRIGGER quantity_unit_conversions_DEL AFTER DELETE ON quantity_unit_conversions
|
|
BEGIN
|
|
-- Delete the inverse QU conversion
|
|
DELETE FROM quantity_unit_conversions
|
|
WHERE from_qu_id = OLD.to_qu_id
|
|
AND to_qu_id = OLD.from_qu_id
|
|
AND IFNULL(product_id, -1) = IFNULL(OLD.product_id, -1);
|
|
|
|
-- Update quantity_unit_conversions_resolved cache
|
|
DELETE FROM cache__quantity_unit_conversions_resolved
|
|
WHERE path LIKE '%/' || OLD.to_qu_id || '/%'
|
|
OR path LIKE '%/' || OLD.from_qu_id || '/%';
|
|
|
|
INSERT INTO cache__quantity_unit_conversions_resolved
|
|
(product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path)
|
|
SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path
|
|
FROM quantity_unit_conversions_resolved
|
|
WHERE path LIKE '%/' || OLD.to_qu_id || '/%'
|
|
OR path LIKE '%/' || OLD.from_qu_id || '/%';
|
|
END;
|
|
|
|
CREATE TRIGGER products_INS AFTER INSERT ON products
|
|
BEGIN
|
|
-- Update quantity_unit_conversions_resolved cache
|
|
DELETE FROM cache__quantity_unit_conversions_resolved
|
|
WHERE product_id = NEW.id;
|
|
|
|
INSERT INTO cache__quantity_unit_conversions_resolved
|
|
(product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path)
|
|
SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path
|
|
FROM quantity_unit_conversions_resolved
|
|
WHERE product_id = NEW.id;
|
|
END;
|
|
|
|
CREATE TRIGGER products_UPD AFTER UPDATE ON products
|
|
BEGIN
|
|
-- Update quantity_unit_conversions_resolved cache
|
|
DELETE FROM cache__quantity_unit_conversions_resolved
|
|
WHERE product_id = NEW.id;
|
|
|
|
INSERT INTO cache__quantity_unit_conversions_resolved
|
|
(product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path)
|
|
SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path
|
|
FROM quantity_unit_conversions_resolved
|
|
WHERE product_id = NEW.id;
|
|
END;
|
|
|
|
CREATE TRIGGER products_DELETE AFTER DELETE ON products
|
|
BEGIN
|
|
-- Update quantity_unit_conversions_resolved cache
|
|
DELETE FROM cache__quantity_unit_conversions_resolved
|
|
WHERE product_id = OLD.id;
|
|
END;
|
|
|
|
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 cache__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 cache__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;
|
|
|
|
DROP VIEW products_view;
|
|
CREATE VIEW products_view
|
|
AS
|
|
SELECT
|
|
p.*,
|
|
CASE WHEN (SELECT 1 FROM products WHERE parent_product_id = p.id) NOTNULL THEN 1 ELSE 0 END AS has_sub_products,
|
|
IFNULL(quc_purchase.factor, 1.0) AS qu_factor_purchase_to_stock,
|
|
IFNULL(quc_consume.factor, 1.0) AS qu_factor_consume_to_stock,
|
|
IFNULL(quc_price.factor, 1.0) AS qu_factor_price_to_stock
|
|
FROM products p
|
|
LEFT JOIN cache__quantity_unit_conversions_resolved quc_purchase
|
|
ON p.id = quc_purchase.product_id
|
|
AND p.qu_id_purchase = quc_purchase.from_qu_id
|
|
AND p.qu_id_stock = quc_purchase.to_qu_id
|
|
LEFT JOIN cache__quantity_unit_conversions_resolved quc_consume
|
|
ON p.id = quc_consume.product_id
|
|
AND p.qu_id_consume = quc_consume.from_qu_id
|
|
AND p.qu_id_stock = quc_consume.to_qu_id
|
|
LEFT JOIN cache__quantity_unit_conversions_resolved quc_price
|
|
ON p.id = quc_price.product_id
|
|
AND p.qu_id_price = quc_price.from_qu_id
|
|
AND p.qu_id_stock = quc_price.to_qu_id;
|