Parcourir la source

update 2 report

master
CANCERYS\kw093 il y a 2 semaines
Parent
révision
599a58a160
4 fichiers modifiés avec 406 ajouts et 604 suppressions
  1. +207
    -291
      src/main/java/com/ffii/fpsms/modules/report/service/StockLedgerReportService.kt
  2. +195
    -309
      src/main/java/com/ffii/fpsms/modules/report/service/StockTakeVarianceReportService.kt
  3. +2
    -2
      src/main/java/com/ffii/fpsms/modules/report/web/StockLedgerReportController.kt
  4. +2
    -2
      src/main/java/com/ffii/fpsms/modules/report/web/StockTakeVarianceReportController.kt

+ 207
- 291
src/main/java/com/ffii/fpsms/modules/report/service/StockLedgerReportService.kt Voir le fichier

@@ -2,7 +2,8 @@ package com.ffii.fpsms.modules.report.service

import com.ffii.core.support.JdbcDao
import org.springframework.stereotype.Service

import java.time.LocalDate
import java.time.format.DateTimeFormatter
@Service
open class StockLedgerReportService(
private val jdbcDao: JdbcDao,
@@ -16,16 +17,42 @@ open class StockLedgerReportService(
* - trnRefNo = stock_ledger.type
*/
fun searchStockLedgerReport(
stockCategory: String?, // items.type,可逗號分隔
itemCode: String?, // item code,可逗號分隔,模糊
storeLocation: String?, // warehouse.code,模糊
reportPeriodStart: String?, // 過濾 stock_ledger.date >=
reportPeriodEnd: String?, // 過濾 stock_ledger.date <
stockCategory: String?,
itemCode: String?,
storeLocation: String?,
reportPeriodStart: String?,
reportPeriodEnd: String?,
): List<Map<String, Any>> {
val args = mutableMapOf<String, Any>()
// items.type 精確多選
// 1) 先決定 reportPeriodEnd:如果有填 end,就用使用者的;否則用今天
val reportPeriodEnd = (reportPeriodEnd?.replace("/", "-")
?: LocalDate.now().format(DateTimeFormatter.ofPattern("yyyy-MM-dd")))
// 2) 如果有填 start,就用使用者的;否則從 DB 查最早一筆日期
val reportPeriodStart = if (!reportPeriodStart.isNullOrBlank()) {
reportPeriodStart.replace("/", "-")
} else {
// 用簡單 SQL 查全表最早一筆日期(可加上類似 stockCategory/itemCode 過濾)
val minDateSql = """
SELECT DATE_FORMAT(MIN(sl.date), '%Y-%m-%d') AS firstDate
FROM stock_ledger sl
WHERE sl.deleted = 0
AND sl.itemCode IS NOT NULL
AND sl.itemCode <> ''
""".trimIndent()
val minDateRow = jdbcDao.queryForList(minDateSql, emptyMap<String, Any>()).firstOrNull()
(minDateRow?.get("firstDate") as? String)
?: reportPeriodEnd // 如果表是空的,就退回用今天
}
// 3) 把 from/to 塞到 args,供後面 SQL 使用
args["reportPeriodStart"] = reportPeriodStart
args["reportPeriodEnd"] = reportPeriodEnd
// 4) 之後再用你原來的 stockCategorySql / itemCodeSql / storeLocationSql
val stockCategorySql = buildMultiValueExactClause(
stockCategory,
"it.type",
@@ -33,7 +60,6 @@ open class StockLedgerReportService(
args
)
// itemCode 模糊多選(用 stock_ledger.itemCode)
val itemCodeSql = buildMultiValueLikeClause(
itemCode,
"sl.itemCode",
@@ -41,7 +67,6 @@ open class StockLedgerReportService(
args
)
// 倉庫位置
val storeLocationSql = if (!storeLocation.isNullOrBlank()) {
args["storeLocation"] = "%$storeLocation%"
"AND (wh_in.code LIKE :storeLocation OR wh_out.code LIKE :storeLocation)"
@@ -49,299 +74,190 @@ open class StockLedgerReportService(
""
}
// 報表期間:按 stock_ledger.date 過濾
val reportPeriodStartSql = if (!reportPeriodStart.isNullOrBlank()) {
args["reportPeriodStart"] = reportPeriodStart
"AND DATE(sl.date) >= :reportPeriodStart"
} else {
""
}
val reportPeriodEndSql = if (!reportPeriodEnd.isNullOrBlank()) {
args["reportPeriodEnd"] = reportPeriodEnd
"AND DATE(sl.date) < :reportPeriodEnd"
} else {
""
}
val reportPeriodEndSql = "AND DATE(sl.date) <= :reportPeriodEnd"

val sql = """
SELECT
/* ====== 基本資料 ====== */
COALESCE(it.type, '') AS stockSubCategory,
COALESCE(sl.itemCode, '') AS itemNo,
COALESCE(it.name, '') AS itemName,
COALESCE(uc.udfudesc, '') AS unitOfMeasure,
COALESCE(il_in.lotNo, il_out.lotNo, '') AS lotNo,
COALESCE(
DATE_FORMAT(COALESCE(il_in.expiryDate, il_out.expiryDate), '%Y-%m-%d'),
''
) AS expiryDate,
/* ====== 累計期初 / 入庫 / 出庫 / 累計存量(全部輸出字串)====== */
-- 累計期初存量:只有每個 item 的第一行顯示(值 = 第一行的累計餘量),其餘為空字串
COALESCE(
CAST(
CASE
WHEN ROW_NUMBER() OVER (
PARTITION BY sl.itemCode
ORDER BY DATE(sl.date), sl.id
) = 1 THEN
CAST(
SUM(COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0))
OVER (
PARTITION BY sl.itemCode
ORDER BY DATE(sl.date), sl.id
) AS DECIMAL(20, 0)
)
ELSE NULL
END AS CHAR
),
''
) AS cumOpeningBal,
-- 本筆入庫(排除 OPEN)
COALESCE(
CAST(
CAST(
CASE
WHEN COALESCE(sl.inQty, 0) > 0 AND sl.type <> 'OPEN'
THEN COALESCE(sl.inQty, 0)
ELSE 0
END AS DECIMAL(20, 0)
) AS CHAR
),
''
) AS stockIn,
-- 本筆出庫
COALESCE(
CAST(
CAST(COALESCE(sl.outQty, 0) AS DECIMAL(20, 0)) AS CHAR
),
''
) AS stockOut,
-- 本筆之後的累計存量(running balance)
COALESCE(
CAST(
CAST(
SUM(COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0))
OVER (
PARTITION BY sl.itemCode
ORDER BY DATE(sl.date), sl.id
) AS DECIMAL(20, 0)
) AS CHAR
),
''
) AS cumBalance,
/* ====== 組小計(Item Code Balance)====== */
COALESCE(
CAST(
CAST(0 AS DECIMAL(20, 0)) AS CHAR
),
''
) AS totalCumOpeningBal,
COALESCE(
CAST(
CAST(
SUM(
CASE
WHEN COALESCE(sl.inQty, 0) > 0 AND sl.type <> 'OPEN'
THEN COALESCE(sl.inQty, 0)
ELSE 0
END
) OVER (PARTITION BY sl.itemCode) AS DECIMAL(20, 0)
) AS CHAR
),
''
) AS totalStockIn,
COALESCE(
CAST(
CAST(
SUM(COALESCE(sl.outQty, 0))
OVER (PARTITION BY sl.itemCode) AS DECIMAL(20, 0)
) AS CHAR
),
''
) AS totalStockOut,
COALESCE(
CAST(
CAST(
SUM(COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0))
OVER (PARTITION BY sl.itemCode) AS DECIMAL(20, 0)
) AS CHAR
),
''
) AS totalCumBalance,
/* ====== 最後入/出倉日期(按 item 彙總)====== */
COALESCE(
DATE_FORMAT(
MAX(
CASE WHEN COALESCE(sl.inQty, 0) > 0 THEN DATE(sl.date) END
) OVER (PARTITION BY sl.itemCode),
'%Y-%m-%d'
),
''
) AS lastInDate,
COALESCE(
DATE_FORMAT(
MAX(
CASE WHEN COALESCE(sl.outQty, 0) > 0 THEN DATE(sl.date) END
) OVER (PARTITION BY sl.itemCode),
'%Y-%m-%d'
),
''
) AS lastOutDate,
'' AS reOrderLevel,
'' AS reOrderQty,
COALESCE(wh_in.code, wh_out.code, '') AS storeLocation,
/* ====== 單據來源:透過 pickOrderLineId → pick_order → DO / JO ====== */
COALESCE(do.code, '') AS deliveryOrderNo,
COALESCE(jo.code, '') AS jobOrderNo,
CASE
WHEN do.code IS NOT NULL THEN do.code
WHEN jo.code IS NOT NULL THEN jo.code
ELSE ''
END AS orderRefNo,
/* ====== 報表要求的兩個欄位 ====== */
COALESCE(sl.date, '') AS trnDate,
COALESCE(sl.type, '') AS trnRefNo,
/* jrxml 額外定義但目前未使用的欄位,給預設字串 "0" or "" */
'0' AS openingBalance,
'0' AS totalStockInDummy,
'0' AS totalStockOutDummy,
'' AS jobOrderCodeDummy
FROM stock_ledger sl
LEFT JOIN items it
ON sl.itemId = it.id
AND it.deleted = 0
LEFT JOIN item_uom iu
ON it.id = iu.itemId
AND iu.stockUnit = 1
AND iu.deleted = 0
LEFT JOIN uom_conversion uc
ON iu.uomId = uc.id
/* IN 方向:stock_in_line → inventory_lot → inventory_lot_line → warehouse */
LEFT JOIN stock_in_line sil
ON sl.stockInLineId = sil.id
AND sil.deleted = 0
LEFT JOIN inventory_lot il_in
ON sil.inventoryLotId = il_in.id
AND il_in.deleted = 0
LEFT JOIN inventory_lot_line ill_in
ON il_in.id = ill_in.inventoryLotId
AND ill_in.deleted = 0
LEFT JOIN warehouse wh_in
ON ill_in.warehouseId = wh_in.id
AND wh_in.deleted = 0
LEFT JOIN stock_out_line sol
WITH base AS (
SELECT
sl.id AS slId,
DATE(sl.date) AS trnDateRaw,
DATE_FORMAT(sl.date, '%Y-%m-%d') AS trnDate,
sl.type AS trnRefNo,

sl.itemId AS itemId,
sl.itemCode AS itemCode,

COALESCE(sl.inQty, 0) AS inQty,
COALESCE(sl.outQty, 0) AS outQty,
(COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0)) AS delta,

it.type AS stockSubCategory,
it.code AS itemNo,
it.name AS itemName,
uc.udfudesc AS unitOfMeasure,

lot.lotNo AS lotNo,
COALESCE(DATE_FORMAT(lot.expiryDate, '%Y-%m-%d'), '') AS expiryDate,
lot.storeLocation AS storeLocation,

'' AS orderRefNo,
'' AS jobOrderNo,

'' AS openingBalance,
'' AS cumStockIn,
'' AS cumStockOut,
'' AS currentBalance,
'' AS lastInDate,
'' AS lastOutDate,
'' AS reOrderLevel,
'' AS reOrderQty
FROM stock_ledger sl
LEFT JOIN stock_in_line sil
ON sl.stockInLineId = sil.id
AND sil.deleted = 0
LEFT JOIN inventory_lot il_in
ON sil.inventoryLotId = il_in.id
AND il_in.deleted = 0

LEFT JOIN stock_out_line sol
ON sl.stockOutLineId = sol.id
AND sol.deleted = 0
AND sol.deleted = 0
LEFT JOIN inventory_lot_line ill_out
ON sol.inventoryLotLineId = ill_out.id
AND ill_out.deleted = 0
LEFT JOIN inventory_lot il_out
ON ill_out.inventoryLotId = il_out.id
AND il_out.deleted = 0

LEFT JOIN stock_out so
ON sol.stockOutId = so.id
AND so.deleted = 0
LEFT JOIN (
SELECT
il.id AS lotId,
il.lotNo AS lotNo,
il.expiryDate AS expiryDate,
MAX(wh.code) AS storeLocation
FROM inventory_lot il
LEFT JOIN inventory_lot_line ill
ON ill.inventoryLotId = il.id
AND ill.deleted = 0
LEFT JOIN warehouse wh
ON ill.warehouseId = wh.id
AND wh.deleted = 0
GROUP BY
il.id, il.lotNo, il.expiryDate
) lot
ON lot.lotId = COALESCE(il_in.id, il_out.id)

LEFT JOIN pick_order_line pol
ON sol.pickOrderLineId = pol.id
AND pol.deleted = 0
LEFT JOIN items it
ON sl.itemId = it.id
AND it.deleted = 0
LEFT JOIN item_uom iu
ON it.id = iu.itemId
AND iu.stockUnit = 1
AND iu.deleted = 0
LEFT JOIN uom_conversion uc
ON iu.uomId = uc.id

LEFT JOIN pick_order po
ON pol.poId = po.id
AND po.deleted = 0
-- 這兩個 alias 是為了配合你上面 storeLocationSql 的 wh_in / wh_out
LEFT JOIN inventory_lot_line ill_in
ON il_in.id = ill_in.inventoryLotId
AND ill_in.deleted = 0
LEFT JOIN warehouse wh_in
ON ill_in.warehouseId = wh_in.id
AND wh_in.deleted = 0
LEFT JOIN warehouse wh_out
ON ill_out.warehouseId = wh_out.id
AND wh_out.deleted = 0

LEFT JOIN delivery_order do
ON po.doId = do.id
AND do.deleted = 0
WHERE
sl.deleted = 0
AND sl.itemCode IS NOT NULL
AND sl.itemCode <> ''
AND DATE(sl.date) <= :reportPeriodEnd
$stockCategorySql
$itemCodeSql
$storeLocationSql
AND lot.lotId IS NOT NULL
),
opening AS (
SELECT
itemCode,
COALESCE(SUM(delta), 0) AS openingBeforeStart
FROM base
WHERE trnDateRaw < :reportPeriodStart
GROUP BY itemCode
),
period AS (
SELECT
b.*,
COALESCE(o.openingBeforeStart, 0) AS openingBeforeStart
FROM base b
LEFT JOIN opening o
ON o.itemCode = b.itemCode
WHERE b.trnDateRaw BETWEEN :reportPeriodStart AND :reportPeriodEnd
)
SELECT
stockSubCategory,
itemNo,
itemName,
unitOfMeasure,
lotNo,
expiryDate,
trnDate,
trnRefNo,
storeLocation,
orderRefNo,
jobOrderNo,

LEFT JOIN job_order jo
ON po.joId = jo.id
AND jo.deleted = 0
LEFT JOIN inventory_lot_line ill_out
ON sol.inventoryLotLineId = ill_out.id
AND ill_out.deleted = 0
LEFT JOIN inventory_lot il_out
ON ill_out.inventoryLotId = il_out.id
AND il_out.deleted = 0
LEFT JOIN warehouse wh_out
ON ill_out.warehouseId = wh_out.id
AND wh_out.deleted = 0
WHERE
sl.deleted = 0
AND sl.itemCode IS NOT NULL
AND sl.itemCode <> ''
$stockCategorySql
$itemCodeSql
$storeLocationSql
$reportPeriodStartSql
$reportPeriodEndSql
ORDER BY
it.type,
sl.itemCode,
lotNo,
DATE(sl.date),
sl.id
""".trimIndent()
openingBalance,
cumStockIn,
cumStockOut,
currentBalance,
lastInDate,
lastOutDate,
reOrderLevel,
reOrderQty,

-- jrxml 需要 String,避免 BigDecimal cast/trim 爆炸
CAST(CAST(inQty AS DECIMAL(20,0)) AS CHAR) AS stockIn,
CAST(CAST(outQty AS DECIMAL(20,0)) AS CHAR) AS stockOut,

-- 累計存量(跨 lot:只用 itemCode 分區)
CAST(CAST(
(openingBeforeStart
+ SUM(delta) OVER (PARTITION BY itemCode ORDER BY trnDateRaw, slId)
) AS DECIMAL(20,0)
) AS CHAR) AS cumBalance,

-- 累計期初存量 = 本行累計 - 本行異動
CAST(CAST(
(openingBeforeStart
+ SUM(delta) OVER (PARTITION BY itemCode ORDER BY trnDateRaw, slId)
- delta
) AS DECIMAL(20,0)
) AS CHAR) AS cumOpeningBal,

-- footer totals(同樣輸出 String)
CAST(CAST(openingBeforeStart AS DECIMAL(20,0)) AS CHAR) AS totalCumOpeningBal,
CAST(CAST(SUM(inQty) OVER (PARTITION BY itemCode) AS DECIMAL(20,0)) AS CHAR) AS totalStockIn,
CAST(CAST(SUM(outQty) OVER (PARTITION BY itemCode) AS DECIMAL(20,0)) AS CHAR) AS totalStockOut,
CAST(CAST(
(openingBeforeStart
+ SUM(inQty) OVER (PARTITION BY itemCode)
- SUM(outQty) OVER (PARTITION BY itemCode)
) AS DECIMAL(20,0)
) AS CHAR) AS totalCumBalance

FROM period
ORDER BY
itemNo,
trnDateRaw,
slId,
lotNo
""".trimIndent()
val result = jdbcDao.queryForList(sql, args)
println("stockSubCategory: ${result[0]["stockSubCategory"]}")
println("itemNo: ${result[0]["itemNo"]}")
println("itemName: ${result[0]["itemName"]}")
println("unitOfMeasure: ${result[0]["unitOfMeasure"]}")
println("lotNo: ${result[0]["lotNo"]}")
println("expiryDate: ${result[0]["expiryDate"]}")
println("cumOpeningBal: ${result[0]["cumOpeningBal"]}")
println("stockIn: ${result[0]["stockIn"]}")
println("stockOut: ${result[0]["stockOut"]}")
println("cumBalance: ${result[0]["cumBalance"]}")
println("totalCumOpeningBal: ${result[0]["totalCumOpeningBal"]}")
println("totalStockIn: ${result[0]["totalStockIn"]}")
println("totalStockOut: ${result[0]["totalStockOut"]}")
println("totalCumBalance: ${result[0]["totalCumBalance"]}")
println("lastInDate: ${result[0]["lastInDate"]}")
println("lastOutDate: ${result[0]["lastOutDate"]}")
println("storeLocation: ${result[0]["storeLocation"]}")
println("jobOrderNo: ${result[0]["jobOrderNo"]}")
println("deliveryOrderNo: ${result[0]["deliveryOrderNo"]}")

println("stockSubCategory: ${result[1]["stockSubCategory"]}")
println("itemNo: ${result[1]["itemNo"]}")
println("itemName: ${result[1]["itemName"]}")
println("unitOfMeasure: ${result[1]["unitOfMeasure"]}")
println("lotNo: ${result[1]["lotNo"]}")
println("expiryDate: ${result[1]["expiryDate"]}")
println("cumOpeningBal: ${result[1]["cumOpeningBal"]}")
println("stockIn: ${result[1]["stockIn"]}")
println("stockOut: ${result[1]["stockOut"]}")
println("cumBalance: ${result[1]["cumBalance"]}")
println("totalCumOpeningBal: ${result[1]["totalCumOpeningBal"]}")
println("totalStockIn: ${result[1]["totalStockIn"]}")
println("totalStockOut: ${result[1]["totalStockOut"]}")
println("totalCumBalance: ${result[1]["totalCumBalance"]}")
println("lastInDate: ${result[1]["lastInDate"]}")
println("lastOutDate: ${result[1]["lastOutDate"]}")
println("storeLocation: ${result[1]["storeLocation"]}")
println("jobOrderNo: ${result[1]["jobOrderNo"]}")
println("deliveryOrderNo: ${result[1]["deliveryOrderNo"]}")
return result
}



+ 195
- 309
src/main/java/com/ffii/fpsms/modules/report/service/StockTakeVarianceReportService.kt Voir le fichier

@@ -2,7 +2,8 @@ package com.ffii.fpsms.modules.report.service

import com.ffii.core.support.JdbcDao
import org.springframework.stereotype.Service

import java.time.LocalDate
import java.time.format.DateTimeFormatter
@Service
open class StockTakeVarianceReportService(
private val jdbcDao: JdbcDao,
@@ -37,335 +38,220 @@ open class StockTakeVarianceReportService(
stockCategory: String?,
itemCode: String?,
storeLocation: String?,
lastInDateStart: String?,
lastInDateEnd: String?,
lastInDateStart: String?, // 前端 startDateStart
lastInDateEnd: String?, // 前端 startDateEnd
): List<Map<String, Any>> {
val args = mutableMapOf<String, Any>()
// items.type 精確多選
// 基本過濾一樣
val stockCategorySql = buildMultiValueExactClause(
stockCategory,
"it.type",
"stockCategory",
args
)

// itemCode 模糊多選(用 items.code)
val itemCodeSql = buildMultiValueLikeClause(
itemCode,
"it.code",
"itemCode",
args
)

// 倉庫位置:用 warehouse.code 模糊
val storeLocationSql = if (!storeLocation.isNullOrBlank()) {
args["storeLocation"] = "%$storeLocation%"
"AND wh.code LIKE :storeLocation"
} else {
""
}

// 最後入倉日區間:以 sl_agg.lastInDate(來自 stock_in_line.receiptDate)過濾
val lastInDateStartSql = if (!lastInDateStart.isNullOrBlank()) {
args["lastInDateStart"] = lastInDateStart
"AND sl_agg.lastInDate >= :lastInDateStart"
} else ""

val lastInDateEndSql = if (!lastInDateEnd.isNullOrBlank()) {
args["lastInDateEnd"] = lastInDateEnd
"AND sl_agg.lastInDate < :lastInDateEnd"
} else ""

// 1) toDate:有填用傳入,沒填用今天
val toDate = (lastInDateEnd?.replace("/", "-")
?: LocalDate.now().format(DateTimeFormatter.ofPattern("yyyy-MM-dd")))
// 2) fromDate:有填用傳入,沒填查 stock_ledger 最早日期
val fromDate = if (!lastInDateStart.isNullOrBlank()) {
lastInDateStart.replace("/", "-")
} else {
val minDateSql = """
SELECT DATE_FORMAT(MIN(sl.date), '%Y-%m-%d') AS firstDate
FROM stock_ledger sl
WHERE sl.deleted = 0
AND sl.itemCode IS NOT NULL
AND sl.itemCode <> ''
""".trimIndent()
val minDateRow = jdbcDao.queryForList(minDateSql, emptyMap<String, Any>()).firstOrNull()
(minDateRow?.get("firstDate") as? String) ?: toDate
}
args["fromDate"] = fromDate
args["toDate"] = toDate
val sql = """
SELECT
/* ====== 基本資料 ====== */
COALESCE(it.type, '') AS stockSubCategory,
COALESCE(it.code, '') AS itemNo,
COALESCE(it.name, '') AS itemName,
COALESCE(uc.udfudesc, '') AS unitOfMeasure,
COALESCE(il.lotNo, '') AS lotNo,
COALESCE(DATE_FORMAT(il.expiryDate, '%Y-%m-%d'), '') AS expiryDate,

/* ====== 庫存相關:依 stock_ledger 聚合 ====== */
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(sl_agg.openingBalance, 0), 2
))) AS openingBalance,

TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(sl_agg.cumStockIn, 0), 2
))) AS cumStockIn,

TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(sl_agg.cumStockOut, 0), 2
))) AS cumStockOut,

-- 現存存量 = 期初 + 累計存入量 - 累計存出量
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(sl_agg.openingBalance, 0)
+ COALESCE(sl_agg.cumStockIn, 0)
- COALESCE(sl_agg.cumStockOut, 0), 2
))) AS currentBookBalance,

/* 小計欄位(貨品總量):以 itemNo 為單位彙總所有批號 */
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(
SUM(sl_agg.cumStockIn) OVER (PARTITION BY it.code),
0
),
2
))) AS totalCumStockIn,

TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(
SUM(sl_agg.openingBalance) OVER (PARTITION BY it.code),
0
),
2
))) AS totalOpeningBalance,

TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(
SUM(sl_agg.cumStockOut) OVER (PARTITION BY it.code),
0
),
2
))) AS totalCumStockOut,

TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(
SUM(
sl_agg.openingBalance
+ sl_agg.cumStockIn
- sl_agg.cumStockOut
) OVER (PARTITION BY it.code),
0
),
2
))) AS totalCurrentBalance,

/* 最後入/出倉日期:來自 stock_in_line.receiptDate / stock_out_line.endTime */
COALESCE(DATE_FORMAT(sl_agg.lastInDate, '%Y-%m-%d'), '') AS lastInDate,
COALESCE(DATE_FORMAT(sl_agg.lastOutDate, '%Y-%m-%d'), '') AS lastOutDate,

