Files
VapeEZDLL/7.销售预算成本与实际成本分析报表SQL.sql
2025-08-18 21:06:01 +08:00

200 lines
12 KiB
Transact-SQL

IF OBJECT_ID('dbo.[RP_XSYSCBYSJCB]', 'P') IS NOT NULL
BEGIN
DROP PROCEDURE dbo.RP_XSYSCBYSJCB;
PRINT '存储过程 dbo.[RP_XSYSCBYSJCB] 已删除';
END;
GO
-- 创建新的存储过程
CREATE PROCEDURE dbo.RP_XSYSCBYSJCB
@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;
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);
-- 退货成本查询SQL2
SELECT a.FRETCUSTID,CustomerName,a.FNUMBER,a.FNAME,SUM(FREALQTY)/4 AS REALQTY,SUM(a.FAMOUNT_LC) AS FAMOUNT_LC,FAPPROVEDATE2,CustomerCode,groupID INTO #TuiHuoChengBen
FROM (
SELECT t1.FRETCUSTID,t44.FNAME AS CustomerName,t33.FNUMBER AS CustomerCode, T1.FID, T1.FBILLNO,T2.FENTRYID,t55.FNUMBER, FREALQTY ,t4.FAMOUNT_LC,T6.FNAME , FORMAT(t1.FDATE, 'yyyy-MM-01') AS FAPPROVEDATE2
,t55.fid AS groupID
FROM T_SAL_RETURNSTOCK T1 INNER JOIN T_SAL_RETURNSTOCKENTRY T2
INNER JOIN T_SAL_RETURNSTOCKENTRY_C T3 ON T3.FENTRYID = T2.FENTRYID
ON T1.FID = T2.FID
INNER JOIN T_SAL_RETURNSTOCKENTRY_CE T4 ON T3.FENTRYID = T4.FENTRYID
LEFT JOIN T_HS_CALDIMENSIONS T5 ON T3.FDIMENSIONID = T5.FDIMENSIONID
LEFT JOIN T_BD_EXPENSE_L T6 ON T4.FEXPENSEID = T6.FEXPID AND T6.FLOCALEID = 2052
LEFT JOIN T_BD_MATERIAL ff ON t2.FMaterialID=ff.FMaterialID
INNER JOIN VHUB_T_BMMGroupLinkTable cc ON ff.FMATERIALGROUP = cc.[FMATERIALGROUP]
INNER JOIN VHUB_BD_BMMaterialGroup t55 ON cc.[FBMMATERIALGROUP]= t55.FID
LEFT JOIN T_BD_CUSTOMER t33 ON T1.FRETCUSTID= t33.FCUSTID
LEFT JOIN T_BD_CUSTOMER_L t44 ON t33.FCUSTID = t44.FCUSTID
WHERE T1.FDATE>=@begintime AND t1.FDATE<@endtime AND t1.FDOCUMENTSTATUS='C') a
GROUP BY a.FRETCUSTID,a.FNUMBER,a.FNAME,FAPPROVEDATE2 ,CustomerName,CustomerCode,groupID
ORDER BY a.FRETCUSTID,FNUMBER,FAPPROVEDATE2
--SELECT * FROM #TuiHuoChengBen
SELECT * , DATEFROMPARTS((bb.Year), (bb.Month), 1) AS FAPPROVEDATE INTO #TempNianDuXiaoShouYuSuan FROM NianDuXiaoShouYuSuan bb
WHERE bb.Year=2025
--SELECT * FROM #TempNianDuXiaoShouYuSuan
-- 销售出库成本查询SQL
SELECT a.FCustomerID,a. CustomerName,a.FNUMBER,a.FNAME,SUM(FREALQTY)/4 AS RealQty,SUM(a.FAMOUNT_LC) AS FAMOUNT_LC,FAPPROVEDATE2 , CustomerCode,groupID INTO #XiaoShouChengBen FROM (
SELECT t1.FCustomerID,t44.FNAME AS CustomerName,t33.FNUMBER AS CustomerCode,T1.FID, T1.FBILLNO,T2.FENTRYID,t2.FMaterialID,t55.FNUMBER, T2.FREALQTY ,t4.FAMOUNT_LC,T6.FNAME , FORMAT(t1.FDATE, 'yyyy-MM-01') AS FAPPROVEDATE2
,t55.fid AS groupID
FROM T_SAL_OUTSTOCK T1 INNER JOIN T_SAL_OUTSTOCKENTRY T2
INNER JOIN T_SAL_OUTSTOCKENTRY_C T3 ON T3.FENTRYID = T2.FENTRYID
ON T1.FID = T2.FID
INNER JOIN T_SAL_OUTSTOCKENTRY_CE T4 ON T3.FENTRYID = T4.FENTRYID
LEFT JOIN T_HS_CALDIMENSIONS T5 ON T3.FDIMENSIONID = T5.FDIMENSIONID
LEFT JOIN T_BD_EXPENSE_L T6 ON T4.FEXPENSEID = T6.FEXPID AND T6.FLOCALEID = 2052
LEFT JOIN T_BD_MATERIAL ff ON t2.FMaterialID=ff.FMaterialID
INNER JOIN VHUB_T_BMMGroupLinkTable cc ON ff.FMATERIALGROUP = cc.[FMATERIALGROUP]
INNER JOIN VHUB_BD_BMMaterialGroup t55 ON cc.[FBMMATERIALGROUP]= t55.FID
LEFT JOIN T_BD_CUSTOMER t33 ON T1.FCUSTOMERID= t33.FCUSTID
LEFT JOIN T_BD_CUSTOMER_L t44 ON t33.FCUSTID = t44.FCUSTID
WHERE T1.FDATE>=@begintime AND t1.FDATE<@endtime AND t1.FDOCUMENTSTATUS='C' ) a
GROUP BY a.FCustomerID,a.FNUMBER,a.FNAME,FAPPROVEDATE2 ,CustomerName,CustomerCode,groupID
ORDER BY a.FCustomerID, FNUMBER,FAPPROVEDATE2
--SELECT * FROM #XiaoShouChengBen
---最终表
SELECT [客户编码],[客户名称],[预算物料组],FCUSTOMERID,AVG([销售数量]-[退货数量]) AS [销售数量]
,[预算总成本]=AVG([预算销售数量]*[预算总成本单价]),[预算成本(料)-总]=AVG([预算销售数量]*[预算成本_材料单价]),[预算成本(工)-总]=AVG([预算销售数量]*[预算成本_人工单价])
,[预算成本(费)-总]=AVG([预算销售数量]*[预算成本_制费单价]),AVG([预算销售数量]) AS [预算销售数量]
,[实际销售总成本]=AVG([实际销售总成本]),[实际成本(料)-总]=AVG([实际成本(料)-总]),[实际成本(工)-总]=SUM([实际成本(工)-总]),[实际成本(费)-总]=AVG([实际成本(费)-总])
,AVG([预算总成本单价]) AS [预算总成本单价],AVG([预算成本_材料单价]) AS [预算成本_材料单价],AVG([预算成本_人工单价]) AS [预算成本_人工单价],AVG([预算成本_制费单价]) AS [预算成本_制费单价]
INTO #TempResultTable
FROM (
SELECT
ISNULL(t1.CustomerCode,bb.CustomerCode) AS [客户编码],
ISNULL(t1.CustomerName,bb.CustomerName) AS [客户名称],
ISNULL(t1.FNUMBER,bb.FNUMBER) AS [预算物料组],
T1.FCUSTOMERID
, SUM(t1.RealQty) AS [销售数量]
,ISNULL((SELECT bb.MonthValue FROM #TempNianDuXiaoShouYuSuan bb WHERE bb.FAPPROVEDATE=t1.FAPPROVEDATE2
AND bb.FBMMATERIALGROUP= t1.groupID AND bb.FCUSTOMERID=T1.FCUSTOMERID),0) [预算销售数量]
,ISNULL( SUM(bb.RealQty),0) [退货数量]
, ISNULL(t1.FAPPROVEDATE2,bb.FAPPROVEDATE2) AS FAPPROVEDATE2
,ISNULL(AVG(cost.FALLAMOUNT),0) AS [预算总成本单价],ISNULL(AVG(cost.FMATERIALCOSTAMOUNT),0) AS [预算成本_材料单价],ISNULL(AVG(cost.FLABORCOSTAMOUNT),0) [预算成本_人工单价]
,ISNULL(AVG(FLABORCOSTAMOUNT),0) AS [预算成本_制费单价]
, ISNULL(SUM(ISNULL(t1.FAMOUNT_LC,0)-ISNULL(bb.FAMOUNT_LC,0)),0) AS [实际销售总成本]
,( ISNULL((SELECT SUM(jjj.FAMOUNT_LC) FROM #XiaoShouChengBen jjj WHERE t1.FNUMBER=jjj.FNUMBER AND jjj.FAPPROVEDATE2=t1.FAPPROVEDATE2 AND t1.FCUSTOMERID=jjj.FCUSTOMERID AND jjj.fname='材料成本'),0)-
ISNULL((SELECT SUM(jjj.FAMOUNT_LC) FROM #TuiHuoChengBen jjj WHERE bb.FNUMBER=jjj.FNUMBER AND jjj.FAPPROVEDATE2=bb.FAPPROVEDATE2 AND bb.FRETCUSTID=jjj.FRETCUSTID AND jjj.fname='材料成本' ),0)) AS [实际成本(料)-总]
,( ISNULL((SELECT SUM(jjj.FAMOUNT_LC) FROM #XiaoShouChengBen jjj WHERE t1.FNUMBER=jjj.FNUMBER AND jjj.FAPPROVEDATE2=t1.FAPPROVEDATE2 AND t1.FCUSTOMERID=jjj.FCUSTOMERID AND fname IN ('工资','委外加工费')),0)-
ISNULL((SELECT SUM(jjj.FAMOUNT_LC) FROM #TuiHuoChengBen jjj WHERE bb.FNUMBER=jjj.FNUMBER AND jjj.FAPPROVEDATE2=bb.FAPPROVEDATE2 AND bb.FRETCUSTID=jjj.FRETCUSTID AND fname IN ('工资','委外加工费') ),0)) AS [实际成本(工)-总]
,( ISNULL((SELECT SUM(jjj.FAMOUNT_LC) FROM #XiaoShouChengBen jjj WHERE t1.FNUMBER=jjj.FNUMBER AND jjj.FAPPROVEDATE2=t1.FAPPROVEDATE2 AND t1.FCUSTOMERID=jjj.FCUSTOMERID AND fname='制造费用'),0)-
ISNULL((SELECT SUM(jjj.FAMOUNT_LC) FROM #TuiHuoChengBen jjj WHERE bb.FNUMBER=jjj.FNUMBER AND jjj.FAPPROVEDATE2=bb.FAPPROVEDATE2 AND bb.FRETCUSTID=jjj.FRETCUSTID AND fname='制造费用' ),0)) AS [实际成本(费)-总]
FROM
#XiaoShouChengBen t1
INNER JOIN VHUB_BD_BMMaterialGroup t5 ON t5.FNUMBER= t1.FNUMBER
LEFT JOIN VHUB_T_BMGStandCost cost ON cost.FDATE= FAPPROVEDATE2 AND cost.FBMMATERIALGROUP= t5.FID
LEFT JOIN #TuiHuoChengBen bb ON t1.FCUSTOMERID=bb.FRETCUSTID AND t1.FNUMBER=bb.FNUMBER AND t1.FAPPROVEDATE2=bb.FAPPROVEDATE2
WHERE T1.FAPPROVEDATE2>=@begintime AND t1.FAPPROVEDATE2<@endtime
AND (@CustomerId = 'A' OR t1.FCUSTOMERID IN (SELECT value FROM dbo.SplitString(@CustomerId, ',') )) AND
(@FBMMaterialGroup = 'A' OR t5.FID IN (SELECT value FROM dbo.SplitString(@FBMMaterialGroup, ',') ))
GROUP BY t1.FCustomerID,t1.FNUMBER,t1.FNAME,t1.FAPPROVEDATE2 ,t1.CustomerName ,t1.CustomerCode,bb.CustomerCode,bb.CustomerName,bb.FNUMBER,t1.groupID,bb.FAPPROVEDATE2,bb.FRETCUSTID
) a
GROUP BY [客户编码],[客户名称],[预算物料组],FCUSTOMERID
--WHERE a.FCUSTOMERID=641983 AND a.FBMMATERIALGROUP=941609
SELECT [客户编码] AS F_KeHuCode,[客户名称] AS F_KeHuName, [预算物料组] AS F_WuLiaoFenZu,FCUSTOMERID,[预算销售数量] AS F_YuSuanShuLiang,[销售数量] AS F_ShiJiXiaoShouShuLiang
,[预算与实际数量差异] AS F_YSYSJSLCY,a.预算总成本 AS F_YSZCB,实际销售总成本 AS F_SJZCB,a.预算与实际总成本差异 AS F_YSYSJZCBCY,[预算成本(料)-总] AS F_YSZCB_Z
,[实际成本(料)-总] AS F_SJCB_L_Z,[差异-总料] AS F_CHaYi_Z,[预算成本(工)-总] AS F_YSCB_G_Z,[实际成本(工)-总] AS F_SJCB_G_Z,[差异-总工] AS F_ChaYi_ZG,[预算成本(费)-总] AS F_YSCB_F_Z
,[实际成本(费)-总] AS F_SJCB_F_Z,[差异-总费] AS F_ChaYi_ZF,[单位总预算成本] AS F_DWZYSCB,[单位实际总成本] AS F_DWSJZCB
,F_DWCBCY=[单位总预算成本]-[单位实际总成本],[预算成本(料)-单] AS F_YSCB_L_D,[实际成本(料)-单] AS F_SJCB_L_D
--,[差异-单料] AS F_ChaYi_DanLiao,
,[实际成本(料)-总] F_SJCB_L_Z, [差异-总料] AS F_CHaYi_Z,[预算成本(工)-总] AS F_YSCB_G_Z,[实际成本(工)-总] AS F_SJCB_G_Z
,[差异-总工] AS F_ChaYi_ZG,[预算成本(费)-总] AS F_YSCB_F_Z,[实际成本(费)-总] AS F_SJCB_F_Z,[差异-总费] AS F_ChaYi_ZF,[单位总预算成本] AS F_DWZYSCB
,[单位实际总成本] AS F_DWSJZCB, [预算成本(工)-单] AS F_YSCB_G_D,[实际成本(工)-单] AS F_SJCB_G_D,[预算成本(费)-单] AS F_YSCB_F_D,[实际成本(费)-单] AS F_SJCB_F_D
,[F_ChaYi_DanLiao]=[预算成本(料)-单]-[实际成本(料)-单],F_ChaYi_D_G=[预算成本(工)-单]-[实际成本(工)-单],F_ChaYi_F_D=[预算成本(费)-单]-[实际成本(费)-单]
FROM (
SELECT *,[预算与实际数量差异]=[预算销售数量]-[销售数量],[预算与实际总成本差异]=[预算总成本]-[实际销售总成本]
,[差异-总料]=[预算成本(料)-总]-[实际成本(料)-总] ,[差异-总工]=[预算成本(工)-总]-[实际成本(工)-总],[差异-总费]=[预算成本(费)-总]-[实际成本(费)-总]
,[单位总预算成本]=CASE WHEN [预算销售数量]!=0 THEN [预算总成本]/[预算销售数量] ELSE 0 END
,[预算成本(料)-单]=CASE WHEN [预算销售数量]!=0 THEN [预算成本(料)-总]/[预算销售数量] ELSE 0 END
,[预算成本(工)-单]=CASE WHEN [预算销售数量]!=0 THEN [预算成本(工)-总]/[预算销售数量] ELSE 0 END
,[预算成本(费)-单]=CASE WHEN [预算销售数量]!=0 THEN [预算成本(费)-总]/[预算销售数量] ELSE 0 END
,[单位实际总成本]=CASE WHEN [销售数量]!=0 THEN [实际销售总成本]/[销售数量] ELSE 0 END
,[实际成本(料)-单]=CASE WHEN [销售数量]!=0 THEN [实际成本(料)-总]/[销售数量] ELSE 0 END
,[实际成本(工)-单]=CASE WHEN [销售数量]!=0 THEN [实际成本(工)-总]/[销售数量] ELSE 0 END
,[实际成本(费)-单]=CASE WHEN [销售数量]!=0 THEN [实际成本(费)-总]/[销售数量] ELSE 0 END
FROM #TempResultTable) a
DROP TABLE #XiaoShouChengBen
DROP TABLE #TuiHuoChengBen
DROP TABLE #TempNianDuXiaoShouYuSuan
DROP TABLE #TempResultTable
END
-- LEFT JOIN (SELECT SUM(FREALQTY),FORMAT(tui.FAPPROVEDATE, 'yyyy-MM-01') AS FAPPROVEDATE FROM dbo.T_SAL_RETURNSTOCK tui LEFT JOIN T_SAL_RETURNSTOCKENTRY tuide ON tui.FID=tuide.FID
-- WHERE tui.FAPPROVEDATE>=@begintime AND tui.FAPPROVEDATE<@endtime AND tui.FDOCUMENTSTATUS='C'
--) Return11 ON
--SELECT * FROM VHUB_T_BMMGroupLinkTable
-- SELECT * FROM VHUB_BD_BMMaterialGroup
--SELECT TOP 10 * FROM T_SAL_OUTSTOCKENTRY
-- -- 退货成本查询SQL
--SELECT T1.FID, T1.FBILLNO,T2.FENTRYID,t2.FMaterialID,ff.FNUMBER, FMustQty ,t4.*,T6.*
--FROM T_SAL_RETURNSTOCK T1 INNER JOIN T_SAL_RETURNSTOCKENTRY T2
--INNER JOIN T_SAL_RETURNSTOCKENTRY_C T3 ON T3.FENTRYID = T2.FENTRYID
--ON T1.FID = T2.FID
-- INNER JOIN T_SAL_OUTSTOCKENTRY_CE T4 ON T3.FENTRYID = T4.FENTRYID
-- LEFT JOIN T_HS_CALDIMENSIONS T5 ON T3.FDIMENSIONID = T5.FDIMENSIONID
-- LEFT JOIN T_BD_EXPENSE_L T6 ON T4.FEXPENSEID = T6.FEXPID AND T6.FLOCALEID = 2052
-- LEFT JOIN T_BD_MATERIAL ff ON t2.FMaterialID=ff.FMaterialID
-- WHERE T1.FAPPROVEDATE>=@begintime AND t1.FAPPROVEDATE<@endtime
--ORDER BY T2.FENTRYID DESC
--SELECT * FROM VHUB_T_BMGStandCost
------预算成本表
--,(
--SELECT SUM(FALLAMOUNT)
-- FROM VHUB_T_BMGStandCost cost WHERE 1=1 AND cost.FBMMATERIALGROUP AND cost.FDATE=@begintime AND cost.FDATE<@endtime ) AS F_YSZCB
-- ,(
--SELECT SUM(FMATERIALCOSTAMOUNT)
-- FROM VHUB_T_BMGStandCost WHERE 1=1 AND cost.FBMMATERIALGROUP=t5.FNUMBER ) AS F_YSZCB_Z
-- ,(
--SELECT SUM(FLABORCOSTAMOUNT)
-- FROM VHUB_T_BMGStandCost WHERE 1=1 AND cost.FBMMATERIALGROUP=t5.FNUMBER) AS F_YSCB_G_Z
-- ,(
--SELECT SUM(FFEEAMOUNT)
-- FROM VHUB_T_BMGStandCost WHERE 1=1 ) AS F_YSCB_F_Z