From 42dc55625a818b74f5f0f69da33ed8824b63dada Mon Sep 17 00:00:00 2001 From: fipwmaqzufheoxq92ebc <29818044+fipwmaqzufheoxq92ebc@users.noreply.github.com> Date: Tue, 18 Aug 2020 19:23:37 +0200 Subject: [PATCH] Improve Performance (#927) * Stock-Overview: Reduce amount of database queries and FindObjectInArray()-calls * Speed-up stock_current by improving products_resolved and creating indices. * Review Co-authored-by: Bernd Bestel --- controllers/StockController.php | 6 +-- migrations/0105.sql | 65 +++++++++++++++++++++++++++++++++ migrations/0106.sql | 29 +++++++++++++++ services/StockService.php | 11 +++++- views/stockoverview.blade.php | 60 +++++++++++++++--------------- 5 files changed, 134 insertions(+), 37 deletions(-) create mode 100644 migrations/0105.sql create mode 100644 migrations/0106.sql diff --git a/controllers/StockController.php b/controllers/StockController.php index f704c84e..ab88ffaa 100644 --- a/controllers/StockController.php +++ b/controllers/StockController.php @@ -16,17 +16,13 @@ class StockController extends BaseController $nextXDays = $usersService->GetUserSettings(GROCY_USER_ID)['stock_expring_soon_days']; return $this->renderPage($response, 'stockoverview', [ - 'products' => $this->getDatabase()->products()->where('active = 1')->orderBy('name'), - 'quantityunits' => $this->getDatabase()->quantity_units()->orderBy('name'), + 'currentStock' => $this->getStockService()->GetCurrentStockOverview(), 'locations' => $this->getDatabase()->locations()->orderBy('name'), - 'currentStock' => $this->getStockService()->GetCurrentStock(true), 'currentStockLocations' => $this->getStockService()->GetCurrentStockLocations(), - 'missingProducts' => $this->getStockService()->GetMissingProducts(), 'nextXDays' => $nextXDays, 'productGroups' => $this->getDatabase()->product_groups()->orderBy('name'), 'userfields' => $this->getUserfieldsService()->GetFields('products'), 'userfieldValues' => $this->getUserfieldsService()->GetAllValues('products'), - 'shoppingListItems' => $this->getDatabase()->shopping_list(), ]); } diff --git a/migrations/0105.sql b/migrations/0105.sql new file mode 100644 index 00000000..7ab17f23 --- /dev/null +++ b/migrations/0105.sql @@ -0,0 +1,65 @@ +CREATE VIEW uihelper_stock_current_overview_including_opened +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.product_id AS product_id, + sc.best_before_date AS best_before_date, + EXISTS(SELECT id FROM stock_missing_products_including_opened WHERE id = sc.product_id) AS product_missing, + (SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name, + (SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name_plural, + p.name AS product_name, + (SELECT name FROM product_groups WHERE product_groups.id = product_group_id) AS product_group_name, + EXISTS(SELECT * FROM shopping_list WHERE shopping_list.product_id = sc.product_id) AS on_shopping_list, + sc.factor_purchase_amount AS factor_purchase_amount, + (SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name, + (SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name_plural, + sc.is_aggregated_amount, + sc.amount_opened_aggregated +FROM ( + SELECT * + FROM stock_current + WHERE best_before_date IS NOT NULL + UNION + SELECT id, 0, 0, 0, 0, null, 0, 0, 0 + FROM stock_missing_products_including_opened + WHERE id NOT IN (SELECT product_id FROM stock_current) + ) sc +LEFT JOIN products p + ON sc.product_id = p.id; + +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.product_id AS product_id, + sc.best_before_date AS best_before_date, + EXISTS(SELECT id FROM stock_missing_products_including_opened WHERE id = sc.product_id) AS product_missing, + (SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name, + (SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_stock) AS qu_unit_name_plural, + p.name AS product_name, + (SELECT name FROM product_groups WHERE product_groups.id = product_group_id) AS product_group_name, + EXISTS(SELECT * FROM shopping_list WHERE shopping_list.product_id = sc.product_id) AS on_shopping_list, + sc.factor_purchase_amount AS factor_purchase_amount, + (SELECT name FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name, + (SELECT name_plural FROM quantity_units WHERE quantity_units.id = p.qu_id_purchase) AS qu_purchase_unit_name_plural, + sc.is_aggregated_amount, + sc.amount_opened_aggregated +FROM ( + SELECT * + FROM stock_current + WHERE best_before_date IS NOT NULL + UNION + SELECT id, 0, 0, 0, 0, null, 0, 0, 0 + FROM stock_missing_products + WHERE id NOT IN (SELECT product_id FROM stock_current) + ) sc +LEFT JOIN products p + ON sc.product_id = p.id; diff --git a/migrations/0106.sql b/migrations/0106.sql new file mode 100644 index 00000000..753cece3 --- /dev/null +++ b/migrations/0106.sql @@ -0,0 +1,29 @@ +CREATE INDEX ix_products_performance1 ON products ( + parent_product_id +); + +CREATE INDEX ix_products_performance2 ON products ( + CASE WHEN parent_product_id IS NULL THEN id ELSE parent_product_id END, + active +); + +CREATE INDEX ix_stock_performance1 ON stock ( + product_id, + open, + best_before_date, + amount +); + +DROP VIEW products_resolved; +CREATE VIEW products_resolved +AS +SELECT + CASE + WHEN p.parent_product_id IS NULL THEN + p.id + ELSE + p.parent_product_id + END AS parent_product_id, + p.id as sub_product_id +FROM products p +WHERE p.active = 1; diff --git a/services/StockService.php b/services/StockService.php index 2abfae88..ae499507 100644 --- a/services/StockService.php +++ b/services/StockService.php @@ -14,7 +14,16 @@ class StockService extends BaseService const TRANSACTION_TYPE_PRODUCT_OPENED = 'product-opened'; const TRANSACTION_TYPE_SELF_PRODUCTION = 'self-production'; - public function GetCurrentStock($includeNotInStockButMissingProducts = false) + public function GetCurrentStockOverview() + { + if (!GROCY_FEATURE_SETTING_STOCK_COUNT_OPENED_PRODUCTS_AGAINST_MINIMUM_STOCK_AMOUNT) { + return $this->getDatabase()->uihelper_stock_current_overview(); + } else { + return $this->getDatabase()->uihelper_stock_current_overview_including_opened(); + } + } + + public function GetCurrentStock($includeNotInStockButMissingProducts = false) { $sql = 'SELECT * FROM stock_current'; if ($includeNotInStockButMissingProducts) diff --git a/views/stockoverview.blade.php b/views/stockoverview.blade.php index 9024be13..97d90325 100644 --- a/views/stockoverview.blade.php +++ b/views/stockoverview.blade.php @@ -117,29 +117,29 @@ - @foreach($currentStock as $currentStockEntry) - amount > 0) table-warning @elseif (FindObjectInArrayByPropertyValue($missingProducts, 'id', $currentStockEntry->product_id) !== null) table-info @endif"> + @foreach($currentStock as $currentStockEntry) + amount > 0) table-warning @elseif ($currentStockEntry->product_missing) table-info @endif"> - 1 - {{ $__t('All') }} @if(GROCY_FEATURE_FLAG_STOCK_PRODUCT_OPENED_TRACKING) - + data-product-name="{{ $currentStockEntry->product_name }}" + data-product-qu-name="{{ $currentStockEntry->qu_unit_name }}"> 1 @endif @@ -150,10 +150,10 @@ - {{ FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->name }} - - @php $productGroup = FindObjectInArrayByPropertyValue($productGroups, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->product_group_id) @endphp - - @if($productGroup !== null){{ $productGroup->name }}@endif + {{ $currentStockEntry->product_name }} - {{ $currentStockEntry->amount }} {{ $__n($currentStockEntry->amount, FindObjectInArrayByPropertyValue($quantityunits, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->qu_id_stock)->name, FindObjectInArrayByPropertyValue($quantityunits, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->qu_id_stock)->name_plural) }} + @if($currentStockEntry->product_group_name !== null){{ $currentStockEntry->product_group_name }}@endif + + + {{ $currentStockEntry->amount }} {{ $__n($currentStockEntry->amount, $currentStockEntry->qu_unit_name, $currentStockEntry->qu_unit_name_plural) }} @if($currentStockEntry->amount_opened > 0){{ $__t('%s opened', $currentStockEntry->amount_opened) }}@endif @if($currentStockEntry->amount != $currentStockEntry->factor_purchase_amount) - ({{ $currentStockEntry->factor_purchase_amount }} {{ $__n($currentStockEntry->factor_purchase_amount, FindObjectInArrayByPropertyValue($quantityunits, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->qu_id_purchase)->name, FindObjectInArrayByPropertyValue($quantityunits, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->qu_id_purchase)->name_plural) }}) + ({{ $currentStockEntry->factor_purchase_amount }} {{ $__n($currentStockEntry->factor_purchase_amount, $currentStockEntry->qu_purchase_unit_name,$currentStockEntry->qu_purchase_unit_name_plural) }}) @endif @if($currentStockEntry->is_aggregated_amount == 1) - {{ $currentStockEntry->amount_aggregated }} {{ $__n($currentStockEntry->amount_aggregated, FindObjectInArrayByPropertyValue($quantityunits, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->qu_id_stock)->name, FindObjectInArrayByPropertyValue($quantityunits, 'id', FindObjectInArrayByPropertyValue($products, 'id', $currentStockEntry->product_id)->qu_id_stock)->name_plural) }} + {{ $currentStockEntry->amount_aggregated }} {{ $__n($currentStockEntry->amount_aggregated, $currentStockEntry->qu_unit_name, $currentStockEntry->qu_unit_name_plural) }} @if($currentStockEntry->amount_opened_aggregated > 0){{ $__t('%s opened', $currentStockEntry->amount_opened_aggregated) }}@endif @endif @if(boolval($userSettings['show_icon_on_stock_overview_page_when_product_is_on_shopping_list'])) - @php $currentStockEntryShoppingListItems = FindAllObjectsInArrayByPropertyValue($shoppingListItems, 'product_id', $currentStockEntry->product_id) @endphp - @if(count($currentStockEntryShoppingListItems) > 0) + @if($currentStockEntry->on_shopping_list) @@ -236,12 +234,12 @@ - @foreach(FindAllObjectsInArrayByPropertyValue($currentStockLocations, 'product_id', $currentStockEntry->product_id) as $locationsForProduct) + @foreach(FindAllObjectsInArrayByPropertyValue($currentStockLocations, 'product_id', $currentStockEntry->product_id) as $locationsForProduct) {{ FindObjectInArrayByPropertyValue($locations, 'id', $locationsForProduct->location_id)->name }} @endforeach - @if($currentStockEntry->best_before_date < date('Y-m-d 23:59:59', strtotime('-1 days')) && $currentStockEntry->amount > 0) expired @elseif($currentStockEntry->best_before_date < date('Y-m-d 23:59:59', strtotime("+$nextXDays days")) && $currentStockEntry->amount > 0) expiring @endif @if(FindObjectInArrayByPropertyValue($missingProducts, 'id', $currentStockEntry->product_id) !== null) belowminstockamount @endif + @if($currentStockEntry->best_before_date < date('Y-m-d 23:59:59', strtotime('-1 days')) && $currentStockEntry->amount > 0) expired @elseif($currentStockEntry->best_before_date < date('Y-m-d 23:59:59', strtotime("+$nextXDays days")) && $currentStockEntry->amount > 0) expiring @endif @if($currentStockEntry->product_missing) belowminstockamount @endif @include('components.userfields_tbody', array(