Optimized performance of GetProductDetails

This commit is contained in:
Bernd Bestel 2023-09-01 17:03:22 +02:00
parent 07db1f35bc
commit fdbb8a045a
No known key found for this signature in database
GPG Key ID: 71BD34C0D4891300
3 changed files with 79 additions and 63 deletions

64
migrations/0234.sql Normal file
View File

@ -0,0 +1,64 @@
CREATE VIEW uihelper_product_details
AS
SELECT
p.id,
plp.purchased_date AS last_purchased_date,
plp.price AS last_purchased_price,
plp.shopping_location_id AS last_purchased_shopping_location_id,
pap.price AS average_price,
sl.average_shelf_life_days,
pcp.price AS current_price,
last_used.used_date AS last_used_date,
next_due.best_before_date AS next_due_date,
IFNULL((spoil_count.amount * 100.0) / consume_count.amount, 0) AS spoil_rate,
CAST(IFNULL(quc_purchase2stock.factor, 1.0) AS REAL) AS qu_factor_purchase_to_stock,
CAST(IFNULL(quc_price2stock.factor, 1.0) AS REAL) AS qu_factor_price_to_stock,
CASE WHEN EXISTS(SELECT 1 FROM products px WHERE px.parent_product_id = p.id) THEN 1 ELSE 0 END AS has_childs
FROM products p
LEFT JOIN cache__products_last_purchased plp
ON p.id = plp.product_id
LEFT JOIN cache__products_average_price pap
ON p.id = pap.product_id
LEFT JOIN stock_average_product_shelf_life sl
ON p.id = sl.id
LEFT JOIN products_current_price pcp
ON p.id = pcp.product_id
LEFT JOIN cache__quantity_unit_conversions_resolved quc_purchase2stock
ON p.id = quc_purchase2stock.product_id
AND p.qu_id_purchase = quc_purchase2stock.from_qu_id
AND p.qu_id_stock = quc_purchase2stock.to_qu_id
LEFT JOIN cache__quantity_unit_conversions_resolved quc_price2stock
ON p.id = quc_price2stock.product_id
AND p.qu_id_price = quc_price2stock.from_qu_id
AND p.qu_id_stock = quc_price2stock.to_qu_id
LEFT JOIN (
SELECT product_id, MAX(used_date) AS used_date
FROM stock_log
WHERE transaction_type = 'consume'
AND undone = 0
GROUP BY product_id
) last_used
ON p.id = last_used.product_id
LEFT JOIN (
SELECT product_id,MIN(best_before_date) AS best_before_date
FROM stock
GROUP BY product_id
) next_due
ON p.id = next_due.product_id
LEFT JOIN (
SELECT product_id, SUM(amount) AS amount
FROM stock_log
WHERE transaction_type = 'consume'
AND undone = 0
GROUP BY product_id
) consume_count
ON p.id = consume_count.product_id
LEFT JOIN (
SELECT product_id, SUM(amount) AS amount
FROM stock_log
WHERE transaction_type = 'consume'
AND undone = 0
AND spoiled = 1
GROUP BY product_id
) spoil_count
ON p.id = spoil_count.product_id;

View File