/* 倉庫位置:使用 warehouse.code */
COALESCE(wh.code, '') AS storeLocation,

/* 取貨量(Stock Take Qty [b]):若無 stocktake 則為空字串,有則 = bookQty + varianceQty */
CASE
WHEN str.id IS NULL THEN ''
ELSE TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(str.bookQty, 0) + COALESCE(str.varianceQty, 0),
2
)))
END AS stockTakeQty,

/* 差異量 = 盤點量[b] - 現存存量[a];若無 stocktake 則為空字串 */
CASE
WHEN str.id IS NULL THEN ''
ELSE TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
COALESCE(
(
COALESCE(str.bookQty, 0) + COALESCE(str.varianceQty, 0)
) - (
COALESCE(sl_agg.openingBalance, 0)
+ COALESCE(sl_agg.cumStockIn, 0)
- COALESCE(sl_agg.cumStockOut, 0)
),
0
),
2
)))
END AS variance,

/* 差異百分比:((b - a)/a),若無 stocktake 或 a=0 則為空字串 */
CASE
WHEN str.id IS NULL THEN ''
WHEN COALESCE(
COALESCE(sl_agg.openingBalance, 0)
+ COALESCE(sl_agg.cumStockIn, 0)
- COALESCE(sl_agg.cumStockOut, 0),
0
) = 0 THEN ''
ELSE CONCAT(
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
(
(
COALESCE(str.bookQty, 0) + COALESCE(str.varianceQty, 0)
) - (
COALESCE(sl_agg.openingBalance, 0)
+ COALESCE(sl_agg.cumStockIn, 0)
- COALESCE(sl_agg.cumStockOut, 0)
)
) / NULLIF(
COALESCE(
COALESCE(sl_agg.openingBalance, 0)
+ COALESCE(sl_agg.cumStockIn, 0)
- COALESCE(sl_agg.cumStockOut, 0),
0
),
0
) * 100,
2
))),
'%'
)
END AS variancePercentage

