313 lines
9.7 KiB
SQL
313 lines
9.7 KiB
SQL
|
|
-- 片区
|
|
|
|
|
|
${if(len(p_area)=0,"", "/*")}
|
|
SELECT
|
|
B.hr_organ_name AS comm_organ_name -- 片区
|
|
,SUM(IFNULL(A.bzs,0)) AS bzs -- 编制数
|
|
,SUM(IFNULL(A.zzs,0)) AS zzs -- 在职数
|
|
,SUM(IFNULL(C.full_rate_target,0)) AS full_rate_target -- 满编率目标值
|
|
,SUM(IFNULL(C.avg_full_rate_target,0)) AS avg_full_rate_target -- 月均满编率目标值
|
|
,CASE WHEN SUM(IFNULL(A.bzs,0)) = 0 THEN 0 ELSE SUM(IFNULL(A.zzs,0)) / SUM(IFNULL(A.bzs,0)) END AS RATE -- 月均满编率
|
|
FROM
|
|
(
|
|
SELECT
|
|
A1.pq AS pq
|
|
,SUM(A1.zzs) AS zzs
|
|
,sum(A1.bzs) AS bzs
|
|
FROM
|
|
(
|
|
SELECT
|
|
pq -- 片区
|
|
,ny
|
|
,SUM(zzs) AS zzs -- 在职数
|
|
,SUM(bzs) AS bzs -- 编制数
|
|
FROM ods_hr_view_mbl_d
|
|
WHERE pq NOT IN ('89','267') -- 这里剔除了佳美物业公司/悦汇发展公司
|
|
and ny > '2024-10'
|
|
GROUP BY pq,ny
|
|
UNION ALL
|
|
SELECT
|
|
organ_code as pq
|
|
,concat(left(ym,4),'-',right(ym,2)) as ny
|
|
,SUM(zzs) AS zzs
|
|
,SUM(bzs) AS bzs
|
|
FROM ods_hr_history_bz_num
|
|
WHERE 1 = 1
|
|
GROUP BY organ_code,concat(left(ym,4),'-',right(ym,2))
|
|
)A1
|
|
WHERE A1.ny >= '${p_startym}'
|
|
AND A1.ny <= '${p_ym}'
|
|
group by A1.pq
|
|
)A
|
|
LEFT JOIN
|
|
(
|
|
SELECT
|
|
organ_code -- erp片区编码
|
|
,organ_name -- erp片区名称
|
|
,hr_organ_id -- hr片区编码
|
|
,hr_organ_name -- hr片区名称
|
|
|
|
FROM dim_organ_mapping
|
|
WHERE length(hr_comm_id) > 0
|
|
GROUP BY
|
|
organ_code
|
|
,organ_name
|
|
,hr_organ_id
|
|
,hr_organ_name
|
|
UNION ALL
|
|
SELECT
|
|
'0000' AS organ_code -- erp片区编码
|
|
,'' AS organ_name -- erp片区名称
|
|
,'153' AS hr_organ_id -- hr片区编码
|
|
,'领悦集团总部' AS hr_organ_name -- hr片区名称
|
|
FROM dual
|
|
)B
|
|
ON A.pq = B.hr_organ_id
|
|
LEFT JOIN
|
|
(
|
|
SELECT
|
|
organ_code
|
|
,full_rate_target -- 满编率目标
|
|
,avg_full_rate_target -- 月均满编率目标
|
|
FROM ods_hr_collection_target_organ
|
|
WHERE ym = '${p_ym}'
|
|
)C
|
|
ON B.organ_code = C.organ_code
|
|
GROUP BY
|
|
B.hr_organ_name
|
|
|
|
${if(len(p_area)=0,"", "*/")}
|
|
|
|
|
|
-- 项目
|
|
${if(len(p_area)>0,"", "/*")}
|
|
with one_to_many AS(
|
|
SELECT
|
|
a.username AS username -- 用户名
|
|
,SUBSTRING_INDEX(SUBSTRING_INDEX(a.mang_project, ',',b.help_topic_id + 1),',',-1) AS mang_project -- 管理项目名
|
|
FROM ods_one_to_many_perm a
|
|
JOIN mysql.help_topic b
|
|
on b.help_topic_id < (LENGTH(a.mang_project) - length(replace(a.mang_project,',','')) + 1)
|
|
WHERE a.username = '${fine_username}'
|
|
)
|
|
SELECT
|
|
B.hr_comm_name AS comm_organ_name -- 片区
|
|
,SUM(IFNULL(A.bzs,0)) AS bzs -- 编制数
|
|
,SUM(IFNULL(A.zzs,0)) AS zzs -- 在职数
|
|
,SUM(IFNULL(C.full_rate_target,0)) AS full_rate_target -- 满编率目标值
|
|
,SUM(IFNULL(C.avg_full_rate_target,0)) AS avg_full_rate_target -- 月均满编率目标值
|
|
,CASE WHEN SUM(IFNULL(A.bzs,0)) = 0 THEN 0 ELSE SUM(IFNULL(A.zzs,0)) / SUM(IFNULL(A.bzs,0)) END AS RATE -- 月均满编率
|
|
FROM
|
|
(
|
|
SELECT
|
|
A1.pq AS pq
|
|
,A1.xm AS xm
|
|
,A1.zzs AS zzs
|
|
,A1.bzs AS bzs
|
|
FROM
|
|
(
|
|
SELECT
|
|
pq -- 片区
|
|
,xm
|
|
,ny
|
|
,SUM(CASE WHEN ny >= '2024-10' THEN zzs ELSE 0 end) AS zzs -- 在职数
|
|
,SUM(bzs) AS bzs -- 编制数
|
|
FROM ods_hr_view_mbl_d
|
|
WHERE pq NOT IN ('89','267') -- 这里剔除了佳美物业公司/悦汇发展公司
|
|
GROUP BY pq,ny,xm
|
|
UNION ALL
|
|
SELECT
|
|
T1.organ_code AS pq
|
|
,T1.comm_id AS xm
|
|
,T1.ym AS ny
|
|
,SUM(T1.begin_num ) AS zzs-- 月初在职
|
|
,0 AS bzs
|
|
FROM
|
|
(
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-01' AS ym
|
|
,COALESCE(jan_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-02' AS ym
|
|
,COALESCE(feb_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-03' AS ym
|
|
,COALESCE(mar_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-04' AS ym
|
|
,COALESCE(apr_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-05' AS ym
|
|
,COALESCE(may_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-06' AS ym
|
|
,COALESCE(jun_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-07' AS ym
|
|
,COALESCE(jul_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-08' AS ym
|
|
,COALESCE(aug_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
UNION ALL
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-09' AS ym
|
|
,COALESCE(sep_begin_num,0) AS begin_num -- 月初在职
|
|
FROM ods_hr_history_erp_date
|
|
)T1
|
|
GROUP BY T1.ym,T1.organ_code,T1.comm_id
|
|
)A1
|
|
WHERE A1.ny >= '${p_startym}'
|
|
AND A1.ny <= '${p_ym}'
|
|
)A
|
|
RIGHT 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项目名称
|
|
,comm_id
|
|
,comm_name
|
|
FROM dim_organ_mapping
|
|
WHERE length(hr_comm_id) > 0
|
|
GROUP BY
|
|
organ_code
|
|
,organ_name
|
|
,hr_organ_id
|
|
,hr_organ_name
|
|
,hr_comm_id
|
|
,hr_comm_name
|
|
,comm_id
|
|
,comm_name
|
|
UNION ALL
|
|
SELECT
|
|
'0000' AS organ_code -- erp片区编码
|
|
,'' AS organ_name -- erp片区名称
|
|
,'153' AS hr_organ_id -- hr片区编码
|
|
,'领悦集团总部' AS hr_organ_name -- hr片区名称
|
|
,'153' AS hr_comm_id -- hr项目id
|
|
,'领悦集团总部' AS hr_comm_name -- hr项目名称
|
|
,'' AS comm_id
|
|
,'' AS comm_name
|
|
FROM dual
|
|
)B
|
|
ON A.pq = B.hr_organ_id
|
|
and A.xm = B.hr_comm_id
|
|
LEFT JOIN
|
|
(
|
|
SELECT
|
|
comm_id
|
|
,organ_code
|
|
,full_rate_target -- 满编率目标
|
|
,avg_full_rate_target -- 月均满编率目标
|
|
FROM ods_hr_collection_target
|
|
WHERE ym = '${p_ym}'
|
|
)C
|
|
ON B.organ_code = C.organ_code
|
|
AND B.hr_comm_id = C.comm_id
|
|
WHERE 1=1
|
|
${IF(LEN(p_area)>0," AND B.organ_code IN ('" + p_area +"')", "")}
|
|
AND CASE WHEN (SELECT mang_project FROM ods_one_to_many_perm WHERE username = '${fine_username}' AND mang_organ IS NULL) IS NOT NULL
|
|
THEN B.comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}')
|
|
ELSE ${if(left(fine_role,2)=="项目","B.comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")} END
|
|
GROUP BY
|
|
B.hr_comm_name
|
|
|
|
${if(len(p_area)>0,"", "*/")}
|
|
|
|
|
|
-- 满编率整体目标
|
|
${if(len(p_area)=0,"", "/*")}
|
|
SELECT
|
|
full_rate_target -- 满编率目标
|
|
FROM ods_hr_collection_target_overall
|
|
WHERE ym = '${p_ym}'
|
|
${if(len(p_area)=0,"", "*/")}
|
|
|
|
-- 片区整体目标
|
|
${if(len(p_area) =1,"", "/*")}
|
|
SELECT
|
|
full_rate_target -- 满编率目标
|
|
FROM ods_hr_collection_target_organ
|
|
WHERE ym = '${p_ym}'
|
|
AND organ_code = '${p_area}'
|
|
${if(len(p_area)=1,"", "*/")}
|
|
|
|
-- ======================================
|
|
-- 编制历史数据
|
|
-- ======================================
|
|
|
|
DROP TABLE ods_hr_history_bz_num;
|
|
|
|
CREATE TABLE ods_hr_history_bz_num (
|
|
organ_name varchar(100) COMMENT 'erp片区名称'
|
|
,organ_code varchar(100) COMMENT 'erp片区编码'
|
|
,bzs bigint COMMENT '编制数'
|
|
,ym varchar(50) COMMENT '年月'
|
|
,zzs bigint COMMENT '在职数'
|
|
) COMMENT='编制人数历史数据';
|
|
|
|
|
|
select * from ods_hr_history_bz_num
|
|
|
|
|
|
SELECT
|
|
full_rate_target -- 满编率目标
|
|
FROM ods_hr_collection_target_overall
|
|
WHERE ym = '${p_ym}'
|