mirror of
https://github.com/grocy/grocy.git
synced 2025-04-29 17:45:39 +00:00
Fixed average shelf life (productcard) for edited stock entries (fixes #1924)
This commit is contained in:
parent
dbf660f953
commit
bef261d869
55
changelog/69_UNRELEASED_xxxx-xx-xx.md
Normal file
55
changelog/69_UNRELEASED_xxxx-xx-xx.md
Normal file
@ -0,0 +1,55 @@
|
||||
> ⚠️ xxxBREAKING CHANGESxxx
|
||||
|
||||
> ❗ xxxImportant upgrade informationXXX
|
||||
|
||||
### New feature: xxxx
|
||||
|
||||
- xxx
|
||||
|
||||
### Stock
|
||||
|
||||
- Fixed that the average shelf life of a product (on the productcard) was wrong when the corresponding stock entry was edited
|
||||
|
||||
### Shopping list
|
||||
|
||||
- xxx
|
||||
|
||||
### Recipes
|
||||
|
||||
- xxx
|
||||
|
||||
### Meal plan
|
||||
|
||||
- xxx
|
||||
|
||||
### Chores
|
||||
|
||||
- xxx
|
||||
|
||||
### Calendar
|
||||
|
||||
- xxx
|
||||
|
||||
### Tasks
|
||||
|
||||
- xxx
|
||||
|
||||
### Batteries
|
||||
|
||||
- xxx
|
||||
|
||||
### Equipment
|
||||
|
||||
- xxx
|
||||
|
||||
### Userfields
|
||||
|
||||
- xxx
|
||||
|
||||
### General
|
||||
|
||||
- xxx
|
||||
|
||||
### API
|
||||
|
||||
- xxx
|
34
migrations/0194.sql
Normal file
34
migrations/0194.sql
Normal file
@ -0,0 +1,34 @@
|
||||
CREATE VIEW stock_edited_entries
|
||||
AS
|
||||
/*
|
||||
Returns stock_id's which have been edited manually
|
||||
*/
|
||||
SELECT DISTINCT sl_add.stock_id
|
||||
fROM stock_log sl_add
|
||||
JOIN stock_log sl_edit
|
||||
ON sl_add.stock_id = sl_edit.stock_id
|
||||
AND sl_edit.transaction_type = 'stock-edit-new'
|
||||
WHERE sl_add.transaction_type IN ('purchase', 'inventory-correction', 'self-production')
|
||||
AND sl_add.amount > 0;
|
||||
|
||||
DROP VIEW stock_average_product_shelf_life;
|
||||
CREATE VIEW stock_average_product_shelf_life
|
||||
AS
|
||||
SELECT
|
||||
p.id,
|
||||
CASE WHEN x.product_id IS NULL THEN -1 ELSE AVG(x.shelf_life_days) END AS average_shelf_life_days
|
||||
FROM products p
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
sl_p.product_id,
|
||||
JULIANDAY(sl_p.best_before_date) - JULIANDAY(sl_p.purchased_date) AS shelf_life_days
|
||||
FROM stock_log sl_p
|
||||
WHERE (
|
||||
(sl_p.transaction_type IN ('purchase', 'inventory-correction', 'self-production') AND sl_p.stock_id NOT IN (SELECT stock_id FROM stock_edited_entries))
|
||||
OR (sl_p.transaction_type = 'stock-edit-new' AND sl_p.stock_id IN (SELECT stock_id FROM stock_edited_entries))
|
||||
)
|
||||
AND sl_p.undone = 0
|
||||
|
||||
) x
|
||||
ON p.id = x.product_id
|
||||
GROUP BY p.id;
|
Loading…
x
Reference in New Issue
Block a user