leading-project/finereport/xiazuan/2_operation/计划到期明细.sql

142 lines
6.0 KiB
MySQL
Raw Normal View History

2024-07-22 18:51:46 +08:00
-- ****************************************
-- 创建人员: 杨坤安
-- 创建日期: 2024-07-18
-- 功 能: 帆软明细报表-计划到期明细
-- 目 录: xianzuan>2_运营>计划到期明细.fvs
-- ****************************************
-- 【数据集: report_计划到期】
select
${if(len(p_area) == 0,"c.organ_name","c.comm_name")} 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 -- 计划等级
,left(a.start_date,7) as ym -- 计划开始年月
,a.start_dt as start_dt -- 计划开始时
,a.end_date as end_date -- 计划结束时间
2024-07-22 18:51:46 +08:00
,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 -- 责任人名称
2024-07-22 18:51:46 +08:00
,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 -- 责任人
2024-07-22 18:51:46 +08:00
,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 -- 评价标准
FROM dw.dwd_operations_plan_info_d a,
JSON_TABLE (
cast( CONCAT( '["', REPLACE ( responsible_person1, ',', '","' ), '"]' ) AS json ),
"$[*]" COLUMNS ( responsible_person1 INT PATH "$" )
2024-07-22 18:51:46 +08:00
) 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')
2024-07-22 18:51:46 +08:00
)a
left join
(
select
id
,subcompanyid1 -- 公司id
,lastname -- 执行人
from dw.ods_oa_hrmresource_d
)b
on a.responsible_person1 = b.id
left join
2024-07-22 18:51:46 +08:00
(
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
2024-07-22 18:51:46 +08:00
)c
on b.subcompanyid1 = c.oa_comm_id
where 1 = 1
2024-07-22 18:51:46 +08:00
${if(len(p_startdate) == 0,"","and left(a.end_ym,7) = '" + p_startdate + "'")}
${IF(LEN(p_area)!=0," and organ_code IN ('"+p_area+"')","")}
2024-07-22 18:51:46 +08:00
-- 【筛选框数据集: 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