From 01b2840df26ff635d241f90664b1045fd7538cae Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?=D0=A2=D0=B8=D0=BC=D1=83=D1=80?= Date: Tue, 17 Jun 2025 12:19:18 +0300 Subject: [PATCH] ERVU-483 main_profile all lvl --- .../main_profile/main_profile.hpl | 272 ++++++++++++++++++ .../main_profile/main_profile.hwf | 126 ++++++++ .../main_profile/nlvl_main_profile.hpl | 210 ++++++++++++++ 3 files changed, 608 insertions(+) create mode 100644 mappings/info_recruits/main_profile/main_profile.hpl create mode 100644 mappings/info_recruits/main_profile/main_profile.hwf create mode 100644 mappings/info_recruits/main_profile/nlvl_main_profile.hpl diff --git a/mappings/info_recruits/main_profile/main_profile.hpl b/mappings/info_recruits/main_profile/main_profile.hpl new file mode 100644 index 0000000..1726bc2 --- /dev/null +++ b/mappings/info_recruits/main_profile/main_profile.hpl @@ -0,0 +1,272 @@ + + + + main_profile + Y + + + + Normal + + + N + 1000 + 100 + - + 2025/06/17 10:17:01.438 + - + 2025/06/17 10:17:01.438 + + + + + + Table input main profile + Table output + N + + + Table input main profile + Value mapper main profile + Y + + + Value mapper main profile + Insert / update main profile + Y + + + + Table input main profile + TableInput + + Y + + 1 + + none + + + ervu-dashboard + N + 0 + SELECT + c.recruitment_id, + ROUND(AVG(DATE_PART('year', AGE(CURRENT_DATE, c.birth_date)))::numeric, 0) AS avg_age, + MODE() WITHIN GROUP (ORDER BY c.gender) AS most_common_gender, + MODE() WITHIN GROUP (ORDER BY c.employment) AS most_common_employment, + ROUND(AVG(COALESCE(child_counts.child_count, 0))::numeric, 0) AS avg_children, + MODE() WITHIN GROUP (ORDER BY education_groups.highest_group) AS most_common_education_group, + current_date recording_date, + 'Department' as schema +FROM citizen c +LEFT JOIN ( + SELECT + recruit_id, + COUNT(*) AS child_count + FROM citizen_child + WHERE death_date IS NULL + AND DATE_PART('year', AGE(CURRENT_DATE, birth_date)) < 18 + GROUP BY recruit_id +) child_counts ON c.recruit_id = child_counts.recruit_id +LEFT JOIN ( + SELECT + recruit_id, + MIN(CASE + WHEN education_level_code IN ('1', '2', '3', '4', '5') THEN 1 -- Высшее + WHEN education_level_code IN ('10', '11') THEN 2 -- Среднее проф. + WHEN education_level_code IN ('7', '9') THEN 3 -- Общее + ELSE 4 -- Прочее/неизвестное + END) AS highest_group + FROM citizen_foreign_education_diploma + GROUP BY recruit_id +) education_groups ON c.recruit_id = education_groups.recruit_id +--join appeals.appeals_list al on c.system_esia_id = al.system_esia_id +GROUP BY c.recruitment_id +HAVING c.recruitment_id IS NOT NULL; + N + + + 304 + 256 + + + + Table output + TableOutput + + Y + + 1 + + none + + + 1000 + ervu-dashboard + + + gender + most_common_gender + + + age + avg_age + + + education + most_common_education_group + + + employment + most_common_employment + + + child_min_18 + avg_children + + + schema + schema + + + recruitment_id + recruitment_id + + + N + N + N + N + + Y + + N + appeals + Y + main_profile
+ + N + Y + N + Y + + + 560 + 400 + +
+ + Insert / update main profile + InsertUpdate + + Y + + 1 + + none + + + 100 + ervu-dashboard + + + = + recruitment_id + recruitment_id + + + + = + recording_date + recording_date + + + appeals + main_profile
+ + age + avg_age + Y + + + child_min_18 + avg_children + Y + + + education + most_common_education_group + Y + + + employment + most_common_employment + Y + + + gender + most_common_gender + Y + + + recording_date + recording_date + Y + + + recruitment_id + recruitment_id + Y + + + schema + schema + Y + +
+ N + + + 800 + 256 + +
+ + Value mapper main profile + ValueMapper + + Y + + 1 + + none + + + most_common_education_group + + + 1 + Высшее + + + 2 + Среднее проф. + + + 3 + Общее + + + + + + + 528 + 256 + + + + + +
diff --git a/mappings/info_recruits/main_profile/main_profile.hwf b/mappings/info_recruits/main_profile/main_profile.hwf new file mode 100644 index 0000000..45ddbd8 --- /dev/null +++ b/mappings/info_recruits/main_profile/main_profile.hwf @@ -0,0 +1,126 @@ + + + main_profile + Y + + + + - + 2025/06/17 10:16:58.535 + - + 2025/06/17 10:16:58.535 + + + + + Start + + SPECIAL + + 1 + 12 + 60 + 0 + 0 + N + 0 + 1 + N + 192 + 368 + + + + main_profile.hpl + + PIPELINE + + N + N + N + N + N + N + ${PROJECT_HOME}/info_recruits/main_profile/main_profile.hpl + + + Basic + + Y + + N + local + N + N + Y + N + 336 + 368 + + + + nlvl_main_profile.hpl + + PIPELINE + + N + N + N + N + N + N + ${PROJECT_HOME}/info_recruits/main_profile/nlvl_main_profile.hpl + + + Basic + + Y + + N + local + N + N + Y + N + 496 + 368 + + + + Success + + SUCCESS + + N + 656 + 368 + + + + + + Start + main_profile.hpl + Y + Y + Y + + + main_profile.hpl + nlvl_main_profile.hpl + Y + Y + N + + + nlvl_main_profile.hpl + Success + Y + Y + N + + + + + + diff --git a/mappings/info_recruits/main_profile/nlvl_main_profile.hpl b/mappings/info_recruits/main_profile/nlvl_main_profile.hpl new file mode 100644 index 0000000..1be13c2 --- /dev/null +++ b/mappings/info_recruits/main_profile/nlvl_main_profile.hpl @@ -0,0 +1,210 @@ + + + + nlvl_main_profile + Y + + + + Normal + + + N + 1000 + 100 + - + 2025/06/17 10:49:22.576 + - + 2025/06/17 10:49:22.576 + + + + + + Table input nlvl main profile + Insert / update nlvl main profile + Y + + + + Table input nlvl main profile + TableInput + + Y + + 1 + + none + + + ervu-dashboard + N + 0 + --- next_level_org + +WITH latest_hierarchy AS ( + -- Берем только записи с максимальной версией для каждого idm_id + SELECT DISTINCT ON (idm_id) * + FROM ervu_dashboard.recruitment + ORDER BY idm_id +), +latest_date AS ( + -- Определяем последнюю дату загрузки + SELECT MAX(recording_date) AS max_date FROM appeals.main_profile +), +filtered_records AS ( + -- Фильтруем данные, оставляя только записи с последней датой загрузки + SELECT id_main_profile, gender, age, child_min_18, education, employment, recording_date, recruitment_id, "schema" FROM appeals.main_profile + WHERE recording_date = (SELECT max_date FROM latest_date) +), +hierarchy_cte AS ( + -- Строим связи между уровнями (Department → Organization → Region → Ministry) + SELECT + h.idm_id AS department_id, + h.parent_id AS organization_id, + h2.parent_id AS region_id, + h3.parent_id AS ministry_id + FROM latest_hierarchy h + LEFT JOIN latest_hierarchy h2 ON h.parent_id = h2.idm_id -- Organization + LEFT JOIN latest_hierarchy h3 ON h2.parent_id = h3.idm_id -- Region + WHERE h.schema = 'Department' -- Начинаем с Department +), +aggregated_counts AS ( + -- Агрегируем для Organization + SELECT + h.organization_id AS level_id, + ROUND(AVG(age)::numeric, 0) avg_age, + MODE() WITHIN GROUP (ORDER BY gender) AS most_common_gender, + MODE() WITHIN GROUP (ORDER BY employment) AS most_common_employment, + ROUND(AVG(child_min_18)::numeric, 0) AS avg_child_min_18, + MODE() WITHIN GROUP (ORDER BY education) AS most_common_education, + MAX(r.recording_date) as recording_date, + 'Organization' AS level + FROM filtered_records r + JOIN hierarchy_cte h ON r.recruitment_id = h.department_id + WHERE h.organization_id IS NOT NULL + GROUP BY h.organization_id + + UNION ALL + + -- Агрегируем для Region + SELECT + h.region_id AS level_id, + ROUND(AVG(age)::numeric, 0) avg_age, + MODE() WITHIN GROUP (ORDER BY gender) AS most_common_gender, + MODE() WITHIN GROUP (ORDER BY employment) AS most_common_employment, + ROUND(AVG(child_min_18)::numeric, 0) AS avg_child_min_18, + MODE() WITHIN GROUP (ORDER BY education) AS most_common_education, + MAX(r.recording_date) as recording_date, + 'Region' AS level + FROM filtered_records r + JOIN hierarchy_cte h ON r.recruitment_id = h.department_id + WHERE h.region_id IS NOT NULL + GROUP BY h.region_id + + UNION ALL + + -- Агрегируем для Ministry + SELECT + h.ministry_id AS level_id, + ROUND(AVG(age)::numeric, 0) avg_age, + MODE() WITHIN GROUP (ORDER BY gender) AS most_common_gender, + MODE() WITHIN GROUP (ORDER BY employment) AS most_common_employment, + ROUND(AVG(child_min_18)::numeric, 0) AS avg_child_min_18, + MODE() WITHIN GROUP (ORDER BY education) AS most_common_education, + MAX(r.recording_date) as recording_date, + 'Ministry' AS level + FROM filtered_records r + JOIN hierarchy_cte h ON r.recruitment_id = h.department_id + WHERE h.ministry_id IS NOT NULL + GROUP BY h.ministry_id +) +SELECT * FROM aggregated_counts; + + N + + + 608 + 352 + + + + Insert / update nlvl main profile + InsertUpdate + + Y + + 1 + + none + + + 100 + ervu-dashboard + + + = + recruitment_id + level_id + + + + = + recording_date + recording_date + + + appeals + main_profile
+ + age + avg_age + Y + + + child_min_18 + avg_child_min_18 + Y + + + education + most_common_education + Y + + + employment + most_common_employment + Y + + + gender + most_common_gender + Y + + + recording_date + recording_date + Y + + + schema + level + Y + + + recruitment_id + level_id + Y + +
+ N + + + 784 + 368 + +
+ + + +