Cache expensive stock data calculations

This commit is contained in:
Bernd Bestel
2023-08-06 13:28:14 +02:00
parent 7689356a57
commit 1d7f7b2992
8 changed files with 527 additions and 32 deletions

View File

@@ -115,7 +115,6 @@ AS (
JOIN default_conversions s
ON c.path LIKE ('%/' || s.from_qu_id || '/' || s.to_qu_id || '/%') -- the conversion has been used as part of another path ...
WHERE NOT EXISTS(SELECT 1 FROM conversion_factors ci WHERE ci.product_id = c.product_id AND ci.from_qu_id = s.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- ... and is itself new
)
SELECT DISTINCT
@@ -135,6 +134,5 @@ JOIN quantity_units qu_from
JOIN quantity_units qu_to
ON c.to_qu_id = qu_to.id
GROUP BY product_id, from_qu_id, to_qu_id
WINDOW win
AS (PARTITION BY product_id, from_qu_id, to_qu_id ORDER BY depth ASC)
ORDER BY product_id, from_qu_id, to_qu_id;
WINDOW win AS (PARTITION BY product_id, from_qu_id, to_qu_id ORDER BY depth ASC)
ORDER BY product_id, from_qu_id, to_qu_id;

284
migrations/0225.sql Normal file
View File

@@ -0,0 +1,284 @@
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;

213
migrations/0226.sql Normal file
View File

@@ -0,0 +1,213 @@
CREATE TABLE cache__products_average_price (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE,
product_id INT,
price DECIMAL(15, 2),
UNIQUE(product_id)
);
INSERT INTO cache__products_average_price
(product_id, price)
SELECT product_id, price
FROM products_average_price;
CREATE TABLE cache__products_last_purchased (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE,
product_id INT,
amount DECIMAL(15, 2),
best_before_date DATE,
purchased_date DATE,
price DECIMAL(15, 2),
location_id INT,
shopping_location_id INT,
UNIQUE(product_id)
);
INSERT INTO cache__products_last_purchased
(product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id)
SELECT product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id
FROM products_last_purchased;
CREATE TRIGGER stock_log_INS AFTER INSERT ON stock_log
BEGIN
INSERT OR REPLACE INTO cache__products_average_price
(product_id, price)
SELECT product_id, price
FROM products_average_price
WHERE product_id = NEW.product_id;
-- Update products_last_purchased cache
INSERT OR REPLACE INTO cache__products_last_purchased
(product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id)
SELECT product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id
FROM products_last_purchased
WHERE product_id = NEW.product_id;
END;
CREATE TRIGGER stock_log_UPD AFTER UPDATE ON stock_log
BEGIN
-- Update products_average_price cache
INSERT OR REPLACE INTO cache__products_average_price
(product_id, price)
SELECT product_id, price
FROM products_average_price
WHERE product_id = NEW.product_id;
-- Update products_last_purchased cache
INSERT OR REPLACE INTO cache__products_last_purchased
(product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id)
SELECT product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id
FROM products_last_purchased
WHERE product_id = NEW.product_id;
END;
CREATE TRIGGER stock_log_DEL AFTER DELETE ON stock_log
BEGIN
-- Update products_average_price cache
DELETE FROM cache__products_average_price
WHERE product_id = OLD.id;
-- Update products_last_purchased cache
DELETE FROM cache__products_last_purchased
WHERE product_id = OLD.id;
END;
DROP VIEW uihelper_stock_current_overview;
CREATE VIEW uihelper_stock_current_overview
AS
SELECT
p.id,
sc.amount_opened AS amount_opened,
p.tare_weight AS tare_weight,
p.enable_tare_weight_handling AS enable_tare_weight_handling,
sc.amount AS amount,
sc.value as value,
sc.product_id AS product_id,
sc.best_before_date AS best_before_date,
EXISTS(SELECT id FROM stock_missing_products WHERE id = sc.product_id) AS product_missing,
p.name AS product_name,
pg.name AS product_group_name,
EXISTS(SELECT * FROM shopping_list WHERE shopping_list.product_id = sc.product_id) AS on_shopping_list,
qu_stock.name AS qu_stock_name,
qu_stock.name_plural AS qu_stock_name_plural,
qu_purchase.name AS qu_purchase_name,
qu_purchase.name_plural AS qu_purchase_name_plural,
qu_consume.name AS qu_consume_name,
qu_consume.name_plural AS qu_consume_name_plural,
qu_price.name AS qu_price_name,
qu_price.name_plural AS qu_price_name_plural,
sc.is_aggregated_amount,
sc.amount_opened_aggregated,
sc.amount_aggregated,
p.calories AS product_calories,
sc.amount * p.calories AS calories,
sc.amount_aggregated * p.calories AS calories_aggregated,
p.quick_consume_amount,
p.quick_consume_amount / p.qu_factor_consume_to_stock AS quick_consume_amount_qu_consume,
p.quick_open_amount,
p.quick_open_amount / p.qu_factor_consume_to_stock AS quick_open_amount_qu_consume,
p.due_type,
plp.purchased_date AS last_purchased,
plp.price AS last_price,
pap.price as average_price,
p.min_stock_amount,
pbcs.barcodes AS product_barcodes,
p.description AS product_description,
l.name AS product_default_location_name,
p_parent.id AS parent_product_id,
p_parent.name AS parent_product_name,
p.picture_file_name AS product_picture_file_name,
p.no_own_stock AS product_no_own_stock,
p.qu_factor_purchase_to_stock AS product_qu_factor_purchase_to_stock,
p.qu_factor_price_to_stock AS product_qu_factor_price_to_stock
FROM (
SELECT *
FROM stock_current
WHERE best_before_date IS NOT NULL
UNION
SELECT m.id, 0, 0, 0, null, 0, 0, 0, p.due_type
FROM stock_missing_products m
JOIN products p
ON m.id = p.id
WHERE m.id NOT IN (SELECT product_id FROM stock_current)
) sc
JOIN products_view p
ON sc.product_id = p.id
JOIN locations l
ON p.location_id = l.id
JOIN quantity_units qu_stock
ON p.qu_id_stock = qu_stock.id
JOIN quantity_units qu_purchase
ON p.qu_id_purchase = qu_purchase.id
JOIN quantity_units qu_consume
ON p.qu_id_consume = qu_consume.id
JOIN quantity_units qu_price
ON p.qu_id_price = qu_price.id
LEFT JOIN product_groups pg
ON p.product_group_id = pg.id
LEFT JOIN cache__products_last_purchased plp
ON sc.product_id = plp.product_id
LEFT JOIN cache__products_average_price pap
ON sc.product_id = pap.product_id
LEFT JOIN product_barcodes_comma_separated pbcs
ON sc.product_id = pbcs.product_id
LEFT JOIN products p_parent
ON p.parent_product_id = p_parent.id
WHERE p.hide_on_stock_overview = 0;
DROP VIEW uihelper_shopping_list;
CREATE VIEW uihelper_shopping_list
AS
SELECT
sl.*,
p.name AS product_name,
plp.price AS last_price_unit,
plp.price * sl.amount AS last_price_total,
st.name AS default_shopping_location_name,
qu.name AS qu_name,
qu.name_plural AS qu_name_plural,
pg.id AS product_group_id,
pg.name AS product_group_name,
pbcs.barcodes AS product_barcodes
FROM shopping_list sl
LEFT JOIN products p
ON sl.product_id = p.id
LEFT JOIN cache__products_last_purchased plp
ON sl.product_id = plp.product_id
LEFT JOIN shopping_locations st
ON p.shopping_location_id = st.id
LEFT JOIN quantity_units qu
ON sl.qu_id = qu.id
LEFT JOIN product_groups pg
ON p.product_group_id = pg.id
LEFT JOIN product_barcodes_comma_separated pbcs
ON sl.product_id = pbcs.product_id;
DROP VIEW products_current_price;
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
ORDER BY priority DESC, open DESC, best_before_date ASC, purchased_date ASC
) snu
ON p.id = snu.product_id
LEFT JOIN cache__products_last_purchased plp
ON p.id = plp.product_id;