FROM inventory_lot il
LEFT JOIN inventory_lot_line ill
ON ill.inventoryLotId = il.id
AND ill.deleted = 0

LEFT JOIN items it
ON il.itemId = it.id
AND it.deleted = 0

LEFT JOIN warehouse wh
ON ill.warehouseId = wh.id
AND wh.deleted = 0

/* 盤點記錄:以 lotId + warehouseId 對應,若沒有盤點則為 NULL */
LEFT JOIN stocktakerecord str
ON str.lotId = il.id
AND str.warehouseId = ill.warehouseId
AND str.deleted = 0

LEFT JOIN item_uom iu
ON it.id = iu.itemId
AND iu.stockUnit = 1
AND iu.deleted = 0

LEFT JOIN uom_conversion uc
ON iu.uomId = uc.id

/* ====== 從 stock_ledger 按 lot + warehouse 聚合 ====== */
LEFT JOIN (
SELECT
COALESCE(il_in.id, il_out.id) AS lotId,
COALESCE(wh_in.id, wh_out.id) AS warehouseId,

/* 期初存貨:只有 OPEN 的 inQty - outQty */
SUM(
CASE
WHEN sl.type = 'OPEN'
THEN COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0)
ELSE 0
END
) AS openingBalance,

/* 累計存入量:只算 NOR / Miss / Bad 的 inQty */
SUM(
CASE
WHEN sl.type IN ('NOR', 'Miss', 'Bad')
THEN COALESCE(sl.inQty, 0)
ELSE 0
END
) AS cumStockIn,

