406 lines
17 KiB
SQL
406 lines
17 KiB
SQL
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
|
|
${IF(LEN(p_area)>0,"B.hr_comm_name", "hr_organ_name")} AS hr_organ_name
|
|
,SUM(A.StartOfmonth_zzrs) AS StartOfmonth_zzrs -- 月初在职人数
|
|
,SUM(A.EndOfmonth_zsrs) AS EndOfmonth_zsrs -- 月末在职人数
|
|
,sum(A.zdlzrs) AS zdlzrs -- 主动离职人数
|
|
,CASE WHEN SUM(A.zzrs) = 0 THEN 0 ELSE sum(A.zdlzrs) / SUM(A.zzrs) END AS zdlz_rate -- 主动离职率
|
|
,sum(A.bdlzrs) AS bdlzrs -- 当天被动离职人数
|
|
,CASE WHEN SUM(A.zzrs) = 0 THEN 0 ELSE sum(A.bdlzrs) / SUM(A.zzrs) END AS bdlz_rate -- 被动离职率
|
|
,SUM(A.zlzrs) AS zlzrs -- 总离职人数
|
|
,CASE WHEN SUM(A.zzrs) = 0 THEN 0 ELSE sum(A.zlzrs) / SUM(A.zzrs) END AS lz_rate -- 离职率
|
|
FROM
|
|
(
|
|
SELECT
|
|
pq -- 片区
|
|
,xm -- 项目
|
|
,ym -- 年月
|
|
,StartOfmonth_zzrs -- 月初在职人数
|
|
,EndOfmonth_zsrs -- 月末在职人数
|
|
,zdlzrs -- 主动离职人数
|
|
,bdlzrs -- 被动离职人数
|
|
,zlzrs -- 总离职人数
|
|
,(StartOfmonth_zzrs + EndOfmonth_zsrs) / 2 AS zzrs -- 平均在职人数
|
|
FROM
|
|
(
|
|
SELECT
|
|
pq -- 片区
|
|
,xm -- 项目
|
|
,LEFT(rq,7) AS ym
|
|
,SUM(CASE WHEN rq = CONCAT('${p_ym}','-01') THEN zzrs ELSE 0 END) AS StartOfmonth_zzrs -- 月初在职人数
|
|
,SUM(CASE WHEN rq = LAST_DAY(CONCAT('${p_ym}','-01')) THEN zzrs ELSE 0 END) AS EndOfmonth_zsrs -- 月末在职人数
|
|
,SUM(zdlzrs) AS zdlzrs -- 当天主动离职人数
|
|
,SUM(bdlzrs) AS bdlzrs -- 当天被动离职人数
|
|
,SUM(zlzrs) AS zlzrs -- 当天总离职人数
|
|
FROM ods_hr_view_lzbl_d
|
|
WHERE LEFT(rq, 7) >= '2024-10'
|
|
-- 排除了:
|
|
-- 89:佳美物业公司
|
|
-- 267:悦汇发展公司
|
|
GROUP BY pq, xm, rq
|
|
UNION ALL
|
|
|
|
SELECT
|
|
T1.organ_code AS pq
|
|
,T1.comm_id AS xm
|
|
,T1.ym AS ym
|
|
,SUM(T1.begin_num ) AS StartOfmonth_zzrs-- 月初在职
|
|
,SUM(T1.end_num ) AS EndOfmonth_zsrs-- 月末在职
|
|
,SUM(T1.active_quit) AS zdlzrs-- 主动离职人数
|
|
,SUM(T1.pass_quit ) AS bdlzrs-- 被动离职人数
|
|
,SUM(T1.active_quit) + SUM(T1.pass_quit ) AS zlzrs
|
|
FROM
|
|
(
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-01' AS ym
|
|
,COALESCE(jan_begin_num,0) AS begin_num -- 月初在职
|
|
,COALESCE(jan_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(jan_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(jan_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(feb_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(feb_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(feb_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(mar_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(mar_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(mar_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(apr_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(apr_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(apr_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(may_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(may_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(may_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(jun_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(jun_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(jun_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(jul_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(jul_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(jul_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(aug_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(aug_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(aug_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(sep_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(sep_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(sep_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
FROM ods_hr_history_erp_date
|
|
)T1
|
|
GROUP BY T1.organ_code, T1.comm_id ,T1.ym
|
|
)T
|
|
WHERE ym >= '${p_startym}'
|
|
AND ym <= '${p_ym}'
|
|
AND pq not in('89','267')
|
|
AND (pq is NOT NULL OR xm IS NOT NULL )
|
|
|
|
)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项目名称
|
|
FROM dim_organ_mapping
|
|
WHERE length(hr_comm_id) > 0
|
|
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 comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}')
|
|
ELSE ${if(left(fine_role,2)=="项目","comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")} END
|
|
GROUP BY
|
|
organ_code
|
|
,organ_name
|
|
,hr_organ_id
|
|
,hr_organ_name
|
|
,hr_comm_id
|
|
,hr_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项目名称
|
|
FROM dual
|
|
)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 ('" + p_area +"')", "")}
|
|
|
|
GROUP BY
|
|
${IF(LEN(p_area)>0,"B.hr_comm_name", "hr_organ_name")}
|
|
ORDER BY ${IF(LEN(p_area)>0,"B.hr_comm_name", "hr_organ_name")}
|
|
|
|
|
|
|
|
-- ======================================
|
|
-- 天问提供历史数据处理
|
|
-- ======================================
|
|
|
|
|
|
DROP TABLE ods_hr_history_erp_date;
|
|
|
|
CREATE TABLE ods_hr_history_erp_date (
|
|
organ_name varchar(100) COMMENT 'erp片区名称'
|
|
,organ_code varchar(100) COMMENT 'erp片区编码'
|
|
,comm_name varchar(100) COMMENT '项目名称'
|
|
,comm_id varchar(100) COMMENT '项目id'
|
|
,sep_end_num int COMMENT '9月末在职人数'
|
|
,sep_pass_quit int COMMENT '9月被动离职人数'
|
|
,sep_active_quit int COMMENT '9月主动离职人数'
|
|
,sep_begin_num int COMMENT '9月初在职'
|
|
|
|
,aug_end_num int COMMENT '8月末在职人数'
|
|
,aug_pass_quit int COMMENT '8月被动离职人数'
|
|
,aug_active_quit int COMMENT '8月主动离职人数'
|
|
,aug_begin_num int COMMENT '8月初在职'
|
|
|
|
,jul_end_num int COMMENT '7月末在职人数'
|
|
,jul_pass_quit int COMMENT '7月被动离职人数'
|
|
,jul_active_quit int COMMENT '7月主动离职人数'
|
|
,jul_begin_num int COMMENT '7月初在职'
|
|
|
|
,jun_end_num int COMMENT '6月末在职人数'
|
|
,jun_pass_quit int COMMENT '6月被动离职人数'
|
|
,jun_active_quit int COMMENT '6月主动离职人数'
|
|
,jun_begin_num int COMMENT '6月初在职'
|
|
|
|
,may_end_num int COMMENT '5月末在职人数'
|
|
,may_pass_quit int COMMENT '5月被动离职人数'
|
|
,may_active_quit int COMMENT '5月主动离职人数'
|
|
,may_begin_num int COMMENT '5月初在职'
|
|
|
|
,apr_end_num int COMMENT '4月末在职人数'
|
|
,apr_pass_quit int COMMENT '4月被动离职人数'
|
|
,apr_active_quit int COMMENT '4月主动离职人数'
|
|
,apr_begin_num int COMMENT '4月初在职'
|
|
|
|
,mar_end_num int COMMENT '3月末在职人数'
|
|
,mar_pass_quit int COMMENT '3月被动离职人数'
|
|
,mar_active_quit int COMMENT '3月主动离职人数'
|
|
,mar_begin_num int COMMENT '3月初在职'
|
|
|
|
,feb_end_num int COMMENT '2月末在职人数'
|
|
,feb_pass_quit int COMMENT '2月被动离职人数'
|
|
,feb_active_quit int COMMENT '2月主动离职人数'
|
|
,feb_begin_num int COMMENT '2月初在职'
|
|
|
|
,jan_end_num int COMMENT '1月末在职人数'
|
|
,jan_pass_quit int COMMENT '1月被动离职人数'
|
|
,jan_active_quit int COMMENT '1月主动离职人数'
|
|
,jan_begin_num int COMMENT '1月初在职'
|
|
) COMMENT='erp系统历史离职人数';
|
|
|
|
|
|
SELECT * FROM ods_hr_history_erp_date
|
|
|
|
|
|
-- 列转行处理
|
|
|
|
SELECT
|
|
T1.organ_code AS organ_code
|
|
,T1.organ_name AS organ_name
|
|
,T1.comm_id AS comm_id
|
|
,T1.comm_name AS comm_name
|
|
,T1.ym AS ym
|
|
,SUM(T1.begin_num ) AS begin_num-- 月初在职
|
|
,SUM(T1.end_num ) AS end_num-- 月末在职
|
|
,SUM(T1.active_quit) AS active_quit-- 主动离职人数
|
|
,SUM(T1.pass_quit ) AS pass_quit-- 被动离职人数
|
|
FROM
|
|
(
|
|
SELECT
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,'2024-01' AS ym
|
|
,COALESCE(jan_begin_num,0) AS begin_num -- 月初在职
|
|
,COALESCE(jan_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(jan_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(jan_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(feb_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(feb_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(feb_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(mar_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(mar_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(mar_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(apr_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(apr_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(apr_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(may_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(may_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(may_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(jun_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(jun_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(jun_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(jul_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(jul_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(jul_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(aug_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(aug_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(aug_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
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 -- 月初在职
|
|
,COALESCE(sep_end_num,0) AS end_num -- 月末在职
|
|
,COALESCE(sep_active_quit,0) AS active_quit -- 主动离职人数
|
|
,COALESCE(sep_pass_quit,0) AS pass_quit -- 被动离职人数
|
|
FROM ods_hr_history_erp_date
|
|
)T1
|
|
GROUP BY T1.organ_code, T1.organ_name, T1.comm_id, T1.comm_name,T1.ym
|
|
|