Piolot_RepotForm_PeiHao/新条件.sql
李狗蛋 69cf26105d 0
2025-03-14 10:00:24 +08:00

97 lines
7.6 KiB
Transact-SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

Drop Table #TABLETMEP1
Drop Table #TABLETMEP2
go--------------------
Select
CASE WHEN ISNULL(X2.FNAME,'') = '' THEN S.区域 ELSE S2.区域 END as 'SBU',--部门SBU
CASE WHEN ISNULL(X2.FNAME,'') = '' THEN S.明细区域 ELSE S2.明细区域 END as 'DetailArea',--区域明细
G.GFNAME as 'GName', --职位名称
CASE WHEN ISNULL(X2.FNAME,'') = '' THEN X.FNAME ELSE X2.FNAME END as 'Salesperson', --销售员
ISNULL(G2.FSTARTDATE,'') as 'RDate',--入司时间
ISNULL(G.FSTARTDATE,'') as 'ZWDate', --担任本职位日期
CASE WHEN ISNULL(G3.FSTARTDATE,'')='' THen null ELSE ISNULL(G3.FSTARTDATE,'') END as 'XSDate',--担任销售日期
ROUND((DATEDIFF(DAY, ISNULL(G2.FSTARTDATE,''), GETDATE()) / 365.0), 1) as 'RZYear',--入职年限
--ISNULL(Y2.FSHARERATE,100) as 'FSHARERATE', --分摊比例
ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0) as 'CliqueBG',--派诺集团-已进行集团业绩调整(含往年订单变更)
CASE WHEN A.FSaleOrgId = 100302 THEN ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0) ELSE null END as 'PNBG',--派诺业绩(含往年订单变更)
CASE WHEN A.FSaleOrgId = 100303 THEN (ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0)) ELSE null END as 'XNBG',--兴诺业绩(含往年订单变更) *(ISNULL(Y2.FSHARERATE,100)/100)
CASE WHEN A.FSaleOrgId = 100305 THEN (ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0)) ELSE null END as 'WHPNBG',--武汉派诺业绩(含往年订单变更) *(ISNULL(Y2.FSHARERATE,100)/100)
CASE WHEN A.FSaleOrgId = 438223 THEN (ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0)) ELSE null END as 'TSBG',--碳索业绩(含往年订单变更) *(ISNULL(Y2.FSHARERATE,100)/100)
CASE WHEN A.FSaleOrgId = 438224 THEN (ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0)) ELSE null END as 'XGPNBG',--香港派诺业绩(含往年订单变更) *(ISNULL(Y2.FSHARERATE,100)/100)
CASE WHEN A.FSaleOrgId = 533896 THEN (ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0)) ELSE null END as 'HXYLBG',--华夏云联业绩(含往年订单变更) *(ISNULL(Y2.FSHARERATE,100)/100)
CASE WHEN YEAR(A.FDATE) = 2025 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'DNLJYJ',--当年累计业绩
CASE WHEN YEAR(A.FDATE)<2025 THEN ISNULL(A.F_AMOUNTSTAR,0)-ISNULL(B.FBILLALLAMOUNT_LC,0) ELSE null END as 'WNBGHTE',--往年变更合同额(派诺+兴诺+武兴派诺)
ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) as 'JTHKHJ',--集团回款合计
CASE WHEN A.FSaleOrgId = 100302 THEN ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) ELSE null END as 'PNLJHKE',--派诺累计回款额
CASE WHEN A.FSaleOrgId = 100303 THEN ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) ELSE null END as 'XNLJHKE',--兴诺累计回款额
CASE WHEN A.FSaleOrgId = 100305 THEN ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) ELSE null END as 'WHPNLJHKE',--武汉派诺累计回款额
CASE WHEN A.FSaleOrgId = 438223 THEN ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) ELSE null END as 'GDTSLJHKE',--广东碳索累计回款额
CASE WHEN A.FSaleOrgId = 438224 THEN ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) ELSE null END as 'XGPNLJHKE',--香港派诺累计回款额
CASE WHEN A.FSaleOrgId = 533896 THEN ISNULL(H.FALLAMOUNT,0)-ISNULL(C.FREALREFUNDAMOUNT,0) ELSE null END as 'HXYLLJHKE',--华夏云联累计回款额
ISNULL(G4.FPERFORMANCETARGETS,0) as 'XXSMB',--2024年销售目标-新
CASE WHEN ISNULL(G4.FPERFORMANCETARGETS,0) = 0 THEN 0 ELSE ROUND((ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100)/ISNULL(G4.FPERFORMANCETARGETS,0),2) END as 'DBL1',--2024年达成率不含往年订单变更
ISNULL(G4.FPERFORMANCETARGETS,0) as 'YXSMB',--2024年销售目标-原
CASE WHEN ISNULL(G4.FPERFORMANCETARGETS,0) = 0 THEN 0 ELSE ROUND((ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100)/ISNULL(G4.FPERFORMANCETARGETS,0),2) END as 'DBL2',--2024年达成率不含往年订单变更)
ISNULL(G4.FPERFORMANCETARGETS,0)-ISNULL(G4.FPERFORMANCETARGETS,0) as 'MBTZJE',--目标调整金额
CASE WHEN YEAR(A.FDATE) = 2024 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'NDXSE1',--2024年度销售额
CASE WHEN YEAR(A.FDATE) = 2023 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'NDXSE2',--2023年度销售额
CASE WHEN YEAR(A.FDATE) = 2022 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'NDXSE3',--2022年度销售额
CASE WHEN YEAR(A.FDATE) = 2021 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'NDXSE4',--2021年度销售额
CASE WHEN YEAR(A.FDATE) = 2020 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'NDXSE5',--2020年度销售额
CASE WHEN YEAR(A.FDATE) = 2019 THEN ISNULL(B.FBILLALLAMOUNT_LC,0)*ISNULL(Y2.FSHARERATE,100)/100 ELSE 0 END as 'NDXSE6'--2019年度销售额
INTO #TABLETMEP1
From
T_SAL_ORDER A --销售订单
LEFT JOIN
T_SAL_ORDERFIN B on A.FID = B.FID
LEFT JOIN
V_BD_SALESMAN_L X on X.fid = A.FSALERID
LEFT JOIN --收款退款单
T_AR_REFUNDBILL C on C.F_VRYF_TEXT_83G = A.F_CONTRACTNUMBER
LEFT JOIN
T_PerformanceSharing Y on Y.FSOURCEBILLNO = A.FBILLNO
LEFT JOIN
T_PerformanceSharingEntry Y2 on Y2.FID = Y.FID
LEFT JOIN
V_BD_SALESMAN_L X2 on Y2.FSALEID = X2.fid
LEFT JOIN
ERPTOHR.HYHRV3.dbo.v_erp_empinfo S on X.FNAME = S.名称
LEFT JOIN
ERPTOHR.HYHRV3.dbo.v_erp_empinfo S2 on X2.FNAME = S2.名称
LEFT JOIN
(Select a1.FNAME,a2.*,a3.FNAME as 'GFNAME' From T_HR_EMPINFO_L a1 JOIN T_BD_STAFFTEMP a2 on a1.FID = a2.FID
LEFT JOIN T_ORG_POST_L a3 on a2.FPOSTID = a3.FPOSTID
Where a2.FENTRYID in (Select * From V_User_FID_GW)) G on G.FNAME = (CASE WHEN ISNULL(X2.FNAME,'') = '' THEN X.FNAME ELSE X2.FNAME END)
LEFT JOIN --获取入司时间
V_User_FID_GW2 G2 on G2.FNAME = (CASE WHEN ISNULL(X2.FNAME,'') = '' THEN X.FNAME ELSE X2.FNAME END)
LEFT JOIN --获取销售任刚时间
V_User_FID_GW3 G3 on G3.FNAME = (CASE WHEN ISNULL(X2.FNAME,'') = '' THEN X.FNAME ELSE X2.FNAME END)
LEFT JOIN--业绩目标回款表
(Select a2.FPERFORMANCETARGETS,a2.FPAYMENTSUM,a3.FNAME From MBBA_t_Cust100002 a1 JOIn MBBA_t_Cust_Entry100003 a2 on a1.FID = a2.FID
JOIN V_BD_SALESMAN_L a3 on a2.FNAME = a3.fid Where a1.FDOCUMENTSTATUS = 'C' AND F_MBBA_Combo_qtr = '2025')
G4 on G4.FNAME = (CASE WHEN ISNULL(X2.FNAME,'') = '' THEN X.FNAME ELSE X2.FNAME END)
LEFT JOIN
(Select a2.FBILLNO2,CASE WHEN ISNULL(a2.FALLAMOUNT2,0)>ISNULL(b1.FALLAMOUNT3,0) THEN ISNULL(b1.FALLAMOUNT3,0)
ELSE ISNULL(a2.FALLAMOUNT2,0) END as 'FALLAMOUNT' From T_AutoWrireRecord a1
JOIN T_AutoWrireRecordEntry a2 on a1.FID = a2.FID
LEFT JOIN
(Select a1.FID,SUM(CAST(a2.FALLAMOUNT3 as DECIMAL(10,2))) as 'FALLAMOUNT3' From T_AutoWrireRecord a1
JOIN T_AutoWrireRecordEntry2 a2 on a1.FID = a2.FID
Where a1.FDOCUMENTSTATUS = 'C' AND Year(a2.FDATE3) = '2025'
GROUP BY a1.FID) b1 on b1.FID = a1.FID
Where a1.FDOCUMENTSTATUS = 'C') H on H.FBILLNO2 = A.FBILLNO
Where A.FDOCUMENTSTATUS = 'C' AND A.FDATE >= '2025-01-01' AND A.FDATE <= '2025-01-31'
AND ISNULL(X.FNAME,'') != ''
go--------------------------视图id
Select
SBU,DetailArea,GName,Salesperson,RDate,ZWDate,XSDate,RZYear,SUM(CliqueBG)/10000'CliqueBG',SUM(PNBG)/10000'PNBG',SUM(XNBG)/10000'XNBG',
SUM(WHPNBG)/10000'WHPNBG',SUM(TSBG)/10000'TSBG',SUM(XGPNBG)/10000'XGPNBG',SUM(HXYLBG)/10000'HXYLBG',SUM(DNLJYJ)/10000'DNLJYJ',SUM(WNBGHTE)/10000'WNBGHTE',SUM(JTHKHJ)/10000'JTHKHJ',SUM(PNLJHKE)/10000'PNLJHKE',
SUM(XNLJHKE)/10000'XNLJHKE',SUM(WHPNLJHKE)/10000'WHPNLJHKE',SUM(GDTSLJHKE)/10000'GDTSLJHKE',SUM(XGPNLJHKE)/10000'XGPNLJHKE',SUM(HXYLLJHKE)/10000'HXYLLJHKE',SUM(XXSMB)/10000'XXSMB',SUM(DBL1)/10000'DBL1',
SUM(YXSMB)/10000'YXSMB',SUM(DBL2)/10000'DBL2',SUM(MBTZJE)/10000'MBTZJE',SUM(NDXSE1)/10000'NDXSE1',SUM(NDXSE2)/10000'NDXSE2',SUM(NDXSE3)/10000'NDXSE3',SUM(NDXSE4)/10000'NDXSE4',SUM(NDXSE5)/10000'NDXSE5',SUM(NDXSE6)/10000'NDXSE6'
INTO #TABLETMEP2
From #TABLETMEP1 GROUP BY SBU,DetailArea,GName,Salesperson,RDate,ZWDate,XSDate,RZYear;
Select * From #TABLETMEP2
--SELECT distinct F_Papercontract FROM T_SAL_DELIVERYNOTICE WHERE F_SFYFH ='是'