1021 lines
34 KiB
XML
1021 lines
34 KiB
XML
<?xml version="1.0" encoding="UTF-8"?>
|
||
<pipeline>
|
||
<info>
|
||
<name>total_registered.education_level(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>Get variables 3 2 2</from>
|
||
<to>Select values 3 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>Select values 3 2</from>
|
||
<to>Insert / update (total_registered.education_level)</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Table input (person_registry) РФ/все</from>
|
||
<to>Get variables 3 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>Table input (person_registry) РФ/женщины</from>
|
||
<to>Get variables 3 2 2 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Select values 3 2 2</from>
|
||
<to>Insert / update (total_registered.education_level) 2</to>
|
||
<enabled>Y</enabled>
|
||
</hop>
|
||
<hop>
|
||
<from>Select values 3 2 2 2</from>
|
||
<to>Insert / update (total_registered.education_level) 3</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.education_level)</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>education_level</table>
|
||
<value>
|
||
<name>higher</name>
|
||
<rename>higher</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>average</name>
|
||
<rename>average_prof</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"all_M_W"</name>
|
||
<rename>gender</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>only_general</name>
|
||
<rename>only_general</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>no_data</name>
|
||
<rename>count_nodata</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>higher_percent</name>
|
||
<rename>higher_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>average_percent</name>
|
||
<rename>average_prof_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>only_general_percent</name>
|
||
<rename>only_general_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>no_data_percent</name>
|
||
<rename>count_nodata_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>recruitment_id</name>
|
||
<rename>recruitment_id</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>education_level</name>
|
||
<rename>total</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
</lookup>
|
||
<update_bypassed>Y</update_bypassed>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>1072</xloc>
|
||
<yloc>192</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Insert / update (total_registered.education_level) 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>education_level</table>
|
||
<value>
|
||
<name>higher</name>
|
||
<rename>higher</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>average</name>
|
||
<rename>average_prof</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"all_M_W"</name>
|
||
<rename>gender</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>only_general</name>
|
||
<rename>only_general</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>no_data</name>
|
||
<rename>count_nodata</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>higher_percent</name>
|
||
<rename>higher_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>average_percent</name>
|
||
<rename>average_prof_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>only_general_percent</name>
|
||
<rename>only_general_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>no_data_percent</name>
|
||
<rename>count_nodata_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>recruitment_id</name>
|
||
<rename>recruitment_id</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>education_level</name>
|
||
<rename>total</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
</lookup>
|
||
<update_bypassed>Y</update_bypassed>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>1072</xloc>
|
||
<yloc>352</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform>
|
||
<name>Insert / update (total_registered.education_level) 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>REG_ID</name>
|
||
</key>
|
||
<schema>total_registered</schema>
|
||
<table>education_level</table>
|
||
<value>
|
||
<name>higher</name>
|
||
<rename>higher</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>average</name>
|
||
<rename>average_prof</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>"all_M_W"</name>
|
||
<rename>gender</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>only_general</name>
|
||
<rename>only_general</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>no_data</name>
|
||
<rename>count_nodata</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>higher_percent</name>
|
||
<rename>higher_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>average_percent</name>
|
||
<rename>average_prof_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>only_general_percent</name>
|
||
<rename>only_general_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>no_data_percent</name>
|
||
<rename>count_nodata_percentage</rename>
|
||
<update>Y</update>
|
||
</value>
|
||
<value>
|
||
<name>recruitment_id</name>
|
||
<rename>recruitment_id</rename>
|
||
<update>N</update>
|
||
</value>
|
||
<value>
|
||
<name>education_level</name>
|
||
<rename>total</rename>
|
||
<update>Y</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 (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 total_count AS (
|
||
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.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[]
|
||
)
|
||
)
|
||
),
|
||
education_status AS (
|
||
SELECT
|
||
ri.id,
|
||
|
||
-- Высшее образование (российское или иностранное)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' IN ('1', '2', '3', '4', '5')
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' IN ('1', '2', '3', '4', '5')
|
||
)
|
||
) AS has_higher,
|
||
|
||
-- Среднее профессиональное образование (если нет высшего)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' = '10'
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' = '10'
|
||
)
|
||
) AS has_average_prof,
|
||
|
||
-- Общее образование (если нет высшего и среднего)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' IN ('7', '9')
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' IN ('7', '9')
|
||
)
|
||
) AS has_only_general,
|
||
|
||
-- Нет данных об образовании (российское или иностранное)
|
||
(
|
||
NOT (
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
)
|
||
)
|
||
) AND (
|
||
ri.info->'svedRObr'->>'prOtsRObr' = '1'
|
||
OR ri.info->'svedInObr'->>'prOtsInObr' = '1'
|
||
)
|
||
) AS has_no_data
|
||
|
||
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 (
|
||
'${VK_ARRAY}' IS NULL
|
||
OR '${VK_ARRAY}' = ''
|
||
OR r.target_recruitment_id = ANY (
|
||
string_to_array(
|
||
trim(both '{}' FROM replace('${VK_ARRAY}', ' ', '')), ','
|
||
)::uuid[]
|
||
)
|
||
)
|
||
),
|
||
final_counts AS (
|
||
SELECT
|
||
COUNT(DISTINCT CASE WHEN has_higher THEN id END) AS higher,
|
||
COUNT(DISTINCT CASE WHEN NOT has_higher AND has_average_prof THEN id END) AS average_prof,
|
||
COUNT(DISTINCT CASE WHEN NOT has_higher AND NOT has_average_prof AND has_only_general THEN id END) AS only_general,
|
||
COUNT(DISTINCT CASE WHEN has_no_data THEN id END) AS count_nodata
|
||
FROM education_status
|
||
)
|
||
SELECT
|
||
'ALL' AS gender,
|
||
'${REG_ID}' AS recruitment_id,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE higher END AS higher,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE average_prof END AS average_prof,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE only_general END AS only_general,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE count_nodata END AS count_nodata,
|
||
total_count.total,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(higher * 100.0 / NULLIF(total_count.total, 0), 2) END AS higher_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(average_prof * 100.0 / NULLIF(total_count.total, 0), 2) END AS average_prof_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(only_general * 100.0 / NULLIF(total_count.total, 0), 2) END AS only_general_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(count_nodata * 100.0 / NULLIF(total_count.total, 0), 2) END AS count_nodata_percentage
|
||
FROM final_counts, total_count;</sql>
|
||
<variables_active>Y</variables_active>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>400</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 total_count AS (
|
||
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'
|
||
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[]
|
||
)
|
||
)
|
||
),
|
||
education_status AS (
|
||
SELECT
|
||
ri.id,
|
||
|
||
-- Высшее образование (российское или иностранное)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' IN ('1', '2', '3', '4', '5')
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' IN ('1', '2', '3', '4', '5')
|
||
)
|
||
) AS has_higher,
|
||
|
||
-- Среднее профессиональное образование (если нет высшего)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' = '10'
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' = '10'
|
||
)
|
||
) AS has_average_prof,
|
||
|
||
-- Общее образование (если нет высшего и среднего)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' IN ('7', '9')
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' IN ('7', '9')
|
||
)
|
||
) AS has_only_general,
|
||
|
||
-- Нет данных об образовании (российское или иностранное)
|
||
(
|
||
NOT (
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
)
|
||
)
|
||
) AND (
|
||
ri.info->'svedRObr'->>'prOtsRObr' = '1'
|
||
OR ri.info->'svedInObr'->>'prOtsInObr' = '1'
|
||
)
|
||
) AS has_no_data
|
||
|
||
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 (
|
||
'${VK_ARRAY}' IS NULL
|
||
OR '${VK_ARRAY}' = ''
|
||
OR r.target_recruitment_id = ANY (
|
||
string_to_array(
|
||
trim(both '{}' FROM replace('${VK_ARRAY}', ' ', '')), ','
|
||
)::uuid[]
|
||
)
|
||
)
|
||
),
|
||
final_counts AS (
|
||
SELECT
|
||
COUNT(DISTINCT CASE WHEN has_higher THEN id END) AS higher,
|
||
COUNT(DISTINCT CASE WHEN NOT has_higher AND has_average_prof THEN id END) AS average_prof,
|
||
COUNT(DISTINCT CASE WHEN NOT has_higher AND NOT has_average_prof AND has_only_general THEN id END) AS only_general,
|
||
COUNT(DISTINCT CASE WHEN has_no_data THEN id END) AS count_nodata
|
||
FROM education_status
|
||
)
|
||
SELECT
|
||
'W' AS gender,
|
||
'${REG_ID}' AS recruitment_id,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE higher END AS higher,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE average_prof END AS average_prof,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE only_general END AS only_general,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE count_nodata END AS count_nodata,
|
||
total_count.total,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(higher * 100.0 / NULLIF(total_count.total, 0), 2) END AS higher_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(average_prof * 100.0 / NULLIF(total_count.total, 0), 2) END AS average_prof_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(only_general * 100.0 / NULLIF(total_count.total, 0), 2) END AS only_general_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(count_nodata * 100.0 / NULLIF(total_count.total, 0), 2) END AS count_nodata_percentage
|
||
FROM final_counts, total_count;</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 total_count AS (
|
||
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'
|
||
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[]
|
||
)
|
||
)
|
||
),
|
||
education_status AS (
|
||
SELECT
|
||
ri.id,
|
||
|
||
-- Высшее образование (российское или иностранное)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' IN ('1', '2', '3', '4', '5')
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' IN ('1', '2', '3', '4', '5')
|
||
)
|
||
) AS has_higher,
|
||
|
||
-- Среднее профессиональное образование (если нет высшего)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' = '10'
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' = '10'
|
||
)
|
||
) AS has_average_prof,
|
||
|
||
-- Общее образование (если нет высшего и среднего)
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
AND education->>'kodUrObr' IN ('7', '9')
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
AND education->>'kodUrObr' IN ('7', '9')
|
||
)
|
||
) AS has_only_general,
|
||
|
||
-- Нет данных об образовании (российское или иностранное)
|
||
(
|
||
NOT (
|
||
(
|
||
EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedRObr'->'robr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedRObr'->'robr') = 'array'
|
||
) OR EXISTS (
|
||
SELECT 1
|
||
FROM jsonb_array_elements(ri.info->'svedInObr'->'inObr') AS education
|
||
WHERE jsonb_typeof(ri.info->'svedInObr'->'inObr') = 'array'
|
||
)
|
||
)
|
||
) AND (
|
||
ri.info->'svedRObr'->>'prOtsRObr' = '1'
|
||
OR ri.info->'svedInObr'->>'prOtsInObr' = '1'
|
||
)
|
||
) AS has_no_data
|
||
|
||
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 (
|
||
'${VK_ARRAY}' IS NULL
|
||
OR '${VK_ARRAY}' = ''
|
||
OR r.target_recruitment_id = ANY (
|
||
string_to_array(
|
||
trim(both '{}' FROM replace('${VK_ARRAY}', ' ', '')), ','
|
||
)::uuid[]
|
||
)
|
||
)
|
||
),
|
||
final_counts AS (
|
||
SELECT
|
||
COUNT(DISTINCT CASE WHEN has_higher THEN id END) AS higher,
|
||
COUNT(DISTINCT CASE WHEN NOT has_higher AND has_average_prof THEN id END) AS average_prof,
|
||
COUNT(DISTINCT CASE WHEN NOT has_higher AND NOT has_average_prof AND has_only_general THEN id END) AS only_general,
|
||
COUNT(DISTINCT CASE WHEN has_no_data THEN id END) AS count_nodata
|
||
FROM education_status
|
||
)
|
||
SELECT
|
||
'M' AS gender,
|
||
'${REG_ID}' AS recruitment_id,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE higher END AS higher,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE average_prof END AS average_prof,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE only_general END AS only_general,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE count_nodata END AS count_nodata,
|
||
total_count.total,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(higher * 100.0 / NULLIF(total_count.total, 0), 2) END AS higher_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(average_prof * 100.0 / NULLIF(total_count.total, 0), 2) END AS average_prof_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(only_general * 100.0 / NULLIF(total_count.total, 0), 2) END AS only_general_percentage,
|
||
CASE WHEN '${VK_ARRAY}' IS NULL OR '${VK_ARRAY}' = '' THEN 0 ELSE ROUND(count_nodata * 100.0 / NULLIF(total_count.total, 0), 2) END AS count_nodata_percentage
|
||
FROM final_counts, total_count;</sql>
|
||
<variables_active>Y</variables_active>
|
||
<attributes/>
|
||
<GUI>
|
||
<xloc>416</xloc>
|
||
<yloc>352</yloc>
|
||
</GUI>
|
||
</transform>
|
||
<transform_error_handling>
|
||
</transform_error_handling>
|
||
<attributes/>
|
||
</pipeline>
|