/* 累計存出量:只算 NOR / Miss / Bad 的 outQty */
SUM(
CASE
WHEN sl.type IN ('NOR', 'Miss', 'Bad')
THEN COALESCE(sl.outQty, 0)
ELSE 0
END
) AS cumStockOut,
/* ADJ 調整量(取貨量):只算 Adj 的 outQty */
SUM(
CASE
WHEN sl.type = 'Adj'
THEN COALESCE(sl.outQty, 0)
ELSE 0
END
) AS adjOutQty,

/* 最後入倉日期:最近一次有 inQty 的收貨日 */
MAX(
CASE
WHEN sl.inQty IS NOT NULL AND sil.receiptDate IS NOT NULL
THEN DATE(sil.receiptDate)
ELSE NULL
END
) AS lastInDate,

/* 最後出倉日期:最近一次有 outQty 的出庫完成時間 */
MAX(
CASE
WHEN sl.outQty IS NOT NULL AND sol.endTime IS NOT NULL
THEN DATE(sol.endTime)
ELSE NULL
END
) AS lastOutDate,

/* 現存存量:此處只作為差異計算基礎 = 期初 + 累計入 - 累計出 */
SUM(
CASE
WHEN sl.type = 'OPEN'
THEN COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0)
WHEN sl.type IN ('NOR', 'Miss', 'Bad')
THEN COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0)
ELSE 0
END
) AS currentBookBalance

