SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO ALTER proc [dbo].[P_BudgeSaleAndActualSaleReport] ( @FYear nvarchar(10), ---年度 @FStartMonth nvarchar(10), ---开始月份 @FEndMonth nvarchar(10), ---结束月份 @CustomerId nvarchar(max), ---多选客户ID @FBMMaterialGroup nvarchar(max) ---预算物料组ID ) as BEGIN DECLARE @sql NVARCHAR(MAX),@where2 NVARCHAR(max)='',@where3 NVARCHAR(max)=''; DECLARE @begintime DATETIME,@endtime DATETIME; DECLARE @i int=@FStartMonth,@sql2 nvarchar(max)=''; while(@i<=@FEndMonth) BEGIN IF(@i<@FEndMonth) BEGIN SELECT @sql2 +='FMONTH'+CONVERT(nvarchar(10),@i)+'+'; END ELSE BEGIN SELECT @sql2 +='FMONTH'+CONVERT(NVARCHAR(10),@i); END SELECT @i=@i+1; END SELECT @begintime= CAST( @FYear + '-' + RIGHT('0' + @FStartMonth, 2) + '-' + RIGHT('0' + 1, 2) AS DATE ), @endtime= CAST( @FYear + '-' + RIGHT('0' + @FEndMonth, 2) + '-' + RIGHT('0' + 1, 2) AS DATE ); SELECT @endtime=DATEADD(MONTH,1,@endtime); IF(ISNULL(@CustomerId,'') <> '') BEGIN SELECT @CustomerId=CHAR(39)+ REPLACE(@CustomerId, ',', CHAR(39) + ',' + CHAR(39))+CHAR(39); SELECT @where2=' and t3.FNUMBER in ('+@CustomerId+')'; END IF(ISNULL(@FBMMaterialGroup,'') <> '') BEGIN SELECT @FBMMaterialGroup=CHAR(39)+ REPLACE(@FBMMaterialGroup, ',', CHAR(39) + ',' + CHAR(39))+CHAR(39); SELECT @where3=' and t5.FNUMBER in ('++@FBMMaterialGroup+')'; end -- 动态拼接 SQL 字符串 SET @sql = N' SELECT [客户编码], [客户名称], [预算物料组], -- 金额类字段格式化 CAST([预算销售总额] AS DECIMAL(18,2)) AS [预算销售总额], CAST([实际销售总额] AS DECIMAL(18,2)) AS [实际销售总额], -- 数量类字段格式化 CAST([预算销售总数量] AS DECIMAL(18,2)) AS [预算销售总数量], CAST([实际销售总数量] AS DECIMAL(18,2)) AS [实际销售总数量], -- 单价类字段格式化 CAST([预算销售单价] AS DECIMAL(18,2)) AS [预算销售单价], -- 差异计算字段格式化 [销售总金额差异] = CAST( ROUND([预算销售总额] - [实际销售总额], 2) AS DECIMAL(18,2)) , [销售总数量差异] = CAST( ROUND([预算销售总数量] - [实际销售总数量], 2) AS DECIMAL(18,2)) , [实际平均销售单价] = CAST( CASE WHEN [实际销售总数量] != 0 THEN ROUND([实际销售总额] / [实际销售总数量], 2) ELSE 0 END AS DECIMAL(18,2)) , [销售单价差异] = CAST( CASE WHEN [实际销售总数量] != 0 THEN ROUND(([实际销售总额] / [实际销售总数量]) - [预算销售单价], 2) ELSE ROUND([预算销售单价], 2) end AS DECIMAL(18,2)) FROM ( SELECT t3.FNUMBER AS [客户编码], t4.FNAME AS [客户名称], t5.FNUMBER AS [预算物料组], isnull( ROUND(('+@sql2+') * FPrice, 2),0) AS [预算销售总额], ( SELECT ROUND(SUM(bb.FNOTAXAMOUNT), 2) FROM dbo.T_AR_RECEIVABLE aa LEFT JOIN T_AR_RECEIVABLEENTRY bb ON aa.FID = bb.FID INNER JOIN T_BD_MATERIAL matal2 ON bb.FMATERIALID = matal2.FMATERIALID INNER JOIN VHUB_T_BMMGroupLinkTable cc ON matal2.FMATERIALGROUP = cc.[FMATERIALGROUP] WHERE aa.FCUSTOMERID =YingShou.FCUSTOMERID AND aa.FDATE >= @begintime AND aa.FDATE < @endtime AND cc.[FBMMATERIALGROUP] = t5.FID ) AS [实际销售总额], isnull( ('+@sql2+'),0) AS [预算销售总数量], ( SELECT SUM(bb.FPriceQty) FROM dbo.T_AR_RECEIVABLE aa LEFT JOIN T_AR_RECEIVABLEENTRY bb ON aa.FID = bb.FID INNER JOIN T_BD_MATERIAL matal2 ON bb.FMATERIALID = matal2.FMATERIALID INNER JOIN VHUB_T_BMMGroupLinkTable cc ON matal2.FMATERIALGROUP = cc.[FMATERIALGROUP] WHERE aa.FCUSTOMERID =YingShou.FCUSTOMERID AND aa.FDATE >= @begintime AND aa.FDATE < @endtime AND cc.[FBMMATERIALGROUP] = t5.FID ) AS [实际销售总数量], isnull( FPrice,0) AS [预算销售单价] FROM ( SELECT DISTINCT aa.FCUSTOMERID , cc.[FBMMATERIALGROUP] FROM dbo.T_AR_RECEIVABLE aa LEFT JOIN T_AR_RECEIVABLEENTRY bb ON aa.FID = bb.FID INNER JOIN T_BD_MATERIAL matal2 ON bb.FMATERIALID = matal2.FMATERIALID INNER JOIN VHUB_T_BMMGroupLinkTable cc ON matal2.FMATERIALGROUP = cc.[FMATERIALGROUP] where aa.FDATE >= @begintime AND aa.FDATE < @endtime ) YingShou FULL JOIN (select t1.* from VHUB_t_Cust_Entry100007 t1 INNER JOIN (select * from VHUB_t_Cust100008 tt3 where tt3.FYEARS = @FYear) t2 ON t1.FID = t2.FID) t1 ON t1.FCUSTOMERID=YingShou.FCUSTOMERID AND YingShou.FBMMATERIALGROUP=t1.FBMMATERIALGROUP LEFT JOIN T_BD_CUSTOMER t3 ON isnull(YingShou.FCUSTOMERID,t1.FCUSTOMERID) = t3.FCUSTID LEFT JOIN T_BD_CUSTOMER_L t4 ON t3.FCUSTID = t4.FCUSTID INNER JOIN VHUB_BD_BMMaterialGroup t5 ON isnull(YingShou.FBMMATERIALGROUP,t1.FBMMATERIALGROUP)= t5.FID WHERE 1=1 '+@where2+@where3+' ) AS aaa'; PRINT @sql; -- 执行动态 SQL EXEC sp_executesql @sql, N'@FYear INT, @begintime DATETIME, @endtime DATETIME', @FYear, @begintime, @endtime; END