From 32ad2da600b48f547758648b8d452f504a3587a9 Mon Sep 17 00:00:00 2001 From: "Tommy\\2Fi-Staff" Date: Mon, 9 Feb 2026 20:03:54 +0800 Subject: [PATCH] Update StockBalanceReport & StockInTracabilityReport --- .../modules/report/service/ReportService.kt | 176 +++++- .../modules/report/web/ReportController.kt | 54 ++ .../resources/jasper/StockBalanceReport.jrxml | 588 ++++++++++++++++++ .../jasper/StockInTraceabilityReport.jrxml | 26 +- 4 files changed, 806 insertions(+), 38 deletions(-) create mode 100644 src/main/resources/jasper/StockBalanceReport.jrxml diff --git a/src/main/java/com/ffii/fpsms/modules/report/service/ReportService.kt b/src/main/java/com/ffii/fpsms/modules/report/service/ReportService.kt index 09edeb5..139d5e2 100644 --- a/src/main/java/com/ffii/fpsms/modules/report/service/ReportService.kt +++ b/src/main/java/com/ffii/fpsms/modules/report/service/ReportService.kt @@ -329,7 +329,6 @@ return result * Queries the database for Stock In Traceability Report data. * Joins stock_in_line, stock_in, items, qc_result, inventory_lot, inventory_lot_line, warehouse, and shop tables. * Supports comma-separated values for stockCategory (items.type) and itemCode. - * When "All" is selected, it expands to all categories: MAT, FG, WIP, NM, CMB. */ fun searchStockInTraceabilityReport( stockCategory: String?, @@ -339,22 +338,7 @@ return result ): List> { val args = mutableMapOf() - // Handle "All" option by expanding to all categories - val processedStockCategory = if (!stockCategory.isNullOrBlank()) { - val categories = stockCategory.split(",").map { it.trim() }.filter { it.isNotBlank() } - if (categories.contains("All")) { - // Replace "All" with all categories: MAT, FG, WIP, NM, CMB - val allCategories = listOf("MAT", "FG", "WIP", "NM", "CMB") - val otherCategories = categories.filter { it != "All" } - (allCategories + otherCategories).distinct().joinToString(",") - } else { - stockCategory - } - } else { - stockCategory - } - - val stockCategorySql = buildMultiValueExactClause(processedStockCategory, "it.type", "stockCategory", args) + val stockCategorySql = buildMultiValueExactClause(stockCategory, "it.type", "stockCategory", args) val itemCodeSql = buildMultiValueLikeClause(itemCode, "it.code", "itemCode", args) val lastInDateStartSql = if (!lastInDateStart.isNullOrBlank()) { @@ -375,14 +359,14 @@ return result COALESCE(sil.dnNo, '') as dnNo, COALESCE(sil.lotNo, il.lotNo, '') as lotNo, COALESCE(DATE_FORMAT(COALESCE(sil.expiryDate, il.expiryDate), '%Y-%m-%d'), '') as expiryDate, - FORMAT(COALESCE(sil.acceptedQty, 0), 2) as stockInQty, - FORMAT(COALESCE(sil.acceptedQty, 0), 2) as iqcSampleQty, - FORMAT(COALESCE(qr.failQty, 0), 2) as iqcDefectQty, - FORMAT(CASE + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(sil.acceptedQty, 0), 2))) as stockInQty, + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(sil.acceptedQty, 0), 2))) as iqcSampleQty, + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(qr.failQty, 0), 2))) as iqcDefectQty, + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(CASE WHEN COALESCE(sil.acceptedQty, 0) > 0 THEN ROUND((COALESCE(qr.failQty, 0) / sil.acceptedQty) * 100, 2) ELSE 0 - END, 2) as iqcDefectPercentage, + END, 2))) as iqcDefectPercentage, CASE WHEN qr.qcPassed = true OR qr.qcPassed IS NULL THEN 'Accept' ELSE 'Reject' @@ -391,9 +375,9 @@ return result COALESCE(wh.code, '') as storeLocation, COALESCE(sp_si.code, sp_po.code, '') as supplierID, COALESCE(sp_si.name, sp_po.name, '') as supplierName, - FORMAT(SUM(COALESCE(sil.acceptedQty, 0)) OVER (PARTITION BY it.id), 2) as totalStockInQty, - FORMAT(SUM(COALESCE(sil.acceptedQty, 0)) OVER (PARTITION BY it.id), 2) as totalIqcSampleQty, - FORMAT(SUM(COALESCE(qr.failQty, 0)) OVER (PARTITION BY it.id), 2) as totalIqcDefectQty + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(sil.acceptedQty, 0)) OVER (PARTITION BY it.id), 2))) as totalStockInQty, + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(sil.acceptedQty, 0)) OVER (PARTITION BY it.id), 2))) as totalIqcSampleQty, + TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(qr.failQty, 0)) OVER (PARTITION BY it.id), 2))) as totalIqcDefectQty FROM stock_in_line sil LEFT JOIN stock_in si ON sil.stockInId = si.id LEFT JOIN purchase_order po ON sil.purchaseOrderId = po.id @@ -418,6 +402,148 @@ return result } + /** + * Queries the database for Stock Balance Report data. + * Shows stock balances by item code and lot number, including opening balance, + * cumulative stock in/out, current balance, store locations, and last in/out dates. + * Opening balance comes from stock_ledger where type = 'adj'. + */ + fun searchStockBalanceReport( + stockCategory: String?, + itemCode: String?, + balanceFilterStart: String?, + balanceFilterEnd: String?, + storeLocation: String?, + lastInDateStart: String?, + lastInDateEnd: String?, + lastOutDateStart: String?, + lastOutDateEnd: String? + ): List> { + val args = mutableMapOf() + + val stockCategorySql = buildMultiValueExactClause(stockCategory, "it.type", "stockCategory", args) + val itemCodeSql = buildMultiValueLikeClause(itemCode, "it.code", "itemCode", args) + + val storeLocationSql = if (!storeLocation.isNullOrBlank()) { + args["storeLocation"] = "%$storeLocation%" + "AND wh.code LIKE :storeLocation" + } else "" + + val sql = """ + SELECT + '' as stockSubCategory, + COALESCE(it.code, '') as itemNo, + COALESCE(it.name, '') as itemName, + COALESCE(uc.code, '') as unitOfMeasure, + COALESCE(il.lotNo, sil.lotNo, '') as lotNo, + COALESCE(DATE_FORMAT(COALESCE(il.expiryDate, sil.expiryDate), '%Y-%m-%d'), '') as expiryDate, + CAST(ROUND(COALESCE(opening_bal.openingBalance, 0), 0) AS CHAR) as openingBalance, + CAST(ROUND(COALESCE(cum_in.cumStockIn, 0), 0) AS CHAR) as cumStockIn, + CAST(ROUND(COALESCE(cum_out.cumStockOut, 0), 0) AS CHAR) as cumStockOut, + CAST(ROUND(COALESCE(opening_bal.openingBalance, 0) + COALESCE(cum_in.cumStockIn, 0) - COALESCE(cum_out.cumStockOut, 0), 0) AS CHAR) as currentBalance, + '' as reOrderLevel, + '' as reOrderQty, + COALESCE(GROUP_CONCAT(DISTINCT wh.code ORDER BY wh.code SEPARATOR ', '), '') as storeLocation, + COALESCE(DATE_FORMAT(cum_in.lastInDate, '%Y-%m-%d'), '') as lastInDate, + COALESCE(DATE_FORMAT(cum_out.lastOutDate, '%Y-%m-%d'), '') as lastOutDate, + CAST(ROUND(SUM(COALESCE(opening_bal.openingBalance, 0)) OVER (PARTITION BY it.code), 0) AS CHAR) as totalOpeningBalance, + CAST(ROUND(SUM(COALESCE(cum_in.cumStockIn, 0)) OVER (PARTITION BY it.code), 0) AS CHAR) as totalCumStockIn, + CAST(ROUND(SUM(COALESCE(cum_out.cumStockOut, 0)) OVER (PARTITION BY it.code), 0) AS CHAR) as totalCumStockOut, + CAST(ROUND(SUM(COALESCE(opening_bal.openingBalance, 0) + COALESCE(cum_in.cumStockIn, 0) - COALESCE(cum_out.cumStockOut, 0)) OVER (PARTITION BY it.code), 0) AS CHAR) as totalCurrentBalance + FROM inventory_lot il + LEFT JOIN items it ON il.itemId = it.id AND it.deleted = false + LEFT JOIN stock_in_line sil ON il.stockInLineId = sil.id AND sil.deleted = false + LEFT JOIN inventory_lot_line ill ON il.id = ill.inventoryLotId AND ill.deleted = false + LEFT JOIN warehouse wh ON ill.warehouseId = wh.id AND wh.deleted = false + LEFT JOIN item_uom iu ON it.id = iu.itemId AND iu.stockUnit = true + LEFT JOIN uom_conversion uc ON iu.uomId = uc.id + LEFT JOIN ( + SELECT + sl.itemCode, + SUM(COALESCE(sl.balance, 0)) as openingBalance + FROM stock_ledger sl + WHERE sl.deleted = false + AND sl.type = 'adj' + AND sl.itemCode IS NOT NULL + AND sl.itemCode != '' + GROUP BY sl.itemCode + ) opening_bal ON it.code = opening_bal.itemCode + LEFT JOIN ( + SELECT + sl.itemCode, + SUM(COALESCE(sl.inQty, 0)) as cumStockIn, + MAX(CASE WHEN sl.inQty > 0 THEN sl.date ELSE NULL END) as lastInDate + FROM stock_ledger sl + WHERE sl.deleted = false + AND sl.itemCode IS NOT NULL + AND sl.itemCode != '' + AND COALESCE(sl.inQty, 0) > 0 + GROUP BY sl.itemCode + ) cum_in ON it.code = cum_in.itemCode + LEFT JOIN ( + SELECT + sl.itemCode, + SUM(COALESCE(sl.outQty, 0)) as cumStockOut, + MAX(CASE WHEN sl.outQty > 0 THEN sl.date ELSE NULL END) as lastOutDate + FROM stock_ledger sl + WHERE sl.deleted = false + AND sl.itemCode IS NOT NULL + AND sl.itemCode != '' + AND COALESCE(sl.outQty, 0) > 0 + GROUP BY sl.itemCode + ) cum_out ON it.code = cum_out.itemCode + WHERE il.deleted = false + $stockCategorySql + $itemCodeSql + $storeLocationSql + GROUP BY it.code, it.name, uc.code, il.lotNo, sil.lotNo, il.expiryDate, sil.expiryDate, + opening_bal.openingBalance, cum_in.cumStockIn, cum_in.lastInDate, + cum_out.cumStockOut, cum_out.lastOutDate + HAVING 1=1 + """.trimIndent() + + // Apply filters that need to be in HAVING clause + val havingConditions = mutableListOf() + + if (!balanceFilterStart.isNullOrBlank()) { + args["balanceFilterStart"] = balanceFilterStart.toDoubleOrNull() ?: 0.0 + havingConditions.add("(COALESCE(opening_bal.openingBalance, 0) + COALESCE(cum_in.cumStockIn, 0) - COALESCE(cum_out.cumStockOut, 0)) >= :balanceFilterStart") + } + + if (!balanceFilterEnd.isNullOrBlank()) { + args["balanceFilterEnd"] = balanceFilterEnd.toDoubleOrNull() ?: 0.0 + havingConditions.add("(COALESCE(opening_bal.openingBalance, 0) + COALESCE(cum_in.cumStockIn, 0) - COALESCE(cum_out.cumStockOut, 0)) <= :balanceFilterEnd") + } + + if (!lastInDateStart.isNullOrBlank()) { + args["lastInDateStart"] = lastInDateStart + havingConditions.add("(cum_in.lastInDate IS NULL OR cum_in.lastInDate >= :lastInDateStart)") + } + + if (!lastInDateEnd.isNullOrBlank()) { + args["lastInDateEnd"] = lastInDateEnd + havingConditions.add("(cum_in.lastInDate IS NULL OR cum_in.lastInDate < :lastInDateEnd)") + } + + if (!lastOutDateStart.isNullOrBlank()) { + args["lastOutDateStart"] = lastOutDateStart + havingConditions.add("(cum_out.lastOutDate IS NULL OR cum_out.lastOutDate >= :lastOutDateStart)") + } + + if (!lastOutDateEnd.isNullOrBlank()) { + args["lastOutDateEnd"] = lastOutDateEnd + havingConditions.add("(cum_out.lastOutDate IS NULL OR cum_out.lastOutDate < :lastOutDateEnd)") + } + + val finalSql = if (havingConditions.isNotEmpty()) { + sql.replace("HAVING 1=1", "HAVING ${havingConditions.joinToString(" AND ")}") + } else { + sql.replace("HAVING 1=1", "") + } + + return jdbcDao.queryForList(finalSql, args) + } + /** * Compiles and fills a Jasper Report, returning the PDF as a ByteArray. */ diff --git a/src/main/java/com/ffii/fpsms/modules/report/web/ReportController.kt b/src/main/java/com/ffii/fpsms/modules/report/web/ReportController.kt index 997087d..e71dc35 100644 --- a/src/main/java/com/ffii/fpsms/modules/report/web/ReportController.kt +++ b/src/main/java/com/ffii/fpsms/modules/report/web/ReportController.kt @@ -165,4 +165,58 @@ class ReportController( return ResponseEntity(pdfBytes, headers, HttpStatus.OK) } + @GetMapping("/print-stock-balance") + fun generateStockBalanceReport( + @RequestParam(required = false) stockCategory: String?, + @RequestParam(required = false) itemCode: String?, + @RequestParam(required = false) balanceFilterStart: String?, + @RequestParam(required = false) balanceFilterEnd: String?, + @RequestParam(required = false) storeLocation: String?, + @RequestParam(required = false) lastInDateStart: String?, + @RequestParam(required = false) lastInDateEnd: String?, + @RequestParam(required = false) lastOutDateStart: String?, + @RequestParam(required = false) lastOutDateEnd: String? + ): ResponseEntity { + val parameters = mutableMapOf() + + // Set report header parameters + parameters["stockCategory"] = stockCategory ?: "All" + parameters["itemNo"] = itemCode ?: "All" + parameters["reportDate"] = LocalDate.now().format(DateTimeFormatter.ofPattern("yyyy-MM-dd")) + parameters["reportTime"] = LocalTime.now().format(DateTimeFormatter.ofPattern("HH:mm:ss")) + parameters["storeLocation"] = storeLocation ?: "" + parameters["balanceFilterStart"] = balanceFilterStart ?: "" + parameters["balanceFilterEnd"] = balanceFilterEnd ?: "" + parameters["lastInDateStart"] = lastInDateStart ?: "" + parameters["lastInDateEnd"] = lastInDateEnd ?: "" + parameters["lastOutDateStart"] = lastOutDateStart ?: "" + parameters["lastOutDateEnd"] = lastOutDateEnd ?: "" + + val dbData = reportService.searchStockBalanceReport( + stockCategory, + itemCode, + balanceFilterStart, + balanceFilterEnd, + storeLocation, + lastInDateStart, + lastInDateEnd, + lastOutDateStart, + lastOutDateEnd + ) + + val pdfBytes = reportService.createPdfResponse( + "/jasper/StockBalanceReport.jrxml", + parameters, + dbData + ) + + val headers = HttpHeaders().apply { + contentType = MediaType.APPLICATION_PDF + setContentDispositionFormData("attachment", "StockBalanceReport.pdf") + set("filename", "StockBalanceReport.pdf") + } + + return ResponseEntity(pdfBytes, headers, HttpStatus.OK) + } + } \ No newline at end of file diff --git a/src/main/resources/jasper/StockBalanceReport.jrxml b/src/main/resources/jasper/StockBalanceReport.jrxml new file mode 100644 index 0000000..b1497d9 --- /dev/null +++ b/src/main/resources/jasper/StockBalanceReport.jrxml @@ -0,0 +1,588 @@ + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + diff --git a/src/main/resources/jasper/StockInTraceabilityReport.jrxml b/src/main/resources/jasper/StockInTraceabilityReport.jrxml index b1dfa09..ba7e47a 100644 --- a/src/main/resources/jasper/StockInTraceabilityReport.jrxml +++ b/src/main/resources/jasper/StockInTraceabilityReport.jrxml @@ -134,7 +134,7 @@ - + - + @@ -157,7 +157,7 @@ - + - + - + @@ -192,7 +192,7 @@ - + @@ -203,7 +203,7 @@ - + @@ -214,7 +214,7 @@ - + @@ -225,7 +225,7 @@ - + - + @@ -248,7 +248,7 @@ - + - + - +