FROM stock_ledger sl
/* IN 方向:透過 stock_in_line → inventory_lot / inventory_lot_line → warehouse */
LEFT JOIN stock_in_line sil
ON sl.stockInLineId = sil.id
AND sil.deleted = 0
LEFT JOIN inventory_lot il_in
ON sil.inventoryLotId = il_in.id
AND il_in.deleted = 0
LEFT JOIN inventory_lot_line ill_in
ON sil.inventoryLotLineId = ill_in.id
AND ill_in.deleted = 0
LEFT JOIN warehouse wh_in
ON ill_in.warehouseId = wh_in.id
AND wh_in.deleted = 0

/* OUT 方向:透過 stock_out_line → inventory_lot_line → inventory_lot → warehouse */
LEFT JOIN stock_out_line sol
ON sl.stockOutLineId = sol.id
AND sol.deleted = 0
LEFT JOIN inventory_lot_line ill_out
ON sol.inventoryLotLineId = ill_out.id
AND ill_out.deleted = 0
LEFT JOIN inventory_lot il_out
ON ill_out.inventoryLotId = il_out.id
AND il_out.deleted = 0
LEFT JOIN warehouse wh_out
ON ill_out.warehouseId = wh_out.id
AND wh_out.deleted = 0

WHERE
sl.deleted = 0
AND sl.itemCode IS NOT NULL
AND sl.itemCode <> ''

