644 lines
36 KiB
Transact-SQL
644 lines
36 KiB
Transact-SQL
|
||
|
||
ALTER PROCEDURE [dbo].[GZYJPHB_TH]
|
||
@FSDate NVARCHAR(50),
|
||
@FEDate NVARCHAR(50),
|
||
@FSaleOrgId nvarchar(1000)
|
||
AS
|
||
BEGIN
|
||
DECLARE @Year INT;
|
||
DECLARE @SixYearsAgoYear INT;
|
||
|
||
DECLARE @FEDateDate DATE = CAST(@FEDate AS DATE);
|
||
|
||
DECLARE @FSDateDate DATE = CAST(@FSDate AS DATE);
|
||
|
||
-- 结束日期加一天
|
||
set @FEDate = CASE @FEDate WHEN '' THEN '' ELSE FORMAT(DateAdd(DAY,1,CAST(@FEDate AS Date)),'yyyy-MM-dd') END
|
||
-- 提取年份
|
||
SET @Year = YEAR(@FSDate) - 1;
|
||
|
||
-- 计算六年前的年份
|
||
SET @SixYearsAgoYear = @Year - 6;
|
||
|
||
-- 创建变量来存储拆分后的值
|
||
DECLARE @SalesID NVARCHAR(50);
|
||
DECLARE @Pos INT;
|
||
DECLARE @FSaleOrgId1 NVARCHAR(50);
|
||
|
||
-- 初始化
|
||
SET @FSaleOrgId1 = LTRIM(RTRIM(@FSaleOrgId)) + ',';
|
||
SET @Pos = CHARINDEX(',', @FSaleOrgId1);
|
||
|
||
TRUNCATE TABLE SalesIDTable
|
||
-- 循环拆分字符串
|
||
WHILE @Pos > 0
|
||
BEGIN
|
||
SET @SalesID = SUBSTRING(@FSaleOrgId1, 1, @Pos - 1);
|
||
INSERT INTO SalesIDTable (SalesID) VALUES (@SalesID);
|
||
SET @FSaleOrgId1 = SUBSTRING(@FSaleOrgId1, @Pos + 1, LEN(@FSaleOrgId1));
|
||
SET @Pos = CHARINDEX(',', @FSaleOrgId1);
|
||
END
|
||
|
||
|
||
--清空表的数据
|
||
TRUNCATE TABLE YJPHB_GZTH
|
||
|
||
--过滤派诺总
|
||
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 D ON C.FCUSTID= D.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 1=1
|
||
--AND 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)
|
||
OR D.F_correlation = 1)
|
||
AND (ISNULL(@FSDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') > @FSDate)
|
||
AND (ISNULL(@FEDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd')< @FEDate)
|
||
|
||
--查询六年前的销售订单总额
|
||
SELECT
|
||
A.FSALEORGID AS '组织FID',
|
||
FORMAT(A.FDate,'yyyy') AS '年份',
|
||
CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.区域 ELSE ACO.区域 END AS '部门(SBU)',
|
||
CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.明细区域 ELSE ACO.明细区域 END AS '区域明细',
|
||
CASE WHEN ISNULL(O.FNAME,'')='' THEN L.FNAME ELSE O.FNAME END AS '销售员',
|
||
CASE WHEN n.FSHARERATE IS NULL THEN ROUND(F.FALLAMOUNT_LC,10)
|
||
ELSE ROUND( F.FALLAMOUNT_LC * (n.FSHARERATE/100) ,10) END as '订单业绩'
|
||
INTO #SixYearEMP1
|
||
FROM T_SAL_ORDER A --销售订单表头
|
||
INNER JOIN T_SAL_orderentry b on a.FID = B.FID --销售订单表体
|
||
INNER JOIN T_SAL_ORDERENTRY_F F ON F.FENTRYID = B.FENTRYID
|
||
INNER JOIN T_SAL_ORDERENTRY_R AR ON AR.FENTRYID = B.FENTRYID
|
||
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 AND ISNULL(ACO.明细区域,'') != ''
|
||
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=L.FNAME AND ISNULL(ACL.明细区域,'') != ''
|
||
WHERE 1=1
|
||
AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
AND(@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
AND (ISNULL(@FSDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy') >= @SixYearsAgoYear)
|
||
AND (ISNULL(@FEDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy') <= @Year)
|
||
AND A.FDocumentStatus = 'C'
|
||
AND A.FManualClose <> '1'
|
||
AND B.FManualRowClose <> '1'
|
||
AND A.F_contractnumber NOT LIKE 'Z%'
|
||
|
||
----全组织根据日期显示订单金额
|
||
-- SELECT
|
||
-- A.FSALEORGID AS '组织FID',
|
||
-- CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.区域 ELSE ACO.区域 END AS '部门(SBU)',
|
||
-- CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.明细区域 ELSE ACO.明细区域 END AS '区域明细',
|
||
-- CASE WHEN ISNULL(O.FNAME,'')='' THEN L.FNAME ELSE O.FNAME END AS '销售员',
|
||
-- CASE WHEN n.FSHARERATE IS NULL THEN ROUND(F.FALLAMOUNT_LC,10)
|
||
-- ELSE ROUND( F.FALLAMOUNT_LC * (n.FSHARERATE/100) ,10) END as '订单业绩'
|
||
-- INTO #TEMP1
|
||
-- FROM T_SAL_ORDER A --销售订单表头
|
||
-- INNER JOIN T_SAL_orderentry b on a.FID = B.FID --销售订单表体
|
||
-- INNER JOIN T_SAL_ORDERENTRY_F F ON F.FENTRYID = B.FENTRYID
|
||
-- INNER JOIN T_SAL_ORDERENTRY_R AR ON AR.FENTRYID = B.FENTRYID
|
||
-- 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 AND ISNULL(ACO.明细区域,'') != ''
|
||
-- LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=L.FNAME AND ISNULL(ACL.明细区域,'') != ''
|
||
-- WHERE 1=1
|
||
-- AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
-- AND(@FSaleOrgId = '' Or A.FSALEORGID IN(SELECT SalesID FROM SalesIDTable))
|
||
-- AND (ISNULL(@FSDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') >= @FSDate)
|
||
-- AND (ISNULL(@FEDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') < @FEDate)
|
||
-- AND A.FDocumentStatus = 'C'
|
||
-- AND A.FManualClose <> '1'
|
||
-- AND B.FManualRowClose <> '1'
|
||
-- AND A.F_contractnumber NOT LIKE 'Z%'
|
||
|
||
-- --查询全组织的订单变更金额
|
||
-- SELECT
|
||
-- A.FSaleOrgId AS '组织FID'
|
||
-- ,CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.区域 ELSE ACO.区域 END AS '部门(SBU)'
|
||
-- ,CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.明细区域 ELSE ACO.明细区域 END AS '区域明细'
|
||
-- ,CASE WHEN ISNULL(O.FNAME,'')='' THEN XS_L.FNAME
|
||
-- ELSE O.FNAME END AS '销售员'
|
||
-- ,CAST(AN.FBillAllAmount_LC - A.F_Amountstar AS DECIMAL(20, 10)) AS '变更金额'
|
||
-- ,A.F_CONTRACTNUMBER as '纸质合同号'
|
||
-- ,A.fbillno as '销售订单号'
|
||
-- INTO #BGTEMP1
|
||
-- FROM T_SAL_ORDER A
|
||
-- LEFT JOIN T_SAL_ORDERFIN AN ON A.FID = AN.FID --关联销售订单财务明细,获取变更后合同金额
|
||
-- LEFT JOIN V_BD_SALESMAN XS ON XS.fid = A.FSalerId
|
||
-- LEFT JOIN V_BD_SALESMAN_L XS_L ON XS_L.fid = XS.fid --关联销售员数据模型,获取销售员名称
|
||
-- 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 AND ISNULL(ACO.明细区域,'') != ''
|
||
-- LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=XS_L.FNAME AND ISNULL(ACL.明细区域,'') != ''
|
||
-- INNER JOIN T_SEC_USER TU ON A.FChangerId = TU.FUSERID -- 用户单关联表体,获取变更人人
|
||
-- WHERE 1=1
|
||
-- AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
-- AND(@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
-- AND (ISNULL(@FSDate,'') = '' OR FORMAT(A.FCHANGEDATE,'yyyy-MM-dd') >= @FSDate)
|
||
-- AND (ISNULL(@FSDate,'') = '' OR FORMAT(A.FCHANGEDATE,'yyyy-MM-dd') < @FEDate)
|
||
-- --AND FORMAT(A.FDATE,'yyyy') != FORMAT(A.FCHANGEDATE,'yyyy')
|
||
-- AND A.F_contractnumber NOT LIKE 'Z%'
|
||
-- AND A.FManualClose <> '1'
|
||
-- AND (A.F_HSYJ <> '0' OR FORMAT(A.F_HSRQ,'yyyy') != FORMAT(A.FChangeDate,'yyyy'))
|
||
-- AND TU.FNAME NOT LIKE 'ERP%' AND TU.FNAME NOT LIKE '13570668909'
|
||
|
||
|
||
/*时间段内最后一个版本的变更单,且原单为今年审核 */
|
||
SELECT ROW_NUMBER() OVER(PARTITION BY FPKIDX ORDER BY AL.FCHANGEDATE DESC) AS 'rn',
|
||
AL.FID
|
||
INTO #TEMP5
|
||
FROM T_SAL_XORDER AL
|
||
INNER JOIN T_SAL_ORDER A ON A.FID = AL.FPKIDX
|
||
INNER JOIN T_SEC_USER TU ON AL.FCHANGERID = TU.FUSERID -- 用户单关联表体,获取变更人人
|
||
WHERE 1=1
|
||
AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
AND(@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
AND (ISNULL(@FSDate,'') = '' OR FORMAT(AL.FCHANGEDATE,'yyyy-MM-dd') >= @FSDate)
|
||
AND (ISNULL(@FSDate,'') = '' OR FORMAT(AL.FCHANGEDATE,'yyyy-MM-dd') < @FEDate)
|
||
AND (ISNULL(@FSDate,'') = '' OR FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') >= FORMAT(CAST(@FSDate AS DATE),'yyyy-01-01'))
|
||
AND A.F_contractnumber NOT LIKE 'Z%'
|
||
AND AL.FDOCUMENTSTATUS = 'C'
|
||
AND A.FManualClose <> '1'
|
||
AND (A.F_HSYJ <> '0' OR FORMAT(A.F_HSRQ,'yyyy') != FORMAT(A.FChangeDate,'yyyy'))
|
||
AND TU.FNAME NOT LIKE 'ERP%' AND TU.FNAME NOT LIKE '13570668909'
|
||
|
||
DELETE FROM #TEMP5 WHERE rn > 1
|
||
|
||
--查询全组织的当前时间段最后版本订单变更后金额,且原单为今年审核
|
||
SELECT
|
||
A.FSaleOrgId AS '组织FID'
|
||
,CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.区域 ELSE ACO.区域 END AS '部门(SBU)'
|
||
,CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.明细区域 ELSE ACO.明细区域 END AS '区域明细'
|
||
,CASE WHEN ISNULL(O.FNAME,'')='' THEN XS_L.FNAME
|
||
ELSE O.FNAME END AS '销售员'
|
||
,CASE WHEN n.FSHARERATE IS NULL THEN CAST(ROUND(AN.FBillAllAmount_LC, 2) AS DECIMAL(20,10))
|
||
ELSE CAST(ROUND(AN.FBillAllAmount_LC * (n.FSHARERATE/100),2) AS DECIMAL(20, 10)) END AS '订单业绩'
|
||
--,CAST(AN.FBillAllAmount_LC AS DECIMAL(20, 10)) AS '订单业绩'
|
||
,A.F_CONTRACTNUMBER AS '纸质合同号'
|
||
,A.fbillno AS '销售订单号'
|
||
,AL.FPKIDX AS '销售订单FID'
|
||
INTO #TEMP4
|
||
FROM T_SAL_XORDER AL
|
||
--LEFT JOIN T_SAL_ORDERFIN AN ON A.FID = AN.FID --关联销售订单财务明细,获取变更后合同金额
|
||
LEFT JOIN T_SAL_ORDER A ON A.FID = AL.FPKIDX
|
||
LEFT JOIN T_SAL_XORDERFIN AN ON AN.FID = AL.FID --关联销售新变更单财务信息,获取变更后合同金额
|
||
LEFT JOIN V_BD_SALESMAN XS ON XS.fid = A.FSalerId
|
||
LEFT JOIN V_BD_SALESMAN_L XS_L ON XS_L.fid = XS.fid --关联销售员数据模型,获取销售员名称
|
||
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 AND ISNULL(ACO.明细区域,'') != ''
|
||
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=XS_L.FNAME AND ISNULL(ACL.明细区域,'') != ''
|
||
INNER JOIN T_SEC_USER TU ON A.FChangerId = TU.FUSERID -- 用户单关联表体,获取变更人人
|
||
WHERE 1=1
|
||
AND AL.FDOCUMENTSTATUS = 'C'
|
||
AND AL.FID IN (SELECT FID FROM #TEMP5)
|
||
|
||
SELECT *
|
||
INTO #TEMP1 FROM(
|
||
--当前时间段最后版本的变更单变更后
|
||
SELECT * FROM #TEMP4
|
||
UNION ALL
|
||
--当前时间段无变更的订单
|
||
SELECT
|
||
A.FSALEORGID AS '组织FID',
|
||
CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.区域 ELSE ACO.区域 END AS '部门(SBU)',
|
||
CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.明细区域 ELSE ACO.明细区域 END AS '区域明细',
|
||
CASE WHEN ISNULL(O.FNAME,'')='' THEN L.FNAME ELSE O.FNAME END AS '销售员',
|
||
CASE WHEN n.FSHARERATE IS NULL THEN CAST(ROUND(F.FALLAMOUNT_LC, 2) AS DECIMAL(20,10))
|
||
ELSE CAST(ROUND( F.FALLAMOUNT_LC * (n.FSHARERATE/100) ,2) AS DECIMAL(20,10)) END as '订单业绩'
|
||
--,CASE WHEN n.FSHARERATE IS NULL THEN 0 ELSE ROUND( F.FALLAMOUNT_LC * (n.FSHARERATE/100) ,10) END as '分摊金额'
|
||
--,CASE WHEN n.FSHARERATE IS NULL THEN ROUND(F.FALLAMOUNT_LC,10) ELSE 0 END as '无分摊金额'
|
||
,A.F_CONTRACTNUMBER as '纸质合同号'
|
||
,A.fbillno as '销售订单号'
|
||
,A.FID as '销售订单FID'
|
||
FROM T_SAL_ORDER A --销售订单表头
|
||
INNER JOIN T_SAL_orderentry b on a.FID = B.FID --销售订单表体
|
||
INNER JOIN T_SAL_ORDERENTRY_F F ON F.FENTRYID = B.FENTRYID
|
||
INNER JOIN T_SAL_ORDERENTRY_R AR ON AR.FENTRYID = B.FENTRYID
|
||
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 AND ISNULL(ACO.明细区域,'') != ''
|
||
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=L.FNAME AND ISNULL(ACL.明细区域,'') != ''
|
||
WHERE 1=1
|
||
AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
AND A.FID NOT IN(SELECT 销售订单FID FROM #TEMP4)
|
||
AND(@FSaleOrgId = '' Or A.FSALEORGID IN(SELECT SalesID FROM SalesIDTable))
|
||
AND (ISNULL(@FSDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') >= @FSDate)
|
||
AND (ISNULL(@FEDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') < @FEDate)
|
||
AND A.FDocumentStatus = 'C'
|
||
AND A.FManualClose <> '1'
|
||
AND B.FManualRowClose <> '1'
|
||
AND A.F_contractnumber NOT LIKE 'Z%'
|
||
) a
|
||
|
||
/*当年截至结束日期累记变更差额*/
|
||
SELECT AL.FID,
|
||
SUM(CAST((
|
||
ROUND((AM.FQTY * AB.FTAXPRICE - (ISNULL(AM.FQTY,0) * ISNULL(AB.FTAXPRICE,0) * ISNULL(AB.FDISCOUNTRATE,0))/ 100*ISNULL(AN.FEXCHANGERATE,0))/( 1+ FTAXRATE /100 ),2)
|
||
+ROUND(((ISNULL(AM.FQTY,0) * ISNULL(AB.FTAXPRICE,0) - (ISNULL(AM.FQTY,0) * ISNULL(AB.FTAXPRICE,0) * ISNULL(AB.FDISCOUNTRATE,0)/ 100))/( 1+ FTAXRATE /100 )* (FTAXRATE /100)* ISNULL(AN.FEXCHANGERATE,0) ),2)
|
||
-ROUND((AM.FQTYX * AB.FTAXPRICEX - (ISNULL(AM.FQTYX,0) * ISNULL(AB.FTAXPRICEX,0) * ISNULL(AB.FDISCOUNTRATEX,0))/ 100*ISNULL(AN.FEXCHANGERATE,0))/( 1+ FTAXRATEX /100 ),2)
|
||
-ROUND(((ISNULL(AM.FQTYX,0) * ISNULL(AB.FTAXPRICEX,0) - (ISNULL(AM.FQTYX,0) * ISNULL(AB.FTAXPRICEX,0) * ISNULL(AB.FDISCOUNTRATEX,0)/ 100))/( 1+ FTAXRATEX /100 )* (FTAXRATEX /100)* ISNULL(AN.FEXCHANGERATE,0) ),2)) AS DECIMAL(20, 10))) AS '变更金额'
|
||
INTO #TEMPCHANGEFIN
|
||
FROM T_SAL_XORDER AL
|
||
LEFT JOIN T_SAL_ORDER A ON A.FID = AL.FPKIDX
|
||
LEFT JOIN T_SAL_XORDERFIN AN ON AN.FID = AL.FID --关联销售新变更单财务信息,获取变更后合同金额
|
||
LEFT JOIN T_SAL_XORDERENTRY AM ON AM.FID = AL.FID
|
||
LEFT JOIN T_SAL_XORDERENTRY_F AB ON AB.FENTRYID = AM.FENTRYID
|
||
INNER JOIN T_SEC_USER TU ON AL.FCHANGERID = TU.FUSERID -- 用户单关联表体,获取变更人人
|
||
WHERE 1=1
|
||
AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
AND(@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
AND (ISNULL(@FSDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') < FORMAT(CAST(@FSDate AS DATE),'yyyy-01-01'))
|
||
AND (ISNULL(@FSDate,'') = '' OR FORMAT(AL.FCHANGEDATE,'yyyy-MM-dd') >= FORMAT(CAST(@FSDate AS DATE),'yyyy-01-01'))
|
||
AND (ISNULL(@FEDate,'') = '' or FORMAT(AL.FCHANGEDATE,'yyyy-MM-dd') < @FEDate)
|
||
AND A.FManualClose <> '1'
|
||
AND AL.FDOCUMENTSTATUS = 'C'
|
||
AND (A.F_HSYJ <> '0' OR FORMAT(A.F_HSRQ,'yyyy') != FORMAT(A.FChangeDate,'yyyy'))
|
||
AND TU.FNAME NOT LIKE 'ERP%' AND TU.FNAME NOT LIKE '13570668909'
|
||
GROUP BY AL.FID
|
||
|
||
SELECT
|
||
A.FSaleOrgId AS '组织FID'
|
||
,CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.区域 ELSE ACO.区域 END AS '部门(SBU)'
|
||
,CASE WHEN ISNULL(O.FNAME,'')='' THEN ACL.明细区域 ELSE ACO.明细区域 END AS '区域明细'
|
||
,CASE WHEN ISNULL(O.FNAME,'')='' THEN XS_L.FNAME
|
||
ELSE O.FNAME END AS '销售员'
|
||
,CASE WHEN n.FSHARERATE IS NULL THEN ROUND(AN.变更金额,2)
|
||
ELSE CAST(AN.变更金额 * (n.FSHARERATE/100) AS DECIMAL(10, 2)) END AS '变更金额'
|
||
,A.F_CONTRACTNUMBER as '纸质合同号'
|
||
,A.fbillno as '销售订单号'
|
||
,A.FID as '销售订单FID'
|
||
,AL.FBILLNO AS '变更单号'
|
||
INTO #BGTEMP1
|
||
FROM T_SAL_XORDER AL
|
||
--LEFT JOIN T_SAL_ORDERFIN AN ON A.FID = AN.FID --关联销售订单财务明细,获取变更后合同金额
|
||
LEFT JOIN T_SAL_ORDER A ON A.FID = AL.FPKIDX
|
||
LEFT JOIN #TEMPCHANGEFIN AN ON AL.FID = AN.FID
|
||
LEFT JOIN V_BD_SALESMAN XS ON XS.fid = A.FSalerId
|
||
LEFT JOIN V_BD_SALESMAN_L XS_L ON XS_L.fid = XS.fid --关联销售员数据模型,获取销售员名称
|
||
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 AND ISNULL(ACO.明细区域,'') != ''
|
||
LEFT JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACL ON ACL.名称=XS_L.FNAME AND ISNULL(ACL.明细区域,'') != ''
|
||
INNER JOIN T_SEC_USER TU ON AL.FCHANGERID = TU.FUSERID -- 用户单关联表体,获取变更人人
|
||
WHERE 1=1
|
||
AND A.FID NOT IN(SELECT FID FROM #TEMP3)
|
||
AND(@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
AND (ISNULL(@FEDate,'') = '' or FORMAT(A.FAPPROVEDATE,'yyyy-MM-dd') < FORMAT(CAST(@FSDate AS DATE),'yyyy-01-01'))
|
||
AND (ISNULL(@FSDate,'') = '' OR FORMAT(AL.FCHANGEDATE,'yyyy-MM-dd') >= FORMAT(CAST(@FSDate AS DATE),'yyyy-01-01'))
|
||
AND (ISNULL(@FEDate,'') = '' or FORMAT(AL.FCHANGEDATE,'yyyy-MM-dd') < @FEDate)
|
||
AND A.FManualClose <> '1'
|
||
AND AL.FDOCUMENTSTATUS = 'C'
|
||
AND (A.F_HSYJ <> '0' OR FORMAT(A.F_HSRQ,'yyyy') != FORMAT(A.FChangeDate,'yyyy'))
|
||
AND TU.FNAME NOT LIKE 'ERP%' AND TU.FNAME NOT LIKE '13570668909'
|
||
|
||
|
||
--插入派诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[派诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 WHERE [组织FID] = 100302 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入兴诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 WHERE [组织FID] = 100303 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入武汉派诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[武汉派诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 WHERE [组织FID] = 100305 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入广东碳索业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[广东碳索业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 WHERE [组织FID] = 438223 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入香港派诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[香港派诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 WHERE [组织FID] = 438224 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入华夏云联业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[华夏云联业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 WHERE [组织FID] = 533896 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入派诺业绩(含往年订单变更),变更金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[派诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],sum([变更金额]) AS '变更金额' FROM #BGTEMP1 WHERE [组织FID] = 100302 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入兴诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],sum([变更金额]) AS '变更金额' FROM #BGTEMP1 WHERE [组织FID] = 100303 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入武汉派诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[武汉派诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],sum([变更金额]) AS '变更金额' FROM #BGTEMP1 WHERE [组织FID] = 100305 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入广东碳索业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[广东碳索业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],sum([变更金额]) AS '变更金额' FROM #BGTEMP1 WHERE [组织FID] = 438223 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入香港派诺业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[香港派诺业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],SUM([变更金额]) AS '变更金额' FROM #BGTEMP1 WHERE [组织FID] = 438224 GROUP BY [部门(SBU)],[区域明细],[销售员]
|
||
|
||
--插入华夏云联业绩(含往年订单变更),订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[华夏云联业绩_含往年订单变更])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[变更金额] FROM #BGTEMP1 WHERE [组织FID] = 533896;
|
||
|
||
--插入2024年销售额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[年度销售额1])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[订单业绩] FROM #SixYearEMP1 WHERE [年份] = '2024'
|
||
|
||
--插入2023年销售额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[年度销售额2])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[订单业绩] FROM #SixYearEMP1 WHERE [年份] = '2023'
|
||
|
||
--插入2022年销售额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[年度销售额3])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[订单业绩] FROM #SixYearEMP1 WHERE [年份] = '2022'
|
||
|
||
--插入2021年销售额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[年度销售额4])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[订单业绩] FROM #SixYearEMP1 WHERE [年份] = '2021'
|
||
|
||
--插入2020年销售额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[年度销售额5])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[订单业绩] FROM #SixYearEMP1 WHERE [年份] = '2020'
|
||
|
||
--插入2019年销售额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[年度销售额6])
|
||
SELECT [部门(SBU)],[区域明细],[销售员],[订单业绩] FROM #SixYearEMP1 WHERE [年份] = '2019'
|
||
|
||
--查询所有组织下的收款单
|
||
--SELECT
|
||
--A.FSALEORGID AS '销售组织FID',
|
||
--O.FNAME AS '销售员'
|
||
--,A.FREALRECAMOUNT AS '收款金额'
|
||
--,ACO.区域 AS '部门_SBU'
|
||
--,ACO.明细区域 AS '区域明细'
|
||
--INTO #SKTEMP1
|
||
--FROM T_AR_RECEIVEBILL A
|
||
--INNER JOIN V_BD_SALESMAN_L O ON O.fid= A.FSALEERID
|
||
--INNER JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO ON ACO.名称=O.FNAME AND ISNULL(ACO.明细区域,'') != ''
|
||
--WHERE (@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
SELECT
|
||
t1.FSaleOrgId AS '销售组织FID',
|
||
t3.FNAME AS '销售员'
|
||
,t1.BenCiHeXiao AS '收款金额'
|
||
,ACO.区域 AS '部门_SBU'
|
||
,ACO.明细区域 AS '区域明细'
|
||
INTO #SKTEMP1
|
||
FROM ZZZ_HeXiaoBook t1
|
||
INNER JOIN T_SAL_ORDER t2 ON t1.XiaoShouFid = t2.FID
|
||
INNER JOIN V_BD_SALESMAN_L t3 ON t3.fid= t2.FSALERID
|
||
INNER JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO ON ACO.名称=t3.FNAME AND ISNULL(ACO.明细区域,'') != ''
|
||
WHERE (@FSaleOrgId = '' Or t1.FSaleOrgId IN (SELECT SalesID FROM SalesIDTable)) AND t1.ShoukuanType = 0
|
||
|
||
--查询所有组织下的收款退款单
|
||
--SELECT
|
||
--A.FSALEORGID AS '销售组织FID',
|
||
--B.FNAME AS '销售员',
|
||
--A.FREFUNDAMOUNT_H * -1 AS '收款退款金额'
|
||
--,ACO.区域 AS '部门_SBU'
|
||
--,ACO.明细区域 AS '区域明细'
|
||
--INTO #SKTKTEMP1
|
||
--FROM T_AR_REFUNDBILL A
|
||
--INNER JOIN V_BD_SALESMAN_L B ON A.FSALEERID = B.fid
|
||
--INNER JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO ON ACO.名称=B.FNAME AND ISNULL(ACO.明细区域,'') != ''
|
||
--WHERE (@FSaleOrgId = '' Or A.FSALEORGID IN (SELECT SalesID FROM SalesIDTable))
|
||
SELECT
|
||
t1.FSaleOrgId AS '销售组织FID',
|
||
t3.FNAME AS '销售员'
|
||
,t1.BenCiHeXiao AS '收款退款金额'
|
||
,ACO.区域 AS '部门_SBU'
|
||
,ACO.明细区域 AS '区域明细'
|
||
INTO #SKTKTEMP1
|
||
FROM ZZZ_HeXiaoBook t1
|
||
INNER JOIN T_SAL_ORDER t2 ON t1.XiaoShouFid = t2.FID
|
||
INNER JOIN V_BD_SALESMAN_L t3 ON t3.fid= t2.FSALERID
|
||
INNER JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo ACO ON ACO.名称=t3.FNAME AND ISNULL(ACO.明细区域,'') != ''
|
||
WHERE (@FSaleOrgId = '' Or t1.FSaleOrgId IN (SELECT SalesID FROM SalesIDTable)) AND t1.ShoukuanType = 1
|
||
|
||
--插入派诺累计回款额(参考的销售订单累计核销金额,待核销功能上线)
|
||
|
||
|
||
--插入兴诺累计回款额,收款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细],[销售员],[收款金额] FROM #SKTEMP1 WHERE [销售组织FID] = '100303'
|
||
|
||
--插入兴诺累计回款额,收款退款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细], [销售员],[收款退款金额] FROM #SKTKTEMP1 WHERE [销售组织FID] = '100303'
|
||
|
||
--插入武汉派诺累计回款额,收款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细], [销售员],[收款金额] FROM #SKTEMP1 WHERE [销售组织FID] = '100305'
|
||
|
||
--插入武汉派诺累计回款额,收款退款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细], [销售员],[收款退款金额] FROM #SKTKTEMP1 WHERE [销售组织FID] = '100305'
|
||
|
||
--插入广东碳索累计回款额,收款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细], [销售员],[收款金额] FROM #SKTEMP1 WHERE [销售组织FID] = '438223'
|
||
|
||
--插入广东碳索累计回款额,收款+退款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[兴诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细],[销售员],[收款退款金额] FROM #SKTKTEMP1 WHERE [销售组织FID] = '438223'
|
||
|
||
--插入香港派诺累计回款额,收款金额
|
||
INSERT INTO YJPHB_GZTH( [部门_SBU],[区域明细],[姓名],[香港派诺累计回款额])
|
||
SELECT[部门_SBU],[区域明细],[销售员],[收款金额] FROM #SKTEMP1 WHERE [销售组织FID] = '438224'
|
||
|
||
--插入香港派诺累计回款额,收款退款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[香港派诺累计回款额])
|
||
SELECT [部门_SBU],[区域明细], [销售员],[收款退款金额] FROM #SKTKTEMP1 WHERE [销售组织FID] = '438224'
|
||
|
||
--插入华夏云联累计回款额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[华夏云联累计回款额])
|
||
SELECT [部门_SBU],[区域明细],[销售员],[收款金额] FROM #SKTEMP1 WHERE [销售组织FID] = '533896'
|
||
|
||
--插入香港派诺累计回款额,收款退款金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[华夏云联累计回款额])
|
||
SELECT [部门_SBU],[区域明细],[销售员],[收款退款金额] FROM #SKTKTEMP1 WHERE [销售组织FID] = '533896'
|
||
|
||
|
||
|
||
--对已经插入的数据重新计算
|
||
SELECT *
|
||
INTO #TEMP2
|
||
FROM
|
||
(
|
||
SELECT [部门_SBU],[区域明细],[姓名],
|
||
SUM([派诺业绩_含往年订单变更]) AS '派诺业绩_含往年订单变更',
|
||
SUM([兴诺业绩_含往年订单变更]) AS '兴诺业绩_含往年订单变更',
|
||
SUM([武汉派诺业绩_含往年订单变更]) AS '武汉派诺业绩_含往年订单变更',
|
||
SUM([广东碳索业绩_含往年订单变更]) AS '广东碳索业绩_含往年订单变更',
|
||
SUM([香港派诺业绩_含往年订单变更]) AS '香港派诺业绩_含往年订单变更',
|
||
SUM([华夏云联业绩_含往年订单变更]) AS '华夏云联业绩_含往年订单变更',
|
||
SUM([派诺累计回款额]) AS '派诺累计回款额',
|
||
SUM([兴诺累计回款额]) AS '兴诺累计回款额',
|
||
SUM([武汉派诺累计回款额]) AS '武汉派诺累计回款额',
|
||
SUM([广东碳索累计回款额]) AS '广东碳索累计回款额',
|
||
SUM([香港派诺累计回款额]) AS '香港派诺累计回款额',
|
||
SUM([华夏云联累计回款额]) AS '华夏云联累计回款额',
|
||
SUM([年度销售额1]) AS '年度销售额1',
|
||
SUM([年度销售额2]) AS '年度销售额2',
|
||
SUM([年度销售额3]) AS '年度销售额3',
|
||
SUM([年度销售额4]) AS '年度销售额4',
|
||
SUM([年度销售额5]) AS '年度销售额5',
|
||
SUM([年度销售额6]) AS '年度销售额6'
|
||
FROM YJPHB_GZTH
|
||
GROUP BY [部门_SBU],[区域明细],[姓名]
|
||
) AS IDa
|
||
|
||
--清空表的数据
|
||
TRUNCATE TABLE YJPHB_GZTH
|
||
|
||
--重新插入各个组织的订单金额
|
||
INSERT INTO YJPHB_GZTH([部门_SBU],[区域明细],[姓名],[派诺业绩_含往年订单变更],[兴诺业绩_含往年订单变更],
|
||
[武汉派诺业绩_含往年订单变更],[广东碳索业绩_含往年订单变更],[香港派诺业绩_含往年订单变更],[华夏云联业绩_含往年订单变更]
|
||
,[派诺累计回款额],[兴诺累计回款额],[武汉派诺累计回款额],[广东碳索累计回款额],[香港派诺累计回款额],[华夏云联累计回款额]
|
||
,[年度销售额1],[年度销售额2],[年度销售额3],[年度销售额4],[年度销售额5],[年度销售额6])
|
||
SELECT * FROM #TEMP2
|
||
|
||
--更新当年累计业绩
|
||
update A
|
||
SET [当年累计业绩] = B.[订单业绩]
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN (SELECT [销售员],SUM([订单业绩]) AS '订单业绩' FROM #TEMP1 GROUP BY [销售员]) B ON A.[姓名] = B.[销售员]
|
||
|
||
--更新往年变更合同
|
||
update A
|
||
SET [往年变更合同额] = B.[变更金额]
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN (SELECT [销售员],SUM([变更金额]) AS '变更金额' FROM #BGTEMP1 GROUP BY [销售员]) B ON A.[姓名] = B.[销售员]
|
||
|
||
--对派诺集团-已进行集团业绩调整(含往年订单变更)字段进行赋值
|
||
UPDATE YJPHB_GZTH
|
||
SET [派诺集团_已进行集团业绩调整_含往年订单变更] = ISNULL([派诺业绩_含往年订单变更],0) + ISNULL([兴诺业绩_含往年订单变更],0) + ISNULL([武汉派诺业绩_含往年订单变更],0)
|
||
+ISNULL([广东碳索业绩_含往年订单变更],0) + ISNULL([香港派诺业绩_含往年订单变更],0) + ISNULL([华夏云联业绩_含往年订单变更],0);
|
||
|
||
--对集团回款合计字段进行赋值
|
||
UPDATE YJPHB_GZTH
|
||
SET [集团回款合计] = ISNULL([派诺累计回款额],0);
|
||
|
||
|
||
--查询就任岗位信息,赋值到YJPHB_GZTH表中
|
||
WITH RankedPositions AS (
|
||
SELECT B.FNAME AS '员工姓名',
|
||
D.FNAME AS '就任岗位',
|
||
C.FWORKORGID AS '就任组织FID',
|
||
ROW_NUMBER() OVER(
|
||
PARTITION BY B.FNAME
|
||
ORDER BY
|
||
CASE WHEN C.FWORKORGID = '100302' THEN 1 ELSE 2 END,
|
||
C.FWORKORGID DESC
|
||
)AS Rank
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN T_HR_EMPINFO_L B ON A.[姓名] = B.FNAME
|
||
INNER JOIN T_BD_STAFFTEMP C ON C.FID = B.FID
|
||
INNER JOIN T_ORG_POST_L D ON C.FPOSTID = D.FPOSTID
|
||
)
|
||
SELECT [员工姓名],[就任岗位]
|
||
INTO #YGTEMP1
|
||
FROM RankedPositions
|
||
WHERE RANK = 1
|
||
|
||
--对职位名称字段,根据销售员姓名更新数据
|
||
UPDATE A
|
||
SET [职位名称] = B.[就任岗位]
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN #YGTEMP1 B ON A.[姓名] = B.[员工姓名]
|
||
|
||
--查询任岗时间
|
||
SELECT B.FNAME AS '员工姓名',
|
||
MIN(C.FSTARTDATE) AS '就任岗时间'
|
||
INTO #DateTEMP3
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN T_HR_EMPINFO_L B ON A.[姓名] = B.FNAME
|
||
INNER JOIN T_BD_STAFFTEMP C ON C.FID = B.FID
|
||
INNER JOIN T_ORG_POST_L D ON C.FPOSTID = D.FPOSTID
|
||
GROUP BY B.FNAME
|
||
|
||
--对入司时间,担任本职位时间,担任销售日期字段赋值
|
||
update A
|
||
SET --A.[入司时间] = CONVERT(NVARCHAR(10), B.[就任岗时间], 120),
|
||
A.[担任本职位日期]= B.[就任岗时间],A.[担任销售日期] = B.[就任岗时间]
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN #DateTEMP3 B ON A.[姓名] = B.[员工姓名]
|
||
|
||
update A
|
||
SET A.[入司时间] = CONVERT(NVARCHAR(10), B.[入司日期], 120)
|
||
FROM YJPHB_GZTH A
|
||
INNER JOIN ERPTOHR.HYHRV3.dbo.v_erp_empinfo B ON A.[姓名] = B.[名称]
|
||
|
||
|
||
--计算表里入职年限字段
|
||
UPDATE A
|
||
SET A.[入职年限] = CAST(ROUND((DATEDIFF(DAY, A.[入司时间], @FEDateDate) / 365.0), 1) AS DECIMAL(23,1))
|
||
FROM YJPHB_GZTH A
|
||
|
||
--计算[本年销售目标_新]字段
|
||
UPDATE A
|
||
SET A.[本年销售目标_新] = B.FPERFORMANCETARGETS
|
||
FROM YJPHB_GZTH A
|
||
LEFT JOIN(SELECT ROW_NUMBER() OVER (PARTITION BY t3.FNAME ORDER BY F_MBBA_CREATEDATE_6OQ DESC) rn,t3.FNAME [姓名],
|
||
YEAR(F_VRYF_DATE_83G) [年],t2.F_MBBA_CREATEDATE_6OQ [创建日期],FPERFORMANCETARGETS
|
||
FROM MBBA_t_Cust_Entry100003 t1
|
||
LEFT JOIN MBBA_t_Cust100002 t2 ON t1.FID = t2.FID
|
||
LEFT JOIN V_BD_SALESMAN_L t3 ON t1.FNAME = t3.FID
|
||
WHERE YEAR(F_VRYF_DATE_83G)= YEAR(@FSDate) AND t2.FDOCUMENTSTATUS = 'C'
|
||
) B ON A.姓名 = B.姓名 AND B.rn = 1
|
||
|
||
--计算[本年销售目标_原]字段
|
||
UPDATE A
|
||
SET A.[本年销售目标_原] = B.FPERFORMANCETARGETS
|
||
FROM YJPHB_GZTH A
|
||
LEFT JOIN(SELECT ROW_NUMBER() OVER (PARTITION BY t3.FNAME ORDER BY F_MBBA_CREATEDATE_6OQ ASC) rn,t3.FNAME [姓名],
|
||
YEAR(F_VRYF_DATE_83G) [年],t2.F_MBBA_CREATEDATE_6OQ [创建日期],FPERFORMANCETARGETS
|
||
FROM MBBA_t_Cust_Entry100003 t1
|
||
LEFT JOIN MBBA_t_Cust100002 t2 ON t1.FID = t2.FID
|
||
LEFT JOIN V_BD_SALESMAN_L t3 ON t1.FNAME = t3.FID
|
||
WHERE YEAR(F_VRYF_DATE_83G)= YEAR(@FSDate) AND t2.FDOCUMENTSTATUS = 'C'
|
||
) B ON A.姓名 = B.姓名 AND B.rn = 1
|
||
|
||
|
||
--计算[本年达标率_不含往年订单变更_新]字段
|
||
UPDATE A
|
||
SET A.[本年达标率_不含往年订单变更_新] = CASE WHEN [本年销售目标_新] = 0 OR [本年销售目标_新] IS NULL THEN '0%' ELSE CAST(CAST(ISNULL([当年累计业绩],0)/([本年销售目标_新]*10000)*100 AS INT) AS nvarchar(150))+'%' END
|
||
FROM YJPHB_GZTH A
|
||
|
||
|
||
--计算[本年达标率_不含往年订单变更_原]字段
|
||
UPDATE A
|
||
SET A.[本年达标率_不含往年订单变更_原] = CASE WHEN [本年销售目标_原] = 0 OR [本年销售目标_新] IS NULL THEN '0%' ELSE CAST(CAST(ISNULL([当年累计业绩],0)/([本年销售目标_原]*10000)*100 AS INT) AS nvarchar(150))+'%' END
|
||
FROM YJPHB_GZTH A
|
||
|
||
|
||
--计算[目标调整金额]字段
|
||
UPDATE A
|
||
SET A.[目标调整金额] = ISNULL([本年销售目标_原],0)-ISNULL([本年销售目标_新],0)
|
||
FROM YJPHB_GZTH A
|
||
|
||
|
||
DROP TABLE #TEMP1,#TEMP2,#TEMP3,#BGTEMP1,#YGTEMP1,#DateTEMP3,#SKTEMP1,#SKTKTEMP1,#SixYearEMP1,#TEMP4,#TEMP5
|
||
END; |