From 02f30d141e8e9c01aa95fca439a537dd798a2549 Mon Sep 17 00:00:00 2001 From: Bernd Bestel Date: Thu, 26 Sep 2019 12:43:00 +0200 Subject: [PATCH] Reviewed/optimized last changes (references #384) --- migrations/0092.sql | 37 +++++++++++++------------------------ 1 file changed, 13 insertions(+), 24 deletions(-) diff --git a/migrations/0092.sql b/migrations/0092.sql index f4cf3f57..aa3b8215 100644 --- a/migrations/0092.sql +++ b/migrations/0092.sql @@ -1,39 +1,33 @@ ALTER TABLE products ADD cumulate_min_stock_amount_of_subproducts TINYINT DEFAULT 0; -CREATE VIEW products_view -AS -SELECT *, CASE WHEN (SELECT 1 FROM products WHERE parent_product_id = p.id) NOTNULL THEN 1 ELSE 0 END AS has_sub_products -FROM products p; - DROP VIEW stock_missing_products; CREATE VIEW stock_missing_products AS --- Products which are not sub products and not with "cumulate_min_stock_amount_of_subproducts" +-- Parent 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 +FROM products 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_subproducts = 0 - AND p.parent_product_id IS NULL GROUP BY p.id HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount UNION --- Products which have sub products and with "cumulate_min_stock_amount_of_subproducts" +-- Parent 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), 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 +FROM products p JOIN products_resolved pr ON p.id = pr.parent_product_id JOIN products sub_p @@ -42,19 +36,18 @@ 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_subproducts = 1 - AND p.has_sub_products IS NOT NULL GROUP BY p.id HAVING IFNULL(SUM(s.amount), 0) < SUM(sub_p.min_stock_amount) UNION --- Sub products where the parent product has not "cumulate_min_stock_amount_of_subproducts" +-- 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_view p +FROM products p JOIN products_resolved pr ON p.id = pr.parent_product_id JOIN products sub_p @@ -63,7 +56,6 @@ 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_subproducts = 0 - AND sub_p.parent_product_id IS NOT NULL GROUP BY sub_p.id HAVING IFNULL(SUM(s.amount), 0) < sub_p.min_stock_amount; @@ -71,32 +63,31 @@ 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 */ +/* This is basically the same view as stock_missing_products, but the column "amount_missing" includes opened amounts */ --- Products which are not sub products and not with "cumulate_min_stock_amount_of_subproducts" +-- Parent 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 +FROM products 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_subproducts = 0 - AND p.parent_product_id IS NULL GROUP BY p.id HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount UNION --- Products which have sub products and with "cumulate_min_stock_amount_of_subproducts" +-- Parent 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), 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 +FROM products p JOIN products_resolved pr ON p.id = pr.parent_product_id JOIN products sub_p @@ -105,19 +96,18 @@ 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_subproducts = 1 - AND p.has_sub_products IS NOT NULL GROUP BY p.id HAVING IFNULL(SUM(s.amount), 0) < SUM(sub_p.min_stock_amount) UNION --- Sub products where the parent product has not "cumulate_min_stock_amount_of_subproducts" +-- 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_view p +FROM products p JOIN products_resolved pr ON p.id = pr.parent_product_id JOIN products sub_p @@ -126,6 +116,5 @@ 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_subproducts = 0 - AND sub_p.parent_product_id IS NOT NULL GROUP BY sub_p.id HAVING IFNULL(SUM(s.amount), 0) < sub_p.min_stock_amount;