ALTER PROC TEST_CB_CPCBHYFXIBB @billNo varchar(100) AS BEGIN IF EXISTS (SELECT 1 WHERE OBJECT_ID('tempdb..#查询结果') IS NOT NULL) BEGIN DROP TABLE [dbo].[#查询结果] END DECLARE @period int DECLARE @dbName varchar(100) DECLARE @ACCTGORGID int --DECLARE @billNo varchar(100) SET @ACCTGORGID = 100039 SET @period = 201801 --SET @billNo = 'MO000019' SELECT @dbName = DB_NAME() IF @dbName != 'AIS20231110222743' BEGIN SET @period = 202407 --SET @period = 202308 SET @ACCTGORGID = 1 --SET @billNo = 'WO2403210039' --SET @billNo = 'WO2403210048' --SET @billNo = 'WO2304230023' --SET @billNo = 'WO2405290121' --SET @billNo = 'WO2406220013' --SET @billNo = 'TO2302060061' --SET @billNo = 'WO2311020005' --SET @billNo = 'WO2312050303' --SET @billNo = 'WO2403270354' --SET @billNo = 'WO2406050001' --SET @billNo = 'WO2404170154' END CREATE TABLE #查询结果( [FPRODUCTNO] nvarchar(255) COLLATE Chinese_PRC_CI_AS NOT NULL, [FBILLID] int NOT NULL, [FBILLENTRYID] int NOT NULL, [FPRODUCTID] int NOT NULL, --[FFORMID] varchar(36) COLLATE Chinese_PRC_CI_AS NOT NULL, [FPRODUCTDIMEID] int NOT NULL, [FMATERIALID] int NOT NULL, [FEXPTYPE] char(1) COLLATE Chinese_PRC_CI_AS NOT NULL, [单耗] decimal(23,10) NULL, [使用比例] decimal(23,10) NOT NULL, [单价] decimal(23,10) NOT NULL, [物料投入数量] decimal(23,10) NOT NULL, [物料投入成本] decimal(23,10) NOT NULL, [物料完工数量] decimal(23,10) NOT NULL, [物料完工成本] decimal(23,10) NOT NULL, [产品投入数量] decimal(23,10) NOT NULL, [产品投入成本] decimal(23,10) NOT NULL, [产品完工数量] decimal(23,10) NOT NULL, [产品完工成本] decimal(23,10) NOT NULL, [FAMOUNT] decimal(38,10) NULL, [FQTY] decimal(38,10) NULL, [FLOT] int NULL, [FPERIOD] int NULL, [FNUMBER] nvarchar(255) COLLATE Chinese_PRC_CI_AS NULL, [SubBillId] int NULL, [SubBillEntryId] int NULL, [SubPRODUCTDIMEID] int NULL, MPATH nvarchar(MAX) COLLATE Chinese_PRC_CI_AS NOT NULL, [FGOON] int NOT NULL, FLEVEL int not null ) ;WITH #初始数据 AS ( SELECT t0.FPRODUCTNO ,t0.FBILLID ,t0.FBILLENTRYID ,t0.FPRODUCTID ,t0.FFORMID ,t3.FMATERIALID ,t1.FPRODUCTDIMEID ,t3.FEXPTYPE ,t3.FSUMCURRINPUTQTY '物料投入数量' ,t3.FSUMCURRINPUTAMOUNT '物料投入成本' ,t3.FSUMQUALIFIEDINQTY '物料完工数量' ,t3.FSUMQUALIFIEDINAMOUNT '物料完工成本' ,t4.FSUMCURRINPUTQTY '产品投入数量' ,t4.FSUMCURRINPUTAMOUNT '产品投入成本' ,t4.FSUMQUALIFIEDINQTY '产品完工数量' ,t4.FSUMQUALIFIEDINAMOUNT '产品完工成本' ,CONCAT(t0.FPRODUCTNO,'_') AS 'MPATH' ,(t2.FYEAR * 100 + t2.FPERIOD) AS 'FPERIOD' ,RANK() OVER (ORDER BY (t2.FYEAR * 100 + t2.FPERIOD) DESC) 'RN' FROM T_CB_PROORDERDIME t0 INNER JOIN V_CB_PROORDERINFO t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID INNER JOIN V_HS_OUTACCTG t2 on t1.FACCTGID = t2.FID INNER JOIN V_CB_COSTMATTERIAL t3 on t3.FID = t1.FID INNER JOIN V_CB_COSTCALEXPENSE t4 on t4.FID = t3.FID WHERE 1 = 1 AND t0.FPRODUCTNO = @billNo AND t2.FACCTGORGID = @ACCTGORGID AND t2.FCOMPUTEID != '' AND (t2.FYEAR * 100 + t2.FPERIOD) <= @period AND t1.FENDINITKEY = 1 ) INSERT INTO #查询结果 SELECT t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID ,t0.FPRODUCTDIMEID ,t0.FMATERIALID ,t0.FEXPTYPE ,CASE WHEN t0.FEXPTYPE = 0 THEN t0.物料完工数量 / t0.产品完工数量 ELSE 1 END '单耗' ,CASE WHEN (t0.FEXPTYPE = 0 AND ISNULL(t4.FLOT,0)!= 0) THEN (ISNULL(t4.FQTY, 0) / t0.物料投入数量) ELSE 1 END '使用比例' ,CASE WHEN t0.FEXPTYPE = 0 THEN t0.物料完工成本 / t0.物料完工数量 ELSE t0.物料完工成本 / t0.产品完工数量 END AS '单价' ,t0.[物料投入数量] ,t0.物料投入成本 ,t0.物料完工数量 ,t0.物料完工成本 ,t0.[产品投入数量] ,t0.[产品投入成本] ,t0.产品完工数量 ,t0.产品完工成本 ,ISNULL(t4.FAMOUNT, 0) '领料成本' ,ISNULL(t4.FQTY,0) AS '领料数量' ,ISNULL(t4.FLOT,0) AS 'FLOT' ,ISNULL(t4.FPERIOD ,0) AS 'FPERIOD' ,ISNULL(t5.FNUMBER,'') AS 'FLOT_TEXT' ,t6.FBILLID ,t6.FBILLENTRYID ,t6.FPRODUCTDIMEID ,t0.MPATH AS 'MPATH' ,CASE WHEN ISNULL(t6.FBILLENTRYID,0) = 0 THEN 0 WHEN t0.FPRODUCTNO = t5.FNUMBER THEN 0 ELSE 1 END 'FGOON' ,0 --,CASE t0.FEXPTYPE WHEN 0 THEN '直接费用' WHEN 1 THEN '间接费用' WHEN 2 THEN '其他费用' ELSE '其他' END '费用类别' FROM #初始数据 t0 OUTER APPLY ( SELECT t5.FLOT ,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) AS 'FPERIOD' ,SUM(t4.FAMOUNT) AS 'FAMOUNT',SUM(t6.FQTY) AS 'FQTY' FROM V_CB_COSTALLORESULTSEND t4 INNER JOIN T_HS_INIVSTOCKDIMENSION t5 on t5.FENTRYID = t4.FDIMEENTRYID AND t5.FLOT != 0 INNER JOIN V_HS_OUTINSTOCKSEQ t6 on t6.FENTRYID = t4.FOUTINSTOCKID WHERE t4.FPRODUCTDIMEID = t0.FPRODUCTDIMEID AND t5.FMATERIALID = t0.FMATERIALID AND CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) <= t0.FPERIOD GROUP BY t5.FLOT ,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) ) t4 LEFT JOIN T_BD_LOTMASTER t5 on t5.FLOTID = t4.FLOT LEFT JOIN T_CB_PROORDERDIME t6 on t6.FPRODUCTNO = t5.FNUMBER AND t6.FPRODUCTID = t0.FMATERIALID WHERE t0.RN = 1 ORDER BY t0.FPRODUCTDIMEID ,t0.FEXPTYPE DESC ,t0.FMATERIALID ASC ,t4.FLOT ASC DECLARE @num INT,@level int,@LoopCount int SET @num = 1 SET @level =1 SET @LoopCount = 0; WHILE(@num!=0 AND @LoopCount < 30) BEGIN ;WITH #初始数据 AS ( SELECT t0.FPRODUCTNO ,t0.FBILLID ,t0.FBILLENTRYID ,t0.FPRODUCTID ,t0.FFORMID ,t3.FMATERIALID ,t1.FPRODUCTDIMEID ,t3.FEXPTYPE ,t3.FSUMCURRINPUTQTY '物料投入数量' ,t3.FSUMCURRINPUTAMOUNT '物料投入成本' ,t3.FSUMQUALIFIEDINQTY '物料完工数量' ,t3.FSUMQUALIFIEDINAMOUNT '物料完工成本' ,t4.FSUMCURRINPUTQTY '产品投入数量' ,t4.FSUMCURRINPUTAMOUNT '产品投入成本' ,t4.FSUMQUALIFIEDINQTY '产品完工数量' ,t4.FSUMQUALIFIEDINAMOUNT '产品完工成本' ,CONCAT(tt.MPATH,t0.FPRODUCTNO,'_') AS 'MPATH' ,(t2.FYEAR * 100 + t2.FPERIOD) AS 'FPERIOD' ,RANK() OVER (ORDER BY (t2.FYEAR * 100 + t2.FPERIOD) DESC) 'RN' --,(tt.物料完工数量 / tt.物料投入数量) * (tt.FQTY / tt.物料投入数量) '使用比例' ,tt.使用比例 ,tt.单耗 FROM #查询结果 tt INNER JOIN T_CB_PROORDERDIME t0 on tt.SubBillId = t0.FBILLID AND tt.SubBillEntryId = t0.FBILLENTRYID AND tt.SubPRODUCTDIMEID = t0.FPRODUCTDIMEID INNER JOIN V_CB_PROORDERINFO t1 on t1.FPRODUCTDIMEID = t0.FPRODUCTDIMEID INNER JOIN V_HS_OUTACCTG t2 on t1.FACCTGID = t2.FID INNER JOIN V_CB_COSTMATTERIAL t3 on t3.FID = t1.FID INNER JOIN V_CB_COSTCALEXPENSE t4 on t4.FID = t3.FID WHERE 1 = 1 AND tt.FGOON = 1 AND tt.FLEVEL = @level - 1 AND t2.FACCTGORGID = @ACCTGORGID AND t2.FCOMPUTEID != '' AND (t2.FYEAR * 100 + t2.FPERIOD) <= tt.FPERIOD AND t1.FENDINITKEY = 1 --AND tt.FLEVEL < 2 ) INSERT INTO #查询结果 SELECT t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID ,t0.FPRODUCTDIMEID ,t0.FMATERIALID ,t0.FEXPTYPE ,CASE WHEN t0.FEXPTYPE = 0 THEN t0.物料完工数量 / t0.产品完工数量 * t0.单耗 ELSE t0.单耗 END * CASE WHEN (t0.FEXPTYPE = 0 AND ISNULL(t4.FLOT,0)!= 0) THEN (ISNULL(t4.FQTY, 0) / t0.物料投入数量) ELSE 1 END * t0.使用比例 '单耗' ,CASE WHEN (t0.FEXPTYPE = 0 AND ISNULL(t4.FLOT,0)!= 0) THEN (ISNULL(t4.FQTY, 0) / t0.物料投入数量) ELSE 1 END * t0.使用比例 '使用比例' ,CASE WHEN t0.FEXPTYPE = 0 THEN t0.物料完工成本 / t0.物料完工数量 ELSE t0.物料完工成本 / t0.产品完工数量 END '单价' ,t0.[物料投入数量] ,t0.物料投入成本 ,t0.物料完工数量 ,t0.物料完工成本 ,t0.[产品投入数量] ,t0.[产品投入成本] ,t0.产品完工数量 ,t0.产品完工成本 ,ISNULL(t4.FAMOUNT, 0) '领料成本' ,ISNULL(t4.FQTY,0) AS '领料数量' ,ISNULL(t4.FLOT,0) AS 'FLOT' ,ISNULL(t4.FPERIOD ,0) AS 'FPERIOD' ,ISNULL(t5.FNUMBER,'') AS 'FLOT_TEXT' ,t6.FBILLID ,t6.FBILLENTRYID ,t6.FPRODUCTDIMEID ,t0.MPATH AS 'MPATH' ,CASE WHEN ISNULL(t6.FBILLENTRYID,0) = 0 THEN 0 WHEN CHARINDEX(CONCAT(t5.FNUMBER,'_'),t0.MPATH) > 0 THEN 0 ELSE 1 END 'FGOON' ,@level --,CASE t0.FEXPTYPE WHEN 0 THEN '直接费用' WHEN 1 THEN '间接费用' WHEN 2 THEN '其他费用' ELSE '其他' END '费用类别' FROM #初始数据 t0 OUTER APPLY ( SELECT t5.FLOT ,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) AS 'FPERIOD' ,SUM(t4.FAMOUNT) AS 'FAMOUNT',SUM(t6.FQTY) AS 'FQTY' FROM V_CB_COSTALLORESULTSEND t4 INNER JOIN T_HS_INIVSTOCKDIMENSION t5 on t5.FENTRYID = t4.FDIMEENTRYID AND t5.FLOT != 0 INNER JOIN V_HS_OUTINSTOCKSEQ t6 on t6.FENTRYID = t4.FOUTINSTOCKID WHERE t4.FPRODUCTDIMEID = t0.FPRODUCTDIMEID AND t5.FMATERIALID = t0.FMATERIALID AND CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) <= t0.FPERIOD GROUP BY t5.FLOT ,CONVERT(int,CONVERT(varchar(6) ,t6.FBILLDATE,112)) ) t4 LEFT JOIN T_BD_LOTMASTER t5 on t5.FLOTID = t4.FLOT LEFT JOIN T_CB_PROORDERDIME t6 on t6.FPRODUCTNO = t5.FNUMBER AND t6.FPRODUCTID = t0.FMATERIALID WHERE t0.RN = 1 ORDER BY t0.FPRODUCTDIMEID ,t0.FEXPTYPE DESC ,t0.FMATERIALID ASC ,t4.FLOT ASC SET @num = @@ROWCOUNT SET @level += 1 SET @LoopCount += 1 END SELECT t0.FPRODUCTNO,t0.FBILLID,t0.FBILLENTRYID,t0.FPRODUCTID,t0.FPRODUCTDIMEID ,t0.FMATERIALID ,t0.FEXPTYPE ,t1.FNUMBER ,t1_l.FNAME ,t0.单耗 ,t0.使用比例 ,t0.单价 ,t0.单耗 * t0.单价 AS '料工费' ,t0.使用比例 * t0.物料完工成本 AS '料工费2' ,t0.物料完工数量 * t0.使用比例 AS '总工时' ,t0.物料投入数量 ,t0.物料投入成本 ,t0.物料完工数量 ,t0.物料完工成本 ,t0.产品投入数量 ,t0.产品投入成本 ,t0.产品完工数量 ,t0.产品完工成本 ,t0.FAMOUNT ,t0.FQTY ,t0.FLOT ,t0.FPERIOD ,t0.FNUMBER ,t0.SubBillId ,t0.SubBillEntryId ,t0.SubPRODUCTDIMEID ,t0.MPATH,t0.FGOON,t0.FLEVEL FROM #查询结果 t0 LEFT JOIN T_BD_MATERIAL t1 on t0.FMATERIALID = t1.FMATERIALID LEFT JOIN T_BD_MATERIAL_L t1_l on t1_l.FMATERIALID = t0.FMATERIALID AND t1_l.FLOCALEID = 2052 --LEFT JOIN T_PRD_MORPTENTRY t2e on t2e.FMOID = t0.FBILLID AND t2e.FMOENTRYID = t0.FBILLENTRYID AND t0.FEXPTYPE = 9 WHERE 1=1 --AND t0.FGOON = 0 --AND t0.FPRODUCTNO = 'RO2308220002' --AND t0.FEXPTYPE = 9 ORDER BY t0.FLEVEL ,t0.FMATERIALID END