From 8497f37b24e662bc25e25570ce7219108e62ad31 Mon Sep 17 00:00:00 2001 From: Bernd Bestel Date: Tue, 13 Feb 2024 13:12:56 +0100 Subject: [PATCH] Fixed product's last_price related to empty / 0 stock transactions (fixes #2470) --- changelog/75_UNRELEASED_xxxx-xx-xx.md | 1 + migrations/0236.sql | 56 +++++++++++++++++++++++++++ 2 files changed, 57 insertions(+) create mode 100644 migrations/0236.sql diff --git a/changelog/75_UNRELEASED_xxxx-xx-xx.md b/changelog/75_UNRELEASED_xxxx-xx-xx.md index 12c1770d..e23b844f 100644 --- a/changelog/75_UNRELEASED_xxxx-xx-xx.md +++ b/changelog/75_UNRELEASED_xxxx-xx-xx.md @@ -14,6 +14,7 @@ - This executes the configured barcode lookup plugin with the given barcode - If the lookup was successful, the product edit page of the created product is displayed, where the product setup can be completed (if required) - After that, the transaction is continued with that product +- Fixed that for the product's last price stock transactions with an empty or `0` price weren't ignored ### Shopping list diff --git a/migrations/0236.sql b/migrations/0236.sql new file mode 100644 index 00000000..fdadd0ee --- /dev/null +++ b/migrations/0236.sql @@ -0,0 +1,56 @@ +DROP VIEW products_last_purchased; +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.location_id, + sl.shopping_location_id, + IFNULL((SELECT price FROM products_price_history WHERE product_id = sl.product_id ORDER BY purchased_date DESC LIMIT 1), 0) AS price +FROM stock_log sl +JOIN ( + /* + This subquery gets the ID of the stock_log row (per product) which referes to the last purchase transaction, + while taking undone and edited transactions into account + */ + SELECT + sl1.product_id, + MAX(sl1.id) stock_log_id_of_last_purchase + FROM stock_log sl1 + JOIN ( + /* + This subquery finds the last purchased date per product, + there can be multiple purchase transactions per day, therefore a JOIN by purchased_date + for the outer query on this and then take MAX id of stock_log (of that day) + */ + SELECT + sl2.product_id, + MAX(sl2.purchased_date) AS last_purchased_date + FROM stock_log sl2 + WHERE sl2.undone = 0 + AND ( + (sl2.transaction_type IN ('purchase', 'inventory-correction', 'self-production') AND sl2.stock_id NOT IN (SELECT stock_id FROM stock_edited_entries)) + OR (sl2.transaction_type = 'stock-edit-new' AND sl2.stock_id IN (SELECT stock_id FROM stock_edited_entries) AND sl2.id IN (SELECT stock_log_id_of_newest_edited_entry FROM stock_edited_entries)) + ) + GROUP BY sl2.product_id + ) x2 + ON sl1.product_id = x2.product_id + AND sl1.purchased_date = x2.last_purchased_date + WHERE sl1.undone = 0 + AND ( + (sl1.transaction_type IN ('purchase', 'inventory-correction', 'self-production') AND sl1.stock_id NOT IN (SELECT stock_id FROM stock_edited_entries)) + OR (sl1.transaction_type = 'stock-edit-new' AND sl1.stock_id IN (SELECT stock_id FROM stock_edited_entries) AND sl1.id IN (SELECT stock_log_id_of_newest_edited_entry FROM stock_edited_entries)) + ) + GROUP BY sl1.product_id +) x + ON sl.product_id = x.product_id + AND sl.id = x.stock_log_id_of_last_purchase; + +-- Update products_last_purchased cache +INSERT OR REPLACE INTO cache__products_last_purchased + (product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id) +SELECT product_id, amount, best_before_date, purchased_date, price, location_id, shopping_location_id +FROM products_last_purchased;