diff --git a/changelog/71_UNRELEASED_xxxx-xx-xx.md b/changelog/71_UNRELEASED_xxxx-xx-xx.md index 75dc3b3c..37c4de00 100644 --- a/changelog/71_UNRELEASED_xxxx-xx-xx.md +++ b/changelog/71_UNRELEASED_xxxx-xx-xx.md @@ -10,7 +10,7 @@ ### Stock -- Fixed performance issues affecting the stock overview, shopping list and purchase/consume/inventory/transfer pages +- Fixed performance issues affecting all places where quantity unit conversions / prices are involved - Fixed that the upgrade failed when having improperly defined product specific quantity unit conversions - Fixed that edited stock entries were not considered in some cases (affecting the product's last price, average price, the price history and the stock reports) diff --git a/controllers/RecipesController.php b/controllers/RecipesController.php index 87642af7..3b33dc07 100644 --- a/controllers/RecipesController.php +++ b/controllers/RecipesController.php @@ -64,7 +64,7 @@ class RecipesController extends BaseController 'recipesResolved' => $this->getRecipesService()->GetRecipesResolved("recipe_id IN (SELECT recipe_id FROM meal_plan_internal_recipe_relation WHERE $mealPlanWhereTimespan)"), 'products' => $this->getDatabase()->products()->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'mealplanSections' => $this->getDatabase()->meal_plan_sections()->orderBy('sort_number'), 'usedMealplanSections' => $this->getDatabase()->meal_plan_sections()->where("id IN (SELECT section_id FROM meal_plan WHERE $mealPlanWhereTimespan)")->orderBy('sort_number'), 'weekRecipe' => $this->getDatabase()->recipes()->where("type = 'mealplan-week' AND name = LTRIM(STRFTIME('%Y-%W', DATE('$start')), '0')")->fetch() @@ -107,7 +107,7 @@ class RecipesController extends BaseController 'quantityUnits' => $this->getDatabase()->quantity_units(), 'userfields' => $this->getUserfieldsService()->GetFields('recipes'), 'userfieldValues' => $this->getUserfieldsService()->GetAllValues('recipes'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'selectedRecipeTotalCosts' => $totalCosts, 'selectedRecipeTotalCalories' => $totalCalories, 'mealplanSections' => $this->getDatabase()->meal_plan_sections()->orderBy('sort_number') @@ -162,7 +162,7 @@ class RecipesController extends BaseController 'recipes' => $this->getDatabase()->recipes()->where('type', RecipesService::RECIPE_TYPE_NORMAL)->orderBy('name', 'COLLATE NOCASE'), 'recipeNestings' => $this->getDatabase()->recipes_nestings()->where('recipe_id', $recipeId), 'userfields' => $this->getUserfieldsService()->GetFields('recipes'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved() + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved() ]); } @@ -176,7 +176,7 @@ class RecipesController extends BaseController 'recipePos' => new \stdClass(), 'products' => $this->getDatabase()->products()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved() + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved() ]); } else @@ -187,7 +187,7 @@ class RecipesController extends BaseController 'recipePos' => $this->getDatabase()->recipes_pos($args['recipePosId']), 'products' => $this->getDatabase()->products()->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved() + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved() ]); } } diff --git a/controllers/StockController.php b/controllers/StockController.php index 46c57197..6fb49820 100644 --- a/controllers/StockController.php +++ b/controllers/StockController.php @@ -19,7 +19,7 @@ class StockController extends BaseController 'recipes' => $this->getDatabase()->recipes()->where('type', RecipesService::RECIPE_TYPE_NORMAL)->orderBy('name', 'COLLATE NOCASE'), 'locations' => $this->getDatabase()->locations()->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved() + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved() ]); } @@ -31,7 +31,7 @@ class StockController extends BaseController 'shoppinglocations' => $this->getDatabase()->shopping_locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'locations' => $this->getDatabase()->locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'userfields' => $this->getUserfieldsService()->GetFields('stock') ]); } @@ -147,7 +147,7 @@ class StockController extends BaseController 'product' => $product, 'shoppinglocations' => $this->getDatabase()->shopping_locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'userfields' => $this->getUserfieldsService()->GetFields('product_barcodes') ]); } @@ -159,7 +159,7 @@ class StockController extends BaseController 'product' => $product, 'shoppinglocations' => $this->getDatabase()->shopping_locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'userfields' => $this->getUserfieldsService()->GetFields('product_barcodes') ]); } @@ -192,8 +192,8 @@ class StockController extends BaseController 'locations' => $this->getDatabase()->locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'barcodes' => $this->getDatabase()->product_barcodes()->orderBy('barcode'), 'quantityunits' => $this->getDatabase()->quantity_units()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), - 'quantityunitsStock' => $this->getDatabase()->quantity_units()->where('id IN (SELECT to_qu_id FROM quantity_unit_conversions_resolved WHERE product_id = :1) OR NOT EXISTS(SELECT 1 FROM stock_log WHERE product_id = :1)', $product->id)->orderBy('name', 'COLLATE NOCASE'), - 'referencedQuantityunits' => $this->getDatabase()->quantity_units()->where('active = 1')->where('id IN (SELECT to_qu_id FROM quantity_unit_conversions_resolved WHERE product_id = :1)', $product->id)->orderBy('name', 'COLLATE NOCASE'), + 'quantityunitsStock' => $this->getDatabase()->quantity_units()->where('id IN (SELECT to_qu_id FROM cache__quantity_unit_conversions_resolved WHERE product_id = :1) OR NOT EXISTS(SELECT 1 FROM stock_log WHERE product_id = :1)', $product->id)->orderBy('name', 'COLLATE NOCASE'), + 'referencedQuantityunits' => $this->getDatabase()->quantity_units()->where('active = 1')->where('id IN (SELECT to_qu_id FROM cache__quantity_unit_conversions_resolved WHERE product_id = :1)', $product->id)->orderBy('name', 'COLLATE NOCASE'), 'shoppinglocations' => $this->getDatabase()->shopping_locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'productgroups' => $this->getDatabase()->product_groups()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'userfields' => $this->getUserfieldsService()->GetFields('products'), @@ -289,7 +289,7 @@ class StockController extends BaseController 'shoppinglocations' => $this->getDatabase()->shopping_locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'locations' => $this->getDatabase()->locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'userfields' => $this->getUserfieldsService()->GetFields('stock') ]); } @@ -399,7 +399,7 @@ class StockController extends BaseController 'missingProducts' => $this->getStockService()->GetMissingProducts(), 'shoppingLists' => $this->getDatabase()->shopping_lists()->orderBy('name', 'COLLATE NOCASE'), 'selectedShoppingListId' => $listId, - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'productUserfields' => $this->getUserfieldsService()->GetFields('products'), 'productUserfieldValues' => $this->getUserfieldsService()->GetAllValues('products'), 'productGroupUserfields' => $this->getUserfieldsService()->GetFields('product_groups'), @@ -438,7 +438,7 @@ class StockController extends BaseController 'shoppingLists' => $this->getDatabase()->shopping_lists()->orderBy('name', 'COLLATE NOCASE'), 'mode' => 'create', 'quantityUnits' => $this->getDatabase()->quantity_units()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'userfields' => $this->getUserfieldsService()->GetFields('shopping_list') ]); } @@ -451,7 +451,7 @@ class StockController extends BaseController 'shoppingLists' => $this->getDatabase()->shopping_lists()->orderBy('name', 'COLLATE NOCASE'), 'mode' => 'edit', 'quantityUnits' => $this->getDatabase()->quantity_units()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved(), + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved(), 'userfields' => $this->getUserfieldsService()->GetFields('shopping_list') ]); } @@ -564,7 +564,7 @@ class StockController extends BaseController 'barcodes' => $this->getDatabase()->product_barcodes_comma_separated(), 'locations' => $this->getDatabase()->locations()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), 'quantityUnits' => $this->getDatabase()->quantity_units()->where('active = 1')->orderBy('name', 'COLLATE NOCASE'), - 'quantityUnitConversionsResolved' => $this->getDatabase()->quantity_unit_conversions_resolved() + 'quantityUnitConversionsResolved' => $this->getDatabase()->cache__quantity_unit_conversions_resolved() ]); } @@ -599,11 +599,11 @@ class StockController extends BaseController if (isset($request->getQueryParams()['product'])) { $product = $this->getDatabase()->products($request->getQueryParams()['product']); - $quantityUnitConversionsResolved = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id', $product->id); + $quantityUnitConversionsResolved = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id', $product->id); } else { - $quantityUnitConversionsResolved = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id IS NULL'); + $quantityUnitConversionsResolved = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id IS NULL'); } return $this->renderPage($response, 'quantityunitconversionsresolved', [ diff --git a/migrations/0208.sql b/migrations/0208.sql index 8b8e36d3..3192ce62 100644 --- a/migrations/0208.sql +++ b/migrations/0208.sql @@ -115,7 +115,6 @@ AS ( JOIN default_conversions s ON c.path LIKE ('%/' || s.from_qu_id || '/' || s.to_qu_id || '/%') -- the conversion has been used as part of another path ... WHERE NOT EXISTS(SELECT 1 FROM conversion_factors ci WHERE ci.product_id = c.product_id AND ci.from_qu_id = s.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- ... and is itself new - ) SELECT DISTINCT @@ -135,6 +134,5 @@ JOIN quantity_units qu_from JOIN quantity_units qu_to ON c.to_qu_id = qu_to.id GROUP BY product_id, from_qu_id, to_qu_id -WINDOW win - AS (PARTITION BY product_id, from_qu_id, to_qu_id ORDER BY depth ASC) -ORDER BY product_id, from_qu_id, to_qu_id; \ No newline at end of file +WINDOW win AS (PARTITION BY product_id, from_qu_id, to_qu_id ORDER BY depth ASC) +ORDER BY product_id, from_qu_id, to_qu_id; diff --git a/migrations/0225.sql b/migrations/0225.sql new file mode 100644 index 00000000..b1ce8d26 --- /dev/null +++ b/migrations/0225.sql @@ -0,0 +1,284 @@ +CREATE TABLE cache__quantity_unit_conversions_resolved ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE, + product_id INT, + from_qu_id INT, + from_qu_name TEXT, + from_qu_name_plural TEXT, + to_qu_id INT, + to_qu_name TEXT, + to_qu_name_plural TEXT, + factor TEXT, + path TEXT +); + +INSERT INTO cache__quantity_unit_conversions_resolved + (product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path) +SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path +FROM quantity_unit_conversions_resolved; + +CREATE INDEX ix_cache__quantity_unit_conversions_resolved_performance1 ON cache__quantity_unit_conversions_resolved ( + product_id, + from_qu_id, + to_qu_id +); + +DROP TRIGGER qu_conversions_inverse_INS; +CREATE TRIGGER quantity_unit_conversions_INS AFTER INSERT ON quantity_unit_conversions +BEGIN + -- Create the inverse QU conversion + INSERT OR REPLACE INTO quantity_unit_conversions + (from_qu_id, to_qu_id, factor, product_id) + VALUES + (NEW.to_qu_id, NEW.from_qu_id, 1 / IFNULL(NEW.factor, 1), NEW.product_id); + + -- Update quantity_unit_conversions_resolved cache + DELETE FROM cache__quantity_unit_conversions_resolved + WHERE path LIKE '%/' || NEW.to_qu_id || '/%' + OR path LIKE '%/' || NEW.from_qu_id || '/%'; + + INSERT INTO cache__quantity_unit_conversions_resolved + (product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path) + SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path + FROM quantity_unit_conversions_resolved + WHERE path LIKE '%/' || NEW.to_qu_id || '/%' + OR path LIKE '%/' || NEW.from_qu_id || '/%'; +END; + +DROP TRIGGER qu_conversions_inverse_UPD; +CREATE TRIGGER quantity_unit_conversions_UPD AFTER UPDATE ON quantity_unit_conversions +BEGIN + -- Update the inverse QU conversion + UPDATE quantity_unit_conversions + SET factor = 1 / IFNULL(NEW.factor, 1), + from_qu_id = NEW.to_qu_id, + to_qu_id = NEW.from_qu_id + WHERE from_qu_id = OLD.to_qu_id + AND to_qu_id = OLD.from_qu_id + AND IFNULL(product_id, -1) = IFNULL(NEW.product_id, -1); + + -- Update quantity_unit_conversions_resolved cache + DELETE FROM cache__quantity_unit_conversions_resolved + WHERE path LIKE '%/' || NEW.to_qu_id || '/%' + OR path LIKE '%/' || NEW.from_qu_id || '/%'; + + INSERT INTO cache__quantity_unit_conversions_resolved + (product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path) + SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path + FROM quantity_unit_conversions_resolved + WHERE path LIKE '%/' || NEW.to_qu_id || '/%' + OR path LIKE '%/' || NEW.from_qu_id || '/%'; +END; + +DROP TRIGGER qu_conversions_inverse_DEL; +CREATE TRIGGER quantity_unit_conversions_DEL AFTER DELETE ON quantity_unit_conversions +BEGIN + -- Delete the inverse QU conversion + DELETE FROM quantity_unit_conversions + WHERE from_qu_id = OLD.to_qu_id + AND to_qu_id = OLD.from_qu_id + AND IFNULL(product_id, -1) = IFNULL(OLD.product_id, -1); + + -- Update quantity_unit_conversions_resolved cache + DELETE FROM cache__quantity_unit_conversions_resolved + WHERE path LIKE '%/' || OLD.to_qu_id || '/%' + OR path LIKE '%/' || OLD.from_qu_id || '/%'; + + INSERT INTO cache__quantity_unit_conversions_resolved + (product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path) + SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path + FROM quantity_unit_conversions_resolved + WHERE path LIKE '%/' || OLD.to_qu_id || '/%' + OR path LIKE '%/' || OLD.from_qu_id || '/%'; +END; + +CREATE TRIGGER products_INS AFTER INSERT ON products +BEGIN + -- Update quantity_unit_conversions_resolved cache + DELETE FROM cache__quantity_unit_conversions_resolved + WHERE product_id = NEW.id; + + INSERT INTO cache__quantity_unit_conversions_resolved + (product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path) + SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path + FROM quantity_unit_conversions_resolved + WHERE product_id = NEW.id; +END; + +CREATE TRIGGER products_UPD AFTER UPDATE ON products +BEGIN + -- Update quantity_unit_conversions_resolved cache + DELETE FROM cache__quantity_unit_conversions_resolved + WHERE product_id = NEW.id; + + INSERT INTO cache__quantity_unit_conversions_resolved + (product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path) + SELECT product_id, from_qu_id, from_qu_name, from_qu_name_plural, to_qu_id, to_qu_name, to_qu_name_plural, factor, path + FROM quantity_unit_conversions_resolved + WHERE product_id = NEW.id; +END; + +CREATE TRIGGER products_DELETE AFTER DELETE ON products +BEGIN + -- Update quantity_unit_conversions_resolved cache + DELETE FROM cache__quantity_unit_conversions_resolved + WHERE product_id = OLD.id; +END; + +DROP VIEW recipes_pos_resolved; +CREATE VIEW recipes_pos_resolved +AS + +-- Multiplication by 1.0 to force conversion to float (REAL) + +SELECT + r.id AS recipe_id, + rp.id AS recipe_pos_id, + rp.product_id AS product_id, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END AS recipe_amount, + IFNULL(sc.amount_aggregated, 0) AS stock_amount, + CASE WHEN IFNULL(sc.amount_aggregated, 0) >= CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 0.00000001 ELSE CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END END THEN 1 ELSE 0 END AS need_fulfilled, + CASE WHEN IFNULL(sc.amount_aggregated, 0) - CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 0.00000001 ELSE CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END END < 0 THEN ABS(IFNULL(sc.amount_aggregated, 0) - (CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END)) ELSE 0 END AS missing_amount, + IFNULL(sl.amount, 0) AS amount_on_shopping_list, + CASE WHEN ROUND(IFNULL(sc.amount_aggregated, 0) + CASE WHEN r.not_check_shoppinglist = 1 THEN 0 ELSE IFNULL(sl.amount, 0) END, 2) >= ROUND(CASE WHEN rp.only_check_single_unit_in_stock = 1 THEN 0.00000001 ELSE CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END END, 2) THEN 1 ELSE 0 END AS need_fulfilled_with_shopping_list, + rp.qu_id, + (r.desired_servings*1.0 / r.base_servings*1.0) * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * rp.amount * IFNULL(pcp.price, 0) * rp.price_factor * IFNULL(qucr.factor, 1) AS costs, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN 0 ELSE 1 END AS is_nested_recipe_pos, + rp.ingredient_group, + pg.name as product_group, + rp.id, -- Just a dummy id column + r.type as recipe_type, + rnr.includes_recipe_id as child_recipe_id, + rp.note, + rp.variable_amount AS recipe_variable_amount, + rp.only_check_single_unit_in_stock, + rp.amount / r.base_servings*1.0 * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * IFNULL(p_effective.calories, 0) * IFNULL(qucr.factor, 1) AS calories, + p.active AS product_active, + CASE pvs.current_due_status + WHEN 'ok' THEN 0 + WHEN 'due_soon' THEN 1 + WHEN 'overdue' THEN 10 + WHEN 'expired' THEN 20 + END AS due_score, + IFNULL(pcs.product_id_effective, rp.product_id) AS product_id_effective, + p.name AS product_name +FROM recipes r +JOIN recipes_nestings_resolved rnr + ON r.id = rnr.recipe_id +JOIN recipes rnrr + ON rnr.includes_recipe_id = rnrr.id +JOIN recipes_pos rp + ON rnr.includes_recipe_id = rp.recipe_id +JOIN products p + ON rp.product_id = p.id +JOIN products_volatile_status pvs + ON rp.product_id = pvs.product_id +LEFT JOIN product_groups pg + ON p.product_group_id = pg.id +LEFT JOIN ( + SELECT product_id, SUM(amount) AS amount + FROM shopping_list + GROUP BY product_id) sl + ON rp.product_id = sl.product_id +LEFT JOIN stock_current sc + ON rp.product_id = sc.product_id +LEFT JOIN products_current_substitutions pcs + ON rp.product_id = pcs.parent_product_id +LEFT JOIN products_current_price pcp + ON IFNULL(pcs.product_id_effective, rp.product_id) = pcp.product_id +LEFT JOIN products p_effective + ON IFNULL(pcs.product_id_effective, rp.product_id) = p_effective.id +LEFT JOIN cache__quantity_unit_conversions_resolved qucr + ON IFNULL(pcs.product_id_effective, rp.product_id) = qucr.product_id + AND CASE WHEN rp.product_id != p_effective.id THEN p.qu_id_stock ELSE rp.qu_id END = qucr.from_qu_id + AND IFNULL(p_effective.qu_id_stock, p.qu_id_stock) = qucr.to_qu_id +WHERE rp.not_check_stock_fulfillment = 0 + +UNION + +-- Just add all recipe positions which should not be checked against stock with fulfilled need + +SELECT + r.id AS recipe_id, + rp.id AS recipe_pos_id, + rp.product_id AS product_id, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) ELSE rp.amount * ((r.desired_servings*1.0) / (r.base_servings*1.0)) * ((rnr.includes_servings*1.0) / (rnrr.base_servings*1.0)) END AS recipe_amount, + IFNULL(sc.amount_aggregated, 0) AS stock_amount, + 1 AS need_fulfilled, + 0 AS missing_amount, + IFNULL(sl.amount, 0) AS amount_on_shopping_list, + 1 AS need_fulfilled_with_shopping_list, + rp.qu_id, + (r.desired_servings*1.0 / r.base_servings*1.0) * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * rp.amount * IFNULL(pcp.price, 0) * rp.price_factor * IFNULL(qucr.factor, 1) AS costs, + CASE WHEN rnr.recipe_id = rnr.includes_recipe_id THEN 0 ELSE 1 END AS is_nested_recipe_pos, + rp.ingredient_group, + pg.name as product_group, + rp.id, -- Just a dummy id column + r.type as recipe_type, + rnr.includes_recipe_id as child_recipe_id, + rp.note, + rp.variable_amount AS recipe_variable_amount, + rp.only_check_single_unit_in_stock, + rp.amount / r.base_servings*1.0 * (rnr.includes_servings*1.0 / CASE WHEN rnr.recipe_id != rnr.includes_recipe_id THEN rnrr.base_servings*1.0 ELSE 1 END) * IFNULL(p_effective.calories, 0) * IFNULL(qucr.factor, 1) AS calories, + p.active AS product_active, + CASE pvs.current_due_status + WHEN 'ok' THEN 0 + WHEN 'due_soon' THEN 1 + WHEN 'overdue' THEN 10 + WHEN 'expired' THEN 20 + END AS due_score, + IFNULL(pcs.product_id_effective, rp.product_id) AS product_id_effective, + p.name AS product_name +FROM recipes r +JOIN recipes_nestings_resolved rnr + ON r.id = rnr.recipe_id +JOIN recipes rnrr + ON rnr.includes_recipe_id = rnrr.id +JOIN recipes_pos rp + ON rnr.includes_recipe_id = rp.recipe_id +JOIN products p + ON rp.product_id = p.id +JOIN products_volatile_status pvs + ON rp.product_id = pvs.product_id +LEFT JOIN product_groups pg + ON p.product_group_id = pg.id +LEFT JOIN ( + SELECT product_id, SUM(amount) AS amount + FROM shopping_list + GROUP BY product_id) sl + ON rp.product_id = sl.product_id +LEFT JOIN stock_current sc + ON rp.product_id = sc.product_id +LEFT JOIN products_current_substitutions pcs + ON rp.product_id = pcs.parent_product_id +LEFT JOIN products_current_price pcp + ON IFNULL(pcs.product_id_effective, rp.product_id) = pcp.product_id +LEFT JOIN products p_effective + ON IFNULL(pcs.product_id_effective, rp.product_id) = p_effective.id +LEFT JOIN cache__quantity_unit_conversions_resolved qucr + ON IFNULL(pcs.product_id_effective, rp.product_id) = qucr.product_id + AND CASE WHEN rp.product_id != p_effective.id THEN p.qu_id_stock ELSE rp.qu_id END = qucr.from_qu_id + AND IFNULL(p_effective.qu_id_stock, p.qu_id_stock) = qucr.to_qu_id +WHERE rp.not_check_stock_fulfillment = 1; + +DROP VIEW products_view; +CREATE VIEW products_view +AS +SELECT + p.*, + CASE WHEN (SELECT 1 FROM products WHERE parent_product_id = p.id) NOTNULL THEN 1 ELSE 0 END AS has_sub_products, + IFNULL(quc_purchase.factor, 1.0) AS qu_factor_purchase_to_stock, + IFNULL(quc_consume.factor, 1.0) AS qu_factor_consume_to_stock, + IFNULL(quc_price.factor, 1.0) AS qu_factor_price_to_stock +FROM products p +LEFT JOIN cache__quantity_unit_conversions_resolved quc_purchase + ON p.id = quc_purchase.product_id + AND p.qu_id_purchase = quc_purchase.from_qu_id + AND p.qu_id_stock = quc_purchase.to_qu_id +LEFT JOIN cache__quantity_unit_conversions_resolved quc_consume + ON p.id = quc_consume.product_id + AND p.qu_id_consume = quc_consume.from_qu_id + AND p.qu_id_stock = quc_consume.to_qu_id +LEFT JOIN cache__quantity_unit_conversions_resolved quc_price + ON p.id = quc_price.product_id + AND p.qu_id_price = quc_price.from_qu_id + AND p.qu_id_stock = quc_price.to_qu_id; diff --git a/migrations/0226.sql b/migrations/0226.sql new file mode 100644 index 00000000..418e5a5b --- /dev/null +++ b/migrations/0226.sql @@ -0,0 +1,213 @@ +CREATE TABLE cache__products_average_price ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE, + product_id INT, + price DECIMAL(15, 2), + + UNIQUE(product_id) +); + +INSERT INTO cache__products_average_price + (product_id, price) +SELECT product_id, price +FROM products_average_price; + +CREATE TABLE cache__products_last_purchased ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE, + product_id INT, + amount DECIMAL(15, 2), + best_before_date DATE, + purchased_date DATE, + price DECIMAL(15, 2), + location_id INT, + shopping_location_id INT, + + UNIQUE(product_id) +); + +INSERT 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; + +CREATE TRIGGER stock_log_INS AFTER INSERT ON stock_log +BEGIN + INSERT OR REPLACE INTO cache__products_average_price + (product_id, price) + SELECT product_id, price + FROM products_average_price + WHERE product_id = NEW.product_id; + + -- 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 + WHERE product_id = NEW.product_id; +END; + +CREATE TRIGGER stock_log_UPD AFTER UPDATE ON stock_log +BEGIN + -- Update products_average_price cache + INSERT OR REPLACE INTO cache__products_average_price + (product_id, price) + SELECT product_id, price + FROM products_average_price + WHERE product_id = NEW.product_id; + + -- 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 + WHERE product_id = NEW.product_id; +END; + +CREATE TRIGGER stock_log_DEL AFTER DELETE ON stock_log +BEGIN + -- Update products_average_price cache + DELETE FROM cache__products_average_price + WHERE product_id = OLD.id; + + -- Update products_last_purchased cache + DELETE FROM cache__products_last_purchased + WHERE product_id = OLD.id; +END; + +DROP VIEW uihelper_stock_current_overview; +CREATE VIEW uihelper_stock_current_overview +AS +SELECT + p.id, + sc.amount_opened AS amount_opened, + p.tare_weight AS tare_weight, + p.enable_tare_weight_handling AS enable_tare_weight_handling, + sc.amount AS amount, + sc.value as value, + sc.product_id AS product_id, + sc.best_before_date AS best_before_date, + EXISTS(SELECT id FROM stock_missing_products WHERE id = sc.product_id) AS product_missing, + p.name AS product_name, + pg.name AS product_group_name, + EXISTS(SELECT * FROM shopping_list WHERE shopping_list.product_id = sc.product_id) AS on_shopping_list, + qu_stock.name AS qu_stock_name, + qu_stock.name_plural AS qu_stock_name_plural, + qu_purchase.name AS qu_purchase_name, + qu_purchase.name_plural AS qu_purchase_name_plural, + qu_consume.name AS qu_consume_name, + qu_consume.name_plural AS qu_consume_name_plural, + qu_price.name AS qu_price_name, + qu_price.name_plural AS qu_price_name_plural, + sc.is_aggregated_amount, + sc.amount_opened_aggregated, + sc.amount_aggregated, + p.calories AS product_calories, + sc.amount * p.calories AS calories, + sc.amount_aggregated * p.calories AS calories_aggregated, + p.quick_consume_amount, + p.quick_consume_amount / p.qu_factor_consume_to_stock AS quick_consume_amount_qu_consume, + p.quick_open_amount, + p.quick_open_amount / p.qu_factor_consume_to_stock AS quick_open_amount_qu_consume, + p.due_type, + plp.purchased_date AS last_purchased, + plp.price AS last_price, + pap.price as average_price, + p.min_stock_amount, + pbcs.barcodes AS product_barcodes, + p.description AS product_description, + l.name AS product_default_location_name, + p_parent.id AS parent_product_id, + p_parent.name AS parent_product_name, + p.picture_file_name AS product_picture_file_name, + p.no_own_stock AS product_no_own_stock, + p.qu_factor_purchase_to_stock AS product_qu_factor_purchase_to_stock, + p.qu_factor_price_to_stock AS product_qu_factor_price_to_stock +FROM ( + SELECT * + FROM stock_current + WHERE best_before_date IS NOT NULL + UNION + SELECT m.id, 0, 0, 0, null, 0, 0, 0, p.due_type + FROM stock_missing_products m + JOIN products p + ON m.id = p.id + WHERE m.id NOT IN (SELECT product_id FROM stock_current) + ) sc +JOIN products_view p + ON sc.product_id = p.id +JOIN locations l + ON p.location_id = l.id +JOIN quantity_units qu_stock + ON p.qu_id_stock = qu_stock.id +JOIN quantity_units qu_purchase + ON p.qu_id_purchase = qu_purchase.id +JOIN quantity_units qu_consume + ON p.qu_id_consume = qu_consume.id +JOIN quantity_units qu_price + ON p.qu_id_price = qu_price.id +LEFT JOIN product_groups pg + ON p.product_group_id = pg.id +LEFT JOIN cache__products_last_purchased plp + ON sc.product_id = plp.product_id +LEFT JOIN cache__products_average_price pap + ON sc.product_id = pap.product_id +LEFT JOIN product_barcodes_comma_separated pbcs + ON sc.product_id = pbcs.product_id +LEFT JOIN products p_parent + ON p.parent_product_id = p_parent.id +WHERE p.hide_on_stock_overview = 0; + +DROP VIEW uihelper_shopping_list; +CREATE VIEW uihelper_shopping_list +AS +SELECT + sl.*, + p.name AS product_name, + plp.price AS last_price_unit, + plp.price * sl.amount AS last_price_total, + st.name AS default_shopping_location_name, + qu.name AS qu_name, + qu.name_plural AS qu_name_plural, + pg.id AS product_group_id, + pg.name AS product_group_name, + pbcs.barcodes AS product_barcodes +FROM shopping_list sl +LEFT JOIN products p + ON sl.product_id = p.id +LEFT JOIN cache__products_last_purchased plp + ON sl.product_id = plp.product_id +LEFT JOIN shopping_locations st + ON p.shopping_location_id = st.id +LEFT JOIN quantity_units qu + ON sl.qu_id = qu.id +LEFT JOIN product_groups pg + ON p.product_group_id = pg.id +LEFT JOIN product_barcodes_comma_separated pbcs + ON sl.product_id = pbcs.product_id; + +DROP VIEW products_current_price; +CREATE VIEW products_current_price +AS + +/* + Current price per product, + based on the stock entry to use next, + or on the last price if the product is currently not in stock +*/ + +SELECT + -1 AS id, -- Dummy, + p.id AS product_id, + IFNULL(snu.price, plp.price) AS price +FROM products p +LEFT JOIN ( + SELECT + product_id, + MAX(priority), + price -- Bare column, ref https://www.sqlite.org/lang_select.html#bare_columns_in_an_aggregate_query + FROM stock_next_use + GROUP BY product_id + ORDER BY priority DESC, open DESC, best_before_date ASC, purchased_date ASC + ) snu + ON p.id = snu.product_id +LEFT JOIN cache__products_last_purchased plp + ON p.id = plp.product_id; diff --git a/services/RecipesService.php b/services/RecipesService.php index 5ae0916d..db8f1236 100644 --- a/services/RecipesService.php +++ b/services/RecipesService.php @@ -38,7 +38,7 @@ class RecipesService extends BaseService // => Do the unit conversion here (if any) if ($recipePosition->only_check_single_unit_in_stock == 1) { - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $recipePosition->product_id, $recipePosition->qu_id, $product->qu_id_stock)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $recipePosition->product_id, $recipePosition->qu_id, $product->qu_id_stock)->fetch(); if ($conversion != null) { $toOrderAmount = $toOrderAmount * $conversion->factor; diff --git a/services/StockService.php b/services/StockService.php index 5fb1dbee..7265e82b 100644 --- a/services/StockService.php +++ b/services/StockService.php @@ -420,7 +420,7 @@ class StockService extends BaseService { // A sub product will be used -> use QU conversions $subProduct = $this->getDatabase()->products($stockEntry->product_id); - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $stockEntry->product_id, $productDetails->product->qu_id_stock, $subProduct->qu_id_stock)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $stockEntry->product_id, $productDetails->product->qu_id_stock, $subProduct->qu_id_stock)->fetch(); if ($conversion != null) { $amount = $amount * $conversion->factor; @@ -711,7 +711,7 @@ class StockService extends BaseService $stockCurrentRow->is_aggregated_amount = 0; } - $productLastPurchased = $this->getDatabase()->products_last_purchased()->where('product_id', $productId)->fetch(); + $productLastPurchased = $this->getDatabase()->cache__products_last_purchased()->where('product_id', $productId)->fetch(); $lastPurchasedDate = null; $lastPrice = null; $lastShoppingLocation = null; @@ -721,7 +721,7 @@ class StockService extends BaseService $lastPurchasedDate = $productLastPurchased->purchased_date; $lastPrice = $productLastPurchased->price; $lastShoppingLocation = $productLastPurchased->shopping_location_id; - $avgPriceRow = $this->getDatabase()->products_average_price()->where('product_id', $productId)->fetch(); + $avgPriceRow = $this->getDatabase()->cache__products_average_price()->where('product_id', $productId)->fetch(); if ($avgPriceRow) { $avgPrice = $avgPriceRow->price; @@ -757,7 +757,7 @@ class StockService extends BaseService $quConversionFactorPurchaseToStock = 1.0; if ($product->qu_id_stock != $product->qu_id_purchase) { - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $product->id, $product->qu_id_purchase, $product->qu_id_stock)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $product->id, $product->qu_id_purchase, $product->qu_id_stock)->fetch(); if ($conversion != null) { $quConversionFactorPurchaseToStock = $conversion->factor; @@ -767,7 +767,7 @@ class StockService extends BaseService $quConversionFactorPriceToStock = 1.0; if ($product->qu_id_stock != $product->qu_id_price) { - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $product->id, $product->qu_id_price, $product->qu_id_stock)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $product->id, $product->qu_id_price, $product->qu_id_stock)->fetch(); if ($conversion != null) { $quConversionFactorPriceToStock = $conversion->factor; @@ -1035,7 +1035,7 @@ class StockService extends BaseService { // A sub product will be used -> use QU conversions $subProduct = $this->getDatabase()->products($stockEntry->product_id); - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $stockEntry->product_id, $product->qu_id_stock, $subProduct->qu_id_stock)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $stockEntry->product_id, $product->qu_id_stock, $subProduct->qu_id_stock)->fetch(); if ($conversion != null) { $amount = $amount * $conversion->factor; @@ -1175,7 +1175,7 @@ class StockService extends BaseService if ($isValidProduct) { $product = $this->getDatabase()->products()->where('id = :1', $row->product_id)->fetch(); - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $product->id, $product->qu_id_stock, $row->qu_id)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $product->id, $product->qu_id_stock, $row->qu_id)->fetch(); $factor = 1.0; if ($conversion != null) @@ -1679,7 +1679,7 @@ class StockService extends BaseService { $productToKeep = $this->getDatabase()->products($productIdToKeep); $productToRemove = $this->getDatabase()->products($productIdToRemove); - $conversion = $this->getDatabase()->quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $productToRemove->id, $productToRemove->qu_id_stock, $productToKeep->qu_id_stock)->fetch(); + $conversion = $this->getDatabase()->cache__quantity_unit_conversions_resolved()->where('product_id = :1 AND from_qu_id = :2 AND to_qu_id = :3', $productToRemove->id, $productToRemove->qu_id_stock, $productToKeep->qu_id_stock)->fetch(); $factor = 1.0; if ($conversion != null) {