825 lines
27 KiB
XML
825 lines
27 KiB
XML
<?xml version="1.0" encoding="UTF-8"?>
|
||
<pipeline>
|
||
<info>
|
||
<name>total_registered.driver_license(reg)</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/02 11:56:22.507</created_date>
|
||
<modified_user>-</modified_user>
|
||
<modified_date>2024/08/02 11:56:22.507</modified_date>
|
||
</info>
|
||
<notepads>
|
||
</notepads>
|
||
<order>
|
||
<hop>
|
||
<from>Get variables 3 2</from>
|
||
<to>Select values 3 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Select values 3 2</from>
|
||
<to>Insert / update (total_registered.driver_license) 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Get variables 3 2 2</from>
|
||
<to>Select values 3 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Table input (driver_license) регионы/все</from>
|
||
<to>Get variables 3 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Select values 3 2 2</from>
|
||
<to>Insert / update (total_registered.driver_license) 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Get variables 3 2 2 2</from>
|
||
<to>Select values 3 2 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Table input (person_registry) регионы/мужчины</from>
|
||
<to>Get variables 3 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Select values 3 2 2 2</from>
|
||
<to>Insert / update (total_registered.driver_license) 2 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Table input (person_registry) регионы/женщины</from>
|
||
<to>Get variables 3 2 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
</order>
|
||
<transform>
|
||
<name>Get variables 3 2</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>REG_ID</name>
|
||
<precision>-1</precision>
|
||
<trim_type>none</trim_type>
|
||
<type>String</type>
|
||
</field>
|
||
<field>
|
||
<length>-1</length>
|
||
<name>VK_ARRAY</name>
|
||
<precision>-1</precision>
|
||
<trim_type>none</trim_type>
|
||
<type>String</type>
|
||
</field>
|
||
</fields>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>672</xloc>
|
||
<yloc>192</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Get variables 3 2 2</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>REG_ID</name>
|
||
<precision>-1</precision>
|
||
<trim_type>none</trim_type>
|
||
<type>String</type>
|
||
</field>
|
||
<field>
|
||
<length>-1</length>
|
||
<name>VK_ARRAY</name>
|
||
<precision>-1</precision>
|
||
<trim_type>none</trim_type>
|
||
<type>String</type>
|
||
</field>
|
||
</fields>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>672</xloc>
|
||
<yloc>352</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Get variables 3 2 2 2</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>REG_ID</name>
|
||
<precision>-1</precision>
|
||
<trim_type>none</trim_type>
|
||
<type>String</type>
|
||
</field>
|
||
<field>
|
||
<length>-1</length>
|
||
<name>VK_ARRAY</name>
|
||
<precision>-1</precision>
|
||
<trim_type>none</trim_type>
|
||
<type>String</type>
|
||
</field>
|
||
</fields>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>672</xloc>
|
||
<yloc>512</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Insert / update (total_registered.driver_license) 2</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>REG_ID</name>
|
||
</key>
|
||
<schema>total_registered</schema>
|
||
<table>driver_license</table>
|
||
<value>
|
||
<name>"A"</name>
|
||
<rename>a</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"B"</name>
|
||
<rename>b</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"C"</name>
|
||
<rename>c</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"D"</name>
|
||
<rename>d</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"E"</name>
|
||
<rename>e</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>nope</name>
|
||
<rename>nope</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"A_repcent"</name>
|
||
<rename>a_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"B_repcent"</name>
|
||
<rename>b_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"C_repcent"</name>
|
||
<rename>c_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"D_repcent"</name>
|
||
<rename>d_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"E_repcent"</name>
|
||
<rename>e_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"all_M_W"</name>
|
||
<rename>gender</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>recruitment_id</name>
|
||
<rename>recruitment_id</rename>
|
||
<update>N</update>
|
||
</value>
|
||
</lookup>
|
||
<update_bypassed>Y</update_bypassed>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>1072</xloc>
|
||
<yloc>192</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Insert / update (total_registered.driver_license) 2 2</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>REG_ID</name>
|
||
</key>
|
||
<schema>total_registered</schema>
|
||
<table>driver_license</table>
|
||
<value>
|
||
<name>"A"</name>
|
||
<rename>a</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"B"</name>
|
||
<rename>b</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"C"</name>
|
||
<rename>c</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"D"</name>
|
||
<rename>d</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"E"</name>
|
||
<rename>e</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>nope</name>
|
||
<rename>nope</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"A_repcent"</name>
|
||
<rename>a_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"B_repcent"</name>
|
||
<rename>b_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"C_repcent"</name>
|
||
<rename>c_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"D_repcent"</name>
|
||
<rename>d_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"E_repcent"</name>
|
||
<rename>e_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"all_M_W"</name>
|
||
<rename>gender</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>recruitment_id</name>
|
||
<rename>recruitment_id</rename>
|
||
<update>N</update>
|
||
</value>
|
||
</lookup>
|
||
<update_bypassed>Y</update_bypassed>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>1072</xloc>
|
||
<yloc>352</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Insert / update (total_registered.driver_license) 2 2 2</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>REG_ID</name>
|
||
</key>
|
||
<schema>total_registered</schema>
|
||
<table>driver_license</table>
|
||
<value>
|
||
<name>"A"</name>
|
||
<rename>a</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"B"</name>
|
||
<rename>b</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"C"</name>
|
||
<rename>c</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"D"</name>
|
||
<rename>d</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"E"</name>
|
||
<rename>e</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>nope</name>
|
||
<rename>nope</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"A_repcent"</name>
|
||
<rename>a_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"B_repcent"</name>
|
||
<rename>b_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"C_repcent"</name>
|
||
<rename>c_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"D_repcent"</name>
|
||
<rename>d_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"E_repcent"</name>
|
||
<rename>e_percent</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"all_M_W"</name>
|
||
<rename>gender</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>recruitment_id</name>
|
||
<rename>recruitment_id</rename>
|
||
<update>N</update>
|
||
</value>
|
||
</lookup>
|
||
<update_bypassed>Y</update_bypassed>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>1072</xloc>
|
||
<yloc>512</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Select values 3 2</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>REG_ID</name>
|
||
<rename>REG_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>VK_ARRAY</name>
|
||
<rename>VK_ARRAY</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>816</xloc>
|
||
<yloc>192</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Select values 3 2 2</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>REG_ID</name>
|
||
<rename>REG_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>VK_ARRAY</name>
|
||
<rename>VK_ARRAY</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>816</xloc>
|
||
<yloc>352</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Select values 3 2 2 2</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>REG_ID</name>
|
||
<rename>REG_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>VK_ARRAY</name>
|
||
<rename>VK_ARRAY</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>816</xloc>
|
||
<yloc>512</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Table input (driver_license) регионы/все</name>
|
||
<type>TableInput</type>
|
||
<description/>
|
||
<distribute>Y</distribute>
|
||
<custom_distribution/>
|
||
<copies>1</copies>
|
||
<partitioning>
|
||
<method>none</method>
|
||
<schema_name/>
|
||
</partitioning>
|
||
<connection>ervu_person_registry</connection>
|
||
<execute_each_row>N</execute_each_row>
|
||
<limit>0</limit>
|
||
<sql>WITH categorized AS (
|
||
SELECT
|
||
r.id,
|
||
r.gender,
|
||
-- Проверяем наличие хотя бы одной категории, используем 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
|
||
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 (
|
||
string_to_array(
|
||
trim(both '{}' FROM replace('${VK_ARRAY}', ' ', '')), ','
|
||
)::uuid[]
|
||
)
|
||
)
|
||
GROUP BY r.id, r.gender
|
||
),
|
||
aggregated AS (
|
||
SELECT
|
||
'ALL' AS gender,
|
||
'${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((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((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent
|
||
FROM aggregated;</sql>
|
||
<variables_active>Y</variables_active>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>448</xloc>
|
||
<yloc>192</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Table input (person_registry) регионы/женщины</name>
|
||
<type>TableInput</type>
|
||
<description/>
|
||
<distribute>Y</distribute>
|
||
<custom_distribution/>
|
||
<copies>1</copies>
|
||
<partitioning>
|
||
<method>none</method>
|
||
<schema_name/>
|
||
</partitioning>
|
||
<connection>ervu_person_registry</connection>
|
||
<execute_each_row>N</execute_each_row>
|
||
<limit>0</limit>
|
||
<sql>WITH categorized AS (
|
||
SELECT
|
||
r.id,
|
||
r.gender,
|
||
-- Проверяем наличие хотя бы одной категории, используем 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
|
||
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 (
|
||
string_to_array(
|
||
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,
|
||
-- Считаем количество уникальных рекрутов с каждой категорией
|
||
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((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((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent
|
||
FROM aggregated;</sql>
|
||
<variables_active>Y</variables_active>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>432</xloc>
|
||
<yloc>512</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Table input (person_registry) регионы/мужчины</name>
|
||
<type>TableInput</type>
|
||
<description/>
|
||
<distribute>Y</distribute>
|
||
<custom_distribution/>
|
||
<copies>1</copies>
|
||
<partitioning>
|
||
<method>none</method>
|
||
<schema_name/>
|
||
</partitioning>
|
||
<connection>ervu_person_registry</connection>
|
||
<execute_each_row>N</execute_each_row>
|
||
<limit>0</limit>
|
||
<sql>WITH categorized AS (
|
||
SELECT
|
||
r.id,
|
||
r.gender,
|
||
-- Проверяем наличие хотя бы одной категории, используем 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
|
||
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 (
|
||
string_to_array(
|
||
trim(both '{}' FROM replace('${VK_ARRAY}', ' ', '')), ','
|
||
)::uuid[]
|
||
)
|
||
)
|
||
AND r.gender = 'MALE'
|
||
GROUP BY r.id, r.gender
|
||
),
|
||
aggregated AS (
|
||
SELECT
|
||
'M' AS gender,
|
||
'${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((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((nope * 100.0) / NULLIF(total, 0), 2) END AS nope_percent
|
||
FROM aggregated;</sql>
|
||
<variables_active>Y</variables_active>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>432</xloc>
|
||
<yloc>352</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform_error_handling>
|
||
</transform_error_handling>
|
||
<attributes/>
|
||
</pipeline>
|