@ -204,7 +204,7 @@ class LocalizationService
$quantityUnits = null;
try
{
$quantityUnits = $this->getDatabase()->quantity_units()->fetchAll();
$quantityUnits = $this->getDatabase()->quantity_units()->where('active = 1')->fetchAll();
}
catch (\Exception $ex)
{

View File

@ -711,42 +711,14 @@ class StockService extends BaseService
$stockCurrentRow->is_aggregated_amount = 0;
}
$productLastPurchased = $this->getDatabase()->cache__products_last_purchased()->where('product_id', $productId)->fetch();
$lastPurchasedDate = null;
$lastPrice = null;
$lastShoppingLocation = null;
$avgPrice = null;
if ($productLastPurchased)
{
$lastPurchasedDate = $productLastPurchased->purchased_date;
$lastPrice = $productLastPurchased->price;
$lastShoppingLocation = $productLastPurchased->shopping_location_id;
$avgPriceRow = $this->getDatabase()->cache__products_average_price()->where('product_id', $productId)->fetch();
if ($avgPriceRow)
{
$avgPrice = $avgPriceRow->price;
}
}
$detailsRow = $this->getDatabase()->uihelper_product_details()->where('id', $productId)->fetch();
$product = $this->getDatabase()->products($productId);
$productBarcodes = $this->getDatabase()->product_barcodes()->where('product_id', $productId)->fetchAll();
$productLastUsed = $this->getDatabase()->stock_log()->where('product_id', $productId)->where('transaction_type', self::TRANSACTION_TYPE_CONSUME)->where('undone', 0)->max('used_date');
$nextDueDate = $this->getDatabase()->stock()->where('product_id', $productId)->min('best_before_date');
$quPurchase = $this->getDatabase()->quantity_units($product->qu_id_purchase);
$quStock = $this->getDatabase()->quantity_units($product->qu_id_stock);
$quConsume = $this->getDatabase()->quantity_units($product->qu_id_consume);
$quPrice = $this->getDatabase()->quantity_units($product->qu_id_price);
$location = $this->getDatabase()->locations($product->location_id);
$averageShelfLifeDays = $this->getDatabase()->stock_average_product_shelf_life()->where('id', $productId)->fetch()->average_shelf_life_days;
$currentPrice = $this->getDatabase()->products_current_price()->where('product_id', $productId)->fetch()->price;
$consumeCount = $this->getDatabase()->stock_log()->where('product_id', $productId)->where('transaction_type', self::TRANSACTION_TYPE_CONSUME)->where('undone = 0')->sum('amount') * -1;
$consumeCountSpoiled = $this->getDatabase()->stock_log()->where('product_id', $productId)->where('transaction_type', self::TRANSACTION_TYPE_CONSUME)->where('undone = 0 AND spoiled = 1')->sum('amount') * -1;
if ($consumeCount == 0 || $consumeCount == null)
{
$consumeCount = 1;
}
$spoilRate = ($consumeCountSpoiled * 100.0) / $consumeCount;
$defaultConsumeLocation = null;
if (!empty($product->default_consume_location_id))
@ -754,31 +726,11 @@ class StockService extends BaseService
$defaultConsumeLocation = $this->getDatabase()->locations($product->default_consume_location_id);
}
$quConversionFactorPurchaseToStock = 1.0;
if ($product->qu_id_stock != $product->qu_id_purchase)
{
$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;
}
}
$quConversionFactorPriceToStock = 1.0;
if ($product->qu_id_stock != $product->qu_id_price)
{
$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;
}
}
return [
'product' => $product,
'product_barcodes' => $productBarcodes,
'last_purchased' => $lastPurchasedDate,
'last_used' => $productLastUsed,
'last_purchased' => $detailsRow->last_purchased_date,
'last_used' => $detailsRow->last_used_date,
'stock_amount' => $stockCurrentRow->amount,
'stock_value' => $stockCurrentRow->value,
'stock_amount_opened' => $stockCurrentRow->amount_opened,
@ -788,21 +740,21 @@ class StockService extends BaseService
'default_quantity_unit_purchase' => $quPurchase,
'default_quantity_unit_consume' => $quConsume,
'quantity_unit_price' => $quPrice,
'last_price' => $lastPrice,
'avg_price' => $avgPrice,
'oldest_price' => $currentPrice, // Deprecated
'current_price' => $currentPrice,
'last_shopping_location_id' => $lastShoppingLocation,
'last_price' => $detailsRow->last_purchased_price,
'avg_price' => $detailsRow->average_price,
'oldest_price' => $detailsRow->current_price, // Deprecated
'current_price' => $detailsRow->current_price,
'last_shopping_location_id' => $detailsRow->last_purchased_shopping_location_id,
'default_shopping_location_id' => $product->shopping_location_id,
'next_due_date' => $nextDueDate,
'next_due_date' => $detailsRow->next_due_date,
'location' => $location,
'average_shelf_life_days' => $averageShelfLifeDays,
'spoil_rate_percent' => $spoilRate,
'average_shelf_life_days' => $detailsRow->average_shelf_life_days,
'spoil_rate_percent' => $detailsRow->spoil_rate,
'is_aggregated_amount' => $stockCurrentRow->is_aggregated_amount,
'has_childs' => $this->getDatabase()->products()->where('parent_product_id = :1', $product->id)->count() !== 0,
'has_childs' => boolval($detailsRow->has_childs),
'default_consume_location' => $defaultConsumeLocation,
'qu_conversion_factor_purchase_to_stock' => $quConversionFactorPurchaseToStock,
'qu_conversion_factor_price_to_stock' => $quConversionFactorPriceToStock
'qu_conversion_factor_purchase_to_stock' => $detailsRow->qu_factor_purchase_to_stock,
'qu_conversion_factor_price_to_stock' => $detailsRow->qu_factor_price_to_stock
];
}