From 148e150029222e5b8f08e5ab6d3aafc7d7ca6455 Mon Sep 17 00:00:00 2001 From: "zangch@mesnac.com" Date: Mon, 29 Sep 2025 15:50:53 +0800 Subject: [PATCH] =?UTF-8?q?feat(wms):=20=E6=B7=BB=E5=8A=A06=E4=B8=AA?= =?UTF-8?q?=E6=8A=A5=E8=A1=A8=E7=9A=84=E5=AD=98=E5=82=A8=E8=BF=87=E7=A8=8B?= =?UTF-8?q?=E5=92=8C=E8=A1=A8=E7=BB=93=E6=9E=84?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit - 新增7个WMS报表相关存储过程,包括退库原因分析、库存变动趋势分析、安全库存预警、呆滞料库存、库存差异、库存周转等 - 创建6个报表数据表和1个报表汇总表,支持定时数据更新和统计分析 - 实现主存储过程sp_update_all_wms_reports统一执行所有报表数据更新 - 添加索引优化查询性能,支持租户ID和统计日期等关键字段筛选- 支持物料分类和租户维度的数据隔离和统计分析 --- .../hwmom-wms/wms_report_procedures.sql | 590 ++++++++++++++++++ ruoyi-modules/hwmom-wms/wms_report_tables.sql | 159 +++++ 2 files changed, 749 insertions(+) create mode 100644 ruoyi-modules/hwmom-wms/wms_report_procedures.sql create mode 100644 ruoyi-modules/hwmom-wms/wms_report_tables.sql diff --git a/ruoyi-modules/hwmom-wms/wms_report_procedures.sql b/ruoyi-modules/hwmom-wms/wms_report_procedures.sql new file mode 100644 index 00000000..e7cc60fc --- /dev/null +++ b/ruoyi-modules/hwmom-wms/wms_report_procedures.sql @@ -0,0 +1,590 @@ +-- ============================================= +-- WMS报表存储过程 +-- 用于定时插入和更新报表数据 +-- ============================================= + +-- 1. 退库原因分析报表数据插入存储过程 +CREATE OR ALTER PROCEDURE sp_insert_return_reason_analysis + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + -- 删除当天的数据,重新插入 + DELETE FROM wms_report_return_reason_analysis + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id); + + -- 插入新数据 + INSERT INTO wms_report_return_reason_analysis ( + tenant_id, return_reason_category, return_order_count, total_return_amount, + order_count_ratio, amount_ratio, material_name, material_category_name, + material_code, statistics_date + ) + SELECT + ro.tenant_id, + CASE + WHEN ro.return_reason LIKE '%质量%' OR ro.return_reason LIKE '%不合格%' THEN '质量问题' + WHEN ro.return_reason LIKE '%订单%' OR ro.return_reason LIKE '%变更%' THEN '订单变更' + WHEN ro.return_reason LIKE '%损坏%' OR ro.return_reason LIKE '%破损%' THEN '物料损坏' + WHEN ro.return_reason LIKE '%过期%' OR ro.return_reason LIKE '%超期%' THEN '过期物料' + ELSE ro.return_reason + END AS returnReasonCategory, + COUNT(*) AS returnOrderCount, + SUM(ro.return_amount) AS totalReturnAmount, + CAST(CASE + WHEN (SELECT COUNT(*) FROM wms_return_order WHERE tenant_id = ro.tenant_id AND order_status = '1') = 0 THEN 0 + ELSE COUNT(*) * 100.0 / (SELECT COUNT(*) FROM wms_return_order WHERE tenant_id = ro.tenant_id AND order_status = '1') + END AS DECIMAL(10,2)) AS orderCountRatio, + CAST(CASE + WHEN (SELECT SUM(return_amount) FROM wms_return_order WHERE tenant_id = ro.tenant_id AND order_status = '1') = 0 + OR (SELECT SUM(return_amount) FROM wms_return_order WHERE tenant_id = ro.tenant_id AND order_status = '1') IS NULL THEN 0 + ELSE SUM(ro.return_amount) * 100.0 / (SELECT SUM(return_amount) FROM wms_return_order WHERE tenant_id = ro.tenant_id AND order_status = '1') + END AS DECIMAL(10,2)) AS amountRatio, + mi.material_name, + mc.material_category_name, + mi.material_code, + CAST(GETDATE() AS DATE) + FROM wms_return_order ro + INNER JOIN base_material_info_copy1 mi ON ro.material_id = mi.material_id + INNER JOIN base_material_category mc ON mi.material_category_id = mc.material_category_id + WHERE ro.order_status = '1' + AND (@tenant_id IS NULL OR ro.tenant_id = @tenant_id) + AND (@material_category_id IS NULL OR mc.material_category_id = @material_category_id) + GROUP BY ro.tenant_id, + CASE + WHEN ro.return_reason LIKE '%质量%' OR ro.return_reason LIKE '%不合格%' THEN '质量问题' + WHEN ro.return_reason LIKE '%订单%' OR ro.return_reason LIKE '%变更%' THEN '订单变更' + WHEN ro.return_reason LIKE '%损坏%' OR ro.return_reason LIKE '%破损%' THEN '物料损坏' + WHEN ro.return_reason LIKE '%过期%' OR ro.return_reason LIKE '%超期%' THEN '过期物料' + ELSE ro.return_reason + END, + mi.material_name, + mc.material_category_name, + mi.material_code; + + -- 更新汇总表 + MERGE wms_report_summary AS target + USING ( + SELECT + @tenant_id AS tenant_id, + '退库原因分析' AS report_type, + CAST(GETDATE() AS DATE) AS report_date, + COUNT(*) AS total_records + FROM wms_report_return_reason_analysis + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id) + ) AS source ON target.tenant_id = source.tenant_id + AND target.report_type = source.report_type + AND target.report_date = source.report_date + WHEN MATCHED THEN + UPDATE SET total_records = source.total_records, last_update_time = GETDATE() + WHEN NOT MATCHED THEN + INSERT (tenant_id, report_type, report_date, total_records) + VALUES (source.tenant_id, source.report_type, source.report_date, source.total_records); +END; +GO-- 2. 库 +存变动趋势分析报表数据插入存储过程 +CREATE OR ALTER PROCEDURE sp_insert_inventory_trend_analysis + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + -- 删除当天的数据,重新插入 + DELETE FROM wms_report_inventory_trend_analysis + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id); + + -- 插入新数据 + INSERT INTO wms_report_inventory_trend_analysis ( + tenant_id, material_id, material_code, material_name, material_category_name, + statistics_month, statistics_week, current_inventory_qty, week_instock_qty, + week_outstock_qty, last_week_inventory_qty, key_node_mark, statistics_date + ) + SELECT + inv.tenant_id, + inv.material_id, + mi.material_code, + mi.material_name, + mc.material_category_name, + CONVERT(VARCHAR(7), GETDATE(), 126) AS statisticsMonth, + DATEPART(WEEK, GETDATE()) AS statisticsWeek, + SUM(inv.inventory_qty) AS currentInventoryQty, + ISNULL(instock_data.weekInstockQty, 0) AS weekInstockQty, + ISNULL(outstock_data.weekOutstockQty, 0) AS weekOutstockQty, + (SUM(inv.inventory_qty) + ISNULL(outstock_data.weekOutstockQty, 0) - ISNULL(instock_data.weekInstockQty, 0)) AS lastWeekInventoryQty, + CASE + WHEN ISNULL(instock_data.weekInstockQty, 0) > 1000 THEN '大额入库' + WHEN ISNULL(outstock_data.weekOutstockQty, 0) > 1000 THEN '大额出库' + ELSE '正常变动' + END AS keyNodeMark, + CAST(GETDATE() AS DATE) + FROM wms_inventory inv + INNER JOIN base_material_info_copy1 mi ON inv.material_id = mi.material_id + INNER JOIN base_material_category mc ON mi.material_category_id = mc.material_category_id + LEFT JOIN ( + SELECT material_id, tenant_id, SUM(instock_qty) AS weekInstockQty + FROM wms_instock_record + WHERE create_time >= DATEADD(DAY, -7, GETDATE()) + GROUP BY material_id, tenant_id + ) instock_data ON inv.material_id = instock_data.material_id AND inv.tenant_id = instock_data.tenant_id + LEFT JOIN ( + SELECT material_id, tenant_id, SUM(outstock_qty) AS weekOutstockQty + FROM wms_outstock_record + WHERE create_time >= DATEADD(DAY, -7, GETDATE()) + GROUP BY material_id, tenant_id + ) outstock_data ON inv.material_id = outstock_data.material_id AND inv.tenant_id = outstock_data.tenant_id + WHERE inv.inventory_status = '1' + AND (@tenant_id IS NULL OR inv.tenant_id = @tenant_id) + AND (@material_category_id IS NULL OR mc.material_category_id = @material_category_id) + GROUP BY inv.tenant_id, inv.material_id, mi.material_code, mi.material_name, mc.material_category_name, + instock_data.weekInstockQty, outstock_data.weekOutstockQty; + + -- 更新汇总表 + MERGE wms_report_summary AS target + USING ( + SELECT + @tenant_id AS tenant_id, + '库存变动趋势分析' AS report_type, + CAST(GETDATE() AS DATE) AS report_date, + COUNT(*) AS total_records + FROM wms_report_inventory_trend_analysis + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id) + ) AS source ON target.tenant_id = source.tenant_id + AND target.report_type = source.report_type + AND target.report_date = source.report_date + WHEN MATCHED THEN + UPDATE SET total_records = source.total_records, last_update_time = GETDATE() + WHEN NOT MATCHED THEN + INSERT (tenant_id, report_type, report_date, total_records) + VALUES (source.tenant_id, source.report_type, source.report_date, source.total_records); +END; +GO + +-- 3. 安全库存预警报表数据插入存储过程 +CREATE OR ALTER PROCEDURE sp_insert_safety_stock_alert + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + -- 删除当天的数据,重新插入 + DELETE FROM wms_report_safety_stock_alert + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id); + + -- 插入新数据 + INSERT INTO wms_report_safety_stock_alert ( + tenant_id, material_id, material_code, material_name, material_category_name, + current_inventory_qty, safe_stock_amount, min_stock_amount, max_stock_amount, + alert_status, difference_amount, last_update_time, statistics_date + ) + SELECT + inv.tenant_id, + inv.material_id, + mi.material_code, + mi.material_name, + mc.material_category_name, + SUM(inv.inventory_qty) AS currentInventoryQty, + mi.safe_stock_amount, + mi.min_stock_amount, + mi.max_stock_amount, + CASE + WHEN SUM(inv.inventory_qty) < mi.min_stock_amount THEN '短缺预警' + WHEN SUM(inv.inventory_qty) > mi.max_stock_amount THEN '积压预警' + ELSE '正常' + END AS alertStatus, + CASE + WHEN SUM(inv.inventory_qty) < mi.min_stock_amount THEN mi.min_stock_amount - SUM(inv.inventory_qty) + WHEN SUM(inv.inventory_qty) > mi.max_stock_amount THEN SUM(inv.inventory_qty) - mi.max_stock_amount + WHEN SUM(inv.inventory_qty) < mi.safe_stock_amount THEN mi.safe_stock_amount - SUM(inv.inventory_qty) + ELSE 0 + END AS differenceAmount, + inv.update_time, + CAST(GETDATE() AS DATE) + FROM wms_inventory inv + INNER JOIN base_material_info_copy1 mi ON inv.material_id = mi.material_id + INNER JOIN base_material_category mc ON mi.material_category_id = mc.material_category_id + WHERE inv.inventory_status = '1' + AND mi.active_flag = '1' + AND (mi.safe_stock_amount IS NOT NULL OR mi.min_stock_amount IS NOT NULL OR mi.max_stock_amount IS NOT NULL) + AND (@tenant_id IS NULL OR inv.tenant_id = @tenant_id) + AND (@material_category_id IS NULL OR mc.material_category_id = @material_category_id) + GROUP BY inv.tenant_id, inv.material_id, mi.material_code, mi.material_name, mc.material_category_name, + mi.safe_stock_amount, mi.min_stock_amount, mi.max_stock_amount, inv.update_time + HAVING SUM(inv.inventory_qty) < mi.safe_stock_amount + OR SUM(inv.inventory_qty) < mi.min_stock_amount + OR SUM(inv.inventory_qty) > mi.max_stock_amount; + + -- 更新汇总表 + MERGE wms_report_summary AS target + USING ( + SELECT + @tenant_id AS tenant_id, + '安全库存预警' AS report_type, + CAST(GETDATE() AS DATE) AS report_date, + COUNT(*) AS total_records + FROM wms_report_safety_stock_alert + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id) + ) AS source ON target.tenant_id = source.tenant_id + AND target.report_type = source.report_type + AND target.report_date = source.report_date + WHEN MATCHED THEN + UPDATE SET total_records = source.total_records, last_update_time = GETDATE() + WHEN NOT MATCHED THEN + INSERT (tenant_id, report_type, report_date, total_records) + VALUES (source.tenant_id, source.report_type, source.report_date, source.total_records); +END; +GO-- 4. 呆滞料 +库存报表数据插入存储过程 +CREATE OR ALTER PROCEDURE sp_insert_stagnant_inventory + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + -- 删除当天的数据,重新插入 + DELETE FROM wms_report_stagnant_inventory + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id); + + -- 插入新数据 + INSERT INTO wms_report_stagnant_inventory ( + tenant_id, material_id, material_code, material_name, material_category_name, + stagnant_inventory_qty, material_unit, last_outstock_time, stagnant_days, + stagnant_reason, material_spec, warehouse_name, last_activity_time, statistics_date + ) + SELECT + inv.tenant_id, + inv.material_id, + mi.material_code, + mi.material_name, + mc.material_category_name, + SUM(inv.inventory_qty) AS stagnantInventoryQty, + mi.material_unit, + CASE + WHEN last_out.lastOutstockTime IS NULL THEN '从未出库' + ELSE CONVERT(VARCHAR(19), last_out.lastOutstockTime, 120) + END AS lastOutstockTime, + CASE + WHEN last_out.lastOutstockTime IS NULL THEN DATEDIFF(DAY, first_in.firstInstockTime, GETDATE()) + ELSE DATEDIFF(DAY, last_out.lastOutstockTime, GETDATE()) + END AS stagnantDays, + CASE + WHEN last_out.lastOutstockTime IS NULL THEN '从未出库' + WHEN DATEDIFF(DAY, last_out.lastOutstockTime, GETDATE()) > 180 THEN '超过6个月未出库' + ELSE '正常' + END AS stagnantReason, + mi.material_spec, + w.warehouse_name, + CASE + WHEN last_out.lastOutstockTime IS NULL THEN CONVERT(VARCHAR(19), first_in.firstInstockTime, 120) + ELSE CONVERT(VARCHAR(19), last_out.lastOutstockTime, 120) + END AS lastActivityTime, + CAST(GETDATE() AS DATE) + FROM wms_inventory inv + INNER JOIN base_material_info_copy1 mi ON inv.material_id = mi.material_id + INNER JOIN base_material_category mc ON mi.material_category_id = mc.material_category_id + INNER JOIN wms_base_warehouse w ON inv.warehouse_id = w.warehouse_id + LEFT JOIN ( + SELECT + material_id, + tenant_id, + MIN(create_time) AS firstInstockTime + FROM wms_instock_record + WHERE create_time IS NOT NULL + GROUP BY material_id, tenant_id + ) first_in ON inv.material_id = first_in.material_id AND inv.tenant_id = first_in.tenant_id + LEFT JOIN ( + SELECT + material_id, + tenant_id, + MAX(create_time) AS lastOutstockTime + FROM wms_outstock_record + WHERE create_time IS NOT NULL + GROUP BY material_id, tenant_id + ) last_out ON inv.material_id = last_out.material_id AND inv.tenant_id = last_out.tenant_id + WHERE inv.inventory_status = '1' + AND inv.inventory_qty > 0 + AND mi.active_flag = '1' + AND mi.del_flag = '0' + AND ( + last_out.lastOutstockTime IS NULL + OR DATEDIFF(DAY, last_out.lastOutstockTime, GETDATE()) >= 180 + ) + AND (@tenant_id IS NULL OR inv.tenant_id = @tenant_id) + AND (@material_category_id IS NULL OR mc.material_category_id = @material_category_id) + GROUP BY + inv.tenant_id, + inv.material_id, + mi.material_code, + mi.material_name, + mc.material_category_name, + mi.material_unit, + last_out.lastOutstockTime, + mi.material_spec, + w.warehouse_name, + first_in.firstInstockTime; + + -- 更新汇总表 + MERGE wms_report_summary AS target + USING ( + SELECT + @tenant_id AS tenant_id, + '呆滞料库存' AS report_type, + CAST(GETDATE() AS DATE) AS report_date, + COUNT(*) AS total_records + FROM wms_report_stagnant_inventory + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id) + ) AS source ON target.tenant_id = source.tenant_id + AND target.report_type = source.report_type + AND target.report_date = source.report_date + WHEN MATCHED THEN + UPDATE SET total_records = source.total_records, last_update_time = GETDATE() + WHEN NOT MATCHED THEN + INSERT (tenant_id, report_type, report_date, total_records) + VALUES (source.tenant_id, source.report_type, source.report_date, source.total_records); +END; +GO + +-- 5. 库存差异报表数据插入存储过程 +CREATE OR ALTER PROCEDURE sp_insert_inventory_difference + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + -- 删除当天的数据,重新插入 + DELETE FROM wms_report_inventory_difference + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id); + + -- 插入新数据 + INSERT INTO wms_report_inventory_difference ( + tenant_id, check_code, check_type, warehouse_id, warehouse_name, + material_id, material_code, material_name, material_category_name, + book_inventory_qty, actual_inventory_qty, difference_qty, difference_type, + difference_rate, difference_level, check_time, check_by, statistics_date + ) + SELECT + ic.tenant_id, + ic.check_code, + CASE ic.check_type + WHEN '0' THEN '抽检' + WHEN '1' THEN '盘点' + WHEN '2' THEN '库位/货架盘点' + ELSE '未知' + END AS checkType, + ic.plan_warehouse_id, + w.warehouse_name, + icr.material_id, + mi.material_code, + mi.material_name, + mc.material_category_name, + icr.inventory_qty AS bookInventoryQty, + icr.check_qty AS actualInventoryQty, + (icr.check_qty - icr.inventory_qty) AS differenceQty, + CASE + WHEN ABS(icr.check_qty - icr.inventory_qty) = 0 THEN '无差异' + WHEN (icr.check_qty - icr.inventory_qty) > 0 THEN '盘盈' + ELSE '盘亏' + END AS differenceType, + CASE + WHEN icr.inventory_qty > 0 THEN + ABS((icr.check_qty - icr.inventory_qty) / icr.inventory_qty * 100) + ELSE 0 + END AS differenceRate, + CASE + WHEN ABS(icr.check_qty - icr.inventory_qty) > 10 THEN '重大差异' + WHEN ABS(icr.check_qty - icr.inventory_qty) > 5 THEN '一般差异' + WHEN ABS(icr.check_qty - icr.inventory_qty) > 0 THEN '轻微差异' + ELSE '无差异' + END AS differenceLevel, + ic.create_time, + ic.create_by, + CAST(GETDATE() AS DATE) + FROM wms_inventory_check ic + INNER JOIN wms_base_warehouse w ON ic.plan_warehouse_id = w.warehouse_id + INNER JOIN wms_inventory_check_record icr ON icr.check_code = ic.check_code AND icr.tenant_id = ic.tenant_id + INNER JOIN base_material_info_copy1 mi ON icr.material_id = mi.material_id + INNER JOIN base_material_category mc ON mi.material_category_id = mc.material_category_id + WHERE ic.check_status = '3' + AND (@tenant_id IS NULL OR ic.tenant_id = @tenant_id) + AND (@material_category_id IS NULL OR mc.material_category_id = @material_category_id); + + -- 更新汇总表 + MERGE wms_report_summary AS target + USING ( + SELECT + @tenant_id AS tenant_id, + '库存差异' AS report_type, + CAST(GETDATE() AS DATE) AS report_date, + COUNT(*) AS total_records + FROM wms_report_inventory_difference + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id) + ) AS source ON target.tenant_id = source.tenant_id + AND target.report_type = source.report_type + AND target.report_date = source.report_date + WHEN MATCHED THEN + UPDATE SET total_records = source.total_records, last_update_time = GETDATE() + WHEN NOT MATCHED THEN + INSERT (tenant_id, report_type, report_date, total_records) + VALUES (source.tenant_id, source.report_type, source.report_date, source.total_records); +END; +GO-- + 6. 库存周转报表数据插入存储过程 +CREATE OR ALTER PROCEDURE sp_insert_inventory_turnover + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + -- 删除当天的数据,重新插入 + DELETE FROM wms_report_inventory_turnover + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id); + + -- 插入新数据 + INSERT INTO wms_report_inventory_turnover ( + tenant_id, material_id, material_code, material_name, material_category_name, + statistics_month, begin_inventory_qty, end_inventory_qty, month_outstock_qty, + inventory_turnover_rate, simple_turnover_rate, turnover_evaluation, statistics_date + ) + SELECT + base_data.tenantId, + base_data.materialId, + base_data.materialCode, + base_data.materialName, + base_data.materialCategoryName, + base_data.statisticsMonth, + base_data.beginInventoryQty, + base_data.endInventoryQty, + base_data.monthOutstockQty, + CASE + WHEN (base_data.beginInventoryQty + base_data.endInventoryQty) > 0 THEN + CAST(base_data.monthOutstockQty * 2.0 / (base_data.beginInventoryQty + base_data.endInventoryQty) * 100 AS DECIMAL(10,2)) + ELSE 0 + END AS inventoryTurnoverRate, + CASE + WHEN base_data.endInventoryQty > 0 THEN + CAST(base_data.monthOutstockQty / base_data.endInventoryQty * 100 AS DECIMAL(10,2)) + ELSE 0 + END AS simpleTurnoverRate, + CASE + WHEN base_data.monthOutstockQty = 0 THEN '无流动' + WHEN CAST(base_data.monthOutstockQty * 2.0 / (base_data.beginInventoryQty + base_data.endInventoryQty) * 100 AS DECIMAL(10,2)) >= 100 THEN '快速周转' + WHEN CAST(base_data.monthOutstockQty * 2.0 / (base_data.beginInventoryQty + base_data.endInventoryQty) * 100 AS DECIMAL(10,2)) >= 50 THEN '正常周转' + ELSE '缓慢周转' + END AS turnoverEvaluation, + CAST(GETDATE() AS DATE) + FROM ( + SELECT + inv.tenant_id AS tenantId, + inv.material_id AS materialId, + mi.material_code AS materialCode, + mi.material_name AS materialName, + mc.material_category_name AS materialCategoryName, + CONVERT(VARCHAR(7), GETDATE(), 126) AS statisticsMonth, + SUM(inv.inventory_qty) AS endInventoryQty, + SUM(inv.inventory_qty) + ISNULL(month_out.monthOutstockQty, 0) - ISNULL(month_in.monthInstockQty, 0) AS beginInventoryQty, + ISNULL(month_out.monthOutstockQty, 0) AS monthOutstockQty + FROM wms_inventory inv + INNER JOIN base_material_info_copy1 mi ON inv.material_id = mi.material_id + INNER JOIN base_material_category mc ON mi.material_category_id = mc.material_category_id + LEFT JOIN ( + SELECT material_id, tenant_id, SUM(outstock_qty) AS monthOutstockQty + FROM wms_outstock_record + WHERE create_time >= DATEADD(MONTH, -1, GETDATE()) + GROUP BY material_id, tenant_id + ) month_out ON inv.material_id = month_out.material_id AND inv.tenant_id = month_out.tenant_id + LEFT JOIN ( + SELECT material_id, tenant_id, SUM(instock_qty) AS monthInstockQty + FROM wms_instock_record + WHERE create_time >= DATEADD(MONTH, -1, GETDATE()) + GROUP BY material_id, tenant_id + ) month_in ON inv.material_id = month_in.material_id AND inv.tenant_id = month_in.tenant_id + WHERE inv.inventory_status = '1' + AND (@tenant_id IS NULL OR inv.tenant_id = @tenant_id) + AND (@material_category_id IS NULL OR mc.material_category_id = @material_category_id) + GROUP BY inv.tenant_id, inv.material_id, mi.material_code, mi.material_name, mc.material_category_name, + month_out.monthOutstockQty, month_in.monthInstockQty + ) base_data + WHERE base_data.beginInventoryQty > 0 OR base_data.endInventoryQty > 0 OR base_data.monthOutstockQty > 0; + + -- 更新汇总表 + MERGE wms_report_summary AS target + USING ( + SELECT + @tenant_id AS tenant_id, + '库存周转' AS report_type, + CAST(GETDATE() AS DATE) AS report_date, + COUNT(*) AS total_records + FROM wms_report_inventory_turnover + WHERE statistics_date = CAST(GETDATE() AS DATE) + AND (@tenant_id IS NULL OR tenant_id = @tenant_id) + ) AS source ON target.tenant_id = source.tenant_id + AND target.report_type = source.report_type + AND target.report_date = source.report_date + WHEN MATCHED THEN + UPDATE SET total_records = source.total_records, last_update_time = GETDATE() + WHEN NOT MATCHED THEN + INSERT (tenant_id, report_type, report_date, total_records) + VALUES (source.tenant_id, source.report_type, source.report_date, source.total_records); +END; +GO + +-- 7. 主存储过程 - 执行所有报表数据更新 +CREATE OR ALTER PROCEDURE sp_update_all_wms_reports + @tenant_id NVARCHAR(50) = NULL, + @material_category_id BIGINT = NULL +AS +BEGIN + SET NOCOUNT ON; + + BEGIN TRY + PRINT '开始更新WMS报表数据...' + + -- 1. 更新退库原因分析报表 + PRINT '更新退库原因分析报表...' + EXEC sp_insert_return_reason_analysis @tenant_id, @material_category_id; + + -- 2. 更新库存变动趋势分析报表 + PRINT '更新库存变动趋势分析报表...' + EXEC sp_insert_inventory_trend_analysis @tenant_id, @material_category_id; + + -- 3. 更新安全库存预警报表 + PRINT '更新安全库存预警报表...' + EXEC sp_insert_safety_stock_alert @tenant_id, @material_category_id; + + -- 4. 更新呆滞料库存报表 + PRINT '更新呆滞料库存报表...' + EXEC sp_insert_stagnant_inventory @tenant_id, @material_category_id; + + -- 5. 更新库存差异报表 + PRINT '更新库存差异报表...' + EXEC sp_insert_inventory_difference @tenant_id, @material_category_id; + + -- 6. 更新库存周转报表 + PRINT '更新库存周转报表...' + EXEC sp_insert_inventory_turnover @tenant_id, @material_category_id; + + PRINT 'WMS报表数据更新完成!' + + END TRY + BEGIN CATCH + PRINT 'WMS报表数据更新失败: ' + ERROR_MESSAGE() + THROW; + END CATCH +END; +GO \ No newline at end of file diff --git a/ruoyi-modules/hwmom-wms/wms_report_tables.sql b/ruoyi-modules/hwmom-wms/wms_report_tables.sql new file mode 100644 index 00000000..414c2d2e --- /dev/null +++ b/ruoyi-modules/hwmom-wms/wms_report_tables.sql @@ -0,0 +1,159 @@ +-- ============================================= +-- WMS报表数据库表设计 +-- 基于WmsReportMapper中的查询SQL设计 +-- ============================================= + +-- 1. 退库原因分析报表表 +CREATE TABLE wms_report_return_reason_analysis ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + return_reason_category NVARCHAR(100) NOT NULL, + return_order_count INT NOT NULL DEFAULT 0, + total_return_amount DECIMAL(18,2) NOT NULL DEFAULT 0, + order_count_ratio DECIMAL(10,2) NOT NULL DEFAULT 0, + amount_ratio DECIMAL(10,2) NOT NULL DEFAULT 0, + material_name NVARCHAR(200), + material_category_name NVARCHAR(100), + material_code NVARCHAR(100), + statistics_date DATE NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_date (tenant_id, statistics_date), + INDEX IX_category (return_reason_category), + INDEX IX_material (material_code) +); + +-- 2. 库存变动趋势分析报表表 +CREATE TABLE wms_report_inventory_trend_analysis ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + material_id BIGINT NOT NULL, + material_code NVARCHAR(100) NOT NULL, + material_name NVARCHAR(200) NOT NULL, + material_category_name NVARCHAR(100), + statistics_month NVARCHAR(7) NOT NULL, -- YYYY-MM格式 + statistics_week INT NOT NULL, + current_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + week_instock_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + week_outstock_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + last_week_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + key_node_mark NVARCHAR(50), + statistics_date DATE NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_material (tenant_id, material_id), + INDEX IX_month_week (statistics_month, statistics_week), + INDEX IX_material_code (material_code) +); + +-- 3. 安全库存预警报表表 +CREATE TABLE wms_report_safety_stock_alert ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + material_id BIGINT NOT NULL, + material_code NVARCHAR(100) NOT NULL, + material_name NVARCHAR(200) NOT NULL, + material_category_name NVARCHAR(100), + current_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + safe_stock_amount DECIMAL(18,2), + min_stock_amount DECIMAL(18,2), + max_stock_amount DECIMAL(18,2), + alert_status NVARCHAR(50) NOT NULL, -- 短缺预警/积压预警/正常 + difference_amount DECIMAL(18,2) NOT NULL DEFAULT 0, + last_update_time DATETIME2, + statistics_date DATE NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_material (tenant_id, material_id), + INDEX IX_alert_status (alert_status), + INDEX IX_material_code (material_code) +); + +-- 4. 呆滞料库存报表表 +CREATE TABLE wms_report_stagnant_inventory ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + material_id BIGINT NOT NULL, + material_code NVARCHAR(100) NOT NULL, + material_name NVARCHAR(200) NOT NULL, + material_category_name NVARCHAR(100), + stagnant_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + material_unit NVARCHAR(20), + last_outstock_time NVARCHAR(50), -- 可能是"从未出库"或日期时间 + stagnant_days INT NOT NULL DEFAULT 0, + stagnant_reason NVARCHAR(100), + material_spec NVARCHAR(200), + warehouse_name NVARCHAR(100), + last_activity_time NVARCHAR(50), + statistics_date DATE NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_material (tenant_id, material_id), + INDEX IX_stagnant_days (stagnant_days), + INDEX IX_material_code (material_code) +);-- 5. + 库存差异报表表 +CREATE TABLE wms_report_inventory_difference ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + check_code NVARCHAR(100) NOT NULL, + check_type NVARCHAR(50) NOT NULL, -- 抽检/盘点/库位/货架盘点 + warehouse_id BIGINT, + warehouse_name NVARCHAR(100), + material_id BIGINT NOT NULL, + material_code NVARCHAR(100) NOT NULL, + material_name NVARCHAR(200) NOT NULL, + material_category_name NVARCHAR(100), + book_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + actual_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + difference_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + difference_type NVARCHAR(20) NOT NULL, -- 无差异/盘盈/盘亏 + difference_rate DECIMAL(10,2) NOT NULL DEFAULT 0, + difference_level NVARCHAR(20) NOT NULL, -- 重大差异/一般差异/轻微差异/无差异 + check_time DATETIME2, + check_by NVARCHAR(100), + statistics_date DATE NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_check (tenant_id, check_code), + INDEX IX_difference_type (difference_type), + INDEX IX_material_code (material_code) +); + +-- 6. 库存周转报表表 +CREATE TABLE wms_report_inventory_turnover ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + material_id BIGINT NOT NULL, + material_code NVARCHAR(100) NOT NULL, + material_name NVARCHAR(200) NOT NULL, + material_category_name NVARCHAR(100), + statistics_month NVARCHAR(7) NOT NULL, -- YYYY-MM格式 + begin_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + end_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + month_outstock_qty DECIMAL(18,2) NOT NULL DEFAULT 0, + inventory_turnover_rate DECIMAL(10,2) NOT NULL DEFAULT 0, + simple_turnover_rate DECIMAL(10,2) NOT NULL DEFAULT 0, + turnover_evaluation NVARCHAR(50), -- 无流动/快速周转/正常周转/缓慢周转 + statistics_date DATE NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_material (tenant_id, material_id), + INDEX IX_month (statistics_month), + INDEX IX_turnover_rate (inventory_turnover_rate), + INDEX IX_material_code (material_code) +); + +-- ============================================= +-- 报表数据汇总表(可选,用于快速查询) +-- ============================================= +CREATE TABLE wms_report_summary ( + id BIGINT IDENTITY(1,1) PRIMARY KEY, + tenant_id NVARCHAR(50) NOT NULL, + report_type NVARCHAR(50) NOT NULL, -- 报表类型 + report_date DATE NOT NULL, + total_records INT NOT NULL DEFAULT 0, + last_update_time DATETIME2 NOT NULL DEFAULT GETDATE(), + create_time DATETIME2 NOT NULL DEFAULT GETDATE(), + INDEX IX_tenant_type_date (tenant_id, report_type, report_date) +); \ No newline at end of file