From 857e962055a0790ba6aeb29bf4f7d05a38fd453f Mon Sep 17 00:00:00 2001 From: Ruslan Date: Fri, 28 Mar 2025 11:09:42 +0300 Subject: [PATCH] fix subpoenas --- .../m_d.rec_cam(m_c)_to_subpoena_registry.hpl | 72 +++++++--- ...rec_cam(m_c)_to_subpoena_registry_uniq.hpl | 133 ++++++++++++------ .../recruitment_campaign.subpoenas(m_c).hpl | 92 +++++++++--- .../total_registered.subpoenas(m_c).hpl | 99 ++++++++----- 4 files changed, 274 insertions(+), 122 deletions(-) diff --git a/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry.hpl b/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry.hpl index d89748d..e1ba69a 100644 --- a/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry.hpl +++ b/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry.hpl @@ -46,12 +46,12 @@ ids AS ( SELECT unnest(string_to_array(trim(both '{}' from '${ARR_MC}'), ','))::uuid AS recruitment_id ), subpoena_data AS ( - SELECT + SELECT s.id AS subpoena_id, s.create_date, - s.department_id AS recruitment_id, + s.visit_date, + s.department_id::uuid AS recruitment_id, s.status_id, - sr.type, ssh.code AS sub_stat_hist, s.send_date, sh.date_time::timestamp AS history_date, @@ -59,18 +59,45 @@ subpoena_data AS ( rdi.applied_date AS ap_date, rdi.id AS rdi_id, ssi.delivery_code AS d_code, - ssi.act_number, - ROW_NUMBER() OVER (PARTITION BY s.id ORDER BY sh.date_time DESC) AS rn - FROM public.subpoena s - JOIN public.subpoena_history AS sh ON sh.subpoena_id = s.id - JOIN public.subpoena_status AS ss ON ss.id = s.status_id - JOIN public.subpoena_status AS ssh ON ssh.id = sh.status_id - JOIN public.subpoena_reason AS sr ON sr.id = s.reason_id - LEFT JOIN public.restriction_document AS rd ON rd.subpoena_id = s.id - LEFT JOIN public.restriction_document_item AS rdi ON rdi.restriction_document_create_id = rd.id - LEFT JOIN public.subpoena_send_info AS ssi ON ssi.subpoena_id = s.id - WHERE sr.type = '3' - AND ssh.code NOT IN ('3.7','3.72', '3.71') + ssi.act_number + FROM subpoena s + JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY date_time DESC) AS rn, + subpoena_id, + status_id, + date_time + FROM subpoena_history sh + ) sh on sh.subpoena_id = s.id + JOIN subpoena_status AS ssh ON ssh.id = sh.status_id + JOIN subpoena_reason AS sr ON sr.id = s.reason_id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY created_at DESC) AS rn_d, + subpoena_id, + id + FROM restriction_document + ) AS rd ON rd.subpoena_id = s.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY restriction_document_create_id ORDER BY created_at DESC) AS rn_di, + restriction_document_create_id, + restriction_document_cancel_id, + applied_date, + id + FROM restriction_document_item + ) AS rdi ON rdi.restriction_document_create_id = rd.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY send_date DESC) AS rn_si, + subpoena_id, + delivery_code, + act_number + FROM subpoena_send_info + ) AS ssi ON ssi.subpoena_id = s.id + WHERE sh.rn = 1 AND rd.rn_d = 1 AND rdi.rn_di = 1 AND ssi.rn_si = 1 + AND sr.type = '3' + AND ssh.code NOT IN ('3.7','3.72', '3.71') -- 3.14 снесено от 14.03.2025 AND s.department_id::uuid IN (SELECT recruitment_id FROM ids) AND EXISTS ( SELECT 1 @@ -79,15 +106,11 @@ subpoena_data AS ( AND sh2.status_id = (SELECT id FROM subpoena_status WHERE code = '3') ) ), -last_status AS ( - SELECT * - FROM subpoena_data - WHERE rn = 1 -), season_separations AS ( SELECT DISTINCT ls.recruitment_id, ls.create_date, + ls.visit_date, ls.sub_stat_hist, ls.subpoena_id, ls.history_date, @@ -105,8 +128,13 @@ season_separations AS ( AND DATE_TRUNC('year', ls.create_date) + INTERVAL '12 months' + INTERVAL '31 days') THEN 'Осень' END AS spring_autumn - FROM last_status ls - --WHERE ls.create_date >= DATE_TRUNC('year', CURRENT_DATE) + FROM subpoena_data ls + WHERE --ls.create_date >= DATE_TRUNC('year', CURRENT_DATE) + ((ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '3 months' + INTERVAL '1 day' + AND DATE_TRUNC('year', ls.create_date) + INTERVAL '6 months' + INTERVAL '15 days') + or + (ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '9 months' + INTERVAL '1 day' + AND DATE_TRUNC('year', ls.create_date) + INTERVAL '12 months' + INTERVAL '31 days')) ), season_separations_clean AS ( SELECT DISTINCT recruitment_id, spring_autumn FROM season_separations diff --git a/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry_uniq.hpl b/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry_uniq.hpl index 9efb73b..dc6fc55 100644 --- a/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry_uniq.hpl +++ b/v1_apache-hop dash mapping/mil_com/main_dashboard.recruitment_campaign(m_c)/m_d.rec_cam(m_c)_to_subpoena_registry_uniq.hpl @@ -51,13 +51,13 @@ ids AS ( SELECT unnest(string_to_array(nullif(trim(both '{}' from '${ARR_MC_AU}'), ''), ','))::uuid AS recruitment_id, 'Осень' AS spring_autumn ), -subpoena_data AS ( - SELECT +subpoena_data AS ( + SELECT s.id AS subpoena_id, s.create_date, - s.department_id AS recruitment_id, + s.visit_date, + s.department_id::uuid AS recruitment_id, s.status_id, - sr.type, ssh.code AS sub_stat_hist, s.send_date, sh.date_time::timestamp AS history_date, @@ -66,19 +66,46 @@ subpoena_data AS ( rdi.id AS rdi_id, ssi.delivery_code AS d_code, ssi.act_number, - 'Весна' AS season, - ROW_NUMBER() OVER (PARTITION BY s.id ORDER BY sh.date_time DESC) AS rn - FROM public.subpoena s - JOIN public.subpoena_history AS sh ON sh.subpoena_id = s.id - JOIN public.subpoena_status AS ss ON ss.id = s.status_id - JOIN public.subpoena_status AS ssh ON ssh.id = sh.status_id - JOIN public.subpoena_reason AS sr ON sr.id = s.reason_id - LEFT JOIN public.restriction_document AS rd ON rd.subpoena_id = s.id - LEFT JOIN public.restriction_document_item AS rdi ON rdi.restriction_document_create_id = rd.id - LEFT JOIN public.subpoena_send_info AS ssi ON ssi.subpoena_id = s.id - WHERE sr.type = '3' - AND ssh.code NOT IN ('3.7','3.72', '3.71') - AND s.department_id::uuid IN (SELECT recruitment_id FROM ids WHERE spring_autumn = 'Весна') + 'Весна' AS season + FROM subpoena s + JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY date_time DESC) AS rn, + subpoena_id, + status_id, + date_time + FROM subpoena_history sh + ) sh on sh.subpoena_id = s.id + JOIN subpoena_status AS ssh ON ssh.id = sh.status_id + JOIN subpoena_reason AS sr ON sr.id = s.reason_id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY created_at DESC) AS rn_d, + subpoena_id, + id + FROM restriction_document + ) AS rd ON rd.subpoena_id = s.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY restriction_document_create_id ORDER BY created_at DESC) AS rn_di, + restriction_document_create_id, + restriction_document_cancel_id, + applied_date, + id + FROM restriction_document_item + ) AS rdi ON rdi.restriction_document_create_id = rd.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY send_date DESC) AS rn_si, + subpoena_id, + delivery_code, + act_number + FROM subpoena_send_info + ) AS ssi ON ssi.subpoena_id = s.id + WHERE sh.rn = 1 AND rd.rn_d = 1 AND rdi.rn_di = 1 AND ssi.rn_si = 1 + AND sr.type = '3' + AND ssh.code NOT IN ('3.7','3.72', '3.71') -- 3.14 снесено от 14.03.2025 + AND s.department_id::uuid IN (SELECT recruitment_id FROM ids) AND EXISTS ( SELECT 1 FROM subpoena_history sh2 @@ -86,12 +113,12 @@ subpoena_data AS ( AND sh2.status_id = (SELECT id FROM subpoena_status WHERE code = '3') ) UNION ALL - SELECT + SELECT s.id AS subpoena_id, s.create_date, - s.department_id AS recruitment_id, + s.visit_date, + s.department_id::uuid AS recruitment_id, s.status_id, - sr.type, ssh.code AS sub_stat_hist, s.send_date, sh.date_time::timestamp AS history_date, @@ -100,19 +127,46 @@ subpoena_data AS ( rdi.id AS rdi_id, ssi.delivery_code AS d_code, ssi.act_number, - 'Осень' AS season, - ROW_NUMBER() OVER (PARTITION BY s.id ORDER BY sh.date_time DESC) AS rn - FROM public.subpoena s - JOIN public.subpoena_history AS sh ON sh.subpoena_id = s.id - JOIN public.subpoena_status AS ss ON ss.id = s.status_id - JOIN public.subpoena_status AS ssh ON ssh.id = sh.status_id - JOIN public.subpoena_reason AS sr ON sr.id = s.reason_id - LEFT JOIN public.restriction_document AS rd ON rd.subpoena_id = s.id - LEFT JOIN public.restriction_document_item AS rdi ON rdi.restriction_document_create_id = rd.id - LEFT JOIN public.subpoena_send_info AS ssi ON ssi.subpoena_id = s.id - WHERE sr.type = '3' - AND ssh.code NOT IN ('3.7','3.72', '3.71') - AND s.department_id::uuid IN (SELECT recruitment_id FROM ids WHERE spring_autumn = 'Осень') + 'Осень' AS season + FROM subpoena s + JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY date_time DESC) AS rn, + subpoena_id, + status_id, + date_time + FROM subpoena_history sh + ) sh on sh.subpoena_id = s.id + JOIN subpoena_status AS ssh ON ssh.id = sh.status_id + JOIN subpoena_reason AS sr ON sr.id = s.reason_id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY created_at DESC) AS rn_d, + subpoena_id, + id + FROM restriction_document + ) AS rd ON rd.subpoena_id = s.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY restriction_document_create_id ORDER BY created_at DESC) AS rn_di, + restriction_document_create_id, + restriction_document_cancel_id, + applied_date, + id + FROM restriction_document_item + ) AS rdi ON rdi.restriction_document_create_id = rd.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY send_date DESC) AS rn_si, + subpoena_id, + delivery_code, + act_number + FROM subpoena_send_info + ) AS ssi ON ssi.subpoena_id = s.id + WHERE sh.rn = 1 AND rd.rn_d = 1 AND rdi.rn_di = 1 AND ssi.rn_si = 1 + AND sr.type = '3' + AND ssh.code NOT IN ('3.7','3.72', '3.71') -- 3.14 снесено от 14.03.2025 + AND s.department_id::uuid IN (SELECT recruitment_id FROM ids) AND EXISTS ( SELECT 1 FROM subpoena_history sh2 @@ -120,15 +174,11 @@ subpoena_data AS ( AND sh2.status_id = (SELECT id FROM subpoena_status WHERE code = '3') ) ), -last_status AS ( - SELECT * - FROM subpoena_data - WHERE rn = 1 -), season_separations AS ( SELECT DISTINCT ls.recruitment_id, ls.create_date, + ls.visit_date, ls.sub_stat_hist, ls.subpoena_id, ls.history_date, @@ -139,16 +189,19 @@ season_separations AS ( ls.act_number, ls.rdi_id, ls.season AS spring_autumn - FROM last_status ls + FROM subpoena_data ls WHERE (ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '4 months' + INTERVAL '1 day' AND DATE_TRUNC('year', ls.create_date) + INTERVAL '7 months' + INTERVAL '14 days') AND ls.season = 'Весна' + --WHERE ls.create_date >= DATE_TRUNC('year', CURRENT_DATE) + UNION ALL SELECT DISTINCT ls.recruitment_id, ls.create_date, + ls.visit_date, ls.sub_stat_hist, ls.subpoena_id, ls.history_date, @@ -159,7 +212,7 @@ season_separations AS ( ls.act_number, ls.rdi_id, ls.season AS spring_autumn - FROM last_status ls + FROM subpoena_data ls WHERE (ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '10 months' + INTERVAL '1 day' AND DATE_TRUNC('year', ls.create_date) + INTERVAL '12 months' + INTERVAL '30 days') AND ls.season = 'Осень' diff --git a/v1_apache-hop dash mapping/mil_com/recruitment_campaign.subpoenas(m_c).hpl b/v1_apache-hop dash mapping/mil_com/recruitment_campaign.subpoenas(m_c).hpl index 5bae844..63fc670 100644 --- a/v1_apache-hop dash mapping/mil_com/recruitment_campaign.subpoenas(m_c).hpl +++ b/v1_apache-hop dash mapping/mil_com/recruitment_campaign.subpoenas(m_c).hpl @@ -290,9 +290,9 @@ subpoena_data AS ( SELECT s.id AS subpoena_id, s.create_date, - s.department_id AS recruitment_id, + s.visit_date, + s.department_id::uuid AS recruitment_id, s.status_id, - sr.type, ssh.code AS sub_stat_hist, s.send_date, sh.date_time::timestamp AS history_date, @@ -300,18 +300,45 @@ subpoena_data AS ( rdi.applied_date AS ap_date, rdi.id AS rdi_id, ssi.delivery_code AS d_code, - ssi.act_number, - ROW_NUMBER() OVER (PARTITION BY s.id ORDER BY sh.date_time DESC) AS rn + ssi.act_number FROM subpoena s - JOIN subpoena_history AS sh ON sh.subpoena_id = s.id - JOIN subpoena_status AS ss ON ss.id = s.status_id + JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY date_time DESC) AS rn, + subpoena_id, + status_id, + date_time + FROM subpoena_history sh + ) sh on sh.subpoena_id = s.id JOIN subpoena_status AS ssh ON ssh.id = sh.status_id JOIN subpoena_reason AS sr ON sr.id = s.reason_id - LEFT JOIN restriction_document AS rd ON rd.subpoena_id = s.id - LEFT JOIN restriction_document_item AS rdi ON rdi.restriction_document_create_id = rd.id - LEFT JOIN subpoena_send_info AS ssi ON ssi.subpoena_id = s.id - WHERE sr.type = '3' - AND ssh.code NOT IN ('3.7','3.72', '3.71') + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY created_at DESC) AS rn_d, + subpoena_id, + id + FROM restriction_document + ) AS rd ON rd.subpoena_id = s.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY restriction_document_create_id ORDER BY created_at DESC) AS rn_di, + restriction_document_create_id, + restriction_document_cancel_id, + applied_date, + id + FROM restriction_document_item + ) AS rdi ON rdi.restriction_document_create_id = rd.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY send_date DESC) AS rn_si, + subpoena_id, + delivery_code, + act_number + FROM subpoena_send_info + ) AS ssi ON ssi.subpoena_id = s.id + WHERE sh.rn = 1 AND rd.rn_d = 1 AND rdi.rn_di = 1 AND ssi.rn_si = 1 + AND sr.type = '3' + AND ssh.code NOT IN ('3.7','3.72', '3.71') -- 3.14 снесено от 14.03.2025 AND s.department_id::uuid IN (SELECT recruitment_id FROM ids) AND EXISTS ( SELECT 1 @@ -320,15 +347,11 @@ subpoena_data AS ( AND sh2.status_id = (SELECT id FROM subpoena_status WHERE code = '3') ) ), -last_status AS ( - SELECT * - FROM subpoena_data - WHERE rn = 1 -), season_separations AS ( SELECT distinct ls.recruitment_id, ls.create_date, + ls.visit_date, ls.sub_stat_hist, ls.subpoena_id, ls.history_date, @@ -339,11 +362,21 @@ season_separations AS ( ls.act_number, ls.rdi_id, CASE - WHEN EXTRACT(MONTH FROM ls.create_date) BETWEEN 1 AND 6 THEN 'Весна' - WHEN EXTRACT(MONTH FROM ls.create_date) BETWEEN 7 AND 12 THEN 'Осень' + WHEN (ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '3 months' + INTERVAL '1 day' + AND DATE_TRUNC('year', ls.create_date) + INTERVAL '6 months' + INTERVAL '15 days') + THEN 'Весна' + WHEN (ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '9 months' + INTERVAL '1 day' + AND DATE_TRUNC('year', ls.create_date) + INTERVAL '12 months' + INTERVAL '31 days') + THEN 'Осень' END AS spring_autumn - FROM last_status ls - WHERE ls.create_date >= DATE_TRUNC('year', CURRENT_DATE) + FROM subpoena_data ls + WHERE --ls.create_date >= DATE_TRUNC('year', CURRENT_DATE) + --AND + ((ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '3 months' + INTERVAL '1 day' + AND DATE_TRUNC('year', ls.create_date) + INTERVAL '6 months' + INTERVAL '15 days') + OR + (ls.create_date BETWEEN DATE_TRUNC('year', ls.create_date) + INTERVAL '9 months' + INTERVAL '1 day' + AND DATE_TRUNC('year', ls.create_date) + INTERVAL '12 months' + INTERVAL '31 days')) ), season_separations_clean AS ( SELECT DISTINCT recruitment_id, spring_autumn FROM season_separations @@ -361,9 +394,24 @@ t2 AS ( SELECT ss.recruitment_id, ss.spring_autumn, - ROUND(AVG(EXTRACT(DAY FROM (history_date::timestamp - send_date::timestamp))), 1) AS average_appeared + ROUND( + AVG( + CASE + WHEN ss.sub_stat_hist = '4.2' THEN + GREATEST(EXTRACT(DAY FROM (ss.history_date::timestamp - ss.visit_date::timestamp)), 0) + ELSE + GREATEST(EXTRACT(DAY FROM (CURRENT_DATE::timestamp - ss.visit_date::timestamp)), 0) + END + ) FILTER (WHERE + CASE + WHEN ss.sub_stat_hist = '4.2' THEN + EXTRACT(DAY FROM (ss.history_date::timestamp - ss.visit_date::timestamp)) + ELSE + EXTRACT(DAY FROM (CURRENT_DATE::timestamp - ss.visit_date::timestamp)) + END > 0 + ), 1 + ) AS average_appeared FROM season_separations ss - WHERE ss.sub_stat_hist IN ('4.1', '4.2') -- снесен 4 статус от 14.03.2025 GROUP BY ss.recruitment_id, ss.spring_autumn ), t3 AS ( diff --git a/v1_apache-hop dash mapping/mil_com/total_registered.subpoenas(m_c).hpl b/v1_apache-hop dash mapping/mil_com/total_registered.subpoenas(m_c).hpl index 6bbc234..54fab14 100644 --- a/v1_apache-hop dash mapping/mil_com/total_registered.subpoenas(m_c).hpl +++ b/v1_apache-hop dash mapping/mil_com/total_registered.subpoenas(m_c).hpl @@ -324,16 +324,44 @@ subpoena_data AS ( rdi.id AS rdi_id, ssi.delivery_code AS d_code, ssi.act_number, - s.visit_date, - ROW_NUMBER() OVER (PARTITION BY s.id ORDER BY sh.date_time DESC) AS rn + s.visit_date FROM subpoena s - JOIN subpoena_history AS sh ON sh.subpoena_id = s.id + JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY date_time DESC) AS rn, + subpoena_id, + status_id, + date_time + FROM subpoena_history sh + ) sh on sh.subpoena_id = s.id JOIN subpoena_status AS ssh ON ssh.id = sh.status_id JOIN subpoena_reason AS sr ON sr.id = s.reason_id - LEFT JOIN restriction_document AS rd ON rd.subpoena_id = s.id - LEFT JOIN restriction_document_item AS rdi ON rdi.restriction_document_create_id = rd.id - LEFT JOIN subpoena_send_info AS ssi ON ssi.subpoena_id = s.id - WHERE sr.type IS NOT NULL + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY created_at DESC) AS rn_d, + subpoena_id, + id + FROM restriction_document + ) AS rd ON rd.subpoena_id = s.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY restriction_document_create_id ORDER BY created_at DESC) AS rn_di, + restriction_document_create_id, + restriction_document_cancel_id, + applied_date, + id + FROM restriction_document_item + ) AS rdi ON rdi.restriction_document_create_id = rd.id + LEFT JOIN ( + SELECT + ROW_NUMBER() OVER (PARTITION BY subpoena_id ORDER BY send_date DESC) AS rn_si, + subpoena_id, + delivery_code, + act_number + FROM subpoena_send_info + ) AS ssi ON ssi.subpoena_id = s.id + WHERE sh.rn = 1 AND rd.rn_d = 1 AND rdi.rn_di = 1 AND ssi.rn_si = 1 + AND sr.type IS NOT NULL AND ssh.code NOT IN ('3.7','3.72', '3.71') -- 3.14 снесено от 14.03.2025 AND s.department_id::uuid IN (SELECT recruitment_id FROM ids) AND EXISTS ( @@ -343,24 +371,19 @@ subpoena_data AS ( AND sh2.status_id = (SELECT id FROM subpoena_status WHERE code = '3') ) ), -last_status AS ( - SELECT * - FROM subpoena_data - WHERE rn = 1 -), uniq_ls AS ( SELECT distinct department_id, mil_reg - FROM last_status + FROM subpoena_data ), t1 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_subpoena - FROM last_status ls + COUNT(subpoena_id) AS count_subpoena + FROM subpoena_data ls WHERE sub_stat_hist IS NOT NULL GROUP BY ls.department_id, ls.mil_reg ), @@ -385,15 +408,15 @@ SELECT END > 0 ), 1 ) AS average_appeared -FROM last_status ls +FROM subpoena_data ls GROUP BY ls.department_id, ls.mil_reg ), t3 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_appeared - FROM last_status ls + COUNT(subpoena_id) AS count_appeared + FROM subpoena_data ls WHERE sub_stat_hist IN ('4.1', '4.2') -- снесен 4 статус от 14.03.2025 GROUP BY ls.department_id, ls.mil_reg ), @@ -401,8 +424,8 @@ t4 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_not_appeared - FROM last_status ls + COUNT(subpoena_id) AS count_not_appeared + FROM subpoena_data ls WHERE sub_stat_hist = '5' GROUP BY ls.department_id, ls.mil_reg ), @@ -410,8 +433,8 @@ t5 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_not_ap_good_reason -- не явились по уважительной причине - FROM last_status ls + COUNT(subpoena_id) AS count_not_ap_good_reason -- не явились по уважительной причине + FROM subpoena_data ls WHERE sub_stat_hist = '5.1' GROUP BY ls.department_id, ls.mil_reg ), @@ -419,8 +442,8 @@ t6 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_ap_not_required -- явка не требуется - FROM last_status ls + COUNT(subpoena_id) AS count_ap_not_required -- явка не требуется + FROM subpoena_data ls WHERE sub_stat_hist IN ('3.8', '5.2') GROUP BY ls.department_id, ls.mil_reg ), @@ -428,8 +451,8 @@ t7 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT rdi_id) AS count_restrictions_applied - FROM last_status ls + COUNT(rdi_id) AS count_restrictions_applied + FROM subpoena_data ls WHERE rdi_id IS NOT NULL AND restr_dc IS NULL GROUP BY ls.department_id, ls.mil_reg ), @@ -437,8 +460,8 @@ t8 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT rdi_id) AS count_introduced_measures - FROM last_status ls + COUNT(rdi_id) AS count_introduced_measures + FROM subpoena_data ls WHERE rdi_id IS NOT NULL AND restr_dc IS NULL AND ap_date IS NOT NULL GROUP BY ls.department_id, ls.mil_reg ), @@ -446,8 +469,8 @@ t9 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_paper - FROM last_status ls + COUNT(subpoena_id) AS count_paper + FROM subpoena_data ls WHERE d_code != '7' GROUP BY ls.department_id, ls.mil_reg ), @@ -455,8 +478,8 @@ t10 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_electron - FROM last_status ls + COUNT(subpoena_id) AS count_electron + FROM subpoena_data ls WHERE d_code = '7' GROUP BY ls.department_id, ls.mil_reg ), @@ -464,16 +487,16 @@ t11 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT (DISTINCT rdi_id) AS count_restrictions - FROM last_status ls + COUNT(rdi_id) AS count_restrictions + FROM subpoena_data ls GROUP BY ls.department_id, ls.mil_reg ), t12 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS count_not_delivery - FROM last_status ls + COUNT(subpoena_id) AS count_not_delivery + FROM subpoena_data ls WHERE act_number IS NOT NULL GROUP BY ls.department_id, ls.mil_reg ), @@ -481,8 +504,8 @@ t13 AS ( SELECT ls.mil_reg, ls.department_id, - COUNT(DISTINCT subpoena_id) AS appear_date_is_good - FROM last_status ls + COUNT(subpoena_id) AS appear_date_is_good + FROM subpoena_data ls WHERE sub_stat_hist IN ('3','3.12', '3.13', '3.15', '3.1') GROUP BY ls.department_id, ls.mil_reg )