/****** Object: StoredProcedure [dbo].[Get_PNHTMXBB] Script Date: 2025/9/2 14:40:00 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO ALTER Proc [dbo].[Get_PNHTMXBB] ( @FSaleOrgId NVARCHAR(1000),--组织 @FCZZHTH NVARCHAR(1000),--纸质合同号 @FStartDate2 NVARCHAR(1000), @FEndDate2 NVARCHAR(1000) ) AS --过滤派诺总 SELECT A.FID AS FID INTO #TEMP3 FROM T_SAL_ORDER A INNER JOIN T_BD_CUSTOMER_L C ON C.FCUSTID= A.FCUSTID AND C.FLOCALEID= 2052 INNER JOIN T_BD_CUSTOMER Cccc WITH(NOLOCK) ON Cccc.FCUSTID= A.FCUSTID LEFT JOIN V_BD_SALESMAN_L L ON L.fid = A.FSALERID LEFT JOIN T_PerformanceSharing M ON M.FSOURCEBILLNO = A.FBILLNO AND M.FDOCUMENTSTATUS = 'C' LEFT JOIN T_PerformanceSharingEntry N ON N.FID=M.FID LEFT JOIN V_BD_SALESMAN_L O ON O.fid= N.FSALEID LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO ON ACO.名称=O.FNAME LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=L.FNAME WHERE A.FSALEORGID = 100302 AND ( ACO.区域 = '碳索智控' OR ACL.区域 = '碳索智控' OR C.FNAME IN ('派诺科技(香港)有限公司','武汉派诺科技发展有限公司')) OR (C.FCUSTID = 1150173 AND (ACO.区域 = '决策团队' OR ACL.区域 = '决策团队')) OR L.FNAME = '兴诺总' OR A.FID IN (110185,207800) AND (ISNULL(@FStartDate2,'') = '' OR A.FAPPROVEDATE > @FStartDate2) AND (ISNULL(@FEndDate2,'') = '' OR A.FAPPROVEDATE< @FEndDate2) OR Cccc.F_correlation = '1' SELECT A.FID, A.FSALEORGID AS '组织', A.FDATE AS '日期', K.FNAME AS '客户', MONTH(A.FDATE) AS '月份', --月份 ISNULL(ACO.区域,AW1.区域) AS [所属区域] ,ISNULL(O.FNAME,W1.FNAME) AS [销售员], (SELECT FNAME FROM T_BD_CUSTOMER_L WHERE FCUSTID = A.FCustId) AS '购货单位', --购货单位 A.FAPPROVEDATE AS '签订日期', --签订日期 A.F_contractnumber AS '订单号', --订单号 C.FNAME AS '产品名称', --产品名称 C.FNUMBER AS '产品编号', --产品名称 C.FSPECIFICATION AS '型号规格标准', --型号\规格\标准 A.F_contractnumber+C.FSPECIFICATION AS '订单号型号规格标准', CASE WHEN C.F_114 IS NOT NULL AND C.F_114 !=' ' AND C.F_114 !='' THEN C.F_114 WHEN W8.FNUMBER IN ('E','ES','NWE','HKE') THEN '储能、微电风、光储充剩余部分' WHEN W8.FNUMBER IN ('B','BS') THEN 'BMS产品线剩余部分' WHEN W8.FNUMBER IN ('C','CS','CW','CY') THEN '充电桩剩余部分' WHEN W8.FNUMBER NOT IN ('E','ES','NWE','HKE','BS') THEN '' ELSE C.F_114 END AS '型号分类', CASE WHEN C.F_115 IS NOT NULL AND C.F_115 !=' ' AND C.F_115 !='' THEN C.F_115 WHEN W8.FNUMBER IN ('E','ES','NWE','HKE') THEN '储能、微电风、光储充剩余部分' WHEN W8.FNUMBER IN ('C','CS','CW','CY') THEN '充电桩剩余部分' WHEN W8.FNUMBER IN ('B','BS') THEN 'BMS产品线剩余部分' WHEN W8.FNUMBER NOT IN ('E','ES','NWE','HKE','BS') THEN '' ELSE C.F_115 END AS '产品分类', CASE WHEN C.F_116 IS NOT NULL AND C.F_116 !=' ' AND C.F_116 !='' THEN C.F_116 WHEN W8.FNUMBER IN ('E','ES','NWE','HKE') THEN '储能、微电风、光储充' WHEN W8.FNUMBER IN ('C','CS','CW','CY') THEN '充电桩业务' WHEN W8.FNUMBER IN ('B','BS') THEN 'BMS产品线' WHEN W8.FNUMBER NOT IN ('E','ES','NWE','HKE','BS') THEN '' ELSE C.F_116 END AS '产品线', CASE WHEN A.F_VRYF_COMBO_LSN = 'DDXS' THEN '单独销售' WHEN A.F_VRYF_COMBO_LSN = 'SXTXS' THEN '随系统销售' WHEN A.F_VRYF_COMBO_LSN = 'XTZHT' THEN '系统主合同' ELSE '' END AS '销售类型', CASE WHEN W5.FDATAVALUE = '仪表' THEN '单独销售' ELSE '随系统销售' END AS '销售类型1', CASE WHEN N.FSHARERATE IS NOT NULL THEN CASE WHEN ROW_NUMBER() OVER (PARTITION BY A.FID, B.FENTRYID ORDER BY N.FENTRYID) = 1 THEN CAST(B.FQTY AS REAL) ELSE NULL END ELSE CAST(B.FQTY AS REAL) END AS '数量台' , ISNULL(BB.FTaxPrice,0) AS '单价元台', --单价元/台 CASE WHEN n.FSHARERATE IS NULL THEN ROUND(BB.FALLAMOUNT_LC,2) ELSE ROUND( BB.FALLAMOUNT_LC * (n.FSHARERATE/100) ,2) END AS '合同总价' --业绩分摊只分摊金额不分摊数量,分录【价税合计本位币】*业绩分摊单中的分摊比例 ,CASE WHEN ROW_NUMBER() OVER (PARTITION BY A.FID ORDER BY A.FID, B.FENTRYID ,FSHARERATE DESC) = 1 THEN CAST(j.FBILLALLAMOUNT_LC AS NUMERIC(18,2)) ELSE NULL END AS '订单总额' , CASE WHEN ROW_NUMBER() OVER (PARTITION BY A.FID, B.FENTRYID ORDER BY N.FENTRYID) = 1 THEN (SELECT FStockOutQty FROM T_SAL_ORDERENTRY_R WHERE FENTRYID = B.FENTRYID) ELSE NULL END AS '已交货数', --已交货数 CASE WHEN ROW_NUMBER() OVER (PARTITION BY A.FID, B.FENTRYID ORDER BY N.FENTRYID) = 1 THEN B.FQty-(SELECT FStockOutQty FROM T_SAL_ORDERENTRY_R WHERE FENTRYID = B.FENTRYID) ELSE NULL END AS '未交货数', --未交货数 CASE WHEN (D.FOPENSTATUS)= 'A' THEN '未开' WHEN (D.FOPENSTATUS)= 'B' THEN '部分' WHEN (D.FOPENSTATUS)= 'C' THEN '完全' ELSE '' END AS '开票情况', --开票情况 (SELECT FNAME FROM T_BAS_PREBDONE_L WHERE FID = A.F_projectname) AS '项目名称', --项目名称 CASE WHEN --项目所属1 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 1 THEN '建筑楼宇' WHEN --项目所属2 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 2 THEN '医疗卫生' WHEN --项目所属3 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 3 THEN '学校' WHEN --项目所属4 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 4 THEN '文娱康乐' WHEN --项目所属5 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 5 THEN '市政工程' WHEN --项目所属6 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 6 THEN '能源' WHEN --项目所属7 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 7 THEN '工业' WHEN --项目所属8 (SELECT aq.F_Projectfield FROM T_BAS_PREBDTHREE aq JOIN T_BAS_PREBDTHREE_L aw ON aq.FID = aw.FID WHERE aq.FID = A.F_BON) = 8 THEN '交通运输' ELSE '' END AS '项目所属领域', --项目所属领域 CASE WHEN --集采业务分类 A.F_PurchasingPro = 'LH' THEN '龙湖' WHEN --集采业务分类 A.F_PurchasingPro = 'BL' THEN '保利地产' WHEN --集采业务分类 A.F_PurchasingPro = 'HR' THEN '华润' WHEN --集采业务分类 A.F_PurchasingPro = 'N' THEN '否' WHEN --集采业务分类 A.F_PurchasingPro = 'HEF' THEN '华润非集采' WHEN --集采业务分类 A.F_PurchasingPro = 'LD' THEN '绿地' ELSE '' END AS '集采业务分类', --集采业务分类 LH=龙湖,BL=保利地产,HR=华润,N=否,HEF=华润非集采,LD=绿地 CASE WHEN A.FBUSINESSTYPE = 'VMI' THEN 'VMI业务' WHEN A.FBUSINESSTYPE = 'DRPTRANS' THEN '分销调拨' WHEN A.FBUSINESSTYPE = 'STRAIGHT' THEN '直运销售' WHEN A.FBUSINESSTYPE = 'CONSIGNMENT' THEN '寄售' WHEN A.FBUSINESSTYPE = 'NORMAL' THEN '普通销售' WHEN A.FBUSINESSTYPE = 'DRPSALE' THEN '分销购销' WHEN A.FBUSINESSTYPE = 'RETURNSO' THEN '退货订单' ELSE '' END AS '业务类型-按产品划分', CASE WHEN (SELECT F_Authorization FROM T_BD_CUSTOMER WHERE FCUSTID = A.FCustId) = 'Y' THEN '代理商' WHEN (SELECT F_Authorization FROM T_BD_CUSTOMER WHERE FCUSTID = A.FCustId) = 'N' THEN '直销' ELSE '' END AS '直销经销商', CASE WHEN B.F_SPECIALOFFER = 0 THEN '否' WHEN B.F_SPECIALOFFER = 1 THEN '是' ELSE '' END AS '是否特价', CASE WHEN W6.FNAME = '产品线' OR W6.FNAME = '充电桩团队' OR W6.FNAME = '三电产品线' THEN '产品线' WHEN W6.FNAME = '数据中心' OR W6.FNAME = '医院行业线' THEN '行业线' ELSE '区域线' END AS '业绩类型', ISNULL(AW1.区域,'') AS 'SBU', (SELECT wa.FDATAVALUE FROM T_BAS_ASSISTANTDATAENTRY aw JOIN T_BAS_ASSISTANTDATAENTRY_L wa ON aw.FENTRYID = wa.FENTRYID WHERE wa.FENTRYID = (SELECT F_CreditClassification FROM T_BD_CUSTOMER WHERE FCUSTID = A.FCustId) AND FDocumentStatus = 'C' AND FFORBIDSTATUS = 'A') AS '客户性质', --客户性质 ISNULL(B.F_PROJECTPROPOSAL,'') AS '项目方案类型', --新增字段 ISNULL(W7.F_Province,'') AS '项目所属省份', --新增字段 CASE WHEN A.F_ORDERTYPE = 'YB' THEN '仪表' WHEN A.F_ORDERTYPE = 'XT' THEN '系统' ELSE '' END AS '表计或系统' --新增字段 ,CASE WHEN N.FSHARERATE IS NULL THEN '100' ELSE CONCAT( CAST ( N.FSHARERATE AS REAL),'%') END AS '业绩分摊比例' --销售订单-业绩分摊单-分摊比例 ,CONVERT(DECIMAL(18,2),0) AS 分摊金额 ,0 rownum ,b.FENTRYID INTO #TABLEAAA FROM T_SAL_ORDER A JOIN T_SAL_ORDERENTRY B ON B.FID = A.FID INNER JOIN T_SAL_ORDERFIN J ON J.FID= A.FID LEFT JOIN T_PerformanceSharing M WITH(NOLOCK) ON M.FSOURCEBILLNO = A.FBILLNO AND M.FDOCUMENTSTATUS = 'C' LEFT JOIN (SELECT FID,FENTRYID,FSALEID,CASE WHEN ISNULL(F_res,'')='' THEN NULL ELSE F_res END AS F_res,FSHARERATE FROM T_PerformanceSharingEntry N WITH(NOLOCK) ) N ON N.FID=M.FID LEFT JOIN V_BD_SALESMAN_L O WITH(NOLOCK) ON O.fid= N.FSALEID JOIN T_SAL_ORDERENTRY_F BB ON B.FENTRYID = BB.FENTRYID LEFT JOIN T_ORG_ORGANIZATIONS_L AB ON AB.FORGID = A.FSALEORGID LEFT JOIN V_BD_SALESMAN_L W1 ON W1.fid = A.FSALERID --销售员 LEFT JOIN (SELECT 名称,区域,明细区域 FROM ERPTOHR.HYHRV3.dbo.v_erp_empinfo WHERE ISNULL(明细区域,'')!='' AND ISNULL(区域,'')!='' GROUP BY 名称,区域,明细区域) AW1 ON W1.FNAME = AW1.名称-- AND ISNULL(AW1.明细区域,'') != '' --视图 LEFT JOIN (SELECT DISTINCT ACO22.名称,ACO22.明细区域,ACO22.区域 FROM ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO22 ) ACO ON ACO.名称=ISNULL(N.F_res,O.FNAME) AND ISNULL(ACO.明细区域,'') != '' LEFT JOIN T_BD_DEPARTMENT_L W6 ON A.FSaleDeptId = W6.FDEPTID --所属区域 LEFT JOIN T_BAS_PREBDTHREE W7 ON W7.FID = A.F_BON --商机 LEFT JOIN T_BD_CUSTOMER_L K ON A.FCUSTID = K.FCUSTID --客户 LEFT JOIN (SELECT FNumber,FENTRYID FROM T_BAS_ASSISTANTDATAENTRY WHERE FID = '670cc977263353') W8 --合同类型 ON W8.FENTRYID = A.F_ORDERCATEGORY LEFT JOIN (SELECT a2.FDATAVALUE,a2.FENTRYID FROM T_BAS_ASSISTANTDATAENTRY a1 JOIN T_BAS_ASSISTANTDATAENTRY_L a2 ON a1.FENTRYID = a2.FENTRYID WHERE a1.FID = '670cc977263353') W5 ON W5.FENTRYID = A.F_ORDERCATEGORY LEFT JOIN (SELECT aq.FNUMBER,aq.F_114,aq.F_115,aq.FMATERIALID,qa.FNAME,aq.F_XHDL,aq.F_116,qa.FSpecification FROM T_BD_MATERIAL aq LEFT JOIN T_BD_MATERIAL_L qa ON aq.FMATERIALID = qa.FMATERIALID) C --获取物料名称 ON B.FMaterialId = C.FMATERIALID LEFT JOIN (Select a1.FORDERNUMBER,MAX(a1.FOPENSTATUS)'FOPENSTATUS' From T_AR_RECEIVABLEENTRY a1 JOIN T_AR_RECEIVABLE a2 on a1.FID = a2.FID Where ISNULL(a1.FORDERNUMBER,'') != '' AND a2.FDOCUMENTSTATUS = 'C' GROUP BY FORDERNUMBER) D on A.FBILLNO = D.FORDERNUMBER --条件 Where A.FDocumentStatus = 'C' AND A.FMANUALCLOSE != '1' AND W8.FNumber !='Z' AND A.FID NOT IN (SELECT * FROM #TEMP3) AND (ISNULL(@FSaleOrgId,'') = '' or AB.FNAME = @FSaleOrgId) AND (ISNULL(@FCZZHTH,'') = '' or A.F_contractnumber like '%'+@FCZZHTH+'%') AND (ISNULL(@FStartDate2,'') = '' or A.FAPPROVEDATE >= @FStartDate2) AND (ISNULL(@FEndDate2,'') = '' or A.FAPPROVEDATE < DATEADD(DAY, 1, CONVERT(DATE, @FEndDate2))) UPDATE #TABLEAAA SET 分摊金额=b.合同总价2 FROM (SELECT SUM(CONVERT(DECIMAL(18,2),合同总价)) AS 合同总价2 ,FID FROM #TABLEAAA GROUP BY FID) b WHERE #TABLEAAA.FID=b.FID AND 订单总额 <>0 UPDATE #TABLEAAA SET rownum=b.rownum2 FROM (SELECT ROW_NUMBER() OVER (PARTITION BY FID ORDER BY FID,FENTRYID) AS rownum2, FID, FENTRYID FROM #TABLEAAA ) b WHERE #TABLEAAA.FID=b.FID AND #TABLEAAA.FENTRYID=b.FENTRYID UPDATE #TABLEAAA SET 合同总价=合同总价+(订单总额- 分摊金额 ) WHERE 订单总额<>0 --UPDATE #TABLEAAA SET Select * From #TABLEAAA