ervu-dashboard-etl/mappings/mil_com/recruitment_campaign.subpoenas(m_c).hpl
2025-04-07 20:31:30 +03:00

685 lines
22 KiB
XML

<?xml version="1.0" encoding="UTF-8"?>
<pipeline>
<info>
<name>recruitment_campaign.subpoenas(m_c)</name>
<name_sync_with_filename>Y</name_sync_with_filename>
<description/>
<extended_description/>
<pipeline_version/>
<pipeline_type>Normal</pipeline_type>
<pipeline_status>0</pipeline_status>
<parameters>
</parameters>
<capture_transform_performance>N</capture_transform_performance>
<transform_performance_capturing_delay>1000</transform_performance_capturing_delay>
<transform_performance_capturing_size_limit>100</transform_performance_capturing_size_limit>
<created_user>-</created_user>
<created_date>2024/08/09 13:13:59.825</created_date>
<modified_user>-</modified_user>
<modified_date>2024/08/09 13:13:59.825</modified_date>
</info>
<notepads>
</notepads>
<order>
<hop>
<from>Get variables 4 3</from>
<to>Select values 4 3</to>
<enabled>N</enabled>
</hop>
<hop>
<from>Table input (subpoena) осень/регионы</from>
<to>Get variables 4 3</to>
<enabled>N</enabled>
</hop>
<hop>
<from>Select values 4 3</from>
<to>Insert / update (recruitment_campaign.subpoenas) 3</to>
<enabled>N</enabled>
</hop>
<hop>
<from>Table input (subpoena) осень/регионы</from>
<to>Insert / update (recruitment_campaign.subpoenas) 3</to>
<enabled>N</enabled>
</hop>
<hop>
<from>Table input (subpoena) осень/регионы</from>
<to>Update recruitment_campaign.subpoenas</to>
<enabled>Y</enabled>
</hop>
</order>
<transform>
<name>Get variables 4 3</name>
<type>GetVariable</type>
<description/>
<distribute>Y</distribute>
<custom_distribution/>
<copies>1</copies>
<partitioning>
<method>none</method>
<schema_name/>
</partitioning>
<fields>
<field>
<length>-1</length>
<name>REC_ID</name>
<precision>-1</precision>
<trim_type>none</trim_type>
<type>String</type>
</field>
<field>
<length>-1</length>
<name>SCM</name>
<precision>-1</precision>
<trim_type>none</trim_type>
<type>String</type>
</field>
</fields>
<attributes/>
<GUI>
<xloc>592</xloc>
<yloc>624</yloc>
</GUI>
</transform>
<transform>
<name>Insert / update (recruitment_campaign.subpoenas) 3</name>
<type>InsertUpdate</type>
<description/>
<distribute>Y</distribute>
<custom_distribution/>
<copies>1</copies>
<partitioning>
<method>none</method>
<schema_name/>
</partitioning>
<commit>100</commit>
<connection>ervu-dashboard</connection>
<lookup>
<key>
<condition>=</condition>
<field>recruitment_id</field>
<name>recruitment_id</name>
</key>
<key>
<condition>=</condition>
<field>spring_autumn</field>
<name>spring_autumn</name>
</key>
<key>
<condition>=</condition>
<field>recording_date</field>
<name>recording_date</name>
</key>
<schema>recruitment_campaign</schema>
<table>subpoenas</table>
<value>
<name>subpoena</name>
<rename>count_subpoena</rename>
<update>Y</update>
</value>
<value>
<name>appeared</name>
<rename>count_appeared</rename>
<update>Y</update>
</value>
<value>
<name>not_appeared</name>
<rename>count_not_appeared</rename>
<update>Y</update>
</value>
<value>
<name>not_ap_good_reason</name>
<rename>count_not_ap_good_reason</rename>
<update>Y</update>
</value>
<value>
<name>introduced_measures</name>
<rename>count_introduced_measures</rename>
<update>Y</update>
</value>
<value>
<name>ap_not_required</name>
<rename>count_ap_not_required</rename>
<update>Y</update>
</value>
<value>
<name>restrictions_applied</name>
<rename>count_restrictions_applied</rename>
<update>Y</update>
</value>
<value>
<name>appeared_percent</name>
<rename>appeared_percent</rename>
<update>Y</update>
</value>
<value>
<name>not_appeared_percent</name>
<rename>not_appeared_percent</rename>
<update>Y</update>
</value>
<value>
<name>not_ap_good_reason_percent</name>
<rename>not_ap_good_reason_percent</rename>
<update>Y</update>
</value>
<value>
<name>ap_not_required_percent</name>
<rename>ap_not_required_percent</rename>
<update>Y</update>
</value>
<value>
<name>restrictions_applied_percent</name>
<rename>restrictions_applied_percent</rename>
<update>Y</update>
</value>
<value>
<name>introduced_measures_percent</name>
<rename>introduced_measures_percent</rename>
<update>Y</update>
</value>
<value>
<name>recruitment_id</name>
<rename>recruitment_id</rename>
<update>N</update>
</value>
<value>
<name>rest</name>
<rename>rest</rename>
<update>Y</update>
</value>
<value>
<name>spring_autumn</name>
<rename>spring_autumn</rename>
<update>N</update>
</value>
<value>
<name>count_not_delivery</name>
<rename>count_not_delivery</rename>
<update>Y</update>
</value>
<value>
<name>appear_date_is_good</name>
<rename>appear_date_is_good</rename>
<update>Y</update>
</value>
<value>
<name>not_delivery_percent</name>
<rename>not_delivery_percent</rename>
<update>Y</update>
</value>
<value>
<name>appear_date_is_good_percent</name>
<rename>appear_date_is_good_percent</rename>
<update>Y</update>
</value>
</lookup>
<update_bypassed>N</update_bypassed>
<attributes/>
<GUI>
<xloc>1040</xloc>
<yloc>624</yloc>
</GUI>
</transform>
<transform>
<name>Select values 4 3</name>
<type>SelectValues</type>
<description/>
<distribute>Y</distribute>
<custom_distribution/>
<copies>1</copies>
<partitioning>
<method>none</method>
<schema_name/>
</partitioning>
<fields>
<select_unspecified>N</select_unspecified>
<meta>
<name>REC_ID</name>
<rename>REC_ID</rename>
<type>String</type>
<length>-2</length>
<precision>-2</precision>
<conversion_mask/>
<date_format_lenient>false</date_format_lenient>
<date_format_locale/>
<date_format_timezone/>
<lenient_string_to_number>false</lenient_string_to_number>
<encoding/>
<decimal_symbol/>
<grouping_symbol/>
<currency_symbol/>
<storage_type/>
</meta>
<meta>
<name>SCM</name>
<rename>SCM</rename>
<type>String</type>
<length>-2</length>
<precision>-2</precision>
<conversion_mask/>
<date_format_lenient>false</date_format_lenient>
<date_format_locale/>
<date_format_timezone/>
<lenient_string_to_number>false</lenient_string_to_number>
<encoding/>
<decimal_symbol/>
<grouping_symbol/>
<currency_symbol/>
<storage_type/>
</meta>
</fields>
<attributes/>
<GUI>
<xloc>768</xloc>
<yloc>624</yloc>
</GUI>
</transform>
<transform>
<name>Table input (subpoena) осень/регионы</name>
<type>TableInput</type>
<description/>
<distribute>Y</distribute>
<custom_distribution/>
<copies>1</copies>
<partitioning>
<method>none</method>
<schema_name/>
</partitioning>
<connection>postgres.subpoena</connection>
<execute_each_row>N</execute_each_row>
<limit>0</limit>
<sql>WITH
ids AS (
SELECT unnest(string_to_array(trim(both '{}' from '${ARR_MC}'), ','))::uuid AS recruitment_id
),
subpoena_data AS (
SELECT
s.id AS subpoena_id,
s.create_date,
s.visit_date,
s.department_id::uuid AS recruitment_id,
s.status_id,
ssh.code AS sub_stat_hist,
s.send_date,
sh.date_time::timestamp AS history_date,
rdi.restriction_document_cancel_id AS restr_dc,
rdi.applied_date AS ap_date,
rdi.id AS rdi_id,
ssi.delivery_code AS d_code,
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
FROM subpoena_history sh2
WHERE sh2.subpoena_id = s.id
AND sh2.status_id = (SELECT id FROM subpoena_status WHERE code = '3')
)
),
season_separations AS (
SELECT distinct
ls.recruitment_id,
ls.create_date,
ls.visit_date,
ls.sub_stat_hist,
ls.subpoena_id,
ls.history_date,
ls.send_date,
ls.restr_dc,
ls.ap_date,
ls.d_code,
ls.act_number,
ls.rdi_id,
CASE
WHEN (ls.visit_date BETWEEN DATE_TRUNC('year', ls.visit_date) + INTERVAL '3 months' + INTERVAL '1 day'
AND DATE_TRUNC('year', ls.visit_date) + INTERVAL '6 months' + INTERVAL '15 days')
THEN 'Весна'
WHEN (ls.visit_date BETWEEN DATE_TRUNC('year', ls.visit_date) + INTERVAL '9 months' + INTERVAL '1 day'
AND DATE_TRUNC('year', ls.visit_date) + INTERVAL '12 months' + INTERVAL '31 days')
THEN 'Осень'
END AS spring_autumn
FROM subpoena_data ls
WHERE --ls.create_date >= DATE_TRUNC('year', CURRENT_DATE)
--AND
((ls.visit_date BETWEEN DATE_TRUNC('year', ls.visit_date) + INTERVAL '3 months' + INTERVAL '1 day'
AND DATE_TRUNC('year', ls.visit_date) + INTERVAL '6 months' + INTERVAL '15 days')
OR
(ls.visit_date BETWEEN DATE_TRUNC('year', ls.visit_date) + INTERVAL '9 months' + INTERVAL '1 day'
AND DATE_TRUNC('year', ls.visit_date) + INTERVAL '12 months' + INTERVAL '31 days'))
),
season_separations_clean AS (
SELECT DISTINCT recruitment_id, spring_autumn FROM season_separations
),
t1 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_subpoena
FROM season_separations ss
WHERE sub_stat_hist IS NOT NULL
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t2 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
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
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t3 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_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
),
t4 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_not_appeared
FROM season_separations ss
WHERE sub_stat_hist = '5'
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t5 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_not_ap_good_reason
FROM season_separations ss
WHERE sub_stat_hist = '5.1'
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t6 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_ap_not_required
FROM season_separations ss
WHERE sub_stat_hist IN ('3.8', '5.2')
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t7 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_restrictions_applied
FROM season_separations ss
WHERE restr_dc IS NULL
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t8 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_introduced_measures
FROM season_separations ss
WHERE restr_dc IS NULL AND ap_date IS NOT NULL
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t9 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_paper
FROM season_separations ss
WHERE d_code != '7'
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t10 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_electron
FROM season_separations ss
WHERE d_code = '7'
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t11 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT (DISTINCT ss.rdi_id) AS count_restrictions
FROM season_separations ss
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t12 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS count_not_delivery
FROM season_separations ss
WHERE ss.act_number IS NOT NULL
GROUP BY ss.recruitment_id, ss.spring_autumn
),
t13 AS (
SELECT
ss.recruitment_id,
ss.spring_autumn,
COUNT(DISTINCT ss.subpoena_id) AS appear_date_is_good
FROM season_separations ss
WHERE ss.sub_stat_hist IN ('3','3.12', '3.13', '3.15', '3.1')
GROUP BY ss.recruitment_id, ss.spring_autumn
)
SELECT
current_date AS recording_date,
COALESCE(t1.count_subpoena, 0) AS count_subpoena,
COALESCE(t2.average_appeared, 0) AS average_appeared,
COALESCE(t3.count_appeared, 0) AS count_appeared,
COALESCE(t4.count_not_appeared, 0) AS count_not_appeared,
COALESCE(t5.count_not_ap_good_reason, 0) AS count_not_ap_good_reason,
COALESCE(t6.count_ap_not_required, 0) AS count_ap_not_required,
COALESCE(t7.count_restrictions_applied, 0) AS count_restrictions_applied,
COALESCE(t8.count_introduced_measures, 0) AS count_introduced_measures,
COALESCE(t9.count_paper, 0) AS count_paper,
COALESCE(t10.count_electron, 0) AS count_electron,
COALESCE(t11.count_restrictions, 0) AS count_restrictions,
COALESCE(t12.count_not_delivery, 0) AS count_not_delivery,
COALESCE(t13.appear_date_is_good, 0) AS appear_date_is_good,
ROUND(COALESCE(t3.count_appeared, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS appeared_percent,
ROUND(COALESCE(t4.count_not_appeared, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS not_appeared_percent,
ROUND(COALESCE(t5.count_not_ap_good_reason, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS not_ap_good_reason_percent,
ROUND(COALESCE(t6.count_ap_not_required, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS ap_not_required_percent,
ROUND(COALESCE(t10.count_electron, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS electron_percent,
ROUND(COALESCE(t9.count_paper, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS paper_percent,
ROUND(COALESCE(t7.count_restrictions_applied, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS restrictions_applied_percent,
ROUND(COALESCE(t8.count_introduced_measures, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS introduced_measures_percent,
ROUND(COALESCE(t12.count_not_delivery, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS not_delivery_percent,
ROUND(COALESCE(t13.appear_date_is_good, 0) * 100.0 / NULLIF(t1.count_subpoena, 0), 2) AS appear_date_is_good_percent,
ss.recruitment_id,
0 AS rest,
ss.spring_autumn
FROM season_separations_clean ss
LEFT JOIN t1 ON ss.recruitment_id = t1.recruitment_id AND ss.spring_autumn = t1.spring_autumn
LEFT JOIN t2 ON ss.recruitment_id = t2.recruitment_id AND ss.spring_autumn = t2.spring_autumn
LEFT JOIN t3 ON ss.recruitment_id = t3.recruitment_id AND ss.spring_autumn = t3.spring_autumn
LEFT JOIN t4 ON ss.recruitment_id = t4.recruitment_id AND ss.spring_autumn = t4.spring_autumn
LEFT JOIN t5 ON ss.recruitment_id = t5.recruitment_id AND ss.spring_autumn = t5.spring_autumn
LEFT JOIN t6 ON ss.recruitment_id = t6.recruitment_id AND ss.spring_autumn = t6.spring_autumn
LEFT JOIN t7 ON ss.recruitment_id = t7.recruitment_id AND ss.spring_autumn = t7.spring_autumn
LEFT JOIN t8 ON ss.recruitment_id = t8.recruitment_id AND ss.spring_autumn = t8.spring_autumn
LEFT JOIN t9 ON ss.recruitment_id = t9.recruitment_id AND ss.spring_autumn = t9.spring_autumn
LEFT JOIN t10 ON ss.recruitment_id = t10.recruitment_id AND ss.spring_autumn = t10.spring_autumn
LEFT JOIN t11 ON ss.recruitment_id = t11.recruitment_id AND ss.spring_autumn = t11.spring_autumn
LEFT JOIN t12 ON ss.recruitment_id = t12.recruitment_id AND ss.spring_autumn = t12.spring_autumn
LEFT JOIN t13 ON ss.recruitment_id = t13.recruitment_id AND ss.spring_autumn = t13.spring_autumn</sql>
<variables_active>Y</variables_active>
<attributes/>
<GUI>
<xloc>464</xloc>
<yloc>400</yloc>
</GUI>
</transform>
<transform>
<name>Update recruitment_campaign.subpoenas</name>
<type>Update</type>
<description/>
<distribute>Y</distribute>
<custom_distribution/>
<copies>1</copies>
<partitioning>
<method>none</method>
<schema_name/>
</partitioning>
<commit>100</commit>
<connection>ervu-dashboard</connection>
<error_ignored>Y</error_ignored>
<ignore_flag_field/>
<lookup>
<key>
<condition>=</condition>
<field>recruitment_id</field>
<name>recruitment_id</name>
<name2/>
</key>
<key>
<condition>=</condition>
<field>spring_autumn</field>
<name>spring_autumn</name>
<name2/>
</key>
<key>
<condition>=</condition>
<field>recording_date</field>
<name>recording_date</name>
<name2/>
</key>
<schema>recruitment_campaign</schema>
<table>subpoenas</table>
<value>
<name>subpoena</name>
<rename>count_subpoena</rename>
</value>
<value>
<name>appeared</name>
<rename>count_appeared</rename>
</value>
<value>
<name>not_appeared</name>
<rename>count_not_appeared</rename>
</value>
<value>
<name>not_ap_good_reason</name>
<rename>count_not_ap_good_reason</rename>
</value>
<value>
<name>ap_not_required</name>
<rename>count_ap_not_required</rename>
</value>
<value>
<name>restrictions_applied</name>
<rename>count_restrictions_applied</rename>
</value>
<value>
<name>appeared_percent</name>
<rename>appeared_percent</rename>
</value>
<value>
<name>not_appeared_percent</name>
<rename>not_appeared_percent</rename>
</value>
<value>
<name>not_ap_good_reason_percent</name>
<rename>not_ap_good_reason_percent</rename>
</value>
<value>
<name>ap_not_required_percent</name>
<rename>ap_not_required_percent</rename>
</value>
<value>
<name>restrictions_applied_percent</name>
<rename>restrictions_applied_percent</rename>
</value>
<value>
<name>introduced_measures</name>
<rename>count_introduced_measures</rename>
</value>
<value>
<name>introduced_measures_percent</name>
<rename>introduced_measures_percent</rename>
</value>
<value>
<name>count_not_delivery</name>
<rename>count_not_delivery</rename>
</value>
<value>
<name>appear_date_is_good</name>
<rename>appear_date_is_good</rename>
</value>
<value>
<name>not_delivery_percent</name>
<rename>not_delivery_percent</rename>
</value>
<value>
<name>appear_date_is_good_percent</name>
<rename>appear_date_is_good_percent</rename>
</value>
</lookup>
<skip_lookup>N</skip_lookup>
<use_batch>Y</use_batch>
<attributes/>
<GUI>
<xloc>1040</xloc>
<yloc>400</yloc>
</GUI>
</transform>
<transform_error_handling>
</transform_error_handling>
<attributes/>
</pipeline>