From f71b65cf52960aad9f932a024d68e37563e6c943 Mon Sep 17 00:00:00 2001 From: Ruslan Date: Mon, 11 Nov 2024 15:04:03 +0300 Subject: [PATCH] fix --- .../region/total_registered.busyness(reg).ktr | 15 +- .../total_registered.driver_license(reg).ktr | 130 ++++++++++-------- .../total_registered.education_level(reg).ktr | 18 ++- 3 files changed, 98 insertions(+), 65 deletions(-) diff --git a/mappings/region/total_registered.busyness(reg).ktr b/mappings/region/total_registered.busyness(reg).ktr index 7179e38..6f62ea4 100644 --- a/mappings/region/total_registered.busyness(reg).ktr +++ b/mappings/region/total_registered.busyness(reg).ktr @@ -1292,7 +1292,10 @@ summary AS ( COUNT(CASE WHEN no_info_vuz AND no_info_college AND no_info_work THEN 1 END) AS no_info, -- Общее количество людей - COUNT(*) AS total_people + CASE + WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 + ELSE COUNT(*) + END AS total_people FROM status_info ) SELECT @@ -1421,7 +1424,10 @@ summary AS ( COUNT(CASE WHEN no_info_vuz AND no_info_college AND no_info_work THEN 1 END) AS no_info, -- Общее количество людей - COUNT(*) AS total_people + CASE + WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 + ELSE COUNT(*) + END AS total_people FROM status_info ) SELECT @@ -1550,7 +1556,10 @@ summary AS ( COUNT(CASE WHEN no_info_vuz AND no_info_college AND no_info_work THEN 1 END) AS no_info, -- Общее количество людей - COUNT(*) AS total_people + CASE + WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 + ELSE COUNT(*) + END AS total_people FROM status_info ) SELECT diff --git a/mappings/region/total_registered.driver_license(reg).ktr b/mappings/region/total_registered.driver_license(reg).ktr index c0f839f..ec128b6 100644 --- a/mappings/region/total_registered.driver_license(reg).ktr +++ b/mappings/region/total_registered.driver_license(reg).ktr @@ -1266,16 +1266,18 @@ SELECT r.id, r.gender, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "A")') AS has_A, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "B")') AS has_B, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "C")') AS has_C, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "D")') AS has_D, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "E")') AS has_E + -- Проверяем наличие хотя бы одной категории, используем DISTINCT для уникальных рекрутов + MAX(CASE WHEN cat->>'kategoriya' like '%A%' THEN 1 ELSE 0 END) AS has_A, + MAX(CASE WHEN cat->>'kategoriya' like '%B%' THEN 1 ELSE 0 END) AS has_B, + MAX(CASE WHEN cat->>'kategoriya' like '%C%' THEN 1 ELSE 0 END) AS has_C, + MAX(CASE WHEN cat->>'kategoriya' like '%D%' THEN 1 ELSE 0 END) AS has_D, + MAX(CASE WHEN cat->>'kategoriya' like '%E%' THEN 1 ELSE 0 END) AS has_E FROM public.recruits_info ri JOIN public.recruits r ON ri.recruit_id = r.id - WHERE r.vu_current_info -> 'isMilitaryRegistered' = 'true' - AND r.current_recruitment_id IS NOT NULL - AND ( + LEFT JOIN jsonb_array_elements(ri.info->'svedVoditUdost'->'voditUdost'->'svedKat') AS cat ON true + WHERE r.vu_current_info->>'isMilitaryRegistered' = 'true' + AND r.current_recruitment_id IS NOT NULL + AND ( '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' OR r.target_recruitment_id = ANY ( @@ -1284,27 +1286,29 @@ )::uuid[] ) ) + GROUP BY r.id, r.gender ), aggregated AS ( SELECT 'ALL' AS gender, '${REG_ID}' AS recruitment_id, - COUNT(*) FILTER (WHERE NOT has_A AND NOT has_B AND NOT has_C AND NOT has_D AND NOT has_E) AS nope, - COUNT(*) FILTER (WHERE has_A) AS a, - COUNT(*) FILTER (WHERE has_B) AS b, - COUNT(*) FILTER (WHERE has_C) AS c, - COUNT(*) FILTER (WHERE has_D) AS d, - COUNT(*) FILTER (WHERE has_E) AS e, - COUNT(*) AS total - FROM categorized + -- Считаем количество уникальных рекрутов с каждой категорией + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_A > 0) END AS a, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_B > 0) END AS b, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_C > 0) END AS c, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_D > 0) END AS d, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_E > 0) END AS e, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_A = 0 AND has_B = 0 AND has_C = 0 AND has_D = 0 AND has_E = 0) END AS nope, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) END AS total + FROM categorized r ) SELECT *, - CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((a * 100.0) / NULLIF(total, 0), 2) END AS a_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((b * 100.0) / NULLIF(total, 0), 2) END AS b_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((c * 100.0) / NULLIF(total, 0), 2) END AS c_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((d * 100.0) / NULLIF(total, 0), 2) END AS d_percent, - CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((e * 100.0) / NULLIF(total, 0), 2) END AS e_percent + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((e * 100.0) / NULLIF(total, 0), 2) END AS e_percent, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent FROM aggregated; 0 @@ -1341,17 +1345,18 @@ FROM aggregated; SELECT r.id, r.gender, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "A")') AS has_A, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "B")') AS has_B, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "C")') AS has_C, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "D")') AS has_D, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "E")') AS has_E + -- Проверяем наличие хотя бы одной категории, используем DISTINCT для уникальных рекрутов + MAX(CASE WHEN cat->>'kategoriya' like '%A%' THEN 1 ELSE 0 END) AS has_A, + MAX(CASE WHEN cat->>'kategoriya' like '%B%' THEN 1 ELSE 0 END) AS has_B, + MAX(CASE WHEN cat->>'kategoriya' like '%C%' THEN 1 ELSE 0 END) AS has_C, + MAX(CASE WHEN cat->>'kategoriya' like '%D%' THEN 1 ELSE 0 END) AS has_D, + MAX(CASE WHEN cat->>'kategoriya' like '%E%' THEN 1 ELSE 0 END) AS has_E FROM public.recruits_info ri JOIN public.recruits r ON ri.recruit_id = r.id - WHERE r.vu_current_info -> 'isMilitaryRegistered' = 'true' - AND r.gender = 'FEMALE' - AND r.current_recruitment_id IS NOT NULL - AND ( + LEFT JOIN jsonb_array_elements(ri.info->'svedVoditUdost'->'voditUdost'->'svedKat') AS cat ON true + WHERE r.vu_current_info->>'isMilitaryRegistered' = 'true' + AND r.current_recruitment_id IS NOT NULL + AND ( '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' OR r.target_recruitment_id = ANY ( @@ -1359,28 +1364,31 @@ FROM aggregated; trim(both '{}' FROM replace('${VK_ARRAY}', ' ', '')), ',' )::uuid[] ) - ) + ) + AND r.gender = 'FEMALE' + GROUP BY r.id, r.gender ), aggregated AS ( SELECT 'W' AS gender, - '${REG_ID}' AS recruitment_id, - COUNT(*) FILTER (WHERE NOT has_A AND NOT has_B AND NOT has_C AND NOT has_D AND NOT has_E) AS nope, - COUNT(*) FILTER (WHERE has_A) AS a, - COUNT(*) FILTER (WHERE has_B) AS b, - COUNT(*) FILTER (WHERE has_C) AS c, - COUNT(*) FILTER (WHERE has_D) AS d, - COUNT(*) FILTER (WHERE has_E) AS e, - COUNT(*) AS total - FROM categorized + '${REG_ID}' as recruitment_id, + -- Считаем количество уникальных рекрутов с каждой категорией + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_A > 0) END AS a, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_B > 0) END AS b, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_C > 0) END AS c, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_D > 0) END AS d, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_E > 0) END AS e, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_A = 0 AND has_B = 0 AND has_C = 0 AND has_D = 0 AND has_E = 0) END AS nope, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) END AS total + FROM categorized r ) SELECT *, - CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((a * 100.0) / NULLIF(total, 0), 2) END AS a_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((b * 100.0) / NULLIF(total, 0), 2) END AS b_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((c * 100.0) / NULLIF(total, 0), 2) END AS c_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((d * 100.0) / NULLIF(total, 0), 2) END AS d_percent, - CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((e * 100.0) / NULLIF(total, 0), 2) END AS e_percent + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((e * 100.0) / NULLIF(total, 0), 2) END AS e_percent, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent FROM aggregated; 0 @@ -1417,17 +1425,18 @@ FROM aggregated; SELECT r.id, r.gender, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "A")') AS has_A, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "B")') AS has_B, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "C")') AS has_C, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "D")') AS has_D, - jsonb_path_exists(ri.info, '$.svedVoditUdost.voditUdost.svedKat[*]?(@.kategoriya like_regex "E")') AS has_E + -- Проверяем наличие хотя бы одной категории, используем DISTINCT для уникальных рекрутов + MAX(CASE WHEN cat->>'kategoriya' like '%A%' THEN 1 ELSE 0 END) AS has_A, + MAX(CASE WHEN cat->>'kategoriya' like '%B%' THEN 1 ELSE 0 END) AS has_B, + MAX(CASE WHEN cat->>'kategoriya' like '%C%' THEN 1 ELSE 0 END) AS has_C, + MAX(CASE WHEN cat->>'kategoriya' like '%D%' THEN 1 ELSE 0 END) AS has_D, + MAX(CASE WHEN cat->>'kategoriya' like '%E%' THEN 1 ELSE 0 END) AS has_E FROM public.recruits_info ri JOIN public.recruits r ON ri.recruit_id = r.id - WHERE r.vu_current_info -> 'isMilitaryRegistered' = 'true' - AND r.gender = 'MALE' - AND r.current_recruitment_id IS NOT NULL - AND ( + LEFT JOIN jsonb_array_elements(ri.info->'svedVoditUdost'->'voditUdost'->'svedKat') AS cat ON true + WHERE r.vu_current_info->>'isMilitaryRegistered' = 'true' + AND r.current_recruitment_id IS NOT NULL + AND ( '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' OR r.target_recruitment_id = ANY ( @@ -1436,27 +1445,30 @@ FROM aggregated; )::uuid[] ) ) + AND r.gender = 'MALE' + GROUP BY r.id, r.gender ), aggregated AS ( SELECT 'M' AS gender, - '${REG_ID}' AS recruitment_id, - COUNT(*) FILTER (WHERE NOT has_A AND NOT has_B AND NOT has_C AND NOT has_D AND NOT has_E) AS nope, - COUNT(*) FILTER (WHERE has_A) AS a, - COUNT(*) FILTER (WHERE has_B) AS b, - COUNT(*) FILTER (WHERE has_C) AS c, - COUNT(*) FILTER (WHERE has_D) AS d, - COUNT(*) FILTER (WHERE has_E) AS e, - COUNT(*) AS total - FROM categorized + '${REG_ID}' as recruitment_id, + -- Считаем количество уникальных рекрутов с каждой категорией + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_A > 0) END AS a, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_B > 0) END AS b, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_C > 0) END AS c, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_D > 0) END AS d, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_E > 0) END AS e, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) FILTER (WHERE has_A = 0 AND has_B = 0 AND has_C = 0 AND has_D = 0 AND has_E = 0) END AS nope, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE COUNT(DISTINCT r.id) END AS total + FROM categorized r ) SELECT *, - CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((a * 100.0) / NULLIF(total, 0), 2) END AS a_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((b * 100.0) / NULLIF(total, 0), 2) END AS b_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((c * 100.0) / NULLIF(total, 0), 2) END AS c_percent, CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((d * 100.0) / NULLIF(total, 0), 2) END AS d_percent, - CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((e * 100.0) / NULLIF(total, 0), 2) END AS e_percent + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((e * 100.0) / NULLIF(total, 0), 2) END AS e_percent, + CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent FROM aggregated; 0 diff --git a/mappings/region/total_registered.education_level(reg).ktr b/mappings/region/total_registered.education_level(reg).ktr index 8cc9002..3303b75 100644 --- a/mappings/region/total_registered.education_level(reg).ktr +++ b/mappings/region/total_registered.education_level(reg).ktr @@ -1233,7 +1233,11 @@ ervu_person_registry WITH total_count AS ( - SELECT COUNT(*) AS total + SELECT + CASE + WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 + ELSE COUNT(*) + END AS total FROM public.recruits_info ri JOIN public.recruits r ON ri.recruit_id = r.id WHERE r.vu_current_info->>'isMilitaryRegistered' = 'true' @@ -1384,7 +1388,11 @@ FROM final_counts, total_count; ervu_person_registry WITH total_count AS ( - SELECT COUNT(*) AS total + SELECT + CASE + WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 + ELSE COUNT(*) + END AS total FROM public.recruits_info ri JOIN public.recruits r ON ri.recruit_id = r.id WHERE r.vu_current_info->>'isMilitaryRegistered' = 'true' AND r.gender = 'FEMALE' @@ -1535,7 +1543,11 @@ FROM final_counts, total_count; ervu_person_registry WITH total_count AS ( - SELECT COUNT(*) AS total + SELECT + CASE + WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 + ELSE COUNT(*) + END AS total FROM public.recruits_info ri JOIN public.recruits r ON ri.recruit_id = r.id WHERE r.vu_current_info->>'isMilitaryRegistered' = 'true' AND r.gender = 'MALE'