Qu factor purchase to stock & Product Barcode Details (#801)

* Puchase add qu_factor_to_stock

* qu_factor_purchase_to_stock for stock edit

* product barcodes with QU and Stores

* remove product barcode tags

* migrations/0103 add value and factor_puchase_amount to stock_current and stock_current_location_content

* Remove unused method

* StockService#GetProductDetails: include stock_value

* productcard: include stock_value

* Add Purchase Factor to Stock Overview

* update demo data with stock qu_factor_purchase_to_stock

* recipes_pos_resolved update

* avg_price and oldest_price in product details

* add average price to product card

* hint for recipe costs not included if not in stock

* Round value and factor_purchas_amount. Include currency for stock value

* Add factor_purchase_amount to product card stock amount

* Allow editing qu_factor_purchase_to_stock for stock entries

* fix update qu_factor_purchase_to_stock for Transfers

* Add barcode to existing product update to add to product_barcodes table

* Add barcode to new product workflow update to add to product_barcodes table

* *** Price now saved as 1 QU to stock in stock tables ***

* remove column product barcode and use product_barcodes

* Allow products to be deactivated instead of deleted

* Embedded barcode and qu-conversion with page reload on change

* Save current product barcode into new product_barcodes table

* Embedded popup for product group add/edit

* barcode scanner added to product barcodes input

* Edit product qu_stock is unavailable after first purchase

* StockOverview: Filters break when columns are reordered so for now just disable colReorder

* view stockoverview.blade: display product_group column

* Review

Co-authored-by: Bernd Bestel <bernd@berrnd.de>
This commit is contained in:
kriddles
2020-08-17 14:47:33 -05:00
committed by GitHub
parent d1e395b45e
commit e8845fe2e8
40 changed files with 1216 additions and 266 deletions

171
migrations/0103.sql Normal file
View File

@@ -0,0 +1,171 @@
ALTER TABLE stock_log
ADD qu_factor_purchase_to_stock REAL NOT NULL DEFAULT 1.0;
ALTER TABLE stock
ADD qu_factor_purchase_to_stock REAL NOT NULL DEFAULT 1.0;
UPDATE stock
SET qu_factor_purchase_to_stock = (SELECT qu_factor_purchase_to_stock FROM products WHERE product_id = id);
UPDATE stock_log
SET qu_factor_purchase_to_stock = (SELECT qu_factor_purchase_to_stock FROM products WHERE product_id = id);
--Price is now going forward to be saved as 1 QU Stock
UPDATE stock
SET price = ROUND(price / qu_factor_purchase_to_stock, 2);
UPDATE stock_log
SET price = ROUND(price / qu_factor_purchase_to_stock, 2);
CREATE TABLE product_barcodes (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE,
product_id INT NOT NULL,
barcode TEXT NOT NULL UNIQUE,
qu_factor_purchase_to_stock REAL NOT NULL DEFAULT 1,
shopping_location_id INTEGER,
row_created_timestamp DATETIME DEFAULT (datetime('now', 'localtime'))
);
-- Convert product table to new product_barcodes table
INSERT INTO product_barcodes
(product_id, barcode, qu_factor_purchase_to_stock, shopping_location_id)
WITH barcodes_splitted(id, barcode, str, qu_factor_purchase_to_stock, shopping_location_id) AS (
SELECT id as product_id, '', barcode || ',', qu_factor_purchase_to_stock, shopping_location_id
FROM products
UNION ALL
SELECT
id as product_id,
SUBSTR(str, 0, instr(str, ',')),
SUBSTR(str, instr(str, ',') + 1),
qu_factor_purchase_to_stock,
shopping_location_id
FROM barcodes_splitted
WHERE str != ''
)
SELECT id as product_id, barcode, qu_factor_purchase_to_stock, shopping_location_id
FROM barcodes_splitted
WHERE barcode != '';
PRAGMA legacy_alter_table = ON;
ALTER TABLE products RENAME TO products_old;
-- Remove barcode column
-- Reorder columns
CREATE TABLE products (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE,
name TEXT NOT NULL UNIQUE,
description TEXT,
product_group_id INTEGER,
active TINYINT NOT NULL DEFAULT 1,
location_id INTEGER NOT NULL,
shopping_location_id INTEGER,
qu_id_purchase INTEGER NOT NULL,
qu_id_stock INTEGER NOT NULL,
qu_factor_purchase_to_stock REAL NOT NULL,
min_stock_amount INTEGER NOT NULL DEFAULT 0,
default_best_before_days INTEGER NOT NULL DEFAULT 0,
default_best_before_days_after_open INTEGER NOT NULL DEFAULT 0,
default_best_before_days_after_freezing INTEGER NOT NULL DEFAULT 0,
default_best_before_days_after_thawing INTEGER NOT NULL DEFAULT 0,
picture_file_name TEXT,
allow_partial_units_in_stock TINYINT NOT NULL DEFAULT 0,
enable_tare_weight_handling TINYINT NOT NULL DEFAULT 0,
tare_weight REAL NOT NULL DEFAULT 0,
not_check_stock_fulfillment_for_recipes TINYINT DEFAULT 0,
parent_product_id INT,
calories INTEGER,
cumulate_min_stock_amount_of_sub_products TINYINT DEFAULT 0,
row_created_timestamp DATETIME DEFAULT (datetime('now', 'localtime'))
);
INSERT INTO products
(id, name, description, location_id, qu_id_purchase, qu_id_stock, qu_factor_purchase_to_stock, min_stock_amount, default_best_before_days, row_created_timestamp, product_group_id, picture_file_name, default_best_before_days_after_open, allow_partial_units_in_stock, enable_tare_weight_handling, tare_weight, not_check_stock_fulfillment_for_recipes, parent_product_id, calories, cumulate_min_stock_amount_of_sub_products, default_best_before_days_after_freezing, default_best_before_days_after_thawing, shopping_location_id)
SELECT id, name, description, location_id, qu_id_purchase, qu_id_stock, qu_factor_purchase_to_stock, min_stock_amount,default_best_before_days, row_created_timestamp, product_group_id, picture_file_name, default_best_before_days_after_open, allow_partial_units_in_stock, enable_tare_weight_handling, tare_weight, not_check_stock_fulfillment_for_recipes, parent_product_id, calories, cumulate_min_stock_amount_of_sub_products, default_best_before_days_after_freezing, default_best_before_days_after_thawing, shopping_location_id
FROM products_old;
DROP TABLE products_old;
DROP VIEW stock_current_location_content;
CREATE VIEW stock_current_location_content
AS
SELECT
IFNULL(s.location_id, p.location_id) AS location_id,
s.product_id,
SUM(s.amount) AS amount,
ROUND(SUM(s.amount / s.qu_factor_purchase_to_stock),2) as factor_purchase_amount,
ROUND(SUM(IFNULL(s.price, 0) * s.amount), 2) AS value,
MIN(s.best_before_date) AS best_before_date,
IFNULL((SELECT SUM(amount) FROM stock WHERE product_id = s.product_id AND location_id = s.location_id AND open = 1), 0) AS amount_opened
FROM stock s
JOIN products p
ON s.product_id = p.id
AND p.active = 1
GROUP BY IFNULL(s.location_id, p.location_id), s.product_id;
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,
IFNULL(ROUND((SELECT SUM(amount / qu_factor_purchase_to_stock) FROM stock WHERE product_id = pr.parent_product_id), 2), 0) as factor_purchase_amount,
SUM(s.amount) * IFNULL(qucr.factor, 1) AS amount_aggregated,
IFNULL(ROUND((SELECT SUM(IFNULL(price,0) * amount) FROM stock WHERE product_id = pr.parent_product_id), 2), 0) AS value,
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) * IFNULL(qucr.factor, 1) AS amount_opened_aggregated,
CASE WHEN p_sub.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_parent
ON pr.parent_product_id = p_parent.id
AND p_parent.active = 1
JOIN products p_sub
ON pr.sub_product_id = p_sub.id
AND p_sub.active = 1
LEFT JOIN quantity_unit_conversions_resolved qucr
ON pr.sub_product_id = qucr.product_id
AND p_sub.qu_id_stock = qucr.from_qu_id
AND p_parent.qu_id_stock = qucr.to_qu_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 (no QU conversion and column is_aggregated_amount = 0 here)
SELECT
pr.sub_product_id AS product_id,
SUM(s.amount) AS amount,
ROUND(SUM(s.amount / s.qu_factor_purchase_to_stock), 2) as factor_purchase_amount,
SUM(s.amount) AS amount_aggregated,
ROUND(SUM(IFNULL(s.price, 0) * s.amount), 2) AS value,
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 products_resolved;
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
AND p.active = 1
UNION
SELECT
p.id parent_product_id,
p.id as sub_product_id
FROM products p
WHERE p.parent_product_id IS NULL
AND p.active = 1;

