SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO ALTER PROCEDURE [dbo].[UpdateYSDZBMX_GZTH] @FSDATE varchar(1000), @FEDATE varchar(1000), @FSaleOrgId varchar(1000), @FCUSTID varchar(1000), @XSYFID varchar(1000), @ZZHTH varchar(1000) ,@SFQJFWDZ varchar(1000) ---是否区间范围对账 AS BEGIN DECLARE @StartDate DATE = CONVERT(DATE, @FSDATE); --DECLARE @EndDate DATE = CONVERT(DATE,@FEDATE); DECLARE @EndDate DATE = CONVERT(DATE,CASE @FEDATE WHEN '' THEN '2099-12-31'ELSE @FEDATE END); -- 将结束日期增加一天 SET @EndDate = DATEADD(DAY, 1, @EndDate); TRUNCATE TABLE YingShouZhanKuanMX_GZTH; SELECT DISTINCT * INTO #TEMP3 FROM( --发货通知单 SELECT F_PAPERCONTRACT ZHHTH,FDELIVERYORGID ZZ FROM T_SAL_DELIVERYNOTICE T1 WHERE (FDELIVERYORGID = @FSaleOrgId OR ISNULL(@FSaleOrgId,'') = '') AND FCUSTOMERID = @FCUSTID --客户 AND FApproveDate >= @StartDate AND FApproveDate < @EndDate AND (ISNULL(@ZZHTH,'') = '' OR F_PAPERCONTRACT = @ZZHTH) AND FDOCUMENTSTATUS = 'C' UNION ALL --退货通知单 SELECT F_PAPERCONTRACT ZHHTH,FRETORGID ZZ FROM T_SAL_RETURNNOTICE T1 WHERE (FRETORGID = @FSaleOrgId OR ISNULL(@FSaleOrgId,'') = '') AND FRETCUSTID = @FCUSTID --客户 AND FApproveDate >= @StartDate AND FApproveDate < @EndDate AND (ISNULL(@ZZHTH,'') = '' OR F_PAPERCONTRACT = @ZZHTH) AND FDOCUMENTSTATUS = 'C' UNION ALL --收款单 SELECT F_CONTRACTNUMBER ZHHTH,FPAYORGID ZZ FROM T_AR_RECEIVEBILL T1 WHERE (FPAYORGID = @FSaleOrgId OR ISNULL(@FSaleOrgId,'') = '') AND FCONTACTUNITTYPE = 'BD_Customer' --往来单位类型 AND FCONTACTUNIT = @FCUSTID --往来单位 AND FApproveDate >= @StartDate AND FApproveDate < @EndDate AND (ISNULL(@ZZHTH,'') = '' OR F_CONTRACTNUMBER = @ZZHTH) AND FDOCUMENTSTATUS = 'C' UNION ALL --收款退款单 SELECT F_VRYF_TEXT_83G ZHHTH,FPAYORGID ZZ FROM T_AR_REFUNDBILL T1 WHERE (FPAYORGID = @FSaleOrgId OR ISNULL(@FSaleOrgId,'') = '') AND FCONTACTUNITTYPE = 'BD_Customer' --往来单位类型 AND FCONTACTUNIT = @FCUSTID --往来单位 AND FApproveDate >= @StartDate AND FApproveDate < @EndDate AND (ISNULL(@ZZHTH,'') = '' OR F_VRYF_TEXT_83G = @ZZHTH) AND FDOCUMENTSTATUS = 'C' UNION ALL --销售增值税专用发票 SELECT F_PAPERNUMBER ZHHTH,FSETTLEORGID ZZ FROM T_IV_SALESIC T1 WHERE (FSETTLEORGID = @FSaleOrgId OR ISNULL(@FSaleOrgId,'') = '') AND FCUSTOMERID = @FCUSTID --客户 AND FApproveDate >= '2025-01-01' AND FApproveDate < @EndDate AND (ISNULL(@ZZHTH,'') = '' OR F_PAPERNUMBER = @ZZHTH) AND FDOCUMENTSTATUS = 'C' UNION ALL --销售订单 SELECT F_CONTRACTNUMBER ZHHTH,FSALEORGID ZZ FROM T_SAL_ORDER WHERE FDOCUMENTSTATUS = 'C' AND 1= @SFQJFWDZ )a INSERT INTO YingShouZhanKuanMX_GZTH (FID,FENTRYID,FSaleOrgId,FBILLNO,FSalerId,[DATE],CONTRACTNUMBER,ProjectName,SizeModel,FQty,FTaxPrice,FAllAmount,OrderAmount,PaymentAmount,[是否K3数据],旧物料编码,NUMBER) SELECT A.FID AS 销售订单FID ,B.FENTRYID AS 销售订单FENTRYID ,A.FSaleOrgId AS 销售组织 ,A.FBILLNO AS 销售订单编号 ,XS.FNAME AS 销售员FID ,FORMAT( A.FApproveDate,'yyyy-MM-dd') AS 签订日期 ,A.F_contractnumber AS 订单号 ,GC.FNAME AS 项目名称 ,WL_L.FSpecification AS 型号 ,B.FQTY AS 数量台 ,B_F.FTAXPRICE AS 单价 ,B_F.FALLAMOUNT_LC AS 价税合计 ,AF.FBillAllAmount 订单金额 ,A.F_Amount AS 累计核销金额 ,0 AS 是否K3数据 ,tmm.FOldNumber ,ROW_NUMBER() OVER(ORDER BY A.FID) AS NUMBER FROM T_SAL_ORDER A INNER JOIN T_SAL_ORDERFIN AF ON A.FID = AF.FID INNER JOIN T_BAS_PREBDONE_L GC ON A.F_projectname = GC.FID INNER JOIN T_SAL_ORDERENTRY B ON A.FID = B.FID INNER JOIN T_BD_MATERIAL_L WL_L ON B.FMATERIALID = WL_L.FMATERIALID INNER JOIN T_BD_MATERIAL tmm ON B.FMATERIALID = tmm.FMATERIALID INNER JOIN T_SAL_ORDERENTRY_F B_F ON B.FENTRYID = B_F.FENTRYID INNER JOIN V_BD_SALESMAN_L XS ON XS.FID = A.FSALERID INNER JOIN #TEMP3 LS ON LS.ZHHTH = A.F_CONTRACTNUMBER AND LS.ZZ = A.FSALEORGID WHERE (A.FSaleOrgId = @FSaleOrgId OR ISNULL(@FSaleOrgId,'') = '') AND A.FCUSTID = @FCUSTID --AND A.FApproveDate >= @StartDate --AND A.FApproveDate <= @EndDate AND (ISNULL(@XSYFID, '') = '' OR A.FSalerId = @XSYFID) AND (ISNULL(@ZZHTH,'') = '' OR A.F_contractnumber = @ZZHTH) AND B.FRETURNTYPE <> 'RETURN' AND A.FDOCUMENTSTATUS = 'C' UPDATE a SET a.[K3发货数量]=b.发货数量,a.[K3发货金额]=b.发货金额,a.[K3退货数量]=b.退货数量 ,a.[K3退货金额]=b.退货金额--,a.[K3专票金额] = b.专票金额 ,a.[K3普票金额]= b.普票金额 FROM YingShouZhanKuanMX_GZTH A INNER JOIN T_SAL_ORDERENTRY C ON A.FENTRYID = C.FENTRYID INNER JOIN [oldk3seorder0701] b ON C.F_K3SEQ = b.行号 AND a.FBILLNO=b.[单据编码] --AND a.旧物料编码=[物料编码] AND a.FQty=[数量] AND (ABS(a.FTaxPrice-b.[含税单价])<=0.02 OR ABS(a.FTaxPrice-b.[面价])<=0.02) WHERE 是否K3数据=0 AND B.日期 >= @StartDate AND B.日期 < @EndDate --k3专票 UPDATE a SET a.[K3专票金额] = b.发票金额 FROM YingShouZhanKuanMX_GZTH A INNER JOIN T_SAL_ORDERENTRY C ON A.FENTRYID = C.FENTRYID INNER JOIN (SELECT 合同号,发票类型,SUM(发票金额) AS '发票金额' FROM [oldk3ICSale0802] GROUP BY 合同号,发票类型) b ON C.FSEQ = 1 AND a.CONTRACTNUMBER=b.合同号 --AND a.旧物料编码=[物料编码] AND a.FQty=[数量] AND (ABS(a.FTaxPrice-b.[含税单价])<=0.02 OR ABS(a.FTaxPrice-b.[面价])<=0.02) WHERE 是否K3数据=0 AND b.发票类型 = '专' --AND B.日期 >= @StartDate --AND B.日期 < @EndDate --k3普票 UPDATE a SET a.[K3普票金额] = b.发票金额 FROM YingShouZhanKuanMX_GZTH A INNER JOIN T_SAL_ORDERENTRY C ON A.FENTRYID = C.FENTRYID INNER JOIN (SELECT 合同号,发票类型,SUM(发票金额) AS '发票金额' FROM [oldk3ICSale0802] GROUP BY 合同号,发票类型) b ON C.FSEQ = 1 AND a.CONTRACTNUMBER=b.合同号 --AND a.旧物料编码=[物料编码] AND a.FQty=[数量] AND (ABS(a.FTaxPrice-b.[含税单价])<=0.02 OR ABS(a.FTaxPrice-b.[面价])<=0.02) WHERE 是否K3数据=0 AND b.发票类型 = '普' UPDATE a SET a.[K3专票金额] = CASE B.rownumber WHEN 1 THEN b.专票金额 ELSE 0 END,a.[K3普票金额]= CASE B.rownumber WHEN 1 THEN b.普票金额 ELSE 0 END FROM YingShouZhanKuanMX_GZTH A INNER JOIN ( SELECT ROW_NUMBER() OVER(PARTITION BY T1.FID ORDER BY T1.FID) rownumber,T1.FID,T1.FENTRYID,T2.专票金额,T2.普票金额 FROM YingShouZhanKuanMX_GZTH T1 INNER JOIN ( SELECT FID,SUM([K3专票金额]) AS 专票金额,SUM([K3普票金额]) AS 普票金额 FROM YingShouZhanKuanMX_GZTH GROUP BY FID) T2 ON T1.FID = t2.FID )B ON A.FID = B.FID AND A.FENTRYID = B.FENTRYID ----插入K3数据 --INSERT INTO --YingShouZhanKuanMX_GZTH --(FID,FENTRYID,FSaleOrgId,FBILLNO,FSalerId,[DATE],CONTRACTNUMBER,ProjectName,SizeModel,[K3发货数量],[K3发货金额],[K3退货数量],[K3退货金额],[K3普票金额],[K3专票金额],[是否K3数据]) --SELECT -- B.FID AS 销售订单FID --,0 AS 销售订单FENTRYID --,B.FSaleOrgId AS 销售组织 --,B.FBILLNO AS 销售订单编号 --,XS.FNAME AS 销售员FID --,FORMAT( B.FApproveDate,'yyyy-MM-dd') AS 签订日期 --,B.F_contractnumber AS 订单号 --,GC.FNAME AS 项目名称 --,A.规格型号 AS 型号 --,A.发货数量 AS 发货数量 --,A.发货金额 AS 发货金额 --,A.退货数量 AS 退货数量 --,A.退货金额 AS 退货金额 --,A.普票金额 AS 普票金额 --,A.专票金额 AS 专票金额 --,1 AS 是否K3数据 --FROM oldk3seorder0701 A --INNER JOIN T_SAL_ORDER B ON A.单据编码 = B.FBILLNO --INNER JOIN T_BAS_PREBDONE_L GC ON B.F_projectname = GC.FID --INNER JOIN V_BD_SALESMAN_L XS ON XS.FID = B.FSALERID --WHERE B.FSaleOrgId = @FSaleOrgId --AND B.FCUSTID = @FCUSTID --AND B.FApproveDate >= @StartDate --AND B.FApproveDate <= @EndDate --AND (ISNULL(@XSYFID, '') = '' OR B.FSalerId = @XSYFID) --AND (ISNULL(@ZZHTH,'') = '' OR B.F_contractnumber = @ZZHTH) --更新发货日期,发货数量和发货金额 SELECT C.FSBILLID AS 销售订单FID ,C.FSID AS 销售订单FENTRYID ,A.FApproveDate AS 发货日期 ,B.FQTY AS 发货数量 ,B_F.FAllAmount_LC AS 发货金额 ,STUFF((SELECT DISTINCT ','+FORMAT(FApproveDate,'yyyy-MM-dd') FROM T_SAL_DELIVERYNOTICE T1 LEFT JOIN T_SAL_DELIVERYNOTICEENTRY T2 ON T1.FID = T2.FID LEFT JOIN T_SAL_DELIVERYNOTICEENTRY_F T3 ON T2.FENTRYID = T3.FENTRYID LEFT JOIN T_SAL_DELIVERYNOTICEENTRY_LK T4 ON T3.FENTRYID = T4.FENTRYID AND T4.FSTABLENAME = 'T_SAL_ORDERENTRY' WHERE T4.FSBILLID IN (SELECT FID FROM YingShouZhanKuanMX_GZTH) AND C.FSBILLID = T4.FSBILLID FOR XML PATH('')),1,1,'') AS 合并发货日期 INTO #TEMP1 FROM T_SAL_DELIVERYNOTICE A LEFT JOIN T_SAL_DELIVERYNOTICEENTRY B ON A.FID = B.FID LEFT JOIN T_SAL_DELIVERYNOTICEENTRY_F B_F ON B.FENTRYID = B_F.FENTRYID LEFT JOIN T_SAL_DELIVERYNOTICEENTRY_LK C ON B_F.FENTRYID = C.FENTRYID AND C.FSTABLENAME = 'T_SAL_ORDERENTRY' WHERE C.FSBILLID IN (SELECT FID FROM YingShouZhanKuanMX_GZTH) AND C.FSID IN (SELECT FENTRYID FROM YingShouZhanKuanMX_GZTH) AND A.FApproveDate >= @StartDate AND A.FApproveDate < @EndDate AND A.FDOCUMENTSTATUS = 'C' ----更新k3发货数据 --update A --SET A.K3发货数量 = C.发货数量,A.K3发货金额 = C.发货金额 --FROM YingShouZhanKuanMX_GZTH A --INNER JOIN T_SAL_ORDERENTRY B ON A.FID = B.FID AND A.FENTRYID = B.FENTRYID --INNER JOIN T_BD_MATERIAL D ON B.FMATERIALID = B.FMaterialId --INNER JOIN oldk3seorder0701 C ON A.FBILLNO = C.单据编码 AND A.CONTRACTNUMBER = C.项目编码 AND D.FOldNumber = C.物料编码 SELECT 销售订单FID, 销售订单FENTRYID, SUM(发货数量) AS 发货数量, SUM(发货金额) AS 发货金额 INTO #FHTEMP1 FROM #TEMP1 GROUP BY 销售订单FID,销售订单FENTRYID UPDATE A SET ShipmentsDate = B.合并发货日期 --FORMAT( B.发货日期,'yyyy-MM-dd') FROM YingShouZhanKuanMX_GZTH A INNER JOIN #TEMP1 B ON A.FID = B.销售订单FID AND A.FENTRYID = B.销售订单FENTRYID UPDATE A SET A.星空发货数量 = B.发货数量,A.星空发货金额 = B.发货金额 FROM YingShouZhanKuanMX_GZTH A INNER JOIN #FHTEMP1 B ON A.FID = B.销售订单FID AND A.FENTRYID = B.销售订单FENTRYID --更新发货数量 UPDATE A SET A.ShipmentsNum = ISNULL([星空发货数量],0) + ISNULL([K3发货数量],0),A.ShipmentsAmount = ISNULL([星空发货金额],0) + ISNULL([K3发货金额],0) FROM YingShouZhanKuanMX_GZTH A --更新退货日期,退货数量,退货金额 (正规流程有源单) SELECT E.FSBILLID AS 销售订单FID ,E.FSID AS 销售订单FENTRYID ,A.FDATE AS 退货日期 ,B.FQTY AS 退货数量 ,B_F.FALLAMOUNT_LC AS 退货金额 ,F.F_CONTRACTNUMBER AS 纸质合同号 INTO #TEMP2 FROM T_SAL_RETURNNOTICE A INNER JOIN T_SAL_RETURNNOTICEENTRY B ON A.FID = B.FID INNER JOIN T_SAL_RETURNNOTICEENTRY_F B_F ON B.FENTRYID = B_F.FENTRYID INNER JOIN T_SAL_RETURNNOTICEENTRY_LK C ON B_F.FENTRYID = C.FENTRYID AND C.FSTABLENAME = 'T_SAL_ORDERENTRY' INNER JOIN T_SAL_ORDERENTRY D ON C.FSBILLID = D.FID AND C.FSID = D.FENTRYID INNER JOIN T_SAL_ORDERENTRY_LK E ON E.FENTRYID = D.FENTRYID AND C.FSTABLENAME = 'T_SAL_ORDERENTRY' INNER JOIN T_SAL_ORDER F ON E.FSBILLID = F.FID WHERE 1=1 AND A.FApproveDate >= @StartDate AND A.FApproveDate < @EndDate AND A.FDOCUMENTSTATUS = 'C' --更新退货日期,退货数量,退货金额 (非正规流程无源单) INSERT INTO #TEMP2 (销售订单FID,销售订单FENTRYID,退货日期,退货数量,退货金额,纸质合同号) SELECT C.FID AS 销售订单FID ,D.FENTRYID AS 销售订单FENTRYID ,A.FDATE AS 退货日期 ,B.FQTY AS 退货数量 ,B_F.FALLAMOUNT_LC AS 退货金额 ,C.F_CONTRACTNUMBER AS 纸质合同号 FROM T_SAL_RETURNNOTICE A INNER JOIN T_SAL_RETURNNOTICEENTRY B ON A.FID = B.FID INNER JOIN T_SAL_RETURNNOTICEENTRY_F B_F ON B.FENTRYID = B_F.FENTRYID INNER JOIN T_SAL_ORDER C ON A.F_SOURPAPERCONTRACT = C.F_CONTRACTNUMBER AND C.FSALEORGID = A.FRETORGID --匹配纸质合同号 INNER JOIN T_SAL_ORDERENTRY D ON C.FID = D.FID AND D.FMATERIALID = B.FMATERIALID --匹配明细物料 WHERE 1=1 AND A.FApproveDate >= @StartDate AND A.FApproveDate < @EndDate AND C.F_CONTRACTNUMBER NOT IN (SELECT DISTINCT [纸质合同号] FROM #TEMP2) AND A.FDOCUMENTSTATUS = 'C' ----更新k3退货数据 --update A --SET A.K3退货数量 = C.退货数量,A.K3退货金额 = C.退货金额 --FROM YingShouZhanKuanMX_GZTH A --INNER JOIN T_SAL_ORDERENTRY B ON A.FID = B.FID AND A.FENTRYID = B.FENTRYID --INNER JOIN T_BD_MATERIAL D ON B.FMATERIALID = B.FMaterialId --INNER JOIN oldk3seorder0701 C ON A.FBILLNO = C.单据编码 AND A.CONTRACTNUMBER = C.项目编码 AND D.FOldNumber = C.物料编码 UPDATE A SET ReturnDate = FORMAT( B.退货日期,'yyyy-MM-dd'),A.星空退货数量 = ISNULL(B.退货数量,0),A.星空退货金额 = ISNULL(B.退货金额,0) FROM YingShouZhanKuanMX_GZTH A INNER JOIN #TEMP2 B ON A.FID = B.销售订单FID AND A.FENTRYID = B.销售订单FENTRYID update YingShouZhanKuanMX_GZTH SET ReturnNum = ISNULL(K3退货数量,0) + ISNULL(星空退货数量,0), ReturnAmount = ISNULL(K3退货金额,0) + ISNULL(星空退货金额,0); --更新回款日期 UPDATE A SET PaymentDate = FORMAT(B.ShouKuanFDate,'yyyy-MM-dd') FROM YingShouZhanKuanMX_GZTH A INNER JOIN ZZZ_HeXiaoBook B ON B.XiaoShouFid = A.FID WHERE 1=1 AND B.ShouKuanFDate >= @StartDate AND B.ShouKuanFDate < @EndDate --SELECT OrderAmount,PaymentAmount,ShippedDebt,InvoicedDebt,IsEnded ,OwedTickets,BillingAmount, CASE WHEN ROW_NUMBER() OVER(PARTITION BY FBILLNO ORDER BY fid) = 1 THEN FBILLNO --END AS 单号,* FROM YingShouZhanKuanMX_GZTH END