select([ 'products.id', 'products.code', 'products.name', 'categories.name as category_name', 'products.cost_price', // Assuming cost_price exists for value calculation ]) ->leftJoin('categories', 'products.category_id', '=', 'categories.id') ->leftJoin('inventories', 'products.id', '=', 'inventories.product_id') ->groupBy(['products.id', 'products.code', 'products.name', 'categories.name', 'products.cost_price']); // Filter by Warehouse (Current Inventory) if ($warehouseId) { $query->where('inventories.warehouse_id', $warehouseId); } // Filter by Category if ($categoryId) { $query->where('products.category_id', $categoryId); } // Filter by Search if ($search) { $query->where(function($q) use ($search) { $q->where('products.name', 'like', "%{$search}%") ->orWhere('products.code', 'like', "%{$search}%"); }); } // Add Aggregated Columns // 1. Current Inventory Quantity $query->addSelect(DB::raw('COALESCE(SUM(inventories.quantity), 0) as current_stock')); // 2. Sales in last 30 days (Outbound) // We need a subquery or join for this to be efficient, or we use a separate query and map. // Given potentially large data, subquery per row might be slow, but for pagination it's okay-ish. // Better approach: Join with a subquery of aggregated transactions. $thirtyDaysAgo = Carbon::now()->subDays(30); // Subquery for 30-day sales $salesSubquery = InventoryTransaction::query() ->select('inventories.product_id', DB::raw('ABS(SUM(inventory_transactions.quantity)) as sales_qty_30d')) ->join('inventories', 'inventory_transactions.inventory_id', '=', 'inventories.id') ->where('inventory_transactions.type', '出庫') // Adjust type as needed based on actual data ->where('inventory_transactions.actual_time', '>=', $thirtyDaysAgo) ->groupBy('inventories.product_id'); if ($warehouseId) { $salesSubquery->where('inventories.warehouse_id', $warehouseId); } $query->leftJoinSub($salesSubquery, 'sales_30d', function ($join) { $join->on('products.id', '=', 'sales_30d.product_id'); }); $query->addSelect(DB::raw('COALESCE(sales_30d.sales_qty_30d, 0) as sales_30d')); // 3. Last Sale Date // Use max actual_time from outbound transactions $lastSaleSubquery = InventoryTransaction::query() ->select('inventories.product_id', DB::raw('MAX(actual_time) as last_sale_date')) ->join('inventories', 'inventory_transactions.inventory_id', '=', 'inventories.id') ->where('inventory_transactions.type', '出庫') ->groupBy('inventories.product_id'); if ($warehouseId) { $lastSaleSubquery->where('inventories.warehouse_id', $warehouseId); } $query->leftJoinSub($lastSaleSubquery, 'last_sales', function ($join) { $join->on('products.id', '=', 'last_sales.product_id'); }); $query->addSelect('last_sales.last_sale_date'); // Apply Status Filter (Dead Stock etc) requires having clauses or wrapper query. // Dead Stock: stock > 0 AND (last_sale_date < 90 days ago OR last_sale_date IS NULL) // Slow Moving: turnover days > X? // Let's modify query to handle ordering and filtering on calculated fields if possible. // For simplicity in Laravel, we might fetch and transform, but pagination breaks. // We'll use HAVING for status filtering if needed. // Order by $sortBy = $filters['sort_by'] ?? 'turnover_days'; // Default sort $sortOrder = $filters['sort_order'] ?? 'desc'; // Turnover Days Calculation in SQL: (stock / (sales_30d / 30)) => (stock * 30) / sales_30d // Handle division by zero: if sales_30d is 0, turnover is 'Inf' (or very high number like 9999) $turnoverDaysSql = "CASE WHEN COALESCE(sales_30d.sales_qty_30d, 0) > 0 THEN (COALESCE(SUM(inventories.quantity), 0) * 30) / sales_30d.sales_qty_30d ELSE 9999 END"; $query->addSelect(DB::raw("$turnoverDaysSql as turnover_days")); // Only show items with stock > 0 ? User might want to see out of stock items too? // Usually analysis focuses on what IS in stock. But Dead Stock needs items with stock. // Stock-out analysis needs items with 0 stock. // Let's filter stock > 0 by default for "Turnover Analysis". // $query->havingRaw('current_stock > 0'); // Wait, better to let user filter? // For dead stock, definitive IS stock > 0. if ($statusFilter === 'dead') { $ninetyDaysAgo = Carbon::now()->subDays(90); $query->havingRaw("current_stock > 0 AND (last_sale_date < ? OR last_sale_date IS NULL)", [$ninetyDaysAgo]); } // Apply Sorting if ($sortBy === 'turnover_days') { $query->orderByRaw("$turnoverDaysSql $sortOrder"); } else if (in_array($sortBy, ['current_stock', 'sales_30d', 'last_sale_date'])) { $query->orderBy($sortBy, $sortOrder); } else { $query->orderBy('products.code', 'asc'); } return $query->paginate($perPage)->withQueryString()->through(function($item) { // Post-processing for display $item->turnover_days_display = $item->turnover_days >= 9999 ? '∞' : number_format($item->turnover_days, 1); // Determine Status Label $lastSale = $item->last_sale_date ? Carbon::parse($item->last_sale_date) : null; $daysSinceSale = $lastSale ? $lastSale->diffInDays(Carbon::now()) : 9999; if ($item->current_stock > 0 && $daysSinceSale > 90) { $item->status = 'dead'; // 滯銷 $item->status_label = '滯銷'; } elseif ($item->current_stock > 0 && $item->turnover_days > 60) { $item->status = 'slow'; // 週轉慢 $item->status_label = '週轉慢'; } elseif ($item->current_stock == 0) { $item->status = 'out_of_stock'; $item->status_label = '缺貨'; } else { $item->status = 'normal'; $item->status_label = '正常'; } return $item; }); } public function getKPIs(array $filters) { // Calculates aggregate KPIs $warehouseId = $filters['warehouse_id'] ?? null; $categoryId = $filters['category_id'] ?? null; // Helper to build base inv query $buildInvQuery = function() use ($warehouseId, $categoryId) { $q = DB::table('inventories') ->join('products', 'inventories.product_id', '=', 'products.id') ->where('inventories.quantity', '>', 0); if ($warehouseId) $q->where('inventories.warehouse_id', $warehouseId); if ($categoryId) $q->where('products.category_id', $categoryId); return $q; }; // 1. Total Inventory Value (Cost) $totalValue = (clone $buildInvQuery()) ->sum(DB::raw('inventories.quantity * COALESCE(products.cost_price, 0)')); // 2. Dead Stock Value (No sale in 90 days) // Need last sale date for each product-location or just product? // Assuming dead stock is product-level logic for simplicity. $ninetyDaysAgo = Carbon::now()->subDays(90); // Get IDs of products sold in last 90 days $soldProductIds = InventoryTransaction::query() ->where('type', '出庫') ->where('actual_time', '>=', $ninetyDaysAgo) ->distinct() ->pluck('inventory_id') // Wait, transaction links to inventory, inventory links to product. // We need product_id. ->map(function($id) { return DB::table('inventories')->where('id', $id)->value('product_id'); }) ->filter() ->unique() ->toArray(); // Optimization: Use join in subquery $soldProductIdsQuery = DB::table('inventory_transactions') ->join('inventories', 'inventory_transactions.inventory_id', '=', 'inventories.id') ->where('inventory_transactions.type', '出庫') ->where('inventory_transactions.actual_time', '>=', $ninetyDaysAgo) ->select('inventories.product_id') ->distinct(); $deadStockQuery = (clone $buildInvQuery()) ->whereNotIn('products.id', $soldProductIdsQuery); $deadStockValue = $deadStockQuery->sum(DB::raw('inventories.quantity * COALESCE(products.cost_price, 0)')); $deadStockCount = $deadStockQuery->count('products.id'); // Count of inventory records (batches) or products? // Let's count distinct products $deadStockProductCount = $deadStockQuery->distinct('products.id')->count('products.id'); // 3. Average Turnover Days (Company wide) // Formula: (Avg Inventory / COGS) * 365 ? // Simplified: (Total Stock / Total Sales 30d) * 30 $totalStock = (clone $buildInvQuery())->sum('inventories.quantity'); $totalSales30d = DB::table('inventory_transactions') ->join('inventories', 'inventory_transactions.inventory_id', '=', 'inventories.id') ->join('products', 'inventories.product_id', '=', 'products.id') ->where('inventory_transactions.type', '出庫') ->where('inventory_transactions.actual_time', '>=', Carbon::now()->subDays(30)) ->when($warehouseId, fn($q) => $q->where('inventories.warehouse_id', $warehouseId)) ->when($categoryId, fn($q) => $q->where('products.category_id', $categoryId)) ->sum(DB::raw('ABS(inventory_transactions.quantity)')); $avgTurnoverDays = $totalSales30d > 0 ? ($totalStock * 30) / $totalSales30d : 0; return [ 'total_stock_value' => $totalValue, 'dead_stock_value' => $deadStockValue, 'dead_stock_count' => $deadStockProductCount, 'avg_turnover_days' => round($avgTurnoverDays, 1), ]; } }