Sfoglia il codice sorgente

stockvariance,StockInTraceability,StockTakeVariance

master
CANCERYS\kw093 1 settimana fa
parent
commit
6219d6fb09
3 ha cambiato i file con 139 aggiunte e 106 eliminazioni
  1. +132
    -100
      src/main/java/com/ffii/fpsms/modules/report/service/ReportService.kt
  2. +3
    -2
      src/main/java/com/ffii/fpsms/modules/report/service/StockTakeVarianceReportService.kt
  3. +4
    -4
      src/main/resources/jasper/StockTakeVarianceReport.jrxml

+ 132
- 100
src/main/java/com/ffii/fpsms/modules/report/service/ReportService.kt Vedi File

@@ -721,29 +721,31 @@ fun searchMaterialStockOutTraceabilityReport(
} else ""

val sql = """
SELECT
SELECT
COALESCE(it.code, '') as itemNo,
COALESCE(it.name, '') as itemName,
COALESCE(uc.code, '') as unitOfMeasure,
COALESCE(uc.udfudesc, '') as unitOfMeasure,
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,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(sil.acceptedQty, 0), 2))) as stockInQty,
CASE WHEN COALESCE(qr_agg.qcFailed, 0) = 1 THEN '0'
ELSE TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(sil.acceptedQty, 0), 2)))
END as stockInQty,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(sil.acceptedQty, 0), 2))) as iqcSampleQty,
-- ↓↓↓ 这四个/五个栏位改成不依赖 qc_result ↓↓↓
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(0, 2))) as iqcDefectQty,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(0, 2))) as iqcDefectPercentage,
'Accept' as iqcResult, -- 或 '' 看你报表需求
'' as iqcRemarks,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(0, 2))) as totalIqcDefectQty,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(COALESCE(qr_agg.failQtySum, 0), 2))) as iqcDefectQty,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(
CASE WHEN COALESCE(sil.acceptedQty, 0) > 0
THEN COALESCE(qr_agg.failQtySum, 0) / sil.acceptedQty * 100
ELSE 0
END, 2))) as iqcDefectPercentage,
CASE WHEN COALESCE(qr_agg.qcFailed, 0) = 1 THEN '不合格' ELSE '已接受' END as iqcResult,
COALESCE(qr_agg.remarksConcat, '') as iqcRemarks,
TRIM(TRAILING '.' FROM TRIM(TRAILING '0' FROM FORMAT(SUM(COALESCE(qr_agg.failQtySum, 0)) OVER (PARTITION BY it.id), 2))) as totalIqcDefectQty,
COALESCE(wh.code, '') as storeLocation,
COALESCE(sp_si.code, sp_po.code, '') as supplierID,
COALESCE(sp_si.name, sp_po.name, '') as supplierName,
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
-- 注意:这里已经不再有 totalIqcDefectQty 的 window function 了
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
@@ -755,6 +757,19 @@ fun searchMaterialStockOutTraceabilityReport(
LEFT JOIN warehouse wh ON ill.warehouseId = wh.id
LEFT JOIN shop sp_si ON si.supplierId = sp_si.id
LEFT JOIN shop sp_po ON po.supplierId = sp_po.id
LEFT JOIN (
SELECT
qr.stockInLineId,
SUM(COALESCE(qr.failQty, 0)) AS failQtySum,
MAX(CASE WHEN qr.qcPassed = 0 THEN 1 ELSE 0 END) AS qcFailed,
GROUP_CONCAT(
CASE WHEN qr.remarks IS NOT NULL AND TRIM(qr.remarks) != '' THEN qr.remarks END
SEPARATOR '; '
) AS remarksConcat
FROM qc_result qr
WHERE qr.deleted = 0
GROUP BY qr.stockInLineId
) qr_agg ON qr_agg.stockInLineId = sil.id
WHERE sil.deleted = false
$stockCategorySql
$itemCodeSql
@@ -766,11 +781,10 @@ fun searchMaterialStockOutTraceabilityReport(
return jdbcDao.queryForList(sql, args)
}

/**
/**
* Queries the database for Stock Balance Report data.
* Shows stock balances by item code and lot number (per-lot quantities from inventory_lot_line),
* including opening balance (item-level from stock_ledger type='adj'), cumulative stock in/out,
* current balance, store locations, and last in/out dates per lot.
* Uses stock_ledger with report period (fromDate/toDate): opening = before fromDate, cum in/out = in period, current = up to toDate.
* Unit from uom_conversion.udfudesc; includes per-lot and per-item totals plus in/out breakdown by source (PO, JO, StockTake, Adj) and type (Miss, Bad, Adj, StockTake, DO, JO, Consumable).
*/
fun searchStockBalanceReport(
stockCategory: String?,
@@ -781,138 +795,156 @@ fun searchMaterialStockOutTraceabilityReport(
lastInDateStart: String?,
lastInDateEnd: String?,
lastOutDateStart: String?,
lastOutDateEnd: String?
lastOutDateEnd: String?,
reportPeriodStart: String? = null,
reportPeriodEnd: String? = null
): List<Map<String, Any>> {
val args = mutableMapOf<String, Any>()
val fromDate = reportPeriodStart?.replace("/", "-")?.takeIf { it.isNotBlank() }
?: java.time.LocalDate.now().withDayOfYear(1).toString()
val toDate = reportPeriodEnd?.replace("/", "-")?.takeIf { it.isNotBlank() }
?: java.time.LocalDate.now().toString()
args["fromDate"] = fromDate
args["toDate"] = toDate

val stockCategorySql = buildMultiValueExactClause(stockCategory, "it.type", "stockCategory", args)
val itemCodeSql = buildMultiValueLikeClause(itemCode, "it.code", "itemCode", args)
val itemCodeSql = buildMultiValueLikeClause(itemCode, "sl.itemCode", "itemCode", args)
val storeLocationSql = if (!storeLocation.isNullOrBlank()) {
args["storeLocation"] = "%$storeLocation%"
"AND wh.code LIKE :storeLocation"
"AND agg.storeLocation LIKE :storeLocation"
} else ""

val sql = """
SELECT
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,
FORMAT(ROUND(COALESCE(lot_agg.lotOpening, 0), 0), 0) as openingBalance,
FORMAT(ROUND(COALESCE(lot_agg.lotCumIn, 0), 0), 0) as cumStockIn,
FORMAT(ROUND(COALESCE(lot_agg.lotCumOut, 0), 0), 0) as cumStockOut,
FORMAT(ROUND(COALESCE(lot_agg.lotOpening, 0) + COALESCE(lot_agg.lotCumIn, 0) - COALESCE(lot_agg.lotCumOut, 0), 0), 0) as currentBalance,
COALESCE(uc.udfudesc, uc.code, '') as unitOfMeasure,
COALESCE(lot.lotNo, '') as lotNo,
COALESCE(DATE_FORMAT(lot.expiryDate, '%Y-%m-%d'), '') as expiryDate,
FORMAT(ROUND(COALESCE(agg.openingBalance, 0), 0), 0) as openingBalance,
FORMAT(ROUND(COALESCE(agg.cumStockIn, 0), 0), 0) as cumStockIn,
FORMAT(ROUND(COALESCE(agg.cumStockOut, 0), 0), 0) as cumStockOut,
FORMAT(ROUND(COALESCE(agg.currentBalance, 0), 0), 0) as currentBalance,
'' as reOrderLevel,
'' as reOrderQty,
COALESCE(GROUP_CONCAT(DISTINCT wh.code ORDER BY wh.code SEPARATOR ', '), '') as storeLocation,
COALESCE(DATE_FORMAT(lot_agg.lotLastInDate, '%Y-%m-%d'), '') as lastInDate,
COALESCE(DATE_FORMAT(lot_agg.lotLastOutDate, '%Y-%m-%d'), '') as lastOutDate,
FORMAT(ROUND(MAX(COALESCE(opening_bal.openingBalance, 0)) OVER (PARTITION BY it.code), 0), 0) as totalOpeningBalance,
FORMAT(ROUND(SUM(COALESCE(lot_agg.lotCumIn, 0)) OVER (PARTITION BY it.code), 0), 0) as totalCumStockIn,
FORMAT(ROUND(SUM(COALESCE(lot_agg.lotCumOut, 0)) OVER (PARTITION BY it.code), 0), 0) as totalCumStockOut,
FORMAT(ROUND(SUM(COALESCE(lot_agg.lotOpening, 0) + COALESCE(lot_agg.lotCumIn, 0) - COALESCE(lot_agg.lotCumOut, 0)) OVER (PARTITION BY it.code), 0), 0) 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
ill_agg.inventoryLotId,
SUM(COALESCE(ill_agg.inQty, 0)) as lotCumIn,
SUM(COALESCE(ill_agg.outQty, 0)) as lotCumOut,
NULL as lotOpening,
last_in.lotLastInDate,
last_out.lotLastOutDate
FROM inventory_lot_line ill_agg
LEFT JOIN (
SELECT sil2.inventoryLotId, MAX(sil2.receiptDate) as lotLastInDate
FROM stock_in_line sil2
WHERE sil2.deleted = false AND sil2.inventoryLotId IS NOT NULL
GROUP BY sil2.inventoryLotId
) last_in ON last_in.inventoryLotId = ill_agg.inventoryLotId
LEFT JOIN (
SELECT ill2.inventoryLotId, MAX(sol.endTime) as lotLastOutDate
FROM stock_out_line sol
INNER JOIN inventory_lot_line ill2 ON sol.inventoryLotLineId = ill2.id AND ill2.deleted = false
WHERE sol.deleted = false
GROUP BY ill2.inventoryLotId
) last_out ON last_out.inventoryLotId = ill_agg.inventoryLotId
WHERE ill_agg.deleted = false
GROUP BY ill_agg.inventoryLotId, last_in.lotLastInDate, last_out.lotLastOutDate
) lot_agg ON lot_agg.inventoryLotId = il.id
LEFT JOIN (
SELECT
COALESCE(agg.storeLocation, '') as storeLocation,
COALESCE(DATE_FORMAT(agg.lastInDate, '%Y-%m-%d'), '') as lastInDate,
COALESCE(DATE_FORMAT(agg.lastOutDate, '%Y-%m-%d'), '') as lastOutDate,
FORMAT(ROUND(SUM(COALESCE(agg.openingBalance, 0)) OVER w_item, 0), 0) as totalOpeningBalance,
FORMAT(ROUND(SUM(COALESCE(agg.cumStockIn, 0)) OVER w_item, 0), 0) as totalCumStockIn,
FORMAT(ROUND(SUM(COALESCE(agg.cumStockOut, 0)) OVER w_item, 0), 0) as totalCumStockOut,
FORMAT(ROUND(SUM(COALESCE(agg.currentBalance, 0)) OVER w_item, 0), 0) as totalCurrentBalance,
FORMAT(ROUND(COALESCE(agg.cumStockInByPO, 0), 0), 0) as cumStockInByPurchaseOrder,
FORMAT(ROUND(COALESCE(agg.cumStockInByJO, 0), 0), 0) as cumStockInByJobOrder,
FORMAT(ROUND(COALESCE(agg.cumStockInByStockTake, 0), 0), 0) as cumStockInByStockTake,
FORMAT(ROUND(COALESCE(agg.cumStockInByAdj, 0), 0), 0) as cumStockInByAdj,
FORMAT(ROUND(COALESCE(agg.cumStockOutMiss, 0), 0), 0) as cumStockOutMissQty,
FORMAT(ROUND(COALESCE(agg.cumStockOutBad, 0), 0), 0) as cumStockOutBadQty,
FORMAT(ROUND(COALESCE(agg.cumStockOutAdj, 0), 0), 0) as cumStockOutAdj,
FORMAT(ROUND(COALESCE(agg.cumStockOutAdjTransfer, 0), 0), 0) as cumStockOutAdjTransfer,
FORMAT(ROUND(COALESCE(agg.cumStockOutAdjStockTake, 0), 0), 0) as cumStockOutAdjStockTake,
FORMAT(ROUND(COALESCE(agg.cumStockOutStockTake, 0), 0), 0) as cumStockOutStockTake,
FORMAT(ROUND(COALESCE(agg.cumStockOutByDO, 0), 0), 0) as cumStockOutByDO,
FORMAT(ROUND(COALESCE(agg.cumStockOutByJO, 0), 0), 0) as cumStockOutByJO,
FORMAT(ROUND(COALESCE(agg.cumStockOutByConsumable, 0), 0), 0) as cumStockOutByConsumable
FROM (
SELECT
sl.itemCode,
SUM(COALESCE(sl.balance, 0)) as openingBalance
sl.itemId,
COALESCE(il_in.id, il_out.id) AS lotId,
SUM(CASE WHEN DATE(sl.date) < :fromDate THEN COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0) ELSE 0 END) AS openingBalance,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate THEN COALESCE(sl.inQty, 0) ELSE 0 END) AS cumStockIn,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate THEN COALESCE(sl.outQty, 0) ELSE 0 END) AS cumStockOut,
SUM(CASE WHEN DATE(sl.date) <= :toDate THEN COALESCE(sl.inQty, 0) - COALESCE(sl.outQty, 0) ELSE 0 END) AS currentBalance,
MAX(CASE WHEN COALESCE(sl.inQty, 0) > 0 THEN sl.date END) AS lastInDate,
MAX(CASE WHEN COALESCE(sl.outQty, 0) > 0 THEN sl.date END) AS lastOutDate,
MAX(lot_wh.storeLocation) AS storeLocation,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.inQty, 0) > 0 AND sil.purchaseOrderId IS NOT NULL THEN sl.inQty ELSE 0 END) AS cumStockInByPO,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.inQty, 0) > 0 AND sil.jobOrderId IS NOT NULL THEN sl.inQty ELSE 0 END) AS cumStockInByJO,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.inQty, 0) > 0 AND sil.stockTakeLineId IS NOT NULL THEN sl.inQty ELSE 0 END) AS cumStockInByStockTake,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.inQty, 0) > 0 AND LOWER(TRIM(COALESCE(sl.type, ''))) = 'adj' THEN sl.inQty ELSE 0 END) AS cumStockInByAdj,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND (LOWER(TRIM(COALESCE(sl.type, ''))) = 'miss' OR LOWER(TRIM(COALESCE(sol.type, ''))) = 'miss') THEN sl.outQty ELSE 0 END) AS cumStockOutMiss,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND (LOWER(TRIM(COALESCE(sl.type, ''))) = 'bad' OR LOWER(TRIM(COALESCE(sol.type, ''))) = 'bad') THEN sl.outQty ELSE 0 END) AS cumStockOutBad,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(sl.type, ''))) = 'adj' THEN sl.outQty ELSE 0 END) AS cumStockOutAdj,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(sl.type, ''))) = 'adj' AND sol.stockTransferId IS NOT NULL THEN sl.outQty ELSE 0 END) AS cumStockOutAdjTransfer,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(sl.type, ''))) = 'adj' AND (sol.stockTransferId IS NULL OR sol.id IS NULL) THEN sl.outQty ELSE 0 END) AS cumStockOutAdjStockTake,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(sl.type, ''))) = 'stocktake' THEN sl.outQty ELSE 0 END) AS cumStockOutStockTake,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(po.type, ''))) = 'do' THEN sl.outQty ELSE 0 END) AS cumStockOutByDO,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(po.type, ''))) = 'jo' THEN sl.outQty ELSE 0 END) AS cumStockOutByJO,
SUM(CASE WHEN DATE(sl.date) BETWEEN :fromDate AND :toDate AND COALESCE(sl.outQty, 0) > 0 AND LOWER(TRIM(COALESCE(po.type, ''))) = 'consumable' THEN sl.outQty ELSE 0 END) AS cumStockOutByConsumable
FROM stock_ledger sl
WHERE sl.deleted = false
AND LOWER(sl.type) = 'adj'
AND sl.itemCode IS NOT NULL
AND sl.itemCode != ''
GROUP BY sl.itemCode
) opening_bal ON it.code = opening_bal.itemCode
WHERE il.deleted = false
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
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 pick_order_line pol ON sol.pickOrderLineId = pol.id AND pol.deleted = 0
LEFT JOIN pick_order po ON pol.poId = po.id AND po.deleted = 0
LEFT JOIN (
SELECT il.id AS lotId, 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
) lot_wh ON lot_wh.lotId = COALESCE(il_in.id, il_out.id)
WHERE sl.deleted = 0
AND sl.itemCode IS NOT NULL AND sl.itemCode <> ''
AND DATE(sl.date) <= :toDate
AND COALESCE(il_in.id, il_out.id) IS NOT NULL
$itemCodeSql
GROUP BY sl.itemCode, sl.itemId, COALESCE(il_in.id, il_out.id)
) agg
LEFT JOIN items it ON agg.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 (SELECT id, lotNo, expiryDate FROM inventory_lot WHERE deleted = 0) lot ON lot.id = agg.lotId
WHERE 1 = 1
$stockCategorySql
$itemCodeSql
$storeLocationSql
GROUP BY it.code, it.name, uc.code, il.id, il.lotNo, sil.lotNo, il.expiryDate, sil.expiryDate,
lot_agg.lotCumIn, lot_agg.lotCumOut, lot_agg.lotOpening, lot_agg.lotLastInDate, lot_agg.lotLastOutDate,
opening_bal.openingBalance
HAVING 1=1
WINDOW w_item AS (PARTITION BY agg.itemCode)
""".trimIndent()
val havingConditions = mutableListOf<String>()
val lotCurrentBalanceExpr = "(COALESCE(lot_agg.lotOpening, 0) + COALESCE(lot_agg.lotCumIn, 0) - COALESCE(lot_agg.lotCumOut, 0))"
val currentBalanceExpr = "COALESCE(agg.currentBalance, 0)"
if (!balanceFilterStart.isNullOrBlank()) {
args["balanceFilterStart"] = balanceFilterStart.toDoubleOrNull() ?: 0.0
havingConditions.add("$lotCurrentBalanceExpr >= :balanceFilterStart")
havingConditions.add("$currentBalanceExpr >= :balanceFilterStart")
}
if (!balanceFilterEnd.isNullOrBlank()) {
args["balanceFilterEnd"] = balanceFilterEnd.toDoubleOrNull() ?: 0.0
havingConditions.add("$lotCurrentBalanceExpr <= :balanceFilterEnd")
havingConditions.add("$currentBalanceExpr <= :balanceFilterEnd")
}
if (!lastInDateStart.isNullOrBlank()) {
val formattedDate = lastInDateStart.replace("/", "-")
args["lastInDateStart"] = formattedDate
havingConditions.add("(lot_agg.lotLastInDate IS NOT NULL AND DATE(lot_agg.lotLastInDate) >= DATE(:lastInDateStart))")
havingConditions.add("(agg.lastInDate IS NOT NULL AND DATE(agg.lastInDate) >= DATE(:lastInDateStart))")
}
if (!lastInDateEnd.isNullOrBlank()) {
val formattedDate = lastInDateEnd.replace("/", "-")
args["lastInDateEnd"] = formattedDate
havingConditions.add("(lot_agg.lotLastInDate IS NOT NULL AND DATE(lot_agg.lotLastInDate) <= DATE(:lastInDateEnd))")
havingConditions.add("(agg.lastInDate IS NOT NULL AND DATE(agg.lastInDate) <= DATE(:lastInDateEnd))")
}
if (!lastOutDateStart.isNullOrBlank()) {
val formattedDate = lastOutDateStart.replace("/", "-")
args["lastOutDateStart"] = formattedDate
havingConditions.add("(lot_agg.lotLastOutDate IS NOT NULL AND DATE(lot_agg.lotLastOutDate) >= DATE(:lastOutDateStart))")
havingConditions.add("(agg.lastOutDate IS NOT NULL AND DATE(agg.lastOutDate) >= DATE(:lastOutDateStart))")
}
if (!lastOutDateEnd.isNullOrBlank()) {
val formattedDate = lastOutDateEnd.replace("/", "-")
args["lastOutDateEnd"] = formattedDate
havingConditions.add("(lot_agg.lotLastOutDate IS NOT NULL AND DATE(lot_agg.lotLastOutDate) <= DATE(:lastOutDateEnd))")
havingConditions.add("(agg.lastOutDate IS NOT NULL AND DATE(agg.lastOutDate) <= DATE(: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)
return jdbcDao.queryForList("$finalSql ORDER BY itemNo, lotNo", args)
}

/**
* Compiles and fills a Jasper Report, returning the PDF as a ByteArray.
*/


+ 3
- 2
src/main/java/com/ffii/fpsms/modules/report/service/StockTakeVarianceReportService.kt Vedi File

@@ -166,7 +166,8 @@ data AS (

ls.bookQty AS stkBookQty,
ls.approverStockTakeQty AS stkApproverQty,
ls.varianceQty AS stkVarianceQty
ls.varianceQty AS stkVarianceQty,
ls.date AS stockTakeDateRaw
FROM inventory_lot_line ill
INNER JOIN inventory_lot il
ON ill.inventoryLotId = il.id
@@ -215,7 +216,7 @@ SELECT

COALESCE(DATE_FORMAT(lastInDateRaw, '%Y-%m-%d'), '') AS lastInDate,
COALESCE(DATE_FORMAT(lastOutDateRaw, '%Y-%m-%d'), '') AS lastOutDate,
COALESCE(DATE_FORMAT(stockTakeDateRaw, '%Y-%m-%d'), '') AS stockTakeDate,
/* 取貨量 = approverStockTakeQty(無盤點紀錄就空白) */
CASE
WHEN stkApproverQty IS NULL THEN ''


+ 4
- 4
src/main/resources/jasper/StockTakeVarianceReport.jrxml Vedi File

@@ -51,10 +51,10 @@
<field name="totalOpeningBalance" class="java.lang.String"/>
<field name="totalCumStockOut" class="java.lang.String"/>
<field name="totalCurrentBalance" class="java.lang.String"/>
<field name="lastMovementDate" class="java.lang.String"/>
<field name="stockTakeDate" class="java.lang.String"/>
<field name="lastInDate" class="java.lang.String"/>
<field name="storeLocation" class="java.lang.String"/>
<field name="stockCountQty" class="java.lang.String"/>
<field name="stockTakeQty" class="java.lang.String"/>
<field name="variance" class="java.lang.String"/>
<field name="variancePercentage" class="java.lang.String"/>
<group name="Group1" keepTogether="true" preventOrphanFooter="true">
@@ -352,7 +352,7 @@
<textElement textAlignment="Center" verticalAlignment="Middle">
<font fontName="微軟正黑體"/>
</textElement>
<textFieldExpression><![CDATA[$F{lastMovementDate}]]></textFieldExpression>
<textFieldExpression><![CDATA[$F{stockTakeDate}]]></textFieldExpression>
</textField>
<textField textAdjust="StretchHeight">
<reportElement x="408" y="0" width="72" height="18" uuid="02d11283-5166-45fd-a900-6ae62315ac0a">
@@ -361,7 +361,7 @@
<textElement textAlignment="Right" verticalAlignment="Middle">
<font fontName="微軟正黑體"/>
</textElement>
<textFieldExpression><![CDATA[$F{stockCountQty}]]></textFieldExpression>
<textFieldExpression><![CDATA[$F{stockTakeQty}]]></textFieldExpression>
</textField>
<textField textAdjust="StretchHeight">
<reportElement x="481" y="0" width="74" height="18" uuid="68b8a311-ac96-4df6-9b9f-fb0db60c8a2d">


Caricamento…
Annulla
Salva