GROUP BY
COALESCE(il_in.id, il_out.id),
COALESCE(wh_in.id, wh_out.id)
) sl_agg
ON sl_agg.lotId = il.id
AND sl_agg.warehouseId = ill.warehouseId

WHERE
il.deleted = 0
$stockCategorySql
$itemCodeSql
$storeLocationSql
$lastInDateStartSql
$lastInDateEndSql

ORDER BY
it.type,
it.code,
il.lotNo,
wh.code
""".trimIndent()

return jdbcDao.queryForList(sql, args)
WITH latest_str AS (
SELECT
s1.lotId,
s1.warehouseId,
s1.bookQty,
s1.varianceQty,
s1.approverStockTakeQty,
s1.date,
s1.id
FROM stocktakerecord s1
WHERE s1.deleted = 0
AND s1.status = 'completed'
AND s1.date >= :fromDate
AND s1.date <= :toDate
AND NOT EXISTS (
SELECT 1
FROM stocktakerecord s2
WHERE s2.deleted = 0
AND s2.status = 'completed'
AND s2.date >= :fromDate
AND s2.date <= :toDate
AND s2.lotId = s1.lotId
AND s2.warehouseId = s1.warehouseId
AND (
s2.date > s1.date
OR (s2.date = s1.date AND s2.id > s1.id)
)
)
),
in_out AS (
SELECT
ill.id AS inventoryLotLineId,

/* 期初:fromDate 之前的入 - 出 */
SUM(CASE WHEN DATE(sil.receiptDate) < :fromDate THEN COALESCE(sil.acceptedQty, 0) ELSE 0 END) AS inBefore,
SUM(CASE WHEN DATE(sol.endTime) < :fromDate THEN COALESCE(sol.qty, 0) ELSE 0 END) AS outBefore,

/* 區間內累計 */
SUM(CASE WHEN DATE(sil.receiptDate) BETWEEN :fromDate AND :toDate THEN COALESCE(sil.acceptedQty, 0) ELSE 0 END) AS inDuring,
SUM(CASE WHEN DATE(sol.endTime) BETWEEN :fromDate AND :toDate THEN COALESCE(sol.qty, 0) ELSE 0 END) AS outDuring,

/* 最後入/出倉日期(不限定區間,通常看整體最後一次) */
MAX(CASE WHEN sil.receiptDate IS NOT NULL THEN DATE(sil.receiptDate) END) AS lastInDate,
MAX(CASE WHEN sol.endTime IS NOT NULL THEN DATE(sol.endTime) END) AS lastOutDate

FROM inventory_lot_line ill
LEFT JOIN stock_in_line sil
ON sil.inventoryLotLineId = ill.id
AND sil.deleted = 0
AND sil.status = 'completed'
LEFT JOIN stock_out_line sol
ON sol.inventoryLotLineId = ill.id
AND sol.deleted = 0
AND sol.status = 'completed'
WHERE ill.deleted = 0
GROUP BY ill.id
),
data AS (
SELECT
it.type AS stockSubCategory,
it.code AS itemNo,
it.name AS itemName,
uc.udfudesc AS unitOfMeasure,

il.lotNo AS lotNo,
COALESCE(DATE_FORMAT(il.expiryDate, '%Y-%m-%d'), '') AS expiryDate,
wh.code AS storeLocation,

/* 數值先算出來,外層再 FORMAT 成字串,方便做 totals */
(COALESCE(io.inBefore, 0) - COALESCE(io.outBefore, 0)) AS openingQty,
COALESCE(io.inDuring, 0) AS inQty,
COALESCE(io.outDuring, 0) AS outQty,
((COALESCE(io.inBefore, 0) - COALESCE(io.outBefore, 0)) + COALESCE(io.inDuring, 0) - COALESCE(io.outDuring, 0)) AS currentQty,

io.lastInDate AS lastInDateRaw,
io.lastOutDate AS lastOutDateRaw,

ls.bookQty AS stkBookQty,
ls.approverStockTakeQty AS stkApproverQty,
ls.varianceQty AS stkVarianceQty
FROM inventory_lot_line ill
INNER JOIN inventory_lot il
ON ill.inventoryLotId = il.id
AND il.deleted = 0
INNER JOIN items it
ON il.itemId = it.id
AND it.deleted = 0
INNER JOIN warehouse wh
ON ill.warehouseId = wh.id
AND wh.deleted = 0

LEFT JOIN item_uom iu
ON it.id = iu.itemId
AND iu.stockUnit = 1
AND iu.deleted = 0
LEFT JOIN uom_conversion uc
ON iu.uomId = uc.id

LEFT JOIN in_out io
ON io.inventoryLotLineId = ill.id

LEFT JOIN latest_str ls
ON ls.lotId = il.id
AND ls.warehouseId = wh.id

WHERE ill.deleted = 0
$stockCategorySql
$itemCodeSql
$storeLocationSql
)

SELECT
stockSubCategory,
itemNo,
itemName,
unitOfMeasure,
lotNo,
expiryDate,
storeLocation,

/* 期初/累計/現存:jrxml 欄位全是 String */
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(openingQty, 0), 2))) AS openingBalance,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(inQty, 0), 2))) AS cumStockIn,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(outQty, 0), 2))) AS cumStockOut,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(currentQty, 0), 2))) AS currentBookBalance,

COALESCE(DATE_FORMAT(lastInDateRaw, '%Y-%m-%d'), '') AS lastInDate,
COALESCE(DATE_FORMAT(lastOutDateRaw, '%Y-%m-%d'), '') AS lastOutDate,

/* 取貨量 = approverStockTakeQty(無盤點紀錄就空白) */
CASE
WHEN stkApproverQty IS NULL THEN ''
ELSE TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(stkApproverQty, 0), 2)))
END AS stockTakeQty,

/* 超撿量 = varianceQty(無盤點紀錄就空白) */
CASE
WHEN stkVarianceQty IS NULL THEN ''
ELSE TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(stkVarianceQty, 0), 2)))
END AS variance,

CASE
WHEN stkVarianceQty IS NULL THEN ''
WHEN COALESCE(stkBookQty, 0) = 0 THEN ''
ELSE CONCAT(
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT((COALESCE(stkVarianceQty, 0) / stkBookQty) * 100, 2))),
'%'
)
END AS variancePercentage,

/* item totals(footer 用) */
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(openingQty, 0)) OVER (PARTITION BY itemNo), 2))) AS totalOpeningBalance,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(inQty, 0)) OVER (PARTITION BY itemNo), 2))) AS totalCumStockIn,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(outQty, 0)) OVER (PARTITION BY itemNo), 2))) AS totalCumStockOut,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(currentQty, 0)) OVER (PARTITION BY itemNo), 2))) AS totalCurrentBalance

FROM data
ORDER BY
itemNo,
lotNo,
storeLocation
""".trimIndent()
val result = jdbcDao.queryForList(sql, args)
return result
}

