diff --git a/changelog/63_UNRELEASED_xxxx.xx.xx.md b/changelog/63_UNRELEASED_xxxx.xx.xx.md index 20989d3d..3fa3218c 100644 --- a/changelog/63_UNRELEASED_xxxx.xx.xx.md +++ b/changelog/63_UNRELEASED_xxxx.xx.xx.md @@ -7,4 +7,5 @@ - Fixed that it was not possible to select a chore/battery on the corresponding tracking pages by mouse/touch - Fixed that grouping by columns in tables may caused duplicate groups - Fixed that grocycode camera barcode scanning didn't recognize the scanned code for chore/battery tracking +- Fixed that `missing_products` of the `/stock/volatile` endpoint also returned incactive products - Optimized the meal plan page to be properly printable (thanks @MrKrisKrisu) diff --git a/migrations/0150.sql b/migrations/0150.sql new file mode 100644 index 00000000..003d9685 --- /dev/null +++ b/migrations/0150.sql @@ -0,0 +1,127 @@ +DROP VIEW stock_missing_products; +CREATE VIEW stock_missing_products +AS + +-- 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) 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 + AND IFNULL(p.active, 0) = 1 +GROUP BY p.id +HAVING IFNULL(SUM(s.amount), 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) 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 + AND IFNULL(p.active, 0) = 1 +GROUP BY p.id +HAVING IFNULL(SUM(s.amount_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) 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 + AND IFNULL(p.active, 0) = 1 +GROUP BY sub_p.id +HAVING IFNULL(SUM(s.amount), 0) < sub_p.min_stock_amount; + +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 + AND IFNULL(p.active, 0) = 1 +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 + AND IFNULL(p.active, 0) = 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 + AND IFNULL(p.active, 0) = 1 +GROUP BY sub_p.id +HAVING IFNULL(SUM(s.amount), 0) - IFNULL(SUM(s.amount_opened), 0) < sub_p.min_stock_amount; diff --git a/services/StockService.php b/services/StockService.php index f39bdd00..a01bbe61 100644 --- a/services/StockService.php +++ b/services/StockService.php @@ -596,7 +596,6 @@ class StockService extends BaseService public function GetMissingProducts() { $sql = 'SELECT * FROM stock_missing_products_including_opened'; - if (!GROCY_FEATURE_SETTING_STOCK_COUNT_OPENED_PRODUCTS_AGAINST_MINIMUM_STOCK_AMOUNT) { $sql = 'SELECT * FROM stock_missing_products';