drop function if exists mmt_staging2.fn_BUDNI_FLD_Block ; CREATE OR REPLACE FUNCTION mmt_staging2.fn_BUDNI_FLD_Block(p_client_id int,p_function_id int, p_file_format text, p_sheet_mnemonic text, p_file_syspk int) RETURNS text AS $$ declare __make text; declare __model text; declare __client_id int :=p_client_id; declare __function_id int :=p_function_id; declare __file_format text :=p_file_format; declare __sheet_mnemonic text :=p_sheet_mnemonic; declare __file_syspk int :=p_file_syspk; declare v_state text; declare v_msg text; declare v_detail text; declare v_hint text; declare v_context text; declare _error int; declare v_block text; begin /*********************************************************************************** Function Name:fn_BUDNI_FLD_Block Function Desc: This function populates data into staging2 blocks File Format: BUDNI Sheet Format: BUDNI_FLD Creation Date: March 21 2021 Updation Date: Author: compegence team Function Call: select mmt_staging2.fn_BUDNI_FLD_Block(20,1,'BUDNI','BUDNI_FLD',261) ************************************************************************************/ SET search_path TO mmt_staging2; /* rerunnability - delete block tables and update config tables to null */ truncate table mmt_staging2.BUDNI_FLD_Spec_H1_Block; truncate table mmt_staging2.BUDNI_FLD_Impl_Test_Int; truncate table mmt_staging2.BUDNI_FLD_Impl_Test_Block; truncate table mmt_staging2.BUDNI_FLD_Cage_Wheel_Block; truncate table mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Int; truncate table mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Block; truncate table mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block; truncate table mmt_staging2.stg_specific_table_BUDNI_FLD; truncate table mmt_staging2.stg_process_table_BUDNI_FLD; execute 'delete from mmt_ods.fw_jobctrl_file_sheet_block_run_schedule where file_syspk='||p_file_syspk||' and sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'update mmt_ods.mmt_config a set row_number_start=null, row_previous_number=null, row_read_end=null, run_time=null where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /* transfer data from generic to specific for BUDNI */ execute 'insert into mmt_staging2.stg_specific_table_BUDNI_FLD select * from mmt_staging1.mmt_staging_generic_table a where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''' and a.file_syspk='||p_file_syspk||''; /* trimming data */ update mmt_staging2.stg_specific_table_BUDNI_FLD set column3 = TRIM (TRAILING FROM column3 ); update mmt_staging2.stg_specific_table_BUDNI_FLD set column3 = TRIM (LEADING FROM column3 ); update mmt_ods.mmt_config set F1_modified = TRIM (TRAILING FROM F1_modified); update mmt_ods.mmt_config set F1_modified = TRIM (LEADING FROM F1_modified) ; update mmt_ods.mmt_config set F1_source=F1_modified ; update mmt_ods.mmt_config set F1_source = TRIM (TRAILING FROM F1_source); update mmt_ods.mmt_config set F1_source = TRIM (LEADING FROM F1_source) ; /* keyword match in config table*/ execute 'update mmt_ods.mmt_config a set row_number_start=(select min(b.row_number) from mmt_staging2.stg_specific_table_BUDNI_FLD b where trim(upper(F1_source))= trim(upper(column3)) and b.is_rownumber_fetched is null) where a.row_number_start is null and a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /* reverese update in process table for match*/ execute 'update mmt_staging2.stg_specific_table_BUDNI_FLD a set is_rownumber_fetched=1 from mmt_ods.mmt_config b where trim(upper(F1_source))= trim(upper(column3)) and b.row_number_start=a.row_number and is_rownumber_fetched is null and a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /* update config files for row numbers start, end */ execute 'update mmt_ods.mmt_config a set row_previous_number=row_number_start-1 where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'update mmt_ods.mmt_config a set row_read_end= (select b.row_number_start from mmt_ods.mmt_config b where b.syspk=a.syspk+1 ) where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /* config file last field update as null otherwise it picks up next format row number*/ execute 'update mmt_ods.mmt_config a set row_read_end = null where f1_modified =''Field Performance Test Observations Summary'' and a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'update mmt_ods.mmt_config a set run_time=current_timestamp where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /* tagging ranks for each block in process table*/ execute 'insert into mmt_staging2.stg_process_table_BUDNI_FLD select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_BUDNI_FLD a join mmt_ods.mmt_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=''Test Tractor Specifiactions'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''' order by a.row_number'; execute 'insert into mmt_staging2.stg_process_table_BUDNI_FLD select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_BUDNI_FLD a join mmt_ods.mmt_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=''BRIEF SPECIFICATION OF IMPLEMENTS USED DURING FIELD TEST'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''' order by a.row_number'; execute 'insert into mmt_staging2.stg_process_table_BUDNI_FLD select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_BUDNI_FLD a join mmt_ods.mmt_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=''SUMMARY OF FIELD PERFORMANCE TEST'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''' order by a.row_number'; execute 'insert into mmt_staging2.stg_process_table_BUDNI_FLD select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_BUDNI_FLD a join mmt_ods.mmt_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=''Field Performance Test Observations Summary'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''' order by a.row_number'; /* fetching tractor model and make */ select column3 into __make from mmt_staging2.stg_process_table_BUDNI_FLD a where rank_tag='BUDNI_FLD_Spec_H1' and rank=3; select column4 into __model from mmt_staging2.stg_process_table_BUDNI_FLD a where rank_tag='BUDNI_FLD_Spec_H1' and rank=3; /* blocks data loading start - BUDNI_FLD_Spec_H1_block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'BUDNI_FLD_Spec_H1_block',__file_format,__sheet_mnemonic,1); v_block:='BUDNI_FLD_Spec_H1_block'; insert into mmt_staging2.BUDNI_FLD_Spec_H1_block ( make,model,tractor_HP,rated_rpm,configuration,transmission_type,wheel_drive_type,rank) select column3,column4,column5,column6,column7,column8,column9,rank from mmt_staging2.stg_process_table_BUDNI_FLD where rank_tag='BUDNI_FLD_Spec_H1' and rank=3; execute 'update mmt_staging2.BUDNI_FLD_Spec_H1_Block set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; update mmt_staging2.BUDNI_FLD_Spec_H1_block a set FIP_type=column3,steering_type=column4,Engine_to_PTO_ratio= column5,Ballast_Condition=column6, Test_Engine_Set_RPM=column7 from mmt_staging2.stg_process_table_BUDNI_FLD b where b.rank_tag='BUDNI_FLD_Spec_H1' and b.rank=5 and a.file_syspk=b.file_syspk; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'BUDNI_FLD_Spec_H1_block'); insert into mmt_staging2.BUDNI_FLD_Impl_Test_Int ( column3,column4,column5,column6,column7, column8,column9,rank ) select column3,column4,column5,column6,column7, column8,column9,rank from mmt_staging2.stg_process_table_BUDNI_FLD a where rank_tag ='BUDNI_FLD_Impl_Test' and rank <> 1 order by rank; update mmt_staging2.BUDNI_FLD_Impl_Test_Int a set column3= b.first_value from (SELECT rank, column3, value_partition, first_value(column3) over (partition by value_partition order by rank) FROM ( SELECT rank, column3, sum(case when column3 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int ORDER BY rank ASC ) as q) b where a.rank = b.rank and a.rank <> 13 ; update mmt_staging2.BUDNI_FLD_Impl_Test_Int a set column4= b.first_value from (SELECT rank, column4, value_partition, first_value(column4) over (partition by value_partition order by rank) FROM ( SELECT rank, column4, sum(case when column4 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int ORDER BY rank ASC ) as q) b where a.rank = b.rank and a.rank <> 13 ; update mmt_staging2.BUDNI_FLD_Impl_Test_Int a set column5= b.first_value from (SELECT rank, column5, value_partition, first_value(column5) over (partition by value_partition order by rank) FROM ( SELECT rank, column5, sum(case when column5 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int ORDER BY rank ASC ) as q) b where a.rank = b.rank and a.rank <> 13 ; update mmt_staging2.BUDNI_FLD_Impl_Test_Int a set column6= b.first_value from (SELECT rank, column6, value_partition, first_value(column6) over (partition by value_partition order by rank) FROM ( SELECT rank, column6, sum(case when column6 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int ORDER BY rank ASC ) as q) b where a.rank = b.rank and a.rank <> 13; update mmt_staging2.BUDNI_FLD_Impl_Test_Int a set column7= b.first_value from (SELECT rank, column7, value_partition, first_value(column7) over (partition by value_partition order by rank) FROM ( SELECT rank, column7, sum(case when column7 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Impl_Test_Int a set column8= b.first_value from (SELECT rank, column8, value_partition, first_value(column8) over (partition by value_partition order by rank) FROM ( SELECT rank, column8, sum(case when column8 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int ORDER BY rank ASC ) as q) b where a.rank = b.rank; execute 'update mmt_staging2.BUDNI_FLD_Impl_Test_Int set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; /* blocks data loading - BUDNI_FLD_Impl_Test_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'BUDNI_FLD_Impl_Test_Block',__file_format,__sheet_mnemonic,2); v_block:='BUDNI_FLD_Impl_Test_Block'; insert into mmt_staging2.BUDNI_FLD_Impl_Test_Block ( dummy_f, items, Make, type, No_of_Disc_blades, Type_of_Disc_blades, Size_of_bottoms_blades_1_mm, Size_of_bottoms_blades_2_mm, Size_of_bottoms_blades_3_mm, Spacing_of_bottoms_flanges_mm, Lower_hitch_point_span_mm, Mast_height_mm, Overall_dimensions_mm, Overall_dimensions_mm_length, Overall_dimensions_mm_Width, Overall_dimensions_mm_Height, Gross_mass_kg ) SELECT * FROM crosstab( 'SELECT unnest(''{column5,column6}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[column5::text,column6::text]) AS val FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int where ods_record=1 ORDER BY generate_series(1,15),rank,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); delete from mmt_staging2.BUDNI_FLD_Impl_Test_Block where dummy_f is null; execute 'update mmt_staging2.BUDNI_FLD_Impl_Test_Block set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'BUDNI_FLD_Impl_Test_Block'); /* blocks data loading - BUDNI_FLD_Cage_Wheel_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'BUDNI_FLD_Cage_Wheel_Block',__file_format,__sheet_mnemonic,3); v_block:='BUDNI_FLD_Cage_Wheel_Block'; insert into mmt_staging2.BUDNI_FLD_Cage_Wheel_Block ( dummy_f, Items, type, Dia_mm, Width_mm, No_and_types_of_lugs, Size_of_angle_section_1_mm, Size_of_angle_section_2_mm, Size_of_angle_section_3_mm, Length_of_lugs_mm, Spacing_of_lugs_mm, Weight_of_each_cage_wheels_kg ) SELECT * FROM crosstab( 'SELECT unnest(''{column9}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[column9::text]) AS val FROM mmt_staging2.BUDNI_FLD_Impl_Test_Int where ods_record=1 ORDER BY generate_series(1,15),rank,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); delete from mmt_staging2.BUDNI_FLD_Cage_Wheel_Block where dummy_f is null; execute 'update mmt_staging2.BUDNI_FLD_Cage_Wheel_Block set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'BUDNI_FLD_Cage_Wheel_Block'); insert into mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Int ( column3,column4,column5,column6,column7,rank ) select column3,column4,column5,column6,column7,rank from mmt_staging2.stg_process_table_BUDNI_FLD a where rank_tag ='BUDNI_FLD_Sum_Perf_Test' and rank <> 1 order by rank,column3 ; update mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Int set make=__make,model=__model; execute 'update mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Int set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; /* blocks data loading - BUDNI_FLD_Sum_Perf_Test_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'BUDNI_FLD_Sum_Perf_Test_Block',__file_format,__sheet_mnemonic,4); v_block:='BUDNI_FLD_Sum_Perf_Test_Block'; insert into mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Block ( dummy_f, Parameter_operation, Type_of_soil, Av_soil_moisture_Av_depth_of_standing_water_cm, Bulk_density_of_soil_g_cc, Cone_index_kgf_sq_cm_Puddling_index, Gear_used, Av_speed_of_operation_kmph, Av_wheel_slip_Av_Travel_reduction, Av_depth_of_cut_cm_Av_Depth_of_puddle_cm, Av_working_width_cm, Area_covered_ha_h, Fuel_consumption, Fuel_consumption_l_h, Fuel_consumption_l_ha, Av_draft_of_implement_kN ) SELECT * FROM crosstab( 'SELECT unnest(''{column5,column6,column7}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[column5::text,column6::text,column7::text]) AS val FROM mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Int where ods_record=1 ORDER BY generate_series(1,15),rank,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 mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Block where dummy_f is null; update mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Block set make=__make,model=__model; execute 'update mmt_staging2.BUDNI_FLD_Sum_Perf_Test_Block set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'BUDNI_FLD_Sum_Perf_Test_Block'); /* blocks data loading - BUDNI_FLD_Test_Obs_Summary_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'BUDNI_FLD_Test_Obs_Summary_Block',__file_format,__sheet_mnemonic,5); v_block:='BUDNI_FLD_Test_Obs_Summary_Block'; insert into mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ( column3,column4,column5,column6,column7, column8,column9,rank ) select column3,column4,column5,column6,column7, column8,column9,rank from mmt_staging2.stg_process_table_BUDNI_FLD a where rank_tag='BUDNI_FLD_Test_Obs_Summary' and rank <=6; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block set ods_record=0 where rank in (1,2); update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block a set column4= b.first_value from (SELECT rank, column4, value_partition, first_value(column4) over (partition by value_partition order by rank) FROM ( SELECT rank, column4, sum(case when column4 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block a set column5= b.first_value from (SELECT rank, column5, value_partition, first_value(column5) over (partition by value_partition order by rank) FROM ( SELECT rank, column5, sum(case when column5 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block a set column6= b.first_value from (SELECT rank, column6, value_partition, first_value(column6) over (partition by value_partition order by rank) FROM ( SELECT rank, column6, sum(case when column6 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block a set column7= b.first_value from (SELECT rank, column7, value_partition, first_value(column7) over (partition by value_partition order by rank) FROM ( SELECT rank, column7, sum(case when column7 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block a set column8= b.first_value from (SELECT rank, column8, value_partition, first_value(column8) over (partition by value_partition order by rank) FROM ( SELECT rank, column8, sum(case when column8 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block a set column9= b.first_value from (SELECT rank, column9, value_partition, first_value(column9) over (partition by value_partition order by rank) FROM ( SELECT rank, column9, sum(case when column9 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block set make=__make,model=__model; execute 'update mmt_staging2.BUDNI_FLD_Test_Obs_Summary_Block set client_id='||p_client_id||', function_id='||p_function_id||', file_syspk='||p_file_syspk||', file_format='''||p_file_format||''', sheet_mnemonic='''||p_sheet_mnemonic||''''; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'BUDNI_FLD_Test_Obs_Summary_Block'); v_context := ''; perform mmt_staging2.mmt_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_format,__sheet_mnemonic ,null,'stg2', 'fn_BUDNI_FLD_Block', v_state, v_msg, v_detail, v_hint, v_context,'success'); return v_context; EXCEPTION when OTHERS then GET STACKED DIAGNOSTICS v_state = returned_sqlstate, v_msg = message_text, v_detail = pg_exception_detail, v_hint = pg_exception_hint, v_context = pg_exception_context; perform mmt_staging2.mmt_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_format,__sheet_mnemonic ,v_block,'stg2', 'fn_BUDNI_FLD_Block', v_state, v_msg, v_detail, v_hint, v_context,'error'); return v_context; end $$ LANGUAGE plpgsql;