/** LIKE 多值工具方法 */


+ 2
- 2
src/main/java/com/ffii/fpsms/modules/report/web/StockLedgerReportController.kt Voir le fichier

@@ -20,8 +20,8 @@ fun generateStockLedgerReport(
@RequestParam(required = false) itemCode: String?,
@RequestParam(required = false) storeLocation: String?,
// URL 參數名仍然是 lastInDateStart / lastInDateEnd
@RequestParam(name = "lastInDateStart", required = false) reportPeriodStart: String?,
@RequestParam(name = "lastInDateEnd", required = false) reportPeriodEnd: String?,
@RequestParam(name = "startDateStart", required = false) reportPeriodStart: String?,
@RequestParam(name = "startDateEnd", required = false) reportPeriodEnd: String?,
): ResponseEntity<ByteArray> {
val parameters = mutableMapOf<String, Any>()



+ 2
- 2
src/main/java/com/ffii/fpsms/modules/report/web/StockTakeVarianceReportController.kt Voir le fichier

@@ -35,8 +35,8 @@ class StockTakeVarianceReportController(
@RequestParam(required = false) stockCategory: String?,
@RequestParam(required = false) itemCode: String?,
@RequestParam(required = false) storeLocation: String?,
@RequestParam(name = "lastInDateStart", required = false) lastInDateStart: String?,
@RequestParam(name = "lastInDateEnd", required = false) lastInDateEnd: String?,
@RequestParam(name = "startDateStart", required = false) lastInDateStart: String?,
@RequestParam(name = "startDateEnd", required = false) lastInDateEnd: String?,
): ResponseEntity<ByteArray> {
val parameters = mutableMapOf<String, Any>()



Chargement…
Annuler
Enregistrer