-- 检查存储过程是否存在,存在则删除 IF OBJECT_ID('dbo.[ZPR_SalesRportShareData]', 'P') IS NOT NULL BEGIN DROP PROCEDURE dbo.ZPR_SalesRportShareData; PRINT '存储过程 dbo.[ZPR_SalesRportShareData] 已删除'; END GO -- 创建新的存储过程 CREATE PROCEDURE dbo.ZPR_SalesRportShareData AS BEGIN -- 存储过程逻辑 TRUNCATE TABLE [ZZZ_SalesRportShareData]; INSERT INTO [ZZZ_SalesRportShareData] ([销售单主键ID],[销售员ID],[F_RecConditionId],[整单订单总额],[销售员],[分摊比例],[分摊金额],[SBU],[明细区域],[购货单位],[公司性质],[客户信用] ,[纸质合同号],[项目名称],[签订年份],[订单日期],[发货日期],[整单累计发货金额],[开票日期],[整单累计退货金额],[整单累计开票金额],[整单累计到款金额],[订单总额],[累计发货金额],[累计退货金额],[累计开票金额],[应收款合计] ,[累计到款金额],[组织ID],[销售订单编号],[收款条件主键ID],[收款条件],[应收单日期]) SELECT [销售单主键ID],[销售员ID],[F_RecConditionId],[整单订单总额],[销售员],[分摊比例],[分摊金额],[SBU],[明细区域],[购货单位],[公司性质],[客户信用] ,[纸质合同号],[项目名称],[签订年份],[订单日期],[发货日期],[整单累计发货金额],[开票日期],[整单累计退货金额],[整单累计开票金额], [整单累计到款金额],0 [订单总额] ,0 [累计发货金额],0 [累计退货金额],0 [累计开票金额],0 [应收款合计],0 [累计到款金额],[组织ID],[销售订单编号],[收款条件主键ID],[收款条件], [应收单日期] FROM ( SELECT A.FID [销售单主键ID] ,ISNULL(O.fid,l.fid) [销售员ID] ,ISNULL(w.FENTRYID,0) [收款条件主键ID], ISNULL(w.FNAME,'') AS [收款条件], W.F_RecConditionId ,(SELECT SUM(FBillAllAmount_LC) FROM T_SAL_ORDERFIN FF WHERE FF.FID = A.FID )AS [整单订单总额] ,ISNULL(O.FNAME,L.FNAME) AS [销售员],CONVERT(DECIMAL(18,2),ISNULL(n.FSHARERATE,100)) AS [分摊比例] ,CONVERT(DECIMAL(18,6),ISNULL(n.FSHAREAMOUNT,fin.FBillAllAmount_LC)) [分摊金额] ,ISNULL(ACO.区域,ACL.区域) AS [SBU] , ISNULL (ACO.[明细区域] , ACL.明细区域) AS [明细区域],c.FNAME AS [购货单位] ,ISNULL(K.FDATAVALUE,'') AS [公司性质] ,P.FDATAVALUE AS [客户信用],A.F_contractnumber AS [纸质合同号] , G.FNAME AS [项目名称] ,CONVERT( NVARCHAR(10), YEAR(A.FAPPROVEDATE)) AS [签订年份],CONVERT(VARCHAR(10), A.FAPPROVEDATE,23) AS [订单日期] ,[发货日期]=ISNULL((SELECT (CONVERT(NVARCHAR(10),MAX(SAL.FDATE),23)) AS '发货日期' FROM T_SAL_DELIVERYNOTICE SAL INNER JOIN T_SAL_DELIVERYNOTICEFIN B ON SAL.FID =B.FID WHERE SAL.FDOCUMENTSTATUS= 'C' AND SAL.F_PAPERCONTRACT = A.F_contractnumber),'') ,[整单累计发货金额]=ISNULL( (SELECT SUM(B.FBillAllAmount_LC) AS '累计发货金额' FROM T_SAL_DELIVERYNOTICE SAL INNER JOIN T_SAL_DELIVERYNOTICEFIN B ON SAL.FID =B.FID WHERE SAL.FDOCUMENTSTATUS= 'C' AND SAL.F_PAPERCONTRACT = A.F_contractnumber),0) ,[开票日期]=ISNULL((CASE WHEN SUBSTRING(U.FDATAVALUE,0,1)= 'W' THEN T.开票日期 ELSE T.没有红色的开票日期 END ),'') ,[整单累计退货金额]=ISNULL(( SELECT SUM(B.FBillAllAmount_LC) AS '累计退货金额' FROM T_SAL_RETURNSTOCK AA INNER JOIN T_SAL_RETURNSTOCKFIN B ON AA.FID =B.FID WHERE AA.FDOCUMENTSTATUS= 'C' AND A.F_contractnumber = AA.F_contractnumber ),0) ,[整单累计开票金额] =ISNULL( CASE WHEN SUBSTRING(U.FDATAVALUE,0,1)= 'W' THEN AD.发票总金额 ELSE AD.[发票总金额(普票存财务)] END,0) ,A.FSALEORGID as '组织ID' ,W.F_DAY AS '天数' ,a.FBILLNO [销售订单编号] ,[应收单日期]=(T.[开票日期]) ,[整单累计到款金额]= ISNULL(a.F_Amount,0) -----------------from 表-------- FROM T_SAL_ORDER A WITH(NOLOCK) LEFT JOIN ( SELECT DISTINCT x.FNAME +'--'+CONVERT(NVARCHAR(50), CONVERT(INT, w.F_DAY))+'--'+CONVERT(NVARCHAR(50),CONVERT(DECIMAL(18,2), w.FRECADVANCERATE))+'%' AS FNAME ,w.FID,w.F_PMSDate ,W.FRECADVANCEAMOUNT,w.F_DAY ,w.FENTRYID, W.F_RecConditionId ,w.FRECADVANCERATE FROM T_SAL_ORDERPLAN w WITH(NOLOCK) LEFT JOIN T_BD_RecCondition_L X ON X.FID = W.F_RecConditionId ) w ON w.FID=A.FID LEFT join (Select a2.FENTRYID,a2.FDATAVALUE From T_BAS_ASSISTANTDATAENTRY a1 JOIN T_BAS_ASSISTANTDATAENTRY_L a2 on a1.FENTRYID = a2.FENTRYID Where a1.FID = '670cc977263353') B on A.F_ORDERCATEGORY = B.FENTRYID LEFT JOIN T_BD_CUSTOMER_L C WITH(NOLOCK) ON C.FCUSTID= A.FCUSTID AND C.FLOCALEID= 2052 left JOIN T_PerformanceSharingEntry TPS ON TPS.fid=a.FID LEFT JOIN V_BD_SALESMAN_L L WITH(NOLOCK) ON L.fid = A.FSALERID LEFT JOIN T_PerformanceSharing M WITH(NOLOCK) ON M.FSOURCEBILLNO = A.FBILLNO AND M.FDOCUMENTSTATUS = 'C' LEFT JOIN T_PerformanceSharingEntry N WITH(NOLOCK) ON N.FID=M.FID LEFT JOIN V_BD_SALESMAN_L O WITH(NOLOCK) ON O.fid= N.FSALEID LEFT JOIN (SELECT DISTINCT ACO22.名称,ACO22.明细区域,ACO22.区域 FROM ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO22 ) ACO ON ACO.名称=O.FNAME AND ISNULL(ACO.明细区域,'') != '' LEFT JOIN (SELECT DISTINCT ACL22.名称,ACL22.明细区域 ,ACL22.区域 FROM ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL22 ) ACL ON ACL.名称=L.FNAME AND ISNULL(ACL.明细区域,'') != '' LEFT JOIN T_SAL_ORDERFIN fin WITH(NOLOCK) ON a.FID=fin.FID LEFT JOIN T_BD_CUSTOMER I WITH(NOLOCK) ON I .FCUSTID = A.FCUSTID lEFT JOIN V_ASSISTANTDATA K WITH(NOLOCK) ON K.FENTRYID = i.FCompanyNature LEFT JOIN V_ASSISTANTDATA P WITH(NOLOCK) ON P.FENTRYID = I.F_CREDITCLASSIFICATION LEFT JOIN T_BAS_PREBDONE_L G WITH(NOLOCK) ON G.FID = A.F_projectname AND G.FLocaleID =2052 LEFT JOIN ( SELECT F_Paper ,CONVERT(NVARCHAR(10), MAX(FDATE),23) AS '开票日期' ,CONVERT(NVARCHAR(10), MAX(FDATE),23) AS '没有红色的开票日期' FROM t_AR_receivable A INNER JOIN T_AR_RECEIVABLEENTRY B ON A.FID = B.FID WHERE A.FDOCUMENTSTATUS = 'C' AND A.FCancelStatus = 'A' GROUP BY F_Paper ) T ON T.F_PAPER = A.F_contractnumber LEFT JOIN V_ASSISTANTDATA U ON U.FENTRYID = A.F_Ordercategory LEFT JOIN ( SELECT F_Papercontract,CAST( sum(b.FALLAMOUNT) AS DECIMAL(18,6)) AS '发票总金额', CAST (sum(CASE WHEN F_Papercontract = 'Y' THEN b.FALLAMOUNT ELSE 0 END ) AS DECIMAL(18,6)) AS '发票总金额(普票存财务)' FROM t_AR_receivable A INNER JOIN T_AR_RECEIVABLEFIN B ON A.FID = B.FID GROUP BY F_Papercontract ) AD ON AD.F_PAPERCONTRACT = A.F_contractnumber LEFT join ( SELECT a.F_Papercontract, sum(d.FCURWRITTENOFFAMOUNT) as '累计收款' FROM t_AR_receivable A INNER JOIN T_AR_RECEIVABLEENTRY E ON E.FID =A.FID INNER JOIN T_AR_RECMacthLogENTRY B ON A.FBILLNO = B.FSRCBILLNO INNER JOIN T_AR_RECMacthLog C ON C.FID = B.FID INNER JOIN T_AR_RECMacthLogENTRY D ON D.FID = B.FID AND D.FSOURCETYPE = '36cf265bd8c3452194ed9c83ec5e73d2' WHERE 1=1 group by a.F_Papercontract ) AE ON AE.F_Papercontract = A.F_contractnumber LEFT JOIN (SELECT DISTINCT F_Papercontract FROM T_SAL_DELIVERYNOTICE WHERE F_SFYFH ='是') AB ON AB.F_PAPERCONTRACT = A.F_contractnumber WHERE ( ( A.FSALEORGID = 100302 AND ( (ACO.区域 != '碳索智控' OR ACO.区域 IS NULL ) AND (ACL.区域 != '碳索智控' OR ACL.区域 IS NULL ) AND C.FNAME NOT IN ('派诺科技(香港)有限公司','武汉派诺科技发展有限公司') AND L.FNAME NOT IN ('兴诺总','陈智勇') )) OR A.FSALEORGID != 100302) AND A.FDocumentStatus = 'C' AND EXISTS(SELECT 1 FROM T_SAL_ORDERENTRY bb WHERE bb.fid=a.fid ) ) A WHERE [整单订单总额]<>0 AND SUBSTRING([纸质合同号],1,1) != 'Z' ORDER BY A.[销售单主键ID],[销售员ID] UPDATE [ZZZ_SalesRportShareData] SET [订单总额]=[分摊金额],[累计发货金额]=[整单累计发货金额]*[分摊比例]*0.01,[累计退货金额]=[整单累计退货金额]*[分摊比例]*0.01 ,[累计开票金额]=[整单累计开票金额]*[分摊比例]*0.01,[累计到款金额]=[整单累计到款金额]*[分摊比例]*0.01 ,[应收款合计]=[分摊金额]-([整单累计退货金额]+[整单累计到款金额])*[分摊比例]*0.01 FROM [ZZZ_SalesRportShareData] A UPDATE [ZZZ_SalesRportShareData] SET [订单日期]=CASE WHEN [订单日期] > '1990-01-01' THEN [订单日期] ELSE NULL END , [发货日期]=CASE WHEN [发货日期] > '1990-01-01' THEN [发货日期] ELSE NULL END ,[开票日期]=CASE WHEN [开票日期] > '1990-01-01' THEN [开票日期] ELSE NULL END END GO --EXEC ZPR_SalesRportShareData;