-- ============================================= -- 月度WMS报表存储过程 -- 功能:每月末0点生成月度报表,按照类别统计每月的出库、入库记录数量、上月数据、环比差额、月末此刻库存 -- 创建时间:2025-09-25 -- ============================================= -- 1. 创建月度报表表(如果不存在) IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_monthly_report]') AND type in (N'U')) BEGIN CREATE TABLE [dbo].[wms_monthly_report] ( [report_id] bigint IDENTITY(1,1) NOT NULL, [tenant_id] varchar(32) COLLATE Chinese_PRC_CI_AS NULL, [report_year] int NOT NULL, [report_month] int NOT NULL, [material_type_id] bigint NULL, [material_type_name] varchar(64) COLLATE Chinese_PRC_CI_AS NULL, -- 当月数据 [current_instock_count] int DEFAULT 0, -- 当月入库数量 [current_instock_qty] decimal(18,6) DEFAULT 0, -- 当月入库总量 [current_outstock_count] int DEFAULT 0, -- 当月出库数量 [current_outstock_qty] decimal(18,6) DEFAULT 0, -- 当月出库总量 -- 上月数据 [last_instock_count] int DEFAULT 0, -- 上月入库数量 [last_instock_qty] decimal(18,6) DEFAULT 0, -- 上月入库总量 [last_outstock_count] int DEFAULT 0, -- 上月出库数量 [last_outstock_qty] decimal(18,6) DEFAULT 0, -- 上月出库总量 -- 环比差额 [instock_count_diff] int DEFAULT 0, -- 入库数量环比差额 [instock_qty_diff] decimal(18,6) DEFAULT 0, -- 入库总量环比差额 [outstock_count_diff] int DEFAULT 0, -- 出库数量环比差额 [outstock_qty_diff] decimal(18,6) DEFAULT 0, -- 出库总量环比差额 -- 月末库存 [inventory_material_count] int DEFAULT 0, -- 库存物料种类数 [inventory_qty] decimal(18,6) DEFAULT 0, -- 库存总量 [create_time] datetime DEFAULT GETDATE(), [create_by] varchar(32) COLLATE Chinese_PRC_CI_AS DEFAULT 'SYSTEM', CONSTRAINT [PK_wms_monthly_report] PRIMARY KEY CLUSTERED ([report_id]) ); -- 添加索引 CREATE INDEX [IX_wms_monthly_report_year_month] ON [dbo].[wms_monthly_report] ([report_year], [report_month]); CREATE INDEX [IX_wms_monthly_report_material_type] ON [dbo].[wms_monthly_report] ([material_type_id]); -- 添加表和字段的中文注释 EXEC sp_addextendedproperty 'MS_Description', N'WMS月度报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report'; EXEC sp_addextendedproperty 'MS_Description', N'报表主键', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'report_id'; EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'tenant_id'; EXEC sp_addextendedproperty 'MS_Description', N'报表年份', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'report_year'; EXEC sp_addextendedproperty 'MS_Description', N'报表月份', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'report_month'; EXEC sp_addextendedproperty 'MS_Description', N'物料类型ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'material_type_id'; EXEC sp_addextendedproperty 'MS_Description', N'物料类型名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'material_type_name'; EXEC sp_addextendedproperty 'MS_Description', N'当月入库记录数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'current_instock_count'; EXEC sp_addextendedproperty 'MS_Description', N'当月入库总量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'current_instock_qty'; EXEC sp_addextendedproperty 'MS_Description', N'当月出库记录数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'current_outstock_count'; EXEC sp_addextendedproperty 'MS_Description', N'当月出库总量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'current_outstock_qty'; EXEC sp_addextendedproperty 'MS_Description', N'上月入库记录数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'last_instock_count'; EXEC sp_addextendedproperty 'MS_Description', N'上月入库总量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'last_instock_qty'; EXEC sp_addextendedproperty 'MS_Description', N'上月出库记录数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'last_outstock_count'; EXEC sp_addextendedproperty 'MS_Description', N'上月出库总量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'last_outstock_qty'; EXEC sp_addextendedproperty 'MS_Description', N'入库记录数量环比差额(当月-上月)', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'instock_count_diff'; EXEC sp_addextendedproperty 'MS_Description', N'入库总量环比差额(当月-上月)', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'instock_qty_diff'; EXEC sp_addextendedproperty 'MS_Description', N'出库记录数量环比差额(当月-上月)', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'outstock_count_diff'; EXEC sp_addextendedproperty 'MS_Description', N'出库总量环比差额(当月-上月)', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'outstock_qty_diff'; EXEC sp_addextendedproperty 'MS_Description', N'月末库存物料种类数', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'inventory_material_count'; EXEC sp_addextendedproperty 'MS_Description', N'月末库存总量', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'inventory_qty'; EXEC sp_addextendedproperty 'MS_Description', N'报表生成时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'create_time'; EXEC sp_addextendedproperty 'MS_Description', N'报表生成人', 'SCHEMA', N'dbo', 'TABLE', N'wms_monthly_report', 'COLUMN', N'create_by'; END; -- 2. 创建月度报表生成存储过程 ALTER PROCEDURE [dbo].[SP_GenerateMonthlyReport] @ReportYear INT = NULL, @ReportMonth INT = NULL, @TenantId VARCHAR(32) = NULL, @ForceRegenerate BIT = 0 -- 是否强制重新生成(默认不强制) AS BEGIN SET NOCOUNT ON; -- 完整DECLARE所有变量(补@LastYear/@LastMonth) DECLARE @CurrentYear INT, @CurrentMonth INT; DECLARE @LastYear INT, @LastMonth INT; -- 升级TenantId防护:处理NULL、''、空格 SET @TenantId = CASE WHEN @TenantId IS NULL OR LTRIM(RTRIM(@TenantId)) = '' THEN '000000' ELSE @TenantId END; -- 年月防护 IF @ReportYear IS NULL OR @ReportYear = 0 SET @ReportYear = YEAR(GETDATE()); IF @ReportMonth IS NULL OR @ReportMonth = 0 SET @ReportMonth = MONTH(GETDATE()); -- 同步到@CurrentYear等 SET @CurrentYear = @ReportYear; SET @CurrentMonth = @ReportMonth; -- 调试PRINT(临时) PRINT '使用的TenantId: ' + ISNULL(@TenantId, 'NULL'); PRINT '使用的CurrentYear: ' + CAST(ISNULL(@CurrentYear, 0) AS VARCHAR); PRINT '使用的CurrentMonth: ' + CAST(ISNULL(@CurrentMonth, 0) AS VARCHAR); -- 计算上月(现在@CurrentMonth已设) IF @CurrentMonth = 1 BEGIN SET @LastYear = @CurrentYear - 1; SET @LastMonth = 12; END ELSE BEGIN SET @LastYear = @CurrentYear; SET @LastMonth = @CurrentMonth - 1; END BEGIN TRY BEGIN TRANSACTION; -- 检查是否已存在报表数据 IF EXISTS (SELECT 1 FROM wms_monthly_report WHERE report_year = @CurrentYear AND report_month = @CurrentMonth AND tenant_id = @TenantId) BEGIN IF @ForceRegenerate = 0 BEGIN PRINT '当月报表已存在,如需重新生成请设置 @ForceRegenerate = 1'; ROLLBACK TRANSACTION; RETURN; END ELSE BEGIN -- 强制重新生成:删除已存在的当月报表数据 DELETE FROM wms_monthly_report WHERE report_year = @CurrentYear AND report_month = @CurrentMonth AND tenant_id = @TenantId; PRINT '强制重新生成:已删除现有报表数据'; END END; -- 生成报表数据 WITH MaterialTypes AS ( -- 获取所有活跃的物料类型 SELECT mt.matrial_type_id, mt.matrial_type_name FROM base_material_type mt WHERE mt.active_flag = '1' AND mt.del_flag = '0' ), CurrentInstock AS ( -- 当月入库统计 SELECT bmi.material_type_id, COUNT(*) AS instock_count, ISNULL(SUM(wir.instock_qty), 0) AS instock_qty FROM wms_instock_record wir INNER JOIN base_material_info_copy1 bmi ON wir.material_id = bmi.material_id WHERE YEAR(wir.create_time) = @CurrentYear AND MONTH(wir.create_time) = @CurrentMonth AND wir.tenant_id = @TenantId GROUP BY bmi.material_type_id ), CurrentOutstock AS ( -- 当月出库统计 SELECT bmi.material_type_id, COUNT(*) AS outstock_count, ISNULL(SUM(wor.outstock_qty), 0) AS outstock_qty FROM wms_outstock_record wor INNER JOIN base_material_info_copy1 bmi ON wor.material_id = bmi.material_id WHERE YEAR(wor.create_time) = @CurrentYear AND MONTH(wor.create_time) = @CurrentMonth AND wor.tenant_id = @TenantId GROUP BY bmi.material_type_id ), LastInstock AS ( -- 上月入库统计 SELECT bmi.material_type_id, COUNT(*) AS last_instock_count, ISNULL(SUM(wir.instock_qty), 0) AS last_instock_qty FROM wms_instock_record wir INNER JOIN base_material_info_copy1 bmi ON wir.material_id = bmi.material_id WHERE YEAR(wir.create_time) = @LastYear AND MONTH(wir.create_time) = @LastMonth AND wir.tenant_id = @TenantId GROUP BY bmi.material_type_id ), LastOutstock AS ( -- 上月出库统计 SELECT bmi.material_type_id, COUNT(*) AS last_outstock_count, ISNULL(SUM(wor.outstock_qty), 0) AS last_outstock_qty FROM wms_outstock_record wor INNER JOIN base_material_info_copy1 bmi ON wor.material_id = bmi.material_id WHERE YEAR(wor.create_time) = @LastYear AND MONTH(wor.create_time) = @LastMonth AND wor.tenant_id = @TenantId GROUP BY bmi.material_type_id ), CurrentInventory AS ( -- 当前库存统计 SELECT bmi.material_type_id, COUNT(DISTINCT wi.material_id) AS inventory_material_count, ISNULL(SUM(wi.inventory_qty), 0) AS inventory_qty FROM wms_inventory wi INNER JOIN base_material_info_copy1 bmi ON wi.material_id = bmi.material_id WHERE wi.inventory_status = '1' AND wi.inventory_qty > 0 AND wi.tenant_id = @TenantId GROUP BY bmi.material_type_id ) -- 插入报表数据 INSERT INTO wms_monthly_report ( tenant_id, report_year, report_month, material_type_id, material_type_name, current_instock_count, current_instock_qty, current_outstock_count, current_outstock_qty, last_instock_count, last_instock_qty, last_outstock_count, last_outstock_qty, instock_count_diff, instock_qty_diff, outstock_count_diff, outstock_qty_diff, inventory_material_count, inventory_qty, create_time, create_by ) SELECT @TenantId, @CurrentYear, @CurrentMonth, mt.matrial_type_id, mt.matrial_type_name, ISNULL(ci.instock_count, 0), ISNULL(ci.instock_qty, 0), ISNULL(co.outstock_count, 0), ISNULL(co.outstock_qty, 0), ISNULL(li.last_instock_count, 0), ISNULL(li.last_instock_qty, 0), ISNULL(lo.last_outstock_count, 0), ISNULL(lo.last_outstock_qty, 0), ISNULL(ci.instock_count, 0) - ISNULL(li.last_instock_count, 0), -- 入库数量环比差额 ISNULL(ci.instock_qty, 0) - ISNULL(li.last_instock_qty, 0), -- 入库总量环比差额 ISNULL(co.outstock_count, 0) - ISNULL(lo.last_outstock_count, 0), -- 出库数量环比差额 ISNULL(co.outstock_qty, 0) - ISNULL(lo.last_outstock_qty, 0), -- 出库总量环比差额 ISNULL(inv.inventory_material_count, 0), ISNULL(inv.inventory_qty, 0), GETDATE(), 'SYSTEM' FROM MaterialTypes mt LEFT JOIN CurrentInstock ci ON mt.matrial_type_id = ci.material_type_id LEFT JOIN CurrentOutstock co ON mt.matrial_type_id = co.material_type_id LEFT JOIN LastInstock li ON mt.matrial_type_id = li.material_type_id LEFT JOIN LastOutstock lo ON mt.matrial_type_id = lo.material_type_id LEFT JOIN CurrentInventory inv ON mt.matrial_type_id = inv.material_type_id ORDER BY mt.matrial_type_id; COMMIT TRANSACTION; PRINT '月度报表生成成功!年月:' + CAST(@CurrentYear AS VARCHAR(4)) + '-' + RIGHT('0' + CAST(@CurrentMonth AS VARCHAR(2)), 2); END TRY BEGIN CATCH ROLLBACK TRANSACTION; DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR(@ErrorMessage, @ErrorSeverity, @ErrorState); END CATCH END -- 3. 创建查询月度报表的存储过程 CREATE OR ALTER PROCEDURE [dbo].[SP_QueryMonthlyReport] @ReportYear INT = NULL, @ReportMonth INT = NULL, @TenantId VARCHAR(32) = '000000' AS BEGIN SET NOCOUNT ON; DECLARE @CurrentYear INT, @CurrentMonth INT; -- 如果没有指定年月,则使用当前年月 IF @ReportYear IS NULL OR @ReportMonth IS NULL BEGIN SET @CurrentYear = YEAR(GETDATE()); SET @CurrentMonth = MONTH(GETDATE()); END ELSE BEGIN SET @CurrentYear = @ReportYear; SET @CurrentMonth = @ReportMonth; END SELECT ROW_NUMBER() OVER (ORDER BY material_type_id) AS 序号, material_type_name AS 物料类型名称, -- 当月数据 current_instock_count AS 当月入库数量, current_instock_qty AS 当月入库总量, current_outstock_count AS 当月出库数量, current_outstock_qty AS 当月出库总量, -- 上月数据 last_instock_count AS 上月入库数量, last_instock_qty AS 上月入库总量, last_outstock_count AS 上月出库数量, last_outstock_qty AS 上月出库总量, -- 环比差额 instock_count_diff AS 入库数量环比差额, instock_qty_diff AS 入库总量环比差额, outstock_count_diff AS 出库数量环比差额, outstock_qty_diff AS 出库总量环比差额, -- 月末库存 inventory_material_count AS 库存物料种类数, inventory_qty AS 月末库存总量, create_time AS 生成时间 FROM wms_monthly_report WHERE report_year = @CurrentYear AND report_month = @CurrentMonth AND tenant_id = @TenantId ORDER BY material_type_id; END GO -- 4. 创建定时任务调度存储过程(每月末0点执行) CREATE OR ALTER PROCEDURE [dbo].[SP_ScheduleMonthlyReport] AS BEGIN SET NOCOUNT ON; -- 检查是否为月末最后一天 DECLARE @Today DATE = CAST(GETDATE() AS DATE); DECLARE @Tomorrow DATE = DATEADD(DAY, 1, @Today); -- 如果明天是下个月的第一天,说明今天是月末 IF DAY(@Tomorrow) = 1 BEGIN EXEC SP_GenerateMonthlyReport; PRINT '定时任务执行:月度报表已生成'; END ELSE BEGIN PRINT '定时任务检查:今天不是月末,跳过报表生成'; END END GO -- 5. 创建历史报表查询存储过程 CREATE OR ALTER PROCEDURE [dbo].[SP_QueryHistoryReports] @StartYear INT = NULL, @StartMonth INT = NULL, @EndYear INT = NULL, @EndMonth INT = NULL, @TenantId VARCHAR(32) = '000000' AS BEGIN SET NOCOUNT ON; -- 如果没有指定时间范围,默认查询最近6个月 IF @StartYear IS NULL OR @StartMonth IS NULL OR @EndYear IS NULL OR @EndMonth IS NULL BEGIN SET @EndYear = YEAR(GETDATE()); SET @EndMonth = MONTH(GETDATE()); -- 计算6个月前的年月 DECLARE @SixMonthsAgo DATE = DATEADD(MONTH, -6, GETDATE()); SET @StartYear = YEAR(@SixMonthsAgo); SET @StartMonth = MONTH(@SixMonthsAgo); END SELECT report_year AS 年份, report_month AS 月份, CAST(report_year AS VARCHAR(4)) + '-' + RIGHT('0' + CAST(report_month AS VARCHAR(2)), 2) AS 年月, material_type_name AS 物料类型名称, current_instock_count AS 入库数量, current_instock_qty AS 入库总量, current_outstock_count AS 出库数量, current_outstock_qty AS 出库总量, inventory_qty AS 月末库存, create_time AS 生成时间 FROM wms_monthly_report WHERE tenant_id = @TenantId AND ( (report_year > @StartYear) OR (report_year = @StartYear AND report_month >= @StartMonth) ) AND ( (report_year < @EndYear) OR (report_year = @EndYear AND report_month <= @EndMonth) ) ORDER BY report_year DESC, report_month DESC, material_type_id; END GO -- 6. 创建报表汇总查询存储过程 CREATE OR ALTER PROCEDURE [dbo].[SP_QueryReportSummary] @TenantId VARCHAR(32) = '000000' AS BEGIN SET NOCOUNT ON; SELECT report_year AS 年份, report_month AS 月份, CAST(report_year AS VARCHAR(4)) + '-' + RIGHT('0' + CAST(report_month AS VARCHAR(2)), 2) AS 年月, COUNT(*) AS 物料类型数量, SUM(current_instock_count) AS 总入库数量, SUM(current_instock_qty) AS 总入库量, SUM(current_outstock_count) AS 总出库数量, SUM(current_outstock_qty) AS 总出库量, SUM(inventory_qty) AS 总库存量, MAX(create_time) AS 生成时间 FROM wms_monthly_report WHERE tenant_id = @TenantId GROUP BY report_year, report_month ORDER BY report_year DESC, report_month DESC; END GO -- 7. 示例:手动执行生成当月报表 -- EXEC SP_GenerateMonthlyReport; -- 8. 使用示例: -- 示例1:生成当月报表(如果已存在会提示) -- EXEC SP_GenerateMonthlyReport; -- 示例2:强制重新生成当月报表 -- EXEC SP_GenerateMonthlyReport @ForceRegenerate = 1; -- 示例3:生成指定月份报表 -- EXEC SP_GenerateMonthlyReport @ReportYear = 2025, @ReportMonth = 8; -- 示例4:查询当月报表 -- EXEC SP_QueryMonthlyReport; -- 示例5:查询指定年月报表 -- EXEC SP_QueryMonthlyReport @ReportYear = 2025, @ReportMonth = 8; -- 示例6:查询历史报表(最近6个月) -- EXEC SP_QueryHistoryReports; -- 示例7:查询指定时间范围的历史报表 -- EXEC SP_QueryHistoryReports @StartYear = 2025, @StartMonth = 1, @EndYear = 2025, @EndMonth = 9; -- 示例8:查看所有月份的报表汇总 -- EXEC SP_QueryReportSummary; -- 9. 创建SQL Server Agent作业的脚本(需要在SQL Server Management Studio中执行) /* -- 创建作业步骤的T-SQL脚本 USE msdb; GO -- 删除已存在的作业(如果存在) IF EXISTS (SELECT job_id FROM dbo.sysjobs WHERE name = N'WMS月度报表生成作业') BEGIN EXEC dbo.sp_delete_job @job_name = N'WMS月度报表生成作业'; END GO -- 创建作业 EXEC dbo.sp_add_job @job_name = N'WMS月度报表生成作业', @enabled = 1, @description = N'每月末0点自动生成WMS月度报表'; -- 添加作业步骤 EXEC dbo.sp_add_jobstep @job_name = N'WMS月度报表生成作业', @step_name = N'生成月度报表', @subsystem = N'TSQL', @command = N'EXEC SP_ScheduleMonthlyReport;', @database_name = N'你的数据库名称'; -- 请替换为实际的数据库名称 -- 创建调度(每月末0点执行) EXEC dbo.sp_add_schedule @schedule_name = N'月末0点执行', @freq_type = 4, -- 每天 @freq_interval = 1, -- 每1天 @active_start_time = 000000; -- 0点执行 -- 将调度附加到作业 EXEC dbo.sp_attach_schedule @job_name = N'WMS月度报表生成作业', @schedule_name = N'月末0点执行'; -- 添加作业服务器 EXEC dbo.sp_add_jobserver @job_name = N'WMS月度报表生成作业'; */ -- 10. 查询报表数据的完整SQL(用于调试和验证) /* -- 完整的月度报表查询SQL WITH ReportData AS ( SELECT mt.matrial_type_id, mt.matrial_type_name, -- 当月入库统计 ISNULL(ci.instock_count, 0) AS current_instock_count, ISNULL(ci.instock_qty, 0) AS current_instock_qty, -- 当月出库统计 ISNULL(co.outstock_count, 0) AS current_outstock_count, ISNULL(co.outstock_qty, 0) AS current_outstock_qty, -- 上月入库统计 ISNULL(li.last_instock_count, 0) AS last_instock_count, ISNULL(li.last_instock_qty, 0) AS last_instock_qty, -- 上月出库统计 ISNULL(lo.last_outstock_count, 0) AS last_outstock_count, ISNULL(lo.last_outstock_qty, 0) AS last_outstock_qty, -- 当前库存统计 ISNULL(inv.inventory_material_count, 0) AS inventory_material_count, ISNULL(inv.inventory_qty, 0) AS inventory_qty FROM base_material_type mt LEFT JOIN ( -- 当月入库 SELECT bmi.material_type_id, COUNT(*) AS instock_count, SUM(wir.instock_qty) AS instock_qty FROM wms_instock_record wir INNER JOIN base_material_info_copy1 bmi ON wir.material_id = bmi.material_id WHERE YEAR(wir.create_time) = YEAR(GETDATE()) AND MONTH(wir.create_time) = MONTH(GETDATE()) AND wir.tenant_id = '000000' GROUP BY bmi.material_type_id ) ci ON mt.matrial_type_id = ci.material_type_id LEFT JOIN ( -- 当月出库 SELECT bmi.material_type_id, COUNT(*) AS outstock_count, SUM(wor.outstock_qty) AS outstock_qty FROM wms_outstock_record wor INNER JOIN base_material_info_copy1 bmi ON wor.material_id = bmi.material_id WHERE YEAR(wor.create_time) = YEAR(GETDATE()) AND MONTH(wor.create_time) = MONTH(GETDATE()) AND wor.tenant_id = '000000' GROUP BY bmi.material_type_id ) co ON mt.matrial_type_id = co.material_type_id LEFT JOIN ( -- 上月入库 SELECT bmi.material_type_id, COUNT(*) AS last_instock_count, SUM(wir.instock_qty) AS last_instock_qty FROM wms_instock_record wir INNER JOIN base_material_info_copy1 bmi ON wir.material_id = bmi.material_id WHERE YEAR(wir.create_time) = CASE WHEN MONTH(GETDATE()) = 1 THEN YEAR(GETDATE()) - 1 ELSE YEAR(GETDATE()) END AND MONTH(wir.create_time) = CASE WHEN MONTH(GETDATE()) = 1 THEN 12 ELSE MONTH(GETDATE()) - 1 END AND wir.tenant_id = '000000' GROUP BY bmi.material_type_id ) li ON mt.matrial_type_id = li.material_type_id LEFT JOIN ( -- 上月出库 SELECT bmi.material_type_id, COUNT(*) AS last_outstock_count, SUM(wor.outstock_qty) AS last_outstock_qty FROM wms_outstock_record wor INNER JOIN base_material_info_copy1 bmi ON wor.material_id = bmi.material_id WHERE YEAR(wor.create_time) = CASE WHEN MONTH(GETDATE()) = 1 THEN YEAR(GETDATE()) - 1 ELSE YEAR(GETDATE()) END AND MONTH(wor.create_time) = CASE WHEN MONTH(GETDATE()) = 1 THEN 12 ELSE MONTH(GETDATE()) - 1 END AND wor.tenant_id = '000000' GROUP BY bmi.material_type_id ) lo ON mt.matrial_type_id = lo.material_type_id LEFT JOIN ( -- 当前库存 SELECT bmi.material_type_id, COUNT(DISTINCT wi.material_id) AS inventory_material_count, SUM(wi.inventory_qty) AS inventory_qty FROM wms_inventory wi INNER JOIN base_material_info_copy1 bmi ON wi.material_id = bmi.material_id WHERE wi.inventory_status = '1' AND wi.inventory_qty > 0 AND wi.tenant_id = '000000' GROUP BY bmi.material_type_id ) inv ON mt.matrial_type_id = inv.material_type_id WHERE mt.active_flag = '1' AND mt.del_flag = '0' ) SELECT ROW_NUMBER() OVER (ORDER BY matrial_type_id) AS 序号, matrial_type_name AS 物料类型名称, current_instock_count AS 当月入库数量, current_instock_qty AS 当月入库总量, current_outstock_count AS 当月出库数量, current_outstock_qty AS 当月出库总量, last_instock_count AS 上月入库数量, last_instock_qty AS 上月入库总量, last_outstock_count AS 上月出库数量, last_outstock_qty AS 上月出库总量, (current_instock_count - last_instock_count) AS 入库数量环比差额, (current_instock_qty - last_instock_qty) AS 入库总量环比差额, (current_outstock_count - last_outstock_count) AS 出库数量环比差额, (current_outstock_qty - last_outstock_qty) AS 出库总量环比差额, inventory_material_count AS 库存物料种类数, inventory_qty AS 月末库存总量 FROM ReportData ORDER BY matrial_type_id; */