Reviewed/optimized last changes (references #384)

This commit is contained in:
Bernd Bestel 2019-09-26 12:43:00 +02:00
parent c5927a10f3
commit 02f30d141e
No known key found for this signature in database
GPG Key ID: 71BD34C0D4891300

View File

@ -1,39 +1,33 @@
ALTER TABLE products ALTER TABLE products
ADD cumulate_min_stock_amount_of_subproducts TINYINT DEFAULT 0; 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; DROP VIEW stock_missing_products;
CREATE VIEW stock_missing_products CREATE VIEW stock_missing_products
AS 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 SELECT
p.id, p.id,
MAX(p.name) AS name, MAX(p.name) AS name,
p.min_stock_amount - IFNULL(SUM(s.amount), 0) AS amount_missing, 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 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 LEFT JOIN stock_current s
ON p.id = s.product_id ON p.id = s.product_id
WHERE p.min_stock_amount != 0 WHERE p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_subproducts = 0 AND p.cumulate_min_stock_amount_of_subproducts = 0
AND p.parent_product_id IS NULL
GROUP BY p.id GROUP BY p.id
HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount
UNION 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 SELECT
p.id, p.id,
MAX(p.name) AS name, MAX(p.name) AS name,
SUM(sub_p.min_stock_amount) - IFNULL(SUM(s.amount), 0) AS amount_missing, 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 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 JOIN products_resolved pr
ON p.id = pr.parent_product_id ON p.id = pr.parent_product_id
JOIN products sub_p JOIN products sub_p
@ -42,19 +36,18 @@ LEFT JOIN stock_current s
ON pr.sub_product_id = s.product_id ON pr.sub_product_id = s.product_id
WHERE sub_p.min_stock_amount != 0 WHERE sub_p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_subproducts = 1 AND p.cumulate_min_stock_amount_of_subproducts = 1
AND p.has_sub_products IS NOT NULL
GROUP BY p.id GROUP BY p.id
HAVING IFNULL(SUM(s.amount), 0) < SUM(sub_p.min_stock_amount) HAVING IFNULL(SUM(s.amount), 0) < SUM(sub_p.min_stock_amount)
UNION 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 SELECT
sub_p.id, sub_p.id,
MAX(sub_p.name) AS name, MAX(sub_p.name) AS name,
SUM(sub_p.min_stock_amount) - IFNULL(SUM(s.amount), 0) AS amount_missing, 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 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 JOIN products_resolved pr
ON p.id = pr.parent_product_id ON p.id = pr.parent_product_id
JOIN products sub_p JOIN products sub_p
@ -63,7 +56,6 @@ LEFT JOIN stock_current s
ON pr.sub_product_id = s.product_id ON pr.sub_product_id = s.product_id
WHERE sub_p.min_stock_amount != 0 WHERE sub_p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_subproducts = 0 AND p.cumulate_min_stock_amount_of_subproducts = 0
AND sub_p.parent_product_id IS NOT NULL
GROUP BY sub_p.id GROUP BY sub_p.id
HAVING IFNULL(SUM(s.amount), 0) < sub_p.min_stock_amount; 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 CREATE VIEW stock_missing_products_including_opened
AS 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 SELECT
p.id, p.id,
MAX(p.name) AS name, MAX(p.name) AS name,
p.min_stock_amount - (IFNULL(SUM(s.amount), 0) - IFNULL(SUM(s.amount_opened), 0)) AS amount_missing, 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 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 LEFT JOIN stock_current s
ON p.id = s.product_id ON p.id = s.product_id
WHERE p.min_stock_amount != 0 WHERE p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_subproducts = 0 AND p.cumulate_min_stock_amount_of_subproducts = 0
AND p.parent_product_id IS NULL
GROUP BY p.id GROUP BY p.id
HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount HAVING IFNULL(SUM(s.amount), 0) < p.min_stock_amount
UNION 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 SELECT
p.id, p.id,
MAX(p.name) AS name, 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, 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 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 JOIN products_resolved pr
ON p.id = pr.parent_product_id ON p.id = pr.parent_product_id
JOIN products sub_p JOIN products sub_p
@ -105,19 +96,18 @@ LEFT JOIN stock_current s
ON pr.sub_product_id = s.product_id ON pr.sub_product_id = s.product_id
WHERE sub_p.min_stock_amount != 0 WHERE sub_p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_subproducts = 1 AND p.cumulate_min_stock_amount_of_subproducts = 1
AND p.has_sub_products IS NOT NULL
GROUP BY p.id GROUP BY p.id
HAVING IFNULL(SUM(s.amount), 0) < SUM(sub_p.min_stock_amount) HAVING IFNULL(SUM(s.amount), 0) < SUM(sub_p.min_stock_amount)
UNION 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 SELECT
sub_p.id, sub_p.id,
MAX(sub_p.name) AS name, 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, 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 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 JOIN products_resolved pr
ON p.id = pr.parent_product_id ON p.id = pr.parent_product_id
JOIN products sub_p JOIN products sub_p
@ -126,6 +116,5 @@ LEFT JOIN stock_current s
ON pr.sub_product_id = s.product_id ON pr.sub_product_id = s.product_id
WHERE sub_p.min_stock_amount != 0 WHERE sub_p.min_stock_amount != 0
AND p.cumulate_min_stock_amount_of_subproducts = 0 AND p.cumulate_min_stock_amount_of_subproducts = 0
AND sub_p.parent_product_id IS NOT NULL
GROUP BY sub_p.id GROUP BY sub_p.id
HAVING IFNULL(SUM(s.amount), 0) < sub_p.min_stock_amount; HAVING IFNULL(SUM(s.amount), 0) < sub_p.min_stock_amount;