Fix grocy/grocy#834 (#855)

* Fix grocy/grocy#834

* stock_missing_products_including_opened didn't take the opened amount in HAVING clauses

* Resolved merge conflicts

Co-authored-by: Bernd Bestel <bernd@berrnd.de>
This commit is contained in:
Michał Przybyś 2020-08-19 19:46:25 +02:00 committed by GitHub
parent 31c412a28c
commit f8c6e81dcb
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
2 changed files with 62 additions and 1 deletions

View File

@ -165,5 +165,5 @@ Setting('FEATURE_FLAG_CHORES_ASSIGNMENTS', true);
# Feature settings
Setting('FEATURE_SETTING_STOCK_COUNT_OPENED_PRODUCTS_AGAINST_MINIMUM_STOCK_AMOUNT', true); // When set to false, opened products will not be considered for minimum stock amounts
Setting('FEATURE_SETTING_STOCK_COUNT_OPENED_PRODUCTS_AGAINST_MINIMUM_STOCK_AMOUNT', true); // When set to true opened items will be counted as missing from stock when calculating if a product is below its minimum.
Setting('FEATURE_FLAG_AUTO_TORCH_ON_WITH_CAMERA', true); // Enables the torch automaticaly in every camera barcode scanner.

61
migrations/0107.sql Normal file
View File

@ -0,0 +1,61 @@
DROP VIEW stock_missing_products_including_opened;
CREATE VIEW stock_missing_products_including_opened
AS
/* This is basically the same view as stock_missing_products, but the column "amount_missing" includes opened amounts */
-- Products WITHOUT sub products where the amount of the sub products SHOULD NOT be cumulated
SELECT
p.id,
MAX(p.name) AS name,
p.min_stock_amount - (IFNULL(SUM(s.amount), 0) - IFNULL(SUM(s.amount_opened), 0)) AS amount_missing,
CASE WHEN IFNULL(SUM(s.amount), 0) > 0 THEN 1 ELSE 0 END AS is_partly_in_stock
FROM products_view p
LEFT JOIN stock_current s
ON p.id = s.product_id
WHERE p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_sub_products = 0
AND p.has_sub_products = 0
AND p.parent_product_id IS NULL
GROUP BY p.id
HAVING IFNULL(SUM(s.amount), 0) - IFNULL(SUM(s.amount_opened), 0) < p.min_stock_amount
UNION
-- Parent products WITH sub products where the amount of the sub products SHOULD be cumulated
SELECT
p.id,
MAX(p.name) AS name,
SUM(sub_p.min_stock_amount) - (IFNULL(SUM(s.amount_aggregated), 0) - IFNULL(SUM(s.amount_opened_aggregated), 0)) AS amount_missing,
CASE WHEN IFNULL(SUM(s.amount), 0) > 0 THEN 1 ELSE 0 END AS is_partly_in_stock
FROM products_view p
JOIN products_resolved pr
ON p.id = pr.parent_product_id
JOIN products sub_p
ON pr.sub_product_id = sub_p.id
LEFT JOIN stock_current s
ON pr.sub_product_id = s.product_id
WHERE sub_p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_sub_products = 1
GROUP BY p.id
HAVING IFNULL(SUM(s.amount_aggregated), 0) - IFNULL(SUM(s.amount_opened_aggregated), 0) < SUM(sub_p.min_stock_amount)
UNION
-- Sub products where the amount SHOULD NOT be cumulated into the parent product
SELECT
sub_p.id,
MAX(sub_p.name) AS name,
SUM(sub_p.min_stock_amount) - (IFNULL(SUM(s.amount), 0) - IFNULL(SUM(s.amount_opened), 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
JOIN products_resolved pr
ON p.id = pr.parent_product_id
JOIN products sub_p
ON pr.sub_product_id = sub_p.id
LEFT JOIN stock_current s
ON pr.sub_product_id = s.product_id
WHERE sub_p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_sub_products = 0
GROUP BY sub_p.id
HAVING IFNULL(SUM(s.amount), 0) - IFNULL(SUM(s.amount_opened), 0) < sub_p.min_stock_amount;