185
migrations/0104.sql Normal file
View File

@@ -0,0 +1,185 @@
-- Deprecate unused view to instead use products_last_purchased
DROP VIEW products_current_price;
CREATE VIEW products_last_purchased
AS
select
1 AS id, -- Dummy, LessQL needs an id column
sl.product_id,
sl.amount,
sl.best_before_date,
sl.purchased_date,
sl.price,
sl.qu_factor_purchase_to_stock,
sl.location_id,
sl.shopping_location_id
from stock_log sl
JOIN (
SELECT
s1.product_id,
MAX(s1.id) max_stock_id
FROM stock_log s1
JOIN (
SELECT
s.product_id,
MAX(s.purchased_date) max_purchased_date
FROM stock_log s
WHERE undone = 0
AND transaction_type in ('purchase', 'stock-edit-new', 'inventory-correction')
GROUP BY s.product_id) sp2
ON s1.product_id = sp2.product_id
AND s1.purchased_date = sp2.max_purchased_date
WHERE undone = 0
AND transaction_type in ('purchase', 'stock-edit-new', 'inventory-correction')
GROUP BY s1.product_id) sp3
ON sl.product_id = sp3.product_id
AND sl.id = sp3.max_stock_id;
CREATE VIEW products_average_price
AS
SELECT
1 AS id, -- Dummy, LessQL needs an id column
s.product_id,
round(sum(s.amount * s.price) / sum(s.amount), 2) as price
FROM stock s
GROUP BY s.product_id;
CREATE VIEW products_oldest_stock_unit_price
AS
-- Find oldest best_before_date then oldest purchased_date then make sure to return one stock row using max
SELECT
1 AS id, -- Dummy, LessQL needs an id column
sw.product_id,
sw.amount,
sw.best_before_date,
sw.purchased_date,
sw.price, sw.qu_factor_purchase_to_stock,
sw.location_id,
sw.shopping_location_id
FROM stock sw
JOIN (
SELECT
s1.product_id,
MIN(s1.id) min_stock_id
FROM stock s1
JOIN (
SELECT
s.product_id,
sp.oldest_date,
MIN(s.purchased_date) min_purchased_date
FROM stock s
JOIN (
SELECT
product_id,
MIN(best_before_date) as oldest_date
FROM stock
GROUP BY product_id) sp
ON s.product_id = sp.product_id
AND s.best_before_date = sp.oldest_date
GROUP BY s.product_id, sp.oldest_date) sp2
ON s1.product_id = sp2.product_id
AND s1.best_before_date = sp2.oldest_date
AND s1.purchased_date = sp2.min_purchased_date
GROUP BY s1.product_id) sp3
ON sw.product_id = sp3.product_id
AND sw.id = sp3.min_stock_id;
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 (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) * rp.amount * pop.price * rp.price_factor 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.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) * IFNULL(p.calories, 0) AS calories,
p.active AS product_active
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 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_oldest_stock_unit_price pop
ON rp.product_id = pop.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 (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) * rp.amount * IFNULL(pop.price, 0) * rp.price_factor 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.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) * IFNULL(p.calories, 0) AS calories,
p.active AS product_active
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 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_oldest_stock_unit_price pop
ON rp.product_id = pop.product_id
WHERE rp.not_check_stock_fulfillment = 1;