From 632069090b5bc37f27211ee484a2cb1ec10caa1f Mon Sep 17 00:00:00 2001 From: "CANCERYS\\kw093" Date: Tue, 10 Feb 2026 19:07:05 +0800 Subject: [PATCH] update --- .../service/StockLedgerReportService.kt | 385 ++++++++++ .../report/web/StockLedgerReportController.kt | 63 ++ .../resources/jasper/StockLedgarReport.jrxml | 693 ++++++++++++++++++ 3 files changed, 1141 insertions(+) create mode 100644 src/main/java/com/ffii/fpsms/modules/report/service/StockLedgerReportService.kt create mode 100644 src/main/java/com/ffii/fpsms/modules/report/web/StockLedgerReportController.kt create mode 100644 src/main/resources/jasper/StockLedgarReport.jrxml diff --git a/src/main/java/com/ffii/fpsms/modules/report/service/StockLedgerReportService.kt b/src/main/java/com/ffii/fpsms/modules/report/service/StockLedgerReportService.kt new file mode 100644 index 0000000..4a8e139 --- /dev/null +++ b/src/main/java/com/ffii/fpsms/modules/report/service/StockLedgerReportService.kt @@ -0,0 +1,385 @@ +package com.ffii.fpsms.modules.report.service + +import com.ffii.core.support.JdbcDao +import org.springframework.stereotype.Service + +@Service +open class StockLedgerReportService( + private val jdbcDao: JdbcDao, +) { + + /** + * Stock Ledger 報表查詢 + * + * - stockSubCategory = items.type + * - trnDate = stock_ledger.date + * - 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 < + ): List> { + + val args = mutableMapOf() + + // items.type 精確多選 + val stockCategorySql = buildMultiValueExactClause( + stockCategory, + "it.type", + "stockCategory", + args + ) + + // itemCode 模糊多選(用 stock_ledger.itemCode) + val itemCodeSql = buildMultiValueLikeClause( + itemCode, + "sl.itemCode", + "itemCode", + args + ) + + // 倉庫位置 + val storeLocationSql = if (!storeLocation.isNullOrBlank()) { + args["storeLocation"] = "%$storeLocation%" + "AND (wh_in.code LIKE :storeLocation OR wh_out.code LIKE :storeLocation)" + } else { + "" + } + + // 報表期間:按 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 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 + ON sl.stockOutLineId = sol.id + AND sol.deleted = 0 + + LEFT JOIN stock_out so + ON sol.stockOutId = so.id + AND so.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 delivery_order do + ON po.doId = do.id + AND do.deleted = 0 + + 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() + + 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 + } + + /** LIKE 多值工具方法 */ + private fun buildMultiValueLikeClause( + paramValue: String?, + columnName: String, + paramPrefix: String, + args: MutableMap + ): String { + if (paramValue.isNullOrBlank()) return "" + val values = paramValue.split(",").map { it.trim() }.filter { it.isNotBlank() } + if (values.isEmpty()) return "" + + val conditions = values.mapIndexed { index, value -> + val paramName = "${paramPrefix}_$index" + args[paramName] = "%$value%" + "$columnName LIKE :$paramName" + } + return "AND (${conditions.joinToString(" OR ")})" + } + + /** = 多值工具方法 */ + private fun buildMultiValueExactClause( + paramValue: String?, + columnName: String, + paramPrefix: String, + args: MutableMap + ): String { + if (paramValue.isNullOrBlank()) return "" + val values = paramValue.split(",").map { it.trim() }.filter { it.isNotBlank() } + if (values.isEmpty()) return "" + + val conditions = values.mapIndexed { index, value -> + val paramName = "${paramPrefix}_$index" + args[paramName] = value + "$columnName = :$paramName" + } + return "AND (${conditions.joinToString(" OR ")})" + } +} \ No newline at end of file diff --git a/src/main/java/com/ffii/fpsms/modules/report/web/StockLedgerReportController.kt b/src/main/java/com/ffii/fpsms/modules/report/web/StockLedgerReportController.kt new file mode 100644 index 0000000..27ea738 --- /dev/null +++ b/src/main/java/com/ffii/fpsms/modules/report/web/StockLedgerReportController.kt @@ -0,0 +1,63 @@ +package com.ffii.fpsms.modules.report.web +import org.springframework.web.bind.annotation.* +import org.springframework.http.* +import java.time.LocalDate +import java.time.LocalTime +import java.time.format.DateTimeFormatter +import com.ffii.fpsms.modules.report.service.StockLedgerReportService +import com.ffii.fpsms.modules.report.service.ReportService + +@RestController +@RequestMapping("/report") +class StockLedgerReportController( + private val reportService: ReportService, + private val stockLedgerReportService: StockLedgerReportService, +) { + + @GetMapping("/print-stock-ledger") +fun generateStockLedgerReport( + @RequestParam(required = false) stockCategory: String?, + @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?, +): ResponseEntity { + val parameters = mutableMapOf() + + parameters["stockCategory"] = stockCategory ?: "All" + parameters["stockSubCategory"] = stockCategory ?: "All" + parameters["itemNo"] = itemCode ?: "All" + parameters["year"] = LocalDate.now().year.toString() + 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"] = "" + parameters["balanceFilterEnd"] = "" + parameters["reportPeriodStart"] = reportPeriodStart ?: "" + parameters["reportPeriodEnd"] = reportPeriodEnd ?: "" + + + val dbData = stockLedgerReportService.searchStockLedgerReport( + stockCategory = stockCategory, + itemCode = itemCode, + storeLocation = storeLocation, + reportPeriodStart = reportPeriodStart, + reportPeriodEnd = reportPeriodEnd, + ) + + val pdfBytes = reportService.createPdfResponse( + "/jasper/StockLedgarReport.jrxml", + parameters, + dbData + ) + + val headers = HttpHeaders().apply { + contentType = MediaType.APPLICATION_PDF + setContentDispositionFormData("attachment", "StockLedgerReport.pdf") + set("filename", "StockLedgerReport.pdf") + } + return ResponseEntity(pdfBytes, headers, HttpStatus.OK) +} +} \ No newline at end of file diff --git a/src/main/resources/jasper/StockLedgarReport.jrxml b/src/main/resources/jasper/StockLedgarReport.jrxml new file mode 100644 index 0000000..988ae7b --- /dev/null +++ b/src/main/resources/jasper/StockLedgarReport.jrxml @@ -0,0 +1,693 @@ + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + <band height="104" splitType="Stretch"> + <staticText> + <reportElement x="319" y="0" width="165" height="23" uuid="1666285e-2b4b-4017-810f-fa9a0a9165b6"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Left" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <text><![CDATA[Stock Ledgar Report +]]></text> + </staticText> + <staticText> + <reportElement x="700" y="12" width="40" height="18" uuid="e212b74e-2e71-4547-9e4a-e4ab2ce64462"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Center" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="12"/> + </textElement> + <text><![CDATA[頁數]]></text> + </staticText> + <textField> + <reportElement x="740" y="12" width="20" height="18" uuid="1b209da7-33e2-4e04-a663-f6170c806ef4"> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Center" verticalAlignment="Middle"> + <font fontName="微軟正黑體"/> + </textElement> + <textFieldExpression><![CDATA[$V{PAGE_NUMBER}]]></textFieldExpression> + </textField> + <staticText> + <reportElement x="760" y="12" width="20" height="18" uuid="542731ff-0b34-401f-af74-5d96753f4a3a"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Center" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="12"/> + </textElement> + <text><![CDATA[/]]></text> + </staticText> + <textField evaluationTime="Report"> + <reportElement x="780" y="12" width="20" height="18" uuid="7124635c-e046-4d7a-9e56-b6a73502a772"> + <property name="com.jaspersoft.studio.unit.width" value="px"/> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Center" verticalAlignment="Middle"> + <font fontName="微軟正黑體"/> + </textElement> + <textFieldExpression><![CDATA[$V{PAGE_NUMBER}]]></textFieldExpression> + </textField> + <staticText> + <reportElement x="0" y="35" width="90" height="23" uuid="a00368d1-1269-4721-9e9f-e8c4a3c7f779"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Left" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <text><![CDATA[報告日期:]]></text> + </staticText> + <staticText> + <reportElement x="0" y="58" width="90" height="23" uuid="a0ece46c-52e7-41dd-ace6-85bf08d98db7"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + </reportElement> + <textElement textAlignment="Left" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <text><![CDATA[貨物分類:]]></text> + </staticText> + <staticText> + <reportElement x="480" y="35" width="90" height="23" uuid="c5cc9643-ab3a-4c5c-9435-589a28f93101"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement textAlignment="Left" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <text><![CDATA[報告時間:]]></text> + </staticText> + <textField> + <reportElement x="90" y="35" width="390" height="23" uuid="a4cfc094-4af4-4ce5-acfa-534c17eeadfd"/> + <textElement verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <textFieldExpression><![CDATA[$P{reportDate}]]></textFieldExpression> + </textField> + <textField> + <reportElement x="90" y="58" width="390" height="23" uuid="9e3719fc-6434-4119-ad51-54f56cb0c110"> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <textFieldExpression><![CDATA[$P{stockCategory}]]></textFieldExpression> + </textField> + <line> + <reportElement x="0" y="103" width="800" height="1" uuid="54929fda-881e-428a-830c-1c06d8d72e67"> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + </line> + <textField> + <reportElement x="570" y="35" width="228" height="23" uuid="fb55961e-94b2-4011-aaa7-834497b4d352"/> + <textElement verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <textFieldExpression><![CDATA[$P{reportTime}]]></textFieldExpression> + </textField> + <staticText> + <reportElement x="0" y="81" width="90" height="23" uuid="083407c6-4fec-4ebe-8791-630b25bdd7e5"> + <property name="com.jaspersoft.studio.unit.y" value="px"/> + </reportElement> + <textElement textAlignment="Left" verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <text><![CDATA[查詢期間:]]></text> + </staticText> + <textField> + <reportElement x="90" y="81" width="490" height="23" uuid="76037c74-490e-4afe-936d-dd8b70230e4c"> + <property name="com.jaspersoft.studio.unit.height" value="px"/> + </reportElement> + <textElement verticalAlignment="Middle"> + <font fontName="微軟正黑體" size="16" isBold="true"/> + </textElement> + <textFieldExpression><![CDATA[$P{reportPeriodStart}+ " 到 " + $P{reportPeriodEnd}]]></textFieldExpression> + </textField> + </band> + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +