update fix
This commit is contained in:
parent
8e30d7436b
commit
892db8d362
8 changed files with 169 additions and 92 deletions
|
|
@ -358,7 +358,7 @@ FROM ervu_dashboard.recruitment r
|
|||
<execute_each_row>N</execute_each_row>
|
||||
<limit>0</limit>
|
||||
<sql>SELECT max(source_update_date) AS max_source_update_date
|
||||
FROM citizenship;</sql>
|
||||
FROM ervu_dashboard.citizenship;</sql>
|
||||
<variables_active>N</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
|
|
|
|||
|
|
@ -81,7 +81,7 @@ FROM ervu_dashboard.recruitment r
|
|||
JOIN recruits_info ri
|
||||
ON COALESCE(ri.current_recruitment_id, ri.target_recruitment_id) = r.idm_id
|
||||
AND ri.updated_at > mud.max_upd_date;</sql>
|
||||
<variables_active>N</variables_active>
|
||||
<variables_active>Y</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
<xloc>352</xloc>
|
||||
|
|
@ -358,11 +358,11 @@ FROM ervu_dashboard.recruitment r
|
|||
<execute_each_row>N</execute_each_row>
|
||||
<limit>0</limit>
|
||||
<sql>SELECT max(source_update_date) AS max_source_update_date
|
||||
FROM citizenship_foreign;</sql>
|
||||
FROM ervu_dashboard.citizenship_foreign;</sql>
|
||||
<variables_active>N</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
<xloc>144</xloc>
|
||||
<xloc>160</xloc>
|
||||
<yloc>288</yloc>
|
||||
</GUI>
|
||||
</transform>
|
||||
|
|
|
|||
|
|
@ -333,19 +333,16 @@ and recruitment_id = '${IDM_ID}';</sql>
|
|||
<condition>=</condition>
|
||||
<field>recruit_id</field>
|
||||
<name>recruit_id</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<key>
|
||||
<condition>=</condition>
|
||||
<field>tractor_driver</field>
|
||||
<name>tractor_driver</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<key>
|
||||
<condition>=</condition>
|
||||
<field>driver</field>
|
||||
<name>driver</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<schema>ervu_dashboard</schema>
|
||||
<table>drivers_licence</table>
|
||||
|
|
@ -430,11 +427,23 @@ and recruitment_id = '${IDM_ID}';</sql>
|
|||
base AS (
|
||||
SELECT
|
||||
ri.recruit_id recruit_id,
|
||||
ri.info
|
||||
ri.info,
|
||||
CASE
|
||||
WHEN jsonb_typeof(ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->'svedKat') = 'array'
|
||||
THEN to_date(ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->>'dataSved', 'YYYY-MM-DD')
|
||||
END as driver_update_date,
|
||||
CASE
|
||||
WHEN ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM' IS NOT NULL
|
||||
THEN to_date(ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM'->>'dataSved', 'YYYY-MM-DD')
|
||||
END as akt_update_date,
|
||||
CASE
|
||||
WHEN ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM' IS NOT NULL
|
||||
THEN to_date(ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM'->>'dataSved', 'YYYY-MM-DD')
|
||||
END as pred_update_date
|
||||
FROM ervu_dashboard.recruits_info ri
|
||||
JOIN ervu_dashboard.citizen r ON r.recruit_id = ri.recruit_id AND '${IDM_ID}' != '' -- Проверка на пустую строку
|
||||
AND COALESCE(ri.current_recruitment_id, ri.target_recruitment_id) = '${IDM_ID}'
|
||||
AND ri.updated_at >= '${M_R_UP_DATE}'::timestamp
|
||||
--AND ri.updated_at >= '${M_R_UP_DATE}'::timestamp
|
||||
WHERE jsonb_typeof(ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->'svedKat') = 'array'
|
||||
OR ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM' IS NOT NULL
|
||||
OR ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM' IS NOT NULL
|
||||
|
|
@ -442,7 +451,7 @@ base AS (
|
|||
all_data AS (
|
||||
SELECT
|
||||
ri.recruit_id,
|
||||
to_date(ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
ri.driver_update_date AS source_update_date,
|
||||
ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->>'kodStatus' AS status,-- статус удостоверения // 1 - действителен, 2 - недействителен
|
||||
ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->>'serNomDok' AS licence_series, -- серия и номер
|
||||
NULL AS licence_number, -- ?серия и номер в одном поле?
|
||||
|
|
@ -456,14 +465,15 @@ all_data AS (
|
|||
NULL AS return_date,
|
||||
false AS tractor_driver
|
||||
FROM base ri
|
||||
WHERE jsonb_typeof(ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->'svedKat') = 'array'
|
||||
WHERE jsonb_typeof(ri.info->'svedFL'->'svedVoditUdost'->'voditUdost'->'svedKat') = 'array'
|
||||
AND ri.driver_update_date > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
ri.recruit_id,
|
||||
to_date(ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM'->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
'1' AS status, -- статус удостоверения тракториста // ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM'->>'kodStatusUTM'
|
||||
ri.akt_update_date AS source_update_date,
|
||||
'1' AS status, -- статус удостоверения тракториста // ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM'->>'kodStatusUTM'
|
||||
ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM'->>'serUTM' AS licence_series, -- серия удостоверения тракториста
|
||||
ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM'->>'nomUTM' AS licence_number, -- номер удостоверения тракториста
|
||||
(SELECT array_to_string(ARRAY(SELECT jsonb_array_elements_text(
|
||||
|
|
@ -475,13 +485,14 @@ all_data AS (
|
|||
true AS tractor_driver
|
||||
FROM base ri
|
||||
WHERE ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'aktUTM' IS NOT NULL
|
||||
AND ri.akt_update_date > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
ri.recruit_id,
|
||||
to_date(ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM'->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
'0' AS status, -- статус удостоверения тракториста // ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM'->>'kodStatusUTM'
|
||||
ri.pred_update_date AS source_update_date,
|
||||
'0' AS status, -- статус удостоверения тракториста // ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM'->>'kodStatusUTM'
|
||||
ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM'->>'serUTM' AS licence_series, -- серия удостоверения тракториста
|
||||
ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM'->>'nomUTM' AS licence_number, -- номер удостоверения тракториста
|
||||
(SELECT array_to_string(ARRAY(SELECT jsonb_array_elements_text(
|
||||
|
|
@ -493,6 +504,7 @@ all_data AS (
|
|||
true AS tractor_driver
|
||||
FROM base ri
|
||||
WHERE ri.info->'svedFL'->'svedUdostTraktMash'->'udostTraktMash'->'predUTM' IS NOT NULL
|
||||
AND ri.pred_update_date > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
)
|
||||
SELECT
|
||||
*,
|
||||
|
|
|
|||
|
|
@ -45,6 +45,11 @@
|
|||
<to>drivers_licence_flow_repeat.hpl 5</to>
|
||||
<enabled>Y</enabled>
|
||||
</hop>
|
||||
<hop>
|
||||
<from>get_max_source_update_date</from>
|
||||
<to>Table input</to>
|
||||
<enabled>Y</enabled>
|
||||
</hop>
|
||||
</order>
|
||||
<transform>
|
||||
<name>Table input</name>
|
||||
|
|
@ -60,14 +65,23 @@
|
|||
<connection>ervu-dashboard</connection>
|
||||
<execute_each_row>N</execute_each_row>
|
||||
<limit>0</limit>
|
||||
<sql>SELECT
|
||||
r.idm_id as recruitment_id
|
||||
<sql>WITH mud AS (
|
||||
SELECT
|
||||
recruitment_id,
|
||||
MAX(execution_datetime) AS max_upd_date
|
||||
FROM etl.job_execution
|
||||
WHERE job_name = '${JOB_NAME}'
|
||||
AND status IN ('SUCCESS','DELTA_ERROR','DELTA_SUCCESS','DELTA_PROCESSING')
|
||||
GROUP BY recruitment_id
|
||||
)
|
||||
SELECT
|
||||
r.idm_id
|
||||
FROM ervu_dashboard.recruitment r
|
||||
LEFT JOIN etl.job_execution je
|
||||
ON r.idm_id = je.recruitment_id
|
||||
and job_name = 'drivers_licence_job'
|
||||
where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
||||
<variables_active>N</variables_active>
|
||||
JOIN mud ON mud.recruitment_id = r.idm_id
|
||||
JOIN recruits_info ri
|
||||
ON COALESCE(ri.current_recruitment_id, ri.target_recruitment_id) = r.idm_id
|
||||
AND ri.updated_at > mud.max_upd_date;</sql>
|
||||
<variables_active>Y</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
<xloc>272</xloc>
|
||||
|
|
@ -95,7 +109,7 @@ where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
|||
<parameters>
|
||||
<variable_mapping>
|
||||
<variable>IDM_ID</variable>
|
||||
<field>recruitment_id</field>
|
||||
<field>idm_id</field>
|
||||
<input/>
|
||||
</variable_mapping>
|
||||
<inherit_all_vars>Y</inherit_all_vars>
|
||||
|
|
@ -146,7 +160,7 @@ where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
|||
<parameters>
|
||||
<variable_mapping>
|
||||
<variable>IDM_ID</variable>
|
||||
<field>recruitment_id</field>
|
||||
<field>idm_id</field>
|
||||
<input/>
|
||||
</variable_mapping>
|
||||
<inherit_all_vars>Y</inherit_all_vars>
|
||||
|
|
@ -197,7 +211,7 @@ where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
|||
<parameters>
|
||||
<variable_mapping>
|
||||
<variable>IDM_ID</variable>
|
||||
<field>recruitment_id</field>
|
||||
<field>idm_id</field>
|
||||
<input/>
|
||||
</variable_mapping>
|
||||
<inherit_all_vars>Y</inherit_all_vars>
|
||||
|
|
@ -248,7 +262,7 @@ where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
|||
<parameters>
|
||||
<variable_mapping>
|
||||
<variable>IDM_ID</variable>
|
||||
<field>recruitment_id</field>
|
||||
<field>idm_id</field>
|
||||
<input/>
|
||||
</variable_mapping>
|
||||
<inherit_all_vars>Y</inherit_all_vars>
|
||||
|
|
@ -299,7 +313,7 @@ where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
|||
<parameters>
|
||||
<variable_mapping>
|
||||
<variable>IDM_ID</variable>
|
||||
<field>recruitment_id</field>
|
||||
<field>idm_id</field>
|
||||
<input/>
|
||||
</variable_mapping>
|
||||
<inherit_all_vars>Y</inherit_all_vars>
|
||||
|
|
@ -329,6 +343,29 @@ where je.status is null or je.status in('ERROR', 'PROCESSING');</sql>
|
|||
<yloc>528</yloc>
|
||||
</GUI>
|
||||
</transform>
|
||||
<transform>
|
||||
<name>get_max_source_update_date</name>
|
||||
<type>TableInput</type>
|
||||
<description/>
|
||||
<distribute>Y</distribute>
|
||||
<custom_distribution/>
|
||||
<copies>1</copies>
|
||||
<partitioning>
|
||||
<method>none</method>
|
||||
<schema_name/>
|
||||
</partitioning>
|
||||
<connection>ervu-dashboard</connection>
|
||||
<execute_each_row>N</execute_each_row>
|
||||
<limit>0</limit>
|
||||
<sql>SELECT max(source_update_date) AS max_source_update_date
|
||||
FROM ervu_dashboard.drivers_licence;</sql>
|
||||
<variables_active>N</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
<xloc>64</xloc>
|
||||
<yloc>368</yloc>
|
||||
</GUI>
|
||||
</transform>
|
||||
<transform_error_handling>
|
||||
</transform_error_handling>
|
||||
<attributes/>
|
||||
|
|
|
|||
|
|
@ -421,7 +421,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
property_data->>'naimVidPrav' AS kind_right, -- Исправлено название поля
|
||||
property_data->'adrObSob'->>'adrObSobTekst' AS address,
|
||||
property_data->>'kodVidPrav' AS vehicle_type,
|
||||
property_data->>'kodVidPrav' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -443,7 +443,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'vidTS' AS vehicle_type,
|
||||
property_data->>'vidTS' AS property_code,
|
||||
property_data->>'godVyp' AS issue_year,
|
||||
property_data->>'markaTS' AS brand_model,
|
||||
property_data->>'gosRegZn' AS reg_plate,
|
||||
|
|
@ -465,7 +465,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'naimVid' AS vehicle_type,
|
||||
property_data->>'naimVid' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -487,7 +487,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'naimVid' AS vehicle_type,
|
||||
property_data->>'naimVid' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -506,7 +506,7 @@ select
|
|||
source_update_date,
|
||||
kind_right,
|
||||
address,
|
||||
vehicle_type,
|
||||
property_code,
|
||||
issue_year::int,
|
||||
brand_model,
|
||||
reg_plate,
|
||||
|
|
@ -567,8 +567,8 @@ from all_data</sql>
|
|||
<stream_name>address</stream_name>
|
||||
</field>
|
||||
<field>
|
||||
<column_name>vehicle_type</column_name>
|
||||
<stream_name>vehicle_type</stream_name>
|
||||
<column_name>property_code</column_name>
|
||||
<stream_name>property_code</stream_name>
|
||||
</field>
|
||||
<field>
|
||||
<column_name>issue_year</column_name>
|
||||
|
|
@ -611,14 +611,11 @@ from all_data</sql>
|
|||
<only_when_have_rows>N</only_when_have_rows>
|
||||
<partitioning_daily>N</partitioning_daily>
|
||||
<partitioning_enabled>N</partitioning_enabled>
|
||||
<partitioning_field/>
|
||||
<partitioning_monthly>Y</partitioning_monthly>
|
||||
<return_field/>
|
||||
<return_keys>N</return_keys>
|
||||
<schema>ervu_dashboard</schema>
|
||||
<specify_fields>Y</specify_fields>
|
||||
<table>property</table>
|
||||
<tablename_field/>
|
||||
<tablename_in_field>N</tablename_in_field>
|
||||
<tablename_in_table>Y</tablename_in_table>
|
||||
<truncate>N</truncate>
|
||||
|
|
|
|||
|
|
@ -348,19 +348,16 @@ and recruitment_id = '${IDM_ID}';</sql>
|
|||
<condition>=</condition>
|
||||
<field>recruit_id</field>
|
||||
<name>recruit_id</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<key>
|
||||
<condition>=</condition>
|
||||
<field>start_date</field>
|
||||
<name>start_date</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<key>
|
||||
<condition>=</condition>
|
||||
<field>type_property</field>
|
||||
<name>type_property</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<schema>ervu_dashboard</schema>
|
||||
<table>property</table>
|
||||
|
|
@ -380,8 +377,8 @@ and recruitment_id = '${IDM_ID}';</sql>
|
|||
<update>Y</update>
|
||||
</value>
|
||||
<value>
|
||||
<name>vehicle_type</name>
|
||||
<rename>vehicle_type</rename>
|
||||
<name>property_code</name>
|
||||
<rename>property_code</rename>
|
||||
<update>Y</update>
|
||||
</value>
|
||||
<value>
|
||||
|
|
@ -450,16 +447,15 @@ and recruitment_id = '${IDM_ID}';</sql>
|
|||
</partitioning>
|
||||
<connection>ervu-dashboard</connection>
|
||||
<execute_each_row>N</execute_each_row>
|
||||
<limit/>
|
||||
<sql>WITH
|
||||
base as(
|
||||
SELECT
|
||||
ri.recruit_id,
|
||||
ri.info
|
||||
FROM ervu_dashboard.recruits_info ri
|
||||
join ervu_dashboard.citizen r ON r.recruit_id = ri.recruit_id AND '${IDM_ID}' != '' -- Проверка на пустую строку
|
||||
AND COALESCE(ri.current_recruitment_id, ri.target_recruitment_id) = '${IDM_ID}'
|
||||
--AND '${M_R_CR_DATE}'::timestamp >= ri.created_at
|
||||
AND ri.updated_at >= '${M_R_UP_DATE}'::timestamp
|
||||
FROM ervu_dashboard.recruits_info ri
|
||||
JOIN ervu_dashboard.citizen r ON r.recruit_id = ri.recruit_id AND '${IDM_ID}' != ''
|
||||
AND COALESCE(ri.current_recruitment_id, ri.target_recruitment_id) = '${IDM_ID}'
|
||||
),
|
||||
prop AS (
|
||||
SELECT
|
||||
|
|
@ -475,6 +471,7 @@ prop AS (
|
|||
END
|
||||
) AS property_data ON true
|
||||
WHERE jsonb_typeof(base.info->'svedFL'->'svedON'->'on') = 'array'
|
||||
AND to_date(property_data->>'dataSved', 'YYYY-MM-DD') > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
|
||||
UNION ALL
|
||||
|
||||
|
|
@ -491,6 +488,7 @@ prop AS (
|
|||
END
|
||||
) AS property_data ON true
|
||||
WHERE jsonb_typeof(base.info->'svedFL'->'svedNazTS'->'nazTS') = 'array'
|
||||
AND to_date(property_data->>'dataSved', 'YYYY-MM-DD') > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
|
||||
UNION ALL
|
||||
|
||||
|
|
@ -507,6 +505,7 @@ prop AS (
|
|||
END
|
||||
) AS property_data ON true
|
||||
WHERE jsonb_typeof(base.info->'svedFL'->'svedVozTS'->'vozTS') = 'array'
|
||||
AND to_date(property_data->>'dataSved', 'YYYY-MM-DD') > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
|
||||
UNION ALL
|
||||
|
||||
|
|
@ -523,15 +522,16 @@ prop AS (
|
|||
END
|
||||
) AS property_data ON true
|
||||
WHERE jsonb_typeof(base.info->'svedFL'->'svedVodTS'->'vodTS') = 'array'
|
||||
AND to_date(property_data->>'dataSved', 'YYYY-MM-DD') > '${MAX_SOURCE_UPDATE_DATE}'::date
|
||||
),
|
||||
all_data as(
|
||||
-- Недвижимость
|
||||
SELECT
|
||||
base.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
property_data->>'naimVidPrav' AS kind_right, -- Исправлено название поля
|
||||
prop.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
property_data->>'naimVidPrav' AS kind_right,
|
||||
property_data->'adrObSob'->>'adrObSobTekst' AS address,
|
||||
property_data->>'kodVidPrav' AS vehicle_type,
|
||||
property_data->>'kodVidPrav' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -541,19 +541,18 @@ all_data as(
|
|||
to_date(property_data->>'dataPrekPrav', 'YYYY-MM-DD') AS close_date,
|
||||
'realty' AS type_property,
|
||||
1 AS is_possibility_reg_residence
|
||||
FROM base
|
||||
JOIN prop ON base.recruit_id = prop.recruit_id
|
||||
FROM prop
|
||||
WHERE prop.property_type = 'realty'
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Наземный транспорт
|
||||
SELECT
|
||||
base.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
prop.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'vidTS' AS vehicle_type,
|
||||
property_data->>'vidTS' AS property_code,
|
||||
property_data->>'godVyp' AS issue_year,
|
||||
property_data->>'markaTS' AS brand_model,
|
||||
property_data->>'gosRegZn' AS reg_plate,
|
||||
|
|
@ -563,19 +562,18 @@ all_data as(
|
|||
to_date(property_data->>'dataPrekPr', 'YYYY-MM-DD') AS close_date,
|
||||
'ground_transportation' AS type_property,
|
||||
0 AS is_possibility_reg_residence
|
||||
FROM base
|
||||
JOIN prop ON base.recruit_id = prop.recruit_id
|
||||
FROM prop
|
||||
WHERE prop.property_type = 'ground_transportation'
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Воздушный транспорт
|
||||
SELECT
|
||||
base.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
prop.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'naimVid' AS vehicle_type,
|
||||
property_data->>'naimVid' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -585,19 +583,18 @@ all_data as(
|
|||
to_date(property_data->>'dataPrekPr', 'YYYY-MM-DD') AS close_date,
|
||||
'air_vehicles' AS type_property,
|
||||
0 AS is_possibility_reg_residence
|
||||
FROM base
|
||||
JOIN prop ON base.recruit_id = prop.recruit_id
|
||||
FROM prop
|
||||
WHERE prop.property_type = 'air_vehicles'
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Водный транспорт
|
||||
SELECT
|
||||
base.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
prop.recruit_id,
|
||||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'naimVid' AS vehicle_type,
|
||||
property_data->>'naimVid' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -607,16 +604,15 @@ all_data as(
|
|||
to_date(property_data->>'dataPrekPr', 'YYYY-MM-DD') AS close_date,
|
||||
'water_vehicles' AS type_property,
|
||||
0 AS is_possibility_reg_residence
|
||||
FROM base
|
||||
JOIN prop ON base.recruit_id = prop.recruit_id
|
||||
FROM prop
|
||||
WHERE prop.property_type = 'water_vehicles'
|
||||
)
|
||||
select
|
||||
SELECT
|
||||
recruit_id,
|
||||
source_update_date,
|
||||
kind_right,
|
||||
address,
|
||||
vehicle_type,
|
||||
property_code,
|
||||
issue_year::int,
|
||||
brand_model,
|
||||
reg_plate,
|
||||
|
|
@ -629,20 +625,20 @@ select
|
|||
CASE
|
||||
WHEN type_property = 'realty' THEN 1
|
||||
ELSE 0
|
||||
END AS is_property, -- недвиж//has_property
|
||||
END AS is_property,
|
||||
CASE
|
||||
WHEN type_property = 'ground_transportation' THEN 1
|
||||
ELSE 0
|
||||
END AS is_ground_transport, -- наземный транспорт//has_ground_transport
|
||||
END AS is_ground_transport,
|
||||
CASE
|
||||
WHEN type_property = 'air_vehicles' THEN 1
|
||||
ELSE 0
|
||||
END AS is_air_transport, -- воздушный транспорт//has_air_transport
|
||||
END AS is_air_transport,
|
||||
CASE
|
||||
WHEN type_property = 'water_vehicles' THEN 1
|
||||
ELSE 0
|
||||
END AS is_water_transport -- водный транспорт//has_water_transport
|
||||
from all_data</sql>
|
||||
END AS is_water_transport
|
||||
FROM all_data</sql>
|
||||
<variables_active>Y</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
|
|
|
|||
|
|
@ -363,19 +363,16 @@ DO UPDATE SET
|
|||
<condition>=</condition>
|
||||
<field>recruit_id</field>
|
||||
<name>recruit_id</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<key>
|
||||
<condition>=</condition>
|
||||
<field>start_date</field>
|
||||
<name>start_date</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<key>
|
||||
<condition>=</condition>
|
||||
<field>type_property</field>
|
||||
<name>type_property</name>
|
||||
<name2/>
|
||||
</key>
|
||||
<schema>ervu_dashboard</schema>
|
||||
<table>property</table>
|
||||
|
|
@ -395,8 +392,8 @@ DO UPDATE SET
|
|||
<update>Y</update>
|
||||
</value>
|
||||
<value>
|
||||
<name>vehicle_type</name>
|
||||
<rename>vehicle_type</rename>
|
||||
<name>property_code</name>
|
||||
<rename>property_code</rename>
|
||||
<update>Y</update>
|
||||
</value>
|
||||
<value>
|
||||
|
|
@ -465,6 +462,7 @@ DO UPDATE SET
|
|||
</partitioning>
|
||||
<connection>ervu-dashboard</connection>
|
||||
<execute_each_row>N</execute_each_row>
|
||||
<limit/>
|
||||
<sql>WITH
|
||||
base as(
|
||||
SELECT
|
||||
|
|
@ -545,7 +543,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
property_data->>'naimVidPrav' AS kind_right, -- Исправлено название поля
|
||||
property_data->'adrObSob'->>'adrObSobTekst' AS address,
|
||||
property_data->>'kodVidPrav' AS vehicle_type,
|
||||
property_data->>'kodVidPrav' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -567,7 +565,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'vidTS' AS vehicle_type,
|
||||
property_data->>'vidTS' AS property_code,
|
||||
property_data->>'godVyp' AS issue_year,
|
||||
property_data->>'markaTS' AS brand_model,
|
||||
property_data->>'gosRegZn' AS reg_plate,
|
||||
|
|
@ -589,7 +587,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'naimVid' AS vehicle_type,
|
||||
property_data->>'naimVid' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -611,7 +609,7 @@ all_data as(
|
|||
to_date(property_data->>'dataSved', 'YYYY-MM-DD') AS source_update_date,
|
||||
NULL AS kind_right,
|
||||
NULL AS address,
|
||||
property_data->>'naimVid' AS vehicle_type,
|
||||
property_data->>'naimVid' AS property_code,
|
||||
NULL AS issue_year,
|
||||
NULL AS brand_model,
|
||||
NULL AS reg_plate,
|
||||
|
|
@ -630,7 +628,7 @@ select
|
|||
source_update_date,
|
||||
kind_right,
|
||||
address,
|
||||
vehicle_type,
|
||||
property_code,
|
||||
issue_year::int,
|
||||
brand_model,
|
||||
reg_plate,
|
||||
|
|
|
|||
|
|
@ -45,6 +45,11 @@
|
|||
<to>property_flow_delta.hpl 5</to>
|
||||
<enabled>Y</enabled>
|
||||
</hop>
|
||||
<hop>
|
||||
<from>get_max_source_update_date</from>
|
||||
<to>Table input</to>
|
||||
<enabled>Y</enabled>
|
||||
</hop>
|
||||
</order>
|
||||
<transform>
|
||||
<name>Table input</name>
|
||||
|
|
@ -60,14 +65,23 @@
|
|||
<connection>ervu-dashboard</connection>
|
||||
<execute_each_row>N</execute_each_row>
|
||||
<limit>0</limit>
|
||||
<sql>SELECT
|
||||
r.idm_id as recruitment_id
|
||||
<sql>WITH mud AS (
|
||||
SELECT
|
||||
recruitment_id,
|
||||
MAX(execution_datetime) AS max_upd_date
|
||||
FROM etl.job_execution
|
||||
WHERE job_name = '${JOB_NAME}'
|
||||
AND status IN ('SUCCESS','DELTA_ERROR','DELTA_SUCCESS','DELTA_PROCESSING')
|
||||
GROUP BY recruitment_id
|
||||
)
|
||||
SELECT
|
||||
r.idm_id
|
||||
FROM ervu_dashboard.recruitment r
|
||||
LEFT JOIN etl.job_execution je
|
||||
ON r.idm_id = je.recruitment_id
|
||||
and job_name = 'property_job'
|
||||
where je.status in ('SUCCESS', 'DELTA_ERROR', 'DELTA_SUCCESS', 'DELTA_PROCESSING');</sql>
|
||||
<variables_active>N</variables_active>
|
||||
JOIN mud ON mud.recruitment_id = r.idm_id
|
||||
JOIN recruits_info ri
|
||||
ON COALESCE(ri.current_recruitment_id, ri.target_recruitment_id) = r.idm_id
|
||||
AND ri.updated_at > mud.max_upd_date;</sql>
|
||||
<variables_active>Y</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
<xloc>352</xloc>
|
||||
|
|
@ -329,6 +343,29 @@ where je.status in ('SUCCESS', 'DELTA_ERROR', 'DELTA_SUCCESS', 'DELTA_PROCESSING
|
|||
<yloc>448</yloc>
|
||||
</GUI>
|
||||
</transform>
|
||||
<transform>
|
||||
<name>get_max_source_update_date</name>
|
||||
<type>TableInput</type>
|
||||
<description/>
|
||||
<distribute>Y</distribute>
|
||||
<custom_distribution/>
|
||||
<copies>1</copies>
|
||||
<partitioning>
|
||||
<method>none</method>
|
||||
<schema_name/>
|
||||
</partitioning>
|
||||
<connection>ervu-dashboard</connection>
|
||||
<execute_each_row>N</execute_each_row>
|
||||
<limit>0</limit>
|
||||
<sql>SELECT max(source_update_date) AS max_source_update_date
|
||||
FROM ervu_dashboard.property;</sql>
|
||||
<variables_active>N</variables_active>
|
||||
<attributes/>
|
||||
<GUI>
|
||||
<xloc>144</xloc>
|
||||
<yloc>288</yloc>
|
||||
</GUI>
|
||||
</transform>
|
||||
<transform_error_handling>
|
||||
</transform_error_handling>
|
||||
<attributes/>
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue