sql files
This commit is contained in:
413
onetime/dataloadfunctions/field/FTDRY_TRS_STG2.sql
Executable file
413
onetime/dataloadfunctions/field/FTDRY_TRS_STG2.sql
Executable file
@@ -0,0 +1,413 @@
|
||||
/*FTDRY_starts*/
|
||||
drop function if exists staging2.fn_FTDRY_TRS_Block ;
|
||||
CREATE OR REPLACE FUNCTION staging2.fn_FTDRY_TRS_Block(p_client_id int,p_function_id int, p_file_mnemonic text,
|
||||
p_file_sheet_mnemonic text, p_file_syspk int)
|
||||
RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS $function$
|
||||
declare __make text;
|
||||
declare __model text;
|
||||
|
||||
declare __client_id int :=p_client_id;
|
||||
declare __function_id int :=p_function_id;
|
||||
declare __file_mnemonic text :=p_file_mnemonic;
|
||||
declare __file_sheet_mnemonic text :=p_file_sheet_mnemonic;
|
||||
declare __file_syspk int :=p_file_syspk;
|
||||
declare err_state text;
|
||||
declare err_msg text;
|
||||
declare err_detail text;
|
||||
declare err_hint text;
|
||||
declare err_context text;
|
||||
declare err_query int;
|
||||
declare err_block text;
|
||||
begin
|
||||
|
||||
|
||||
/***********************************************************************************
|
||||
Function Name:fn_FTDRY_TRS_Block
|
||||
Function Desc: This function populates data into staging2 blocks
|
||||
File Format: FTDRY
|
||||
Sheet Format: FTDRY_TRS
|
||||
Creation Date:
|
||||
Updation Date:
|
||||
Author: compegence team
|
||||
Function Call: select staging2.fn_FTDRY_TRS_Block(20,1,'FTDRY','FTDRY_TRS',257);
|
||||
************************************************************************************/
|
||||
|
||||
SET search_path TO staging2;
|
||||
|
||||
truncate staging2.FTDRY_TRS_H1_INT;
|
||||
truncate staging2.ftdry_trs_h1_block ;
|
||||
truncate staging2.ftdry_trs_implement_block ;
|
||||
truncate staging2.ftdry_trs_spec_block;
|
||||
truncate staging2.ftdry_trs_engine_rpm_block;
|
||||
truncate staging2.stg_specific_table_ftdry_trs;
|
||||
truncate staging2.stg_process_table_ftdry_trs;
|
||||
|
||||
|
||||
execute 'delete from fw_core.fw_jobctl_file_sheet_block_run_schedule where file_syspk='||p_file_syspk||' and file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
execute 'update transactional.source_config a
|
||||
set row_number_start=null,
|
||||
row_previous_number=null,
|
||||
row_read_end=null,
|
||||
run_time=null
|
||||
where a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
|
||||
/* transfer data from generic to specific for ftdry*/
|
||||
|
||||
execute 'insert into staging2.stg_specific_table_ftdry_trs
|
||||
select * from staging1.staging_generic_table a
|
||||
where a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''
|
||||
and a.file_syspk='||p_file_syspk||'';
|
||||
|
||||
select count(*) into err_query from staging2.stg_specific_table_ftdry_trs;
|
||||
|
||||
if err_query=0 then
|
||||
err_context := 'data not present';
|
||||
raise exception using
|
||||
message = 'No Data for FTDRY Tractor Specifications',
|
||||
detail = 'No data in table stg_specific_table_ftdry_trs',
|
||||
errcode = '42704',
|
||||
hint = 'check sheet mnemonic in generic table, if it is null update it';
|
||||
end if;
|
||||
/* trimming data */
|
||||
|
||||
update staging2.stg_specific_table_ftdry_trs set column2 = TRIM (TRAILING FROM column2 );
|
||||
update staging2.stg_specific_table_ftdry_trs set column2 = TRIM (LEADING FROM column2 );
|
||||
--update transactional.source_config set F1_modified = TRIM (TRAILING FROM F1_modified);
|
||||
--update transactional.source_config set F1_modified = TRIM (LEADING FROM F1_modified);
|
||||
--update transactional.source_config set F1_source = TRIM (TRAILING FROM F1_source) ;
|
||||
--update transactional.source_config set F1_source = TRIM (LEADING FROM F1_source);
|
||||
|
||||
|
||||
update transactional.source_config set F1_source=F1_modified;
|
||||
|
||||
/* keyword match in config table*/
|
||||
|
||||
execute 'update transactional.source_config a
|
||||
set row_number_start=(select min(b.row_number)
|
||||
from staging2.stg_specific_table_ftdry_trs b
|
||||
where upper(F1_source)= upper(column2)
|
||||
and b.is_rownumber_fetched is null)
|
||||
where a.row_number_start is null and a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
/* reverese update in process table for match*/
|
||||
execute 'update staging2.stg_specific_table_ftdry_trs a
|
||||
set is_rownumber_fetched=1
|
||||
from transactional.source_config b
|
||||
where upper(F1_source)= upper(column2)
|
||||
and b.row_number_start=a.row_number
|
||||
and is_rownumber_fetched is null and a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
execute 'update transactional.source_config a set row_previous_number=row_number_start-1
|
||||
where a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
/* update config files for row numbers start, end */
|
||||
|
||||
execute 'update transactional.source_config a
|
||||
set row_read_end= (select b.row_number_start
|
||||
from transactional.source_config b
|
||||
where b.syspk=a.syspk+1 )
|
||||
where a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
/* config file last field update as null otherwise it picks up next format row number*/
|
||||
execute 'update transactional.source_config a set row_read_end = null
|
||||
where f1_modified =''Implement Details'' and a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
/*inserting run_time in config*/
|
||||
execute 'update transactional.source_config a
|
||||
set run_time=current_timestamp
|
||||
where a.file_mnemonic='''||p_file_mnemonic||''' and a.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
|
||||
/* tagging block_row_numbers for each block in process table*/
|
||||
|
||||
execute 'insert into staging2.stg_process_table_ftdry_trs
|
||||
select a.* , RANK () OVER ( ORDER BY row_number) as block_row_number,b.block_tag as block_tag
|
||||
from staging2.stg_specific_table_ftdry_trs a
|
||||
join transactional.source_config b
|
||||
on a.row_number >row_number_start
|
||||
and (a.row_number< row_read_end or row_read_end is null)
|
||||
and f1_modified=''Tractor Specifications Sheet''
|
||||
and b.file_mnemonic='''||p_file_mnemonic||''' and b.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''
|
||||
order by a.row_number';
|
||||
|
||||
|
||||
|
||||
execute 'insert into staging2.stg_process_table_ftdry_trs
|
||||
select a.* , RANK () OVER ( ORDER BY row_number),b.block_tag as block_tag
|
||||
from staging2.stg_specific_table_ftdry_trs a
|
||||
join transactional.source_config b
|
||||
on a.row_number >row_number_start
|
||||
and (a.row_number< row_read_end or row_read_end is null)
|
||||
and f1_modified=''Tractor Specifications'' and b.file_mnemonic='''||p_file_mnemonic||''' and b.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''
|
||||
order by a.row_number';
|
||||
|
||||
execute 'insert into staging2.stg_process_table_ftdry_trs
|
||||
select a.* , RANK () OVER ( ORDER BY row_number),b.block_tag as block_tag
|
||||
from staging2.stg_specific_table_ftdry_trs a
|
||||
join transactional.source_config b
|
||||
on a.row_number >row_number_start
|
||||
and (a.row_number< row_read_end or row_read_end is null)
|
||||
and f1_modified=''Engine RPM Data:'' and b.file_mnemonic='''||p_file_mnemonic||''' and b.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''
|
||||
order by a.row_number';
|
||||
|
||||
|
||||
execute 'insert into staging2.stg_process_table_ftdry_trs
|
||||
select a.* , RANK () OVER ( ORDER BY row_number),b.block_tag as block_tag
|
||||
from staging2.stg_specific_table_ftdry_trs a
|
||||
join transactional.source_config b
|
||||
on a.row_number >row_number_start
|
||||
and a.column2 <> ''''
|
||||
and (a.row_number< row_read_end or row_read_end is null)
|
||||
and f1_modified=''Implement Details'' and b.file_mnemonic='''||p_file_mnemonic||''' and b.file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''
|
||||
order by a.row_number';
|
||||
|
||||
/*insert data into h1_int */
|
||||
|
||||
insert into staging2.FTDRY_TRS_H1_INT(
|
||||
column2,column3,column4,column5,column6,column7,block_row_number)
|
||||
select column2,column3,column4,column5,column6,column7,block_row_number
|
||||
from staging2.stg_process_table_ftdry_trs a where block_tag='FTDRY_TRS_H1'
|
||||
order by block_row_number;
|
||||
|
||||
insert into staging2.FTDRY_TRS_H1_INT(column2,column3)
|
||||
select 'Date of Test',column5
|
||||
from staging2.FTDRY_TRS_H1_INT
|
||||
where block_row_number=1;
|
||||
|
||||
insert into staging2.FTDRY_TRS_H1_INT(column2,column3)
|
||||
select 'Report Date',column7
|
||||
from staging2.FTDRY_TRS_H1_INT
|
||||
where block_row_number=1;
|
||||
|
||||
|
||||
insert into staging2.FTDRY_TRS_H1_INT(column2,column3)
|
||||
select column5,column6
|
||||
from staging2.FTDRY_TRS_H1_INT where block_row_number between 4 and 7;
|
||||
|
||||
|
||||
|
||||
/*inserting data into block -FTDRY_TRS_H1_Block*/
|
||||
|
||||
|
||||
perform fw_core.fn_jobctl_block_begin(__client_id,__function_id,__file_syspk,
|
||||
'FTDRY_TRS_H1_Block',__file_mnemonic,__file_sheet_mnemonic,1);
|
||||
|
||||
err_block:='FTDRY_TRS_H1_Block';
|
||||
insert into staging2.FTDRY_TRS_H1_Block
|
||||
(
|
||||
dummy_f,
|
||||
Report_Reference_No,
|
||||
Objective_Of_Test,
|
||||
Background_of_Test,
|
||||
Job_Order_No,
|
||||
Test_Location,
|
||||
Soil_Moisture_Content_,
|
||||
Soil_Bulk_Density_g_cc,
|
||||
Test_Engineer,
|
||||
Test_Operator,
|
||||
Date_of_Test,
|
||||
Report_Date,
|
||||
Season,
|
||||
Type_of_Soil,
|
||||
Soil_Cone_Index_kPa,
|
||||
Field_Condition
|
||||
)
|
||||
SELECT *
|
||||
FROM crosstab(
|
||||
'SELECT unnest(''{column3}''::text[]) AS col
|
||||
, row_number() OVER ()
|
||||
, unnest(ARRAY[column3::text]) AS val
|
||||
FROM staging2.FTDRY_TRS_H1_INT
|
||||
ORDER BY generate_series(1,15),block_row_number,2'
|
||||
) t (col text,a_1 text,a_2 text,a_3 text,a_4 text,a_5 text,a_6 text,a_7 text,a_8 text,a_9 text,a_10 text,
|
||||
a_11 text,a_12 text,a_13 text,a_14 text,a_15 text);
|
||||
|
||||
|
||||
delete from staging2.FTDRY_TRS_H1_Block where dummy_f is null ;
|
||||
execute 'update staging2.FTDRY_TRS_H1_Block set
|
||||
client_id='||p_client_id||',
|
||||
function_id='||p_function_id||',
|
||||
file_syspk='||p_file_syspk||',
|
||||
file_mnemonic='''||p_file_mnemonic||''',
|
||||
file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
perform fw_core.fn_jobctl_block_end(__file_syspk,'FTDRY_TRS_H1_Block');
|
||||
|
||||
|
||||
/*inserting data into block -FTDRY_TRS_SPEC_Block*/
|
||||
|
||||
|
||||
perform fw_core.fn_jobctl_block_begin(__client_id,__function_id,__file_syspk,
|
||||
'FTDRY_TRS_SPEC_Block',__file_mnemonic,__file_sheet_mnemonic,2);
|
||||
|
||||
err_block:='FTDRY_TRS_SPEC_Block';
|
||||
|
||||
insert into staging2.FTDRY_TRS_SPEC_Block
|
||||
(
|
||||
dummy_f,
|
||||
Tractor_Model,
|
||||
Tractor_Make,
|
||||
Tractor_Sr_No,
|
||||
Tractor_Engine_HP,
|
||||
FIP_Type,
|
||||
hour_Meter_Reading,
|
||||
Steering_Type,
|
||||
Transmission_Type,
|
||||
Wheel_Drive_Type_WD,
|
||||
EGR_Yes_No,
|
||||
Brake_Type,
|
||||
PTO_Type,
|
||||
Standard_PTO_Speed_RPM,
|
||||
EPTO_Speed_RPM,
|
||||
Front_Tyre_Make,
|
||||
Front_Tyre_Size,
|
||||
Front_Tyre_Pressure_psi,
|
||||
Rear_Tyre_Make,
|
||||
Rear_Tyre_Size,
|
||||
Rear_Tyre_Pressure_psi ,
|
||||
Tractor_Weight_kg_Front ,
|
||||
Tractor_Weight_kg_Rear ,
|
||||
Tractor_Weight_kg_Total,
|
||||
Ballasted_Tractor_Accessories,
|
||||
Mechanical_Ballast_Rear,
|
||||
Mechanical_Ballast_Rear_in_KG ,
|
||||
Water_Ballast_Rear,
|
||||
Mechanical_Ballast_Front,
|
||||
Mechanical_Ballast_Front_in_Kg,
|
||||
Total_Ballast_Weight
|
||||
)
|
||||
SELECT *
|
||||
FROM crosstab(
|
||||
'SELECT unnest(''{column3,column4,column5,column6,column7}''::text[]) AS col
|
||||
, row_number() OVER ()
|
||||
, unnest(ARRAY[column3::text,column4::text,column5::text,column6::text,column7::text]) AS val
|
||||
FROM staging2.stg_process_table_ftdry_trs where block_tag=''FTDRY_TRS_SPEC''
|
||||
ORDER BY generate_series(1,15),block_row_number,2'
|
||||
) t (col text,a_1 text,a_2 text,a_3 text,a_4 text,a_5 text,a_6 text,a_7 text,a_8 text,
|
||||
a_9 text,a_10 text,a_11 text,a_12 text,a_13 text,a_14 text,a_15 text,a_16 text,a_17 text,a_18 text,a_19 text,a_20 text,a_21 text,
|
||||
a_22 text,a_23 text,a_24 text,a_25 text,a_26 text,a_27 text,a_28 text,a_29 text,a_30 text);
|
||||
|
||||
update staging2.FTDRY_TRS_SPEC_Block set trx_record=0
|
||||
where tractor_make is null and tractor_sr_no is null;
|
||||
|
||||
update staging2.FTDRY_TRS_SPEC_Block set trx_record=0
|
||||
where (tractor_model is null and front_tyre_make is null) or (tractor_model is null and rear_tyre_make is null);
|
||||
|
||||
|
||||
delete from staging2.FTDRY_TRS_SPEC_Block where dummy_f is null ;
|
||||
execute 'update staging2.FTDRY_TRS_SPEC_Block set
|
||||
client_id='||p_client_id||',
|
||||
function_id='||p_function_id||',
|
||||
file_syspk='||p_file_syspk||',
|
||||
file_mnemonic='''||p_file_mnemonic||''',
|
||||
file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
perform fw_core.fn_jobctl_block_end(__file_syspk,'FTDRY_TRS_SPEC_Block');
|
||||
|
||||
|
||||
/*inserting data into block -FTDRY_TRS_Engine_RPM_Block*/
|
||||
|
||||
|
||||
perform fw_core.fn_jobctl_block_begin(__client_id,__function_id,__file_syspk,
|
||||
'FTDRY_TRS_Engine_RPM_Block',__file_mnemonic,__file_sheet_mnemonic,3);
|
||||
|
||||
err_block:='FTDRY_TRS_Engine_RPM_Block';
|
||||
insert into staging2.FTDRY_TRS_Engine_RPM_Block
|
||||
(
|
||||
dummy_f,
|
||||
tractor_model,
|
||||
tractor_make,
|
||||
tractor_sr_no,
|
||||
Low_Idle,
|
||||
High_Idle,
|
||||
Rated_RPM,
|
||||
Engine_to_PTO_Ratio_540_PTO,
|
||||
Engine_to_PTO_Ratio_540E_PTO
|
||||
)
|
||||
SELECT *
|
||||
FROM crosstab(
|
||||
'SELECT unnest(''{column3,column4,column5,column6,column7}''::text[]) AS col
|
||||
, row_number() OVER ()
|
||||
, unnest(ARRAY[column3::text,column4::text,column5::text,column6::text,column7::text]) AS val
|
||||
FROM staging2.stg_process_table_ftdry_trs where block_tag=''FTDRY_TRS_Engine_RPM''
|
||||
or (block_tag=''FTDRY_TRS_SPEC'' and block_row_number in (1,2,3))
|
||||
ORDER BY generate_series(1,15),2'
|
||||
) t (col text,a_1 text,a_2 text,a_3 text,a_4 text,a_5 text,a_6 text,a_7 text,a_8 text);
|
||||
|
||||
update staging2.FTDRY_TRS_Engine_RPM_Block set trx_record=0
|
||||
where tractor_make is null and tractor_sr_no is null;
|
||||
|
||||
delete from staging2.FTDRY_TRS_Engine_RPM_Block where dummy_f is null ;
|
||||
execute 'update staging2.FTDRY_TRS_Engine_RPM_Block set
|
||||
client_id='||p_client_id||',
|
||||
function_id='||p_function_id||',
|
||||
file_syspk='||p_file_syspk||',
|
||||
file_mnemonic='''||p_file_mnemonic||''',
|
||||
file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
perform fw_core.fn_jobctl_block_end(__file_syspk,'FTDRY_TRS_Engine_RPM_Block');
|
||||
|
||||
|
||||
/*inserting data into block -FTDRY_TRS_Implement_Block*/
|
||||
|
||||
|
||||
perform fw_core.fn_jobctl_block_begin(__client_id,__function_id,__file_syspk,
|
||||
'FTDRY_TRS_Implement_Block',__file_mnemonic,__file_sheet_mnemonic,4);
|
||||
|
||||
err_block:='FTDRY_TRS_Implement_Block';
|
||||
insert into staging2.FTDRY_TRS_Implement_Block
|
||||
(
|
||||
dummy_f,
|
||||
Name_of_Implement,
|
||||
Type_of_Implement,
|
||||
Make_of_Implement,
|
||||
No_of_bottoms_Tyne_Disc_Blade,
|
||||
Cutting_Width_m,
|
||||
Implement_Weight_Kg,
|
||||
Hitch_Category,
|
||||
Span_cm_For_Mounted_Implement,
|
||||
Mast_Height_cm_For_Mounted_Implement
|
||||
)
|
||||
SELECT *
|
||||
FROM crosstab(
|
||||
'SELECT unnest(''{column3,column4,column5,column6}''::text[]) AS col
|
||||
, row_number() OVER ()
|
||||
, unnest(ARRAY[column3::text,column4::text,column5::text,column6::text]) AS val
|
||||
FROM staging2.stg_process_table_ftdry_trs where block_tag=''FTDRY_TRS_Implement''
|
||||
ORDER BY generate_series(1,15),block_row_number,2'
|
||||
) t ( col text,a_1 text,a_2 text,a_3 text,a_4 text,a_5 text,a_6 text,a_7 text,a_8 text,a_9 text);
|
||||
|
||||
update staging2.FTDRY_TRS_Implement_Block set trx_record=0
|
||||
where name_of_implement is null;
|
||||
|
||||
update staging2.FTDRY_TRS_Implement_Block set dummy_f='dummy' where dummy_f is null;
|
||||
|
||||
update staging2.FTDRY_TRS_Implement_Block set report_template_no= (select column2 from staging2.stg_process_table_ftdry_trs where block_row_number=10 and block_tag='FTDRY_TRS_Implement');
|
||||
|
||||
|
||||
update staging2.FTDRY_TRS_Implement_Block set report_template_rev_no= (select column4 from staging2.stg_process_table_ftdry_trs where block_row_number=10 and block_tag='FTDRY_TRS_Implement');
|
||||
|
||||
|
||||
update staging2.FTDRY_TRS_Implement_Block set report_template_rev_date= (select column6 from staging2.stg_process_table_ftdry_trs where block_row_number=10 and block_tag='FTDRY_TRS_Implement');
|
||||
|
||||
|
||||
execute 'update staging2.FTDRY_TRS_Implement_Block set
|
||||
client_id='||p_client_id||',
|
||||
function_id='||p_function_id||',
|
||||
file_syspk='||p_file_syspk||',
|
||||
file_mnemonic='''||p_file_mnemonic||''',
|
||||
file_sheet_mnemonic='''||p_file_sheet_mnemonic||'''';
|
||||
|
||||
perform fw_core.fn_jobctl_block_end(__file_syspk,'FTDRY_TRS_Implement_Block');
|
||||
|
||||
perform fw_core.fn_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_mnemonic,__file_sheet_mnemonic ,null,'stg2', 'fn_FTDRY_TRS_Block', err_state, err_msg, err_detail, err_hint, err_context,'success');
|
||||
|
||||
end
|
||||
$function$
|
||||
;
|
||||
|
||||
|
||||
Reference in New Issue
Block a user