655 lines
21 KiB
SQL
655 lines
21 KiB
SQL
-- ======================================
|
||
-- HR组织机构
|
||
-- ======================================
|
||
|
||
WITH one_department AS(
|
||
|
||
SELECT
|
||
id
|
||
,subcompanyname
|
||
FROM ods_hr_hrmsubcompany_d
|
||
WHERE tlevel = '1'
|
||
),
|
||
sec_department AS
|
||
(
|
||
SELECT
|
||
b.id AS one_department_code
|
||
,b.subcompanyname AS one_department_name
|
||
,a.id AS sec_department_code
|
||
,a.subcompanyname AS sec_department_name
|
||
FROM
|
||
(
|
||
SELECT
|
||
id
|
||
,subcompanyname
|
||
,supsubcomid
|
||
FROM ods_hr_hrmsubcompany_d
|
||
WHERE tlevel = '2'
|
||
)A
|
||
LEFT JOIN one_department B
|
||
ON A.supsubcomid = B.id
|
||
),
|
||
third_department AS
|
||
(
|
||
SELECT
|
||
b.one_department_code AS one_department_code
|
||
,b.one_department_name AS one_department_name
|
||
,b.sec_department_code AS sec_department_code
|
||
,b.sec_department_name AS sec_department_name
|
||
,a.id AS third_department_code
|
||
,a.subcompanyname AS third_department_name
|
||
FROM
|
||
(
|
||
SELECT
|
||
id
|
||
,subcompanyname
|
||
,supsubcomid
|
||
FROM ods_hr_hrmsubcompany_d
|
||
WHERE tlevel = '3'
|
||
)A
|
||
LEFT JOIN sec_department B
|
||
ON A.supsubcomid = B.sec_department_code
|
||
)
|
||
|
||
SELECT
|
||
one_department_code
|
||
,one_department_name
|
||
,sec_department_code
|
||
,sec_department_name
|
||
,third_department_code
|
||
,third_department_name
|
||
FROM third_department
|
||
;
|
||
|
||
|
||
-- ======================================
|
||
-- report_指标卡_在职人数
|
||
-- ======================================
|
||
|
||
SELECT
|
||
SUM(zzs) AS SL
|
||
FROM
|
||
(
|
||
SELECT
|
||
pq -- 片区
|
||
,xm -- 项目
|
||
,zzs -- 在职人数
|
||
FROM ods_hr_view_mbl_d -- 在职与编制人数
|
||
WHERE left(rq,7) = '${p_ym}'
|
||
)A
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code
|
||
,organ_name
|
||
,comm_id
|
||
,comm_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,comm_id
|
||
,comm_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
)B
|
||
ON A.pq = B.hr_organ_id
|
||
and A.xm = b.hr_comm_id
|
||
where 1 = 1
|
||
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
-- ======================================
|
||
-- 指标卡_离职人数
|
||
-- ======================================
|
||
|
||
SELECT
|
||
SUM(lzrs) AS SL
|
||
FROM
|
||
(
|
||
SELECT
|
||
pq -- 片区
|
||
,xm -- 项目
|
||
,lzrs -- 离职人数
|
||
,concat(nd,'-',yd) AS YM -- 年月
|
||
FROM ods_hr_view_lzrs_d -- 离职人数
|
||
WHERE left(rq,7) = '${p_ym}'
|
||
)A
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code
|
||
,organ_name
|
||
,comm_id
|
||
,comm_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,comm_id
|
||
,comm_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
)B
|
||
ON A.pq = B.hr_organ_id
|
||
and A.xm = B.hr_comm_id
|
||
where 1 = 1
|
||
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
|
||
-- ======================================
|
||
-- 指标卡_人力成本
|
||
-- ======================================
|
||
SELECT
|
||
sum(total_fee) AS total_fee
|
||
from dw.dws_cost_lc_summary_d -- 人力成本实际值
|
||
WHERE fee_type = '实际值'
|
||
AND concat(yearname,'-',monthname) = '${p_ym}'
|
||
${IF(LEN(p_area)>0," AND organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
|
||
-- ======================================
|
||
-- 指标卡_行政成本
|
||
-- ======================================
|
||
SELECT
|
||
sum(total_fee) AS total_fee
|
||
FROM dw.dws_cost_ac_summary_d -- 费控行政成本实际值
|
||
WHERE fee_type = '实际值'
|
||
AND concat(yearname,'-',monthname) = '${p_ym}'
|
||
${IF(LEN(p_area)>0," AND organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
-- ======================================
|
||
-- 员工满编率柱状图
|
||
-- ======================================
|
||
|
||
SELECT
|
||
A.yd AS yd -- 月度
|
||
,A.pq AS pq -- 片区
|
||
,A.xm AS xm -- 项目
|
||
,A.zzs AS zzs -- 在职数
|
||
,A.bzs AS bzs -- 编制数
|
||
,A.datedif AS datedif -- 结束日期--开始日期
|
||
,A.total_zzs AS total_zzs -- 累计在职人数
|
||
,A.total_bzs AS total_bzs -- 累计编制人数
|
||
,A.avg_zzs AS avg_zzs -- 平均在职人数
|
||
,A.avg_bzs AS avg_bzs -- 平均编制人数
|
||
,A.rate AS rate -- 满编率
|
||
FROM
|
||
(
|
||
SELECT
|
||
|
||
yd -- 月度
|
||
,pq -- 片区
|
||
,xm -- 项目
|
||
,zzs -- 在职数
|
||
,bzs -- 编制数
|
||
,datediff(current_date(),rq) AS datedif -- 结束日期--开始日期
|
||
,sum(zzs) over(PARTITION BY rq,pq,xm) AS total_zzs -- 累计在职人数
|
||
,sum(bzs) over(PARTITION BY rq,pq,xm) AS total_bzs -- 累计编制人数
|
||
,sum(zzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_zzs -- 平均在职人数
|
||
,sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_bzs -- 平均编制人数
|
||
,CASE WHEN sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) = 0 THEN 0
|
||
ELSE (sum(zzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq)) / (sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq))
|
||
END as rate
|
||
FROM ods_hr_view_mbl_d
|
||
)A
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,hr_organ_id -- hr片区编码
|
||
,hr_organ_name -- hr片区名称
|
||
,hr_comm_id -- hr项目id
|
||
,hr_comm_name -- hr项目名称
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
)B
|
||
ON A.pq = B.hr_organ_id
|
||
and A.xm = b.hr_comm_id
|
||
where 1 = 1
|
||
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
|
||
-- ======================================
|
||
-- 员工满编率排名
|
||
-- ======================================
|
||
|
||
-- 注意 目前会有空的排名 是因为佳美物业未做映射
|
||
|
||
SELECT
|
||
T1.organ_comm AS organ_comm
|
||
,ROW_NUMBER() OVER(ORDER BY T1.RATE DESC) 排名
|
||
,T1.rate
|
||
,'0' AS target_rate
|
||
FROM
|
||
(
|
||
SELECT
|
||
${IF(LEN(p_area)>0,"B.hr_comm_name", "B.hr_organ_name")} AS organ_comm
|
||
,CASE WHEN SUM(avg_bzs) = 0 THEN 0 ELSE SUM(avg_zzs) / SUM(avg_bzs) END AS RATE
|
||
FROM
|
||
(
|
||
SELECT
|
||
pq -- 片区
|
||
,xm -- 项目
|
||
,zzs -- 在职数
|
||
,bzs -- 编制数
|
||
,rq
|
||
,datediff(current_date(),rq) AS datedif -- 结束日期--开始日期
|
||
,sum(zzs) over(PARTITION BY rq,pq,xm) AS total_zzs -- 累计在职人数
|
||
,sum(bzs) over(PARTITION BY rq,pq,xm) AS total_bzs -- 累计编制人数
|
||
,sum(zzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_zzs -- 平均在职人数
|
||
,sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_bzs -- 平均编制人数
|
||
FROM ods_hr_view_mbl_d
|
||
WHERE CONCAT(nd,'-',yd) = '${p_ym}'
|
||
-- 注意 目前会有一个空的排名 是因为佳美物业未做映射
|
||
AND pq <> '89'
|
||
)A
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,hr_organ_id -- hr片区编码
|
||
,hr_organ_name -- hr片区名称
|
||
,hr_comm_id -- hr项目id
|
||
,hr_comm_name -- hr项目名称
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
WHERE hr_organ_name IS NOT NULL
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
)B
|
||
ON A.pq = B.hr_organ_id
|
||
and A.xm = B.hr_comm_id
|
||
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
GROUP BY ${IF(LEN(p_area)>0,"B.hr_comm_name", "B.hr_organ_name")}
|
||
)T1
|
||
|
||
|
||
-- ======================================
|
||
-- 员工离职原因占比
|
||
-- ======================================
|
||
|
||
SELECT
|
||
A.lzlx AS lzlx -- 离职类型id
|
||
,A.lzlxname AS lzlxname -- 离职类型名称
|
||
,A.lzyy AS lzyy -- 离职原因id
|
||
,A.lzyyname AS lzyyname -- 离职原因名称
|
||
,A.lzrs AS lzrs -- 离职人数
|
||
FROM
|
||
(
|
||
SELECT
|
||
pq -- 片区
|
||
,xm -- 项目
|
||
,lzlx -- 离职类型id
|
||
,lzlxname -- 离职类型名称
|
||
,lzyy -- 离职原因id
|
||
,lzyyname -- 离职原因名称
|
||
,lzrs -- 离职人数
|
||
FROM ods_hr_view_lzrs_fl_d
|
||
WHERE LEFT(rq,7) = '${p_ym}'
|
||
)A
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,hr_organ_id -- hr片区编码
|
||
,hr_organ_name -- hr片区名称
|
||
,hr_comm_id -- hr项目id
|
||
,hr_comm_name -- hr项目名称
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,hr_organ_id
|
||
,hr_organ_name
|
||
,hr_comm_id
|
||
,hr_comm_name
|
||
)B
|
||
ON A.pq = B.hr_organ_id
|
||
and A.xm = B.hr_comm_id
|
||
where 1 = 1
|
||
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
-- ======================================
|
||
-- 人力行政成本费率柱状图
|
||
-- ======================================
|
||
|
||
${if(p_type='人力',"","/*")}
|
||
SELECT
|
||
T1.yr_month AS yr_month
|
||
,'人力成本' AS name
|
||
,'人力成本费率' AS name_rate
|
||
,RIGHT(T1.yr_month,2) AS MONTHS
|
||
,T1.actual_cost AS actual_cost -- 人力成本
|
||
,T1.index_income_fact AS index_income_fact -- 实际收入
|
||
,T1.actual_cost / T1.index_income_fact AS FEE_RATE -- 费率
|
||
FROM
|
||
(
|
||
SELECT
|
||
A.yr_month AS yr_month
|
||
,A.actual_cost
|
||
,b.index_income_fact AS index_income_fact
|
||
FROM
|
||
(
|
||
-- 费控人力成本科目汇总表
|
||
SELECT
|
||
organ_code
|
||
,CONCAT(yearname,'-',monthname) AS yr_month
|
||
,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本
|
||
from dw.dws_cost_ac_summary_d
|
||
WHERE yearname = left('${p_ym}',4)
|
||
AND CONCAT(yearname,'-',monthname) < '${p_ym}'
|
||
GROUP BY CONCAT(yearname,'-',monthname),organ_code
|
||
)A
|
||
LEFT JOIN
|
||
(-- 公司实际收入
|
||
SELECT
|
||
yr_month
|
||
,organ_code
|
||
,SUM(index_income_fact) AS index_income_fact -- 实际收入
|
||
FROM ods_caiwu_feecollection
|
||
WHERE category = '物业'
|
||
AND LEFT(yr_month,4) = left('${p_ym}',4)
|
||
GROUP BY yr_month,organ_code
|
||
)B
|
||
ON A.yr_month = B.yr_month
|
||
AND A.organ_code = B.organ_code
|
||
WHERE 1 = 1
|
||
${IF(LEN(p_area)>0," AND A.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
)T1
|
||
ORDER BY T1.yr_month
|
||
${if(p_type='人力',"","*/")}
|
||
|
||
${if(p_type='行政',"","/*")}
|
||
|
||
SELECT
|
||
T1.yr_month AS yr_month
|
||
,'行政成本' AS name
|
||
,'行政成本费率' AS name_rate
|
||
,RIGHT(T1.yr_month,2) AS MONTHS
|
||
,T1.actual_cost AS actual_cost -- 人力成本
|
||
,T1.index_income_fact AS index_income_fact -- 实际收入
|
||
,T1.actual_cost / T1.index_income_fact AS FEE_RATE -- 费率
|
||
FROM
|
||
(
|
||
SELECT
|
||
A.yr_month AS yr_month
|
||
,A.actual_cost AS actual_cost -- 人力成本
|
||
,B.index_income_fact AS index_income_fact -- 实际收入
|
||
FROM
|
||
(
|
||
-- 费控人力成本科目汇总表
|
||
SELECT
|
||
organ_code
|
||
,CONCAT(yearname, '-', monthname) AS yr_month
|
||
,SUM(CASE WHEN fee_type IN ('实际值', '目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本
|
||
FROM dw.dws_cost_lc_summary_d
|
||
WHERE yearname = LEFT('${p_ym}', 4)
|
||
AND CONCAT(yearname, '-', monthname) < '${p_ym}'
|
||
GROUP BY CONCAT(yearname, '-', monthname),organ_code
|
||
) A
|
||
LEFT JOIN
|
||
(-- 公司实际收入
|
||
SELECT
|
||
yr_month
|
||
,organ_code
|
||
, SUM(index_income_fact) AS index_income_fact -- 实际收入
|
||
FROM ods_caiwu_feecollection
|
||
WHERE category = '物业'
|
||
AND LEFT(yr_month, 4) = LEFT('${p_ym}', 4)
|
||
GROUP BY yr_month,organ_code
|
||
)B
|
||
ON A.yr_month = B.yr_month
|
||
AND A.organ_code = B.organ_code
|
||
WHERE 1=1
|
||
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
||
)T1
|
||
ORDER BY T1.yr_month
|
||
${if(p_type='行政',"","*/")}
|
||
|
||
|
||
-- ======================================
|
||
-- 人力行政成本费率排名
|
||
-- ======================================
|
||
-- 这里无法筛选片区时展示对应片区下项目费率的排名
|
||
-- 原因: 费控成本均在各片区智能下,普通项目没有费用,可使用如下sql查询:
|
||
|
||
/*
|
||
SELECT
|
||
A.organ_comm_name AS organ_comm_name
|
||
,A.actual_cost AS actual_cost -- 成本
|
||
,B.index_income_fact AS index_income_fact -- 实际收入
|
||
,ROW_NUMBER() OVER (ORDER BY A.actual_cost / B.index_income_fact DESC ) AS 排名 -- 费率排名
|
||
,A.actual_cost / B.index_income_fact AS fee_rate -- 费率
|
||
,A.budget_actual_cost / B.index_income_target AS target_fee_rate -- 费率目标
|
||
FROM
|
||
(
|
||
-- 费控人力成本科目汇总表
|
||
SELECT
|
||
A2.comm_name AS organ_comm_name
|
||
,A2.comm_id AS organ_comm_code
|
||
,A2.cost_comm_name AS cost_comm_name
|
||
,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本
|
||
,SUM(CASE WHEN fee_type = '目标值' THEN total_fee ELSE 0 END) / 10000 AS budget_actual_cost -- 人力成本预算值
|
||
|
||
FROM
|
||
(
|
||
SELECT
|
||
*
|
||
FROM dw.dws_cost_ac_summary_d
|
||
WHERE CONCAT(yearname,'-',monthname) = '2024-09'
|
||
)A1
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,comm_id
|
||
,comm_name
|
||
,cost_comm_id -- 费控项目id
|
||
,cost_comm_name -- 费控项目名称
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
GROUP BY
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,comm_id
|
||
,comm_name
|
||
,cost_comm_id -- 费控项目id
|
||
,cost_comm_name -- 费控项目名称
|
||
)A2
|
||
ON A1.organ_code = A2.organ_code
|
||
AND A1.dimsubjectcode = A2.cost_comm_id
|
||
WHERE 1=1
|
||
-- AND A2.organ_code IN ('0102')
|
||
GROUP BY
|
||
A2.comm_name
|
||
,A2.comm_id
|
||
,A2.cost_comm_name
|
||
)A
|
||
LEFT JOIN
|
||
(-- 公司实际收入
|
||
SELECT
|
||
comm_name AS organ_comm_name
|
||
,comm_id AS organ_comm_code
|
||
,SUM(index_income_fact) AS index_income_fact -- 实际收入
|
||
,SUM(index_income_target) AS index_income_target -- 收入目标
|
||
FROM ods_caiwu_feecollection
|
||
WHERE category = '物业'
|
||
AND yr_month = '2024-09'
|
||
GROUP BY
|
||
comm_name
|
||
,comm_id
|
||
)B
|
||
ON A.organ_comm_code = B.organ_comm_code
|
||
*/
|
||
|
||
|
||
|
||
${if(p_type='人力',"","/*")}
|
||
|
||
SELECT
|
||
A.organ_name AS organ_comm_name
|
||
,A.actual_cost AS actual_cost -- 成本
|
||
,B.index_income_fact AS index_income_fact -- 实际收入
|
||
,ROW_NUMBER() OVER (ORDER BY A.actual_cost / B.index_income_fact DESC ) AS 排名 -- 费率排名
|
||
,A.actual_cost / B.index_income_fact AS fee_rate -- 费率
|
||
,A.budget_actual_cost / B.index_income_target AS target_fee_rate -- 费率目标
|
||
FROM
|
||
(
|
||
-- 费控人力成本科目汇总表
|
||
SELECT
|
||
A1.organ_code
|
||
,A1.organ_name
|
||
-- ${IF(LEN(p_area)>0,"dimsubjectname", "organ_name")} AS organ_comm_name
|
||
,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本
|
||
,SUM(CASE WHEN fee_type = '目标值' THEN total_fee ELSE 0 END) / 10000 AS budget_actual_cost -- 人力成本预算值
|
||
FROM
|
||
(
|
||
SELECT
|
||
*
|
||
FROM dw.dws_cost_ac_summary_d -- 费控人力成本科目汇总表
|
||
WHERE CONCAT(yearname,'-',monthname) = '${LEFT(MONTHDELTA(p_ym,-1),7)}' -- 取上月数据
|
||
)A1
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,cost_comm_id
|
||
,cost_comm_name
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,cost_comm_id
|
||
,cost_comm_name
|
||
)A2
|
||
ON A1.organ_code = A2.organ_code
|
||
-- AND A1.dimsubjectcode = A2.cost_comm_id
|
||
WHERE 1=1
|
||
-- ${IF(LEN(p_area)>0," AND A2.id IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
GROUP BY
|
||
A1.organ_code
|
||
,A1.organ_name
|
||
-- ${IF(LEN(p_area)>0,"dimsubjectname", "organ_name")}
|
||
)A
|
||
LEFT JOIN
|
||
(-- 公司实际收入
|
||
SELECT
|
||
-- ${IF(LEN(p_area)>0,"comm_name", "organ_name")} AS organ_comm_name
|
||
organ_code
|
||
,SUM(index_income_fact) AS index_income_fact -- 实际收入
|
||
,SUM(index_income_target) AS index_income_target -- 收入目标
|
||
FROM ods_caiwu_feecollection
|
||
WHERE category = '物业'
|
||
AND yr_month = '${LEFT(MONTHDELTA(p_ym,-1),7)}'
|
||
GROUP BY
|
||
-- ${IF(LEN(p_area)>0,"comm_name", "organ_name")}
|
||
organ_code
|
||
)B
|
||
ON A.organ_code = B.organ_code
|
||
|
||
${if(p_type='人力',"","*/")}
|
||
|
||
${if(p_type='行政',"","/*")}
|
||
|
||
|
||
|
||
SELECT
|
||
A.organ_name AS organ_comm_name
|
||
,A.actual_cost AS actual_cost -- 成本
|
||
,B.index_income_fact AS index_income_fact -- 实际收入
|
||
,ROW_NUMBER() OVER (ORDER BY A.actual_cost / B.index_income_fact DESC ) AS 排名 -- 费率排名
|
||
,A.actual_cost / B.index_income_fact AS fee_rate -- 费率
|
||
,A.budget_actual_cost / B.index_income_target AS target_fee_rate -- 费率目标
|
||
FROM
|
||
(
|
||
-- 费控人力成本科目汇总表
|
||
SELECT
|
||
-- ${IF(LEN(p_area)>0,"A2.comm_name", "A1.organ_name")} AS organ_comm_name
|
||
-- ${IF(LEN(p_area)>0,",A2.comm_id", ",A1.organ_code")} AS organ_comm_code
|
||
A1.organ_code
|
||
,A1.organ_name
|
||
,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本
|
||
,SUM(CASE WHEN fee_type = '目标值' THEN total_fee ELSE 0 END) / 10000 AS budget_actual_cost -- 人力成本预算值
|
||
|
||
FROM
|
||
(
|
||
SELECT
|
||
*
|
||
FROM dw.dws_cost_lc_summary_d
|
||
WHERE CONCAT(yearname,'-',monthname) = '${LEFT(MONTHDELTA(p_ym,-1),7)}'
|
||
)A1
|
||
LEFT JOIN
|
||
(
|
||
SELECT
|
||
organ_code -- erp片区编码
|
||
,organ_name -- erp片区名称
|
||
,comm_id
|
||
,comm_name
|
||
,cost_comm_id
|
||
,cost_comm_name
|
||
FROM dim_organ_mapping_kunan_tmp
|
||
GROUP BY
|
||
organ_code
|
||
,organ_name
|
||
,comm_id
|
||
,comm_name
|
||
,cost_comm_id
|
||
,cost_comm_name
|
||
)A2
|
||
ON A1.organ_code = A2.organ_code
|
||
-- AND A1.dimsubjectcode = A2.cost_comm_id
|
||
WHERE 1=1
|
||
-- ${IF(LEN(p_area)>0," AND A2.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
GROUP BY
|
||
A1.organ_code
|
||
,A1.organ_name
|
||
-- ${IF(LEN(p_area)>0,"A2.comm_name", "A1.organ_name")}
|
||
-- ${IF(LEN(p_area)>0,",A2.comm_id", ",A1.organ_code")}
|
||
)A
|
||
LEFT JOIN
|
||
(-- 公司实际收入
|
||
SELECT
|
||
-- ${IF(LEN(p_area)>0,"comm_id", "organ_code")} AS organ_comm_code
|
||
organ_code
|
||
,SUM(index_income_fact) AS index_income_fact -- 实际收入
|
||
,SUM(index_income_target) AS index_income_target -- 收入目标
|
||
FROM ods_caiwu_feecollection
|
||
WHERE category = '物业'
|
||
AND yr_month = '${LEFT(MONTHDELTA(p_ym,-1),7)}'
|
||
GROUP BY
|
||
organ_code
|
||
-- ${IF(LEN(p_area)>0,"comm_id", "organ_code")}
|
||
)B
|
||
ON A.organ_code = B.organ_code
|
||
|
||
${if(p_type='行政',"","*/")}
|