-- **************************************** -- 创建人员: 杨坤安 -- 创建日期: 2024-07-18 -- 功 能: 帆软明细报表-计划到期明细 -- 目 录: xianzuan>2_运营>计划到期明细.fvs -- **************************************** -- 【数据集: report_计划到期】 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,"c.organ_name","c.comm_name")} as p_area ${if(len(p_area) == 0,"COALESCE(c.oa_organ_name,e.subcompanyname)","COALESCE(c.oa_comm_name,e.subcompanyname)")} as p_area ,c.oa_comm_id as oa_comm_id -- oa项目id ,c.oa_comm_name as oa_comm_name -- oa项目名称 ,c.oa_organ_code as oa_organ_code -- oa片区id ,c.oa_organ_name as oa_organ_name -- oa片区名称 ,c.organ_code as organ_code -- erp片区编码 ,c.organ_name as organ_name -- erp片区名称 ,c.comm_id as comm_id -- erp项目id ,c.comm_name as comm_name -- erp项目名称 ,b.subcompanyid1 as subcompanyid1 -- 公司id ,a.plan_name as plan_name -- 计划名称 ,a.eval_criteria as plan_desc -- 计划内容 ,a.plan_level as plan_level -- 计划等级 ,a.plan_level_name as plan_level_name -- 计划等级名称 ,left(a.start_date,7) as ym -- 计划开始年月 ,a.start_dt as start_dt -- 计划开始时 ,a.end_date as end_date -- 计划结束时间 ,a.finish_date as finish_date -- 计划完成时间 ,a.input_date as input_date -- 计划录入时间 ,a.day_diff as day_diff -- 距离计划结束天数 ,a.responsible_person1 as responsible_person1 -- 责任人编码 ,b.lastname as executor_name -- 责任人名称 ,d.lastname AS lastname -- 执行人 ,left(a.end_ym,7) as end_ym -- 计划结束年月 from ( SELECT concat(left(trim(start_date),5),lpad(substring_index(substring_index(trim(start_date),'-',2),'-',-1),2,0),right(trim(start_date),3)) as start_date ,a.start_date as start_dt -- 计划开始时间 ,a.plan_level -- 计划等级 ,jt.responsible_person1 -- 责任人 ,a.plan_status -- 计划状态 ,a.input_date -- 录入时间 ,a.end_date -- 计划结束时间 ,a.plan_name -- 计划名称 ,concat(left(trim(end_date),5),lpad(substring_index(substring_index(trim(end_date),'-',2),'-',-1),2,0),right(trim(end_date),3)) as end_ym ,a.finish_date -- 完成时间 ,TO_DAYS(a.end_date) - TO_DAYS(curdate()) AS day_diff ,a.eval_criteria -- 评价标准 ,a.executor -- 执行人 ,case when a.plan_level = 4 then '控股集团级计划' when a.plan_level = 0 then '一级计划' when a.plan_level = 1 then '二级计划' when a.plan_level = 3 then '三级计划' end plan_level_name FROM dw.dwd_operations_plan_info_d a, JSON_TABLE ( cast( CONCAT( '["', REPLACE ( responsible_person1, ',', '","' ), '"]' ) AS json ), "$[*]" COLUMNS ( responsible_person1 INT PATH "$" ) ) AS jt -- WHERE TO_DAYS(a.end_date) - TO_DAYS(curdate()) <= 3 -- AND TO_DAYS(a.end_date) - TO_DAYS(curdate()) >= 1 where a.end_date > date_format(CURDATE() - INTERVAL 3 day,'%Y-%m-%d') and a.end_date <= date_format(CURDATE(),'%Y-%m-%d') )a left join ( select id ,subcompanyid1 -- 公司id ,lastname -- 执行人 from dw.ods_oa_hrmresource_d )b on a.responsible_person1 = b.id left join ( select distinct organ_code -- erp片区id ,organ_name -- erp片区名称 ,comm_id -- erp项目id ,comm_name -- erp项目名称 ,oa_organ_code -- oa片区id ,oa_organ_name -- oa片区名称 ,oa_comm_id -- oa项目id ,oa_comm_name -- oa项目名称 from dim_organ_mapping -- 组织结构映射维度表 -- where comm_id is not null )c on b.subcompanyid1 = c.oa_comm_id left join ( select id ,subcompanyid1 -- 公司id ,lastname -- 执行人 from dw.ods_oa_hrmresource_d )d on a.executor = d.id LEFT JOIN ( SELECT * FROM dw.ods_oa_hrmsubcompany_d -- 分部信息表 -- WHERE id = '288' )e ON b.subcompanyid1 = e.id where 1 = 1 ${if(len(p_startdate) == 0,"","and left(a.end_ym,7) = '" + p_startdate + "'")} ${IF(LEN(p_area)!=0," and coalesce(c.oa_organ_code,e.id) IN ('"+p_area+"')","")} -- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")} 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 COALESCE(c.oa_organ_name,e.subcompanyname) IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}') ELSE ${if(left(fine_role,2)=="项目","COALESCE(c.oa_organ_name,e.subcompanyname) = '"+GETUSERDEPARTMENTS(3)+"'","1=1")} END -- 【筛选框数据集: dic_oa片区】 select distinct d.oa_organ_code, d.oa_organ_name from ( SELECT concat(left(trim(start_date),5),lpad(substring_index(substring_index(trim(start_date),'-',2),'-',-1),2,0),right(trim(start_date),3)) as start_date ,a.start_date as start_dt -- 计划开始时间 ,a.plan_level -- 计划等级 ,jt.executor -- 执行人 责任人 口径可能不一致 ,a.plan_status -- 计划状态 ,a.input_date -- 录入时间 ,a.end_date -- 计划结束时间 ,a.plan_name -- 计划名称 ,concat(left(trim(end_date),5),lpad(substring_index(substring_index(trim(end_date),'-',2),'-',-1),2,0),right(trim(end_date),3)) as end_ym ,a.finish_date -- 完成时间 ,TO_DAYS(a.end_date) - TO_DAYS(curdate()) AS day_diff FROM dw.dwd_operations_plan_info_d a, JSON_TABLE ( cast( CONCAT( '["', REPLACE ( executor, ',', '","' ), '"]' ) AS json ), "$[*]" COLUMNS ( executor INT PATH "$" ) ) AS jt WHERE TO_DAYS(a.end_date) - TO_DAYS(curdate()) <= 3 AND TO_DAYS(a.end_date) - TO_DAYS(curdate()) >= 1 )a left join ( select id ,subcompanyid1 -- 公司id ,lastname -- 执行人 from dw.ods_oa_hrmresource_d )b on a.executor = b.id inner join ( select id ,subcompanyname -- 公司名称 ,supsubcomid -- 父公司id from dw.ods_oa_hrmsubcompany_d )c on b.subcompanyid1 = c.id left join (select distinct oa_comm_id, oa_comm_name, oa_organ_code, oa_organ_name from dim_organ_mapping) d on b.subcompanyid1 = d.oa_comm_id where 1 = 1 ${if(len(p_startdate) == 0,"","and left(a.end_ym,7) = '" + p_startdate + "'")} UNION ALL SELECT '13' AS oa_organ_code ,'领悦集团总部' AS oa_organ_name FROM dual