feat: 實作即時庫存查詢功能、儀表板庫存導盤,及優化手動入庫批號與儲位連動與選單顯示
This commit is contained in:
@@ -229,9 +229,137 @@ class InventoryService implements InventoryServiceInterface
|
||||
->first();
|
||||
}
|
||||
|
||||
public function getDashboardStats(): array
|
||||
/**
|
||||
* 即時庫存查詢:統計卡片 + 分頁明細
|
||||
*/
|
||||
public function getStockQueryData(array $filters = [], int $perPage = 10): array
|
||||
{
|
||||
// 庫存總表 join 安全庫存表,計算低庫存
|
||||
$today = now()->toDateString();
|
||||
$expiryThreshold = now()->addDays(30)->toDateString();
|
||||
|
||||
// 基礎查詢
|
||||
$query = Inventory::query()
|
||||
->join('products', 'inventories.product_id', '=', 'products.id')
|
||||
->join('warehouses', 'inventories.warehouse_id', '=', 'warehouses.id')
|
||||
->leftJoin('categories', 'products.category_id', '=', 'categories.id')
|
||||
->leftJoin('warehouse_product_safety_stocks as ss', function ($join) {
|
||||
$join->on('inventories.warehouse_id', '=', 'ss.warehouse_id')
|
||||
->on('inventories.product_id', '=', 'ss.product_id');
|
||||
})
|
||||
->whereNull('inventories.deleted_at')
|
||||
->select([
|
||||
'inventories.id',
|
||||
'inventories.warehouse_id',
|
||||
'inventories.product_id',
|
||||
'inventories.quantity',
|
||||
'inventories.batch_number',
|
||||
'inventories.expiry_date',
|
||||
'inventories.location',
|
||||
'inventories.quality_status',
|
||||
'inventories.arrival_date',
|
||||
'products.code as product_code',
|
||||
'products.name as product_name',
|
||||
'categories.name as category_name',
|
||||
'warehouses.name as warehouse_name',
|
||||
'ss.safety_stock',
|
||||
]);
|
||||
|
||||
// 篩選:倉庫
|
||||
if (!empty($filters['warehouse_id'])) {
|
||||
$query->where('inventories.warehouse_id', $filters['warehouse_id']);
|
||||
}
|
||||
|
||||
// 篩選:分類
|
||||
if (!empty($filters['category_id'])) {
|
||||
$query->where('products.category_id', $filters['category_id']);
|
||||
}
|
||||
|
||||
// 篩選:關鍵字(商品代碼或名稱)
|
||||
if (!empty($filters['search'])) {
|
||||
$search = $filters['search'];
|
||||
$query->where(function ($q) use ($search) {
|
||||
$q->where('products.code', 'like', "%{$search}%")
|
||||
->orWhere('products.name', 'like', "%{$search}%");
|
||||
});
|
||||
}
|
||||
|
||||
// 篩選:狀態 (改為對齊聚合統計的判斷標準)
|
||||
if (!empty($filters['status'])) {
|
||||
switch ($filters['status']) {
|
||||
case 'low_stock':
|
||||
$query->whereIn(DB::raw('(inventories.warehouse_id, inventories.product_id)'), function ($sub) {
|
||||
$sub->select('i2.warehouse_id', 'i2.product_id')
|
||||
->from('inventories as i2')
|
||||
->join('warehouse_product_safety_stocks as ss2', function ($join) {
|
||||
$join->on('i2.warehouse_id', '=', 'ss2.warehouse_id')
|
||||
->on('i2.product_id', '=', 'ss2.product_id');
|
||||
})
|
||||
->whereNull('i2.deleted_at')
|
||||
->groupBy('i2.warehouse_id', 'i2.product_id', 'ss2.safety_stock')
|
||||
->havingRaw('SUM(i2.quantity) <= ss2.safety_stock');
|
||||
});
|
||||
break;
|
||||
case 'negative':
|
||||
$query->whereIn(DB::raw('(inventories.warehouse_id, inventories.product_id)'), function ($sub) {
|
||||
$sub->select('i2.warehouse_id', 'i2.product_id')
|
||||
->from('inventories as i2')
|
||||
->whereNull('i2.deleted_at')
|
||||
->groupBy('i2.warehouse_id', 'i2.product_id')
|
||||
->havingRaw('SUM(i2.quantity) < 0');
|
||||
});
|
||||
break;
|
||||
case 'expiring':
|
||||
$query->whereNotNull('inventories.expiry_date')
|
||||
->where('inventories.expiry_date', '>', $today)
|
||||
->where('inventories.expiry_date', '<=', $expiryThreshold);
|
||||
break;
|
||||
case 'expired':
|
||||
$query->whereNotNull('inventories.expiry_date')
|
||||
->where('inventories.expiry_date', '<=', $today);
|
||||
break;
|
||||
case 'abnormal':
|
||||
// 只要該「倉庫-品項」對應的總庫存有低庫存、負庫存,或該批次已過期/即將過期
|
||||
$query->where(function ($q) use ($today, $expiryThreshold) {
|
||||
// 1. 低庫存或負庫存 (依聚合判斷)
|
||||
$q->whereIn(DB::raw('(inventories.warehouse_id, inventories.product_id)'), function ($sub) {
|
||||
$sub->select('i3.warehouse_id', 'i3.product_id')
|
||||
->from('inventories as i3')
|
||||
->leftJoin('warehouse_product_safety_stocks as ss3', function ($join) {
|
||||
$join->on('i3.warehouse_id', '=', 'ss3.warehouse_id')
|
||||
->on('i3.product_id', '=', 'ss3.product_id');
|
||||
})
|
||||
->whereNull('i3.deleted_at')
|
||||
->groupBy('i3.warehouse_id', 'i3.product_id', 'ss3.safety_stock')
|
||||
->havingRaw('SUM(i3.quantity) < 0 OR (ss3.safety_stock IS NOT NULL AND SUM(i3.quantity) <= ss3.safety_stock)');
|
||||
})
|
||||
// 2. 或該批次效期異常
|
||||
->orWhere(function ($q_batch) use ($expiryThreshold) {
|
||||
$q_batch->whereNotNull('inventories.expiry_date')
|
||||
->where('inventories.expiry_date', '<=', $expiryThreshold);
|
||||
});
|
||||
});
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
// 排序
|
||||
$sortBy = $filters['sort_by'] ?? 'products.code';
|
||||
$sortOrder = $filters['sort_order'] ?? 'asc';
|
||||
$allowedSorts = ['products.code', 'products.name', 'warehouses.name', 'inventories.quantity', 'inventories.expiry_date'];
|
||||
if (in_array($sortBy, $allowedSorts)) {
|
||||
$query->orderBy($sortBy, $sortOrder);
|
||||
} else {
|
||||
$query->orderBy('products.code', 'asc');
|
||||
}
|
||||
|
||||
// 統計卡片(無篩選條件下的全域統計)
|
||||
// 1. 庫存品項數:在庫的「倉庫-商品」對總數
|
||||
$totalItems = DB::table('inventories')
|
||||
->whereNull('deleted_at')
|
||||
->distinct()
|
||||
->count(DB::raw('CONCAT(warehouse_id, "-", product_id)'));
|
||||
|
||||
// 2. 低庫存:以「倉庫-商品」聚合後的總量與安全庫存比較 (品項計數)
|
||||
$lowStockCount = DB::table('warehouse_product_safety_stocks as ss')
|
||||
->join(DB::raw('(SELECT warehouse_id, product_id, SUM(quantity) as total_qty FROM inventories WHERE deleted_at IS NULL GROUP BY warehouse_id, product_id) as inv'),
|
||||
function ($join) {
|
||||
@@ -241,11 +369,200 @@ class InventoryService implements InventoryServiceInterface
|
||||
->whereRaw('inv.total_qty <= ss.safety_stock')
|
||||
->count();
|
||||
|
||||
// 3. 負庫存:只要該「倉庫-商品」的總庫存為負數 (品項計數)
|
||||
$negativeCount = DB::table(DB::raw('(SELECT warehouse_id, product_id, SUM(quantity) as total_qty FROM inventories WHERE deleted_at IS NULL GROUP BY warehouse_id, product_id) as inv'))
|
||||
->where('total_qty', '<', 0)
|
||||
->count();
|
||||
|
||||
// 4. 即將過期:有任一批次效期符合的「品項」總數
|
||||
$expiringCount = DB::table('inventories')
|
||||
->whereNull('deleted_at')
|
||||
->whereNotNull('expiry_date')
|
||||
->where('expiry_date', '<=', $expiryThreshold)
|
||||
->distinct()
|
||||
->count(DB::raw('CONCAT(warehouse_id, "-", product_id)'));
|
||||
|
||||
// 分頁
|
||||
$paginated = $query->paginate($perPage)->withQueryString();
|
||||
|
||||
// 為每筆紀錄附加最後入庫/出庫時間 + 狀態
|
||||
$items = collect($paginated->items())->map(function ($item) use ($today, $expiryThreshold) {
|
||||
$lastIn = \App\Modules\Inventory\Models\InventoryTransaction::where('inventory_id', $item->id)
|
||||
->where('type', '入庫')
|
||||
->orderByDesc('actual_time')
|
||||
->value('actual_time');
|
||||
|
||||
$lastOut = \App\Modules\Inventory\Models\InventoryTransaction::where('inventory_id', $item->id)
|
||||
->where('type', '出庫')
|
||||
->orderByDesc('actual_time')
|
||||
->value('actual_time');
|
||||
|
||||
// 計算狀態 (明細表格依然呈現該批次的狀態)
|
||||
$statuses = [];
|
||||
if ($item->quantity < 0) {
|
||||
$statuses[] = 'negative';
|
||||
}
|
||||
if ($item->safety_stock !== null && $item->quantity <= $item->safety_stock && $item->quantity >= 0) {
|
||||
$statuses[] = 'low_stock';
|
||||
}
|
||||
if ($item->expiry_date) {
|
||||
if ($item->expiry_date <= $today) {
|
||||
$statuses[] = 'expired';
|
||||
} elseif ($item->expiry_date <= $expiryThreshold) {
|
||||
$statuses[] = 'expiring';
|
||||
}
|
||||
}
|
||||
if (empty($statuses)) {
|
||||
$statuses[] = 'normal';
|
||||
}
|
||||
|
||||
return [
|
||||
'id' => $item->id,
|
||||
'product_code' => $item->product_code,
|
||||
'product_name' => $item->product_name,
|
||||
'category_name' => $item->category_name,
|
||||
'warehouse_name' => $item->warehouse_name,
|
||||
'batch_number' => $item->batch_number,
|
||||
'quantity' => $item->quantity,
|
||||
'safety_stock' => $item->safety_stock,
|
||||
'expiry_date' => $item->expiry_date ? \Carbon\Carbon::parse($item->expiry_date)->toDateString() : null,
|
||||
'location' => $item->location,
|
||||
'quality_status' => $item->quality_status,
|
||||
'last_inbound' => $lastIn ? \Carbon\Carbon::parse($lastIn)->toDateString() : null,
|
||||
'last_outbound' => $lastOut ? \Carbon\Carbon::parse($lastOut)->toDateString() : null,
|
||||
'statuses' => $statuses,
|
||||
];
|
||||
});
|
||||
|
||||
return [
|
||||
'productsCount' => Product::count(),
|
||||
'summary' => [
|
||||
'totalItems' => $totalItems,
|
||||
'lowStockCount' => $lowStockCount,
|
||||
'negativeCount' => $negativeCount,
|
||||
'expiringCount' => $expiringCount,
|
||||
],
|
||||
'data' => $items->toArray(),
|
||||
'pagination' => [
|
||||
'total' => $paginated->total(),
|
||||
'per_page' => $paginated->perPage(),
|
||||
'current_page' => $paginated->currentPage(),
|
||||
'last_page' => $paginated->lastPage(),
|
||||
'links' => $paginated->linkCollection()->toArray(),
|
||||
],
|
||||
];
|
||||
}
|
||||
|
||||
public function getDashboardStats(): array
|
||||
{
|
||||
$today = now()->toDateString();
|
||||
$expiryThreshold = now()->addDays(30)->toDateString();
|
||||
|
||||
// 1. 庫存品項數 (Unique Product-Warehouse)
|
||||
$totalItems = DB::table('inventories')
|
||||
->whereNull('deleted_at')
|
||||
->distinct()
|
||||
->count(DB::raw('CONCAT(warehouse_id, "-", product_id)'));
|
||||
|
||||
// 2. 低庫存 (品項計數)
|
||||
$lowStockCount = DB::table('warehouse_product_safety_stocks as ss')
|
||||
->join(DB::raw('(SELECT warehouse_id, product_id, SUM(quantity) as total_qty FROM inventories WHERE deleted_at IS NULL GROUP BY warehouse_id, product_id) as inv'),
|
||||
function ($join) {
|
||||
$join->on('ss.warehouse_id', '=', 'inv.warehouse_id')
|
||||
->on('ss.product_id', '=', 'inv.product_id');
|
||||
})
|
||||
->whereRaw('inv.total_qty <= ss.safety_stock')
|
||||
->count();
|
||||
|
||||
// 3. 負庫存 (品項計數)
|
||||
$negativeCount = DB::table(DB::raw('(SELECT warehouse_id, product_id, SUM(quantity) as total_qty FROM inventories WHERE deleted_at IS NULL GROUP BY warehouse_id, product_id) as inv'))
|
||||
->where('total_qty', '<', 0)
|
||||
->count();
|
||||
|
||||
// 4. 即將過期 (品項計數)
|
||||
$expiringCount = DB::table('inventories')
|
||||
->whereNull('deleted_at')
|
||||
->whereNotNull('expiry_date')
|
||||
->where('expiry_date', '<=', $expiryThreshold)
|
||||
->distinct()
|
||||
->count(DB::raw('CONCAT(warehouse_id, "-", product_id)'));
|
||||
|
||||
// 異常庫存前 10 筆 (明細面依然以個別批次為主,供快速跳轉)
|
||||
$abnormalItems = Inventory::query()
|
||||
->join('products', 'inventories.product_id', '=', 'products.id')
|
||||
->join('warehouses', 'inventories.warehouse_id', '=', 'warehouses.id')
|
||||
->leftJoin('warehouse_product_safety_stocks as ss', function ($join) {
|
||||
$join->on('inventories.warehouse_id', '=', 'ss.warehouse_id')
|
||||
->on('inventories.product_id', '=', 'ss.product_id');
|
||||
})
|
||||
->whereNull('inventories.deleted_at')
|
||||
->where(function ($q) use ($today, $expiryThreshold) {
|
||||
// 1. 屬於低庫存或負庫存品項的批次
|
||||
$q->whereIn(DB::raw('(inventories.warehouse_id, inventories.product_id)'), function ($sub) {
|
||||
$sub->select('i3.warehouse_id', 'i3.product_id')
|
||||
->from('inventories as i3')
|
||||
->leftJoin('warehouse_product_safety_stocks as ss3', function ($join) {
|
||||
$join->on('i3.warehouse_id', '=', 'ss3.warehouse_id')
|
||||
->on('i3.product_id', '=', 'ss3.product_id');
|
||||
})
|
||||
->whereNull('i3.deleted_at')
|
||||
->groupBy('i3.warehouse_id', 'i3.product_id', 'ss3.safety_stock')
|
||||
->havingRaw('SUM(i3.quantity) < 0 OR (ss3.safety_stock IS NOT NULL AND SUM(i3.quantity) <= ss3.safety_stock)');
|
||||
})
|
||||
// 2. 或單一批次效期異常
|
||||
->orWhere(function ($q2) use ($expiryThreshold) {
|
||||
$q2->whereNotNull('inventories.expiry_date')
|
||||
->where('inventories.expiry_date', '<=', $expiryThreshold);
|
||||
});
|
||||
})
|
||||
->select([
|
||||
'inventories.id',
|
||||
'inventories.quantity',
|
||||
'inventories.expiry_date',
|
||||
'products.code as product_code',
|
||||
'products.name as product_name',
|
||||
'warehouses.name as warehouse_name',
|
||||
'ss.safety_stock',
|
||||
])
|
||||
->orderBy('inventories.id', 'desc')
|
||||
->limit(10)
|
||||
->get()
|
||||
->map(function ($item) use ($today, $expiryThreshold) {
|
||||
$statuses = [];
|
||||
if ($item->quantity < 0) {
|
||||
$statuses[] = 'negative';
|
||||
}
|
||||
if ($item->safety_stock !== null && $item->quantity <= $item->safety_stock && $item->quantity >= 0) {
|
||||
$statuses[] = 'low_stock';
|
||||
}
|
||||
if ($item->expiry_date) {
|
||||
if ($item->expiry_date <= $today) {
|
||||
$statuses[] = 'expired';
|
||||
} elseif ($item->expiry_date <= $expiryThreshold) {
|
||||
$statuses[] = 'expiring';
|
||||
}
|
||||
}
|
||||
return [
|
||||
'id' => $item->id,
|
||||
'product_code' => $item->product_code,
|
||||
'product_name' => $item->product_name,
|
||||
'warehouse_name' => $item->warehouse_name,
|
||||
'quantity' => $item->quantity,
|
||||
'safety_stock' => $item->safety_stock,
|
||||
'expiry_date' => $item->expiry_date,
|
||||
'statuses' => $statuses,
|
||||
];
|
||||
})
|
||||
->toArray();
|
||||
|
||||
return [
|
||||
'productsCount' => $totalItems,
|
||||
'warehousesCount' => Warehouse::count(),
|
||||
'lowStockCount' => $lowStockCount,
|
||||
'negativeCount' => $negativeCount,
|
||||
'expiringCount' => $expiringCount,
|
||||
'totalInventoryQuantity' => Inventory::sum('quantity'),
|
||||
'abnormalItems' => $abnormalItems,
|
||||
];
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
Reference in New Issue
Block a user