drop function if exists mmt_staging2.fn_FTWET_SUM_Block ; CREATE OR REPLACE FUNCTION mmt_staging2.fn_FTWET_SUM_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 __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_FTWET_SUM_Block Function Desc: This function populates data into staging2 blocks File Format: FTWET Sheet Format: FTWET_SUM Creation Date: Updation Date: Author: compegence team Function Call: select mmt_staging2.fn_ftwet_sum_block(20,1,'FTWET','FTWET_SUM',260); ************************************************************************************/ SET search_path TO mmt_staging2; truncate mmt_staging2.FTWET_SUM_Trac_H1_Block; truncate mmt_staging2.FTWET_SUM_Implement_Block; truncate mmt_staging2.FTWET_SUM_Cage_Wheel_Block; truncate mmt_staging2.FTWET_SUM_Test_Condition_Block; truncate mmt_staging2.FTWET_SUM_Comments_By_Block; truncate mmt_staging2.stg_specific_table_ftwet_sum; truncate mmt_staging2.stg_process_table_ftwet_sum; 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 ftwet*/ execute 'insert into mmt_staging2.stg_specific_table_ftwet_sum 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_ftwet_sum set column2 = TRIM (TRAILING FROM column2 ); update mmt_staging2.stg_specific_table_ftwet_sum set column2 = TRIM (LEADING FROM column2 ); 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_ftwet_sum b where F1_source=column2 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_ftwet_sum a set is_rownumber_fetched=1 from mmt_ods.mmt_config b where F1_source=column2 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||''''; 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||''''; /* keyword match in config table*/ 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 =''Test Manager Comments'' and a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /*inserting run_time in config*/ 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_ftwet_sum select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_ftwet_sum 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=''Tractor Model'' 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_ftwet_sum select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_ftwet_sum 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=''Make of Implement'' 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_ftwet_sum select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_ftwet_sum 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=''Type of Cage Wheel'' 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_ftwet_sum select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_ftwet_sum 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 Condition:'' 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_ftwet_sum select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_ftwet_sum 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 Manager Comments'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''' order by a.row_number'; /*inserting data into block -FTWET_SUM_Trac_H1_Block*/ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'FTWET_SUM_Trac_H1_Block',__file_format,__sheet_mnemonic,1); v_block:='FTWET_SUM_Trac_H1_Block'; insert into mmt_staging2.FTWET_SUM_Trac_H1_Block ( Tractor_Model, Tractor_Make, Tractor_Engine_HP, Rated_RPM, Transmission_Type, Wheel_Drive_Type, FIP_Type, Steering_Type, Tractor_Weight_kg_Front, Tractor_Weight_kg_Rear, Tractor_Weight_kg_Total, rank ) select column2,column3,column4,column5,column6,column7,column8,column9,column10,column11,column12,rank from mmt_staging2.stg_process_table_FTWET_sum where rank_tag='FTWET_SUM_Trac_H1' order by rank; delete from mmt_staging2.FTWET_SUM_Trac_H1_Block where tractor_model='0'; update mmt_staging2.FTWET_SUM_Trac_H1_Block set ods_record=0 where rank=1; execute 'update mmt_staging2.FTWET_SUM_Trac_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||''''; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'FTWET_SUM_Trac_H1_Block'); /*inserting data into block -FTWET_SUM_Implement_Block*/ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'FTWET_SUM_Implement_Block',__file_format,__sheet_mnemonic,2); v_block:='FTWET_SUM_Implement_Block'; insert into mmt_staging2.FTWET_SUM_Implement_Block ( Make_of_Implement, Implement_Type, Implement_Size, Hitch_Category, Implement_Weight, Soil_Type, Moisture_Content , Bulk_Density_g_cc , Soil_Cone_index, Field_Condition , Season, rank ) select column2,column3,column4,column5,column6,column7,column8,column9,column10,column11,column12,rank from mmt_staging2.stg_process_table_FTWET_sum where rank_tag='FTWET_SUM_Impement' order by rank; execute 'update mmt_staging2.FTWET_SUM_Implement_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.FTWET_SUM_Implement_Block set ods_record=0 where rank=1; perform mmt_staging2.fn_jobctrl_block_end(__file_syspk,'FTWET_SUM_Implement_Block'); /*inserting data into block -FTWET_SUM_Cage_Wheel_Block*/ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'FTWET_SUM_Cage_Wheel_Block',__file_format,__sheet_mnemonic,3); v_block:='FTWET_SUM_Cage_Wheel_Block'; insert into mmt_staging2.FTWET_SUM_Cage_Wheel_Block ( Type_of_Cage_Wheel, Cage_Wheel_Width_mm, Cage_wheel_Weight, Cage_Wheel_inner_Outer_Ring_Dia_mm, Cage_Wheel_Center_Ring_Dia_mm, Distance_between_RHS_LHS_cage_wheel_Inner_Ring_mm, No_of_angles_on_cage_wheel, rank ) select column2,column3,column4,column5,column6,column7,column8,rank from mmt_staging2.stg_process_table_FTWET_sum where rank_tag='FTWET_SUM_Cage_Wheel' order by rank; update mmt_staging2.FTWET_SUM_Cage_Wheel_Block set ods_record=0 where rank in (1,3); execute 'update mmt_staging2.FTWET_SUM_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,'FTWET_SUM_Cage_Wheel_Block'); /*inserting data into block -FTWET_SUM_Test_Condition_Block*/ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'FTWET_SUM_Test_Condition_Block',__file_format,__sheet_mnemonic,4); v_block:='FTWET_SUM_Test_Condition_Block'; insert into mmt_staging2.FTWET_SUM_Test_Condition_Block ( dummy_f, Test_Condition, Test_Date, Tractor_Model, Engine_RPM_set, PTO_RPM_set, Gear_Used, Nominal_Speed_KMPH, Engine_RPM_Drop_on_straight_1st_Pass, Engine_RPM_Drop_on_straight_2nd_Pass, Engine_RPM_Drop_on_straight_3rd_Pass, Engine_RPM_Drop_on_turn_1st_Pass, Engine_RPM_Drop_on_turn_2nd_Pass, Engine_RPM_Drop_on_turn_3rd_Pass, No_of_passes, Avg_Depth_of_cut_cm, Fuel_consumption_lit_hr, Area_covered_acr_hr, Fuel_consumption_lit_Acr, M_M_Performance_in_compared_to_respective_competitor_tractors, Fuel_consumption_lit_hr_2, Area_covered_acr_hr_2, Fuel_consumption_lit_Acr_2, Trail_Observations, Engine_Smoke_on_Load, Engine_acceleration_smoke, Draft_Response, Tractor_Steer_ability, Tractor_braking_performance, Front_Visibility, Implement_Accessibility, Front_Wheel_dragging_at_turning, Front_end_lifting_during_operation, RPM_Recovery_Time, Engine_Vibration, Engine_Sound, Implement_Lifting_Lowering_response, Pulverization_Quality, Pulverization_Index ) 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 mmt_staging2.stg_process_table_FTWET_sum where rank_tag=''FTWET_SUM_Test_Condition'' 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,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, a_31 text,a_32 text,a_33 text,a_34 text,a_35 text,a_36 text,a_37 text,a_38 text); update mmt_staging2.FTWET_SUM_Test_Condition_Block set test_iterationnumber=1 where test_iterationnumber is null; insert into mmt_staging2.FTWET_SUM_Test_Condition_Block ( dummy_f, Test_Condition, Test_Date, Tractor_Model, Engine_RPM_set, PTO_RPM_set, Gear_Used, Nominal_Speed_KMPH, Engine_RPM_Drop_on_straight_1st_Pass, Engine_RPM_Drop_on_straight_2nd_Pass, Engine_RPM_Drop_on_straight_3rd_Pass, Engine_RPM_Drop_on_turn_1st_Pass, Engine_RPM_Drop_on_turn_2nd_Pass, Engine_RPM_Drop_on_turn_3rd_Pass, No_of_passes, Avg_Depth_of_cut_cm, Fuel_consumption_lit_hr, Area_covered_acr_hr, Fuel_consumption_lit_Acr, M_M_Performance_in_compared_to_respective_competitor_tractors, Fuel_consumption_lit_hr_2, Area_covered_acr_hr_2, Fuel_consumption_lit_Acr_2, Trail_Observations, Engine_Smoke_on_Load, Engine_acceleration_smoke, Draft_Response, Tractor_Steer_ability, Tractor_braking_performance, Front_Visibility, Implement_Accessibility, Front_Wheel_dragging_at_turning, Front_end_lifting_during_operation, RPM_Recovery_Time, Engine_Vibration, Engine_Sound, Implement_Lifting_Lowering_response, Pulverization_Quality, Pulverization_Index ) SELECT * FROM crosstab( 'SELECT unnest(''{column8,column9,column10,column11,column12}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[column8::text, column9::text,column10::text,column11::text,column12::text]) AS val FROM mmt_staging2.stg_process_table_FTWET_sum where rank_tag=''FTWET_SUM_Test_Condition'' 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,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, a_31 text,a_32 text,a_33 text,a_34 text,a_35 text,a_36 text,a_37 text,a_38 text); update mmt_staging2.FTWET_SUM_Test_Condition_Block set test_iterationnumber=2 where test_iterationnumber is null; update mmt_staging2.FTWET_SUM_Test_Condition_Block a set Test_Condition= b.first_value from (SELECT test_iterationnumber,Test_Condition, value_partition, first_value(Test_Condition) over (partition by value_partition order by test_iterationnumber) FROM ( SELECT test_iterationnumber, Test_Condition, sum(case when Test_Condition is null then 0 else 1 end) over (order by test_iterationnumber) as value_partition FROM mmt_staging2.FTWET_SUM_Test_Condition_Block ORDER BY test_iterationnumber asc ) as q) b where a.test_iterationnumber = b.test_iterationnumber; delete from mmt_staging2.FTWET_SUM_Test_Condition_Block where tractor_model is null or engine_rpm_set = '0'; update mmt_staging2.FTWET_SUM_Test_Condition_Block set fuel_consumption_lit_hr_2=null where fuel_consumption_lit_hr_2 like '%indicates%'; update mmt_staging2.FTWET_SUM_Test_Condition_Block set fuel_consumption_lit_hr_2 = left(fuel_consumption_lit_hr_2,length(fuel_consumption_lit_hr_2)-3), Area_covered_acr_hr_2 = left(Area_covered_acr_hr_2,length(Area_covered_acr_hr_2)-3) , Fuel_consumption_lit_Acr_2 = left(Fuel_consumption_lit_Acr_2,length(Fuel_consumption_lit_Acr_2)-3) where fuel_consumption_lit_hr_2 notnull; delete from mmt_staging2.FTWET_SUM_Test_Condition_Block where dummy_f is null ; execute 'update mmt_staging2.FTWET_SUM_Test_Condition_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,'FTWET_SUM_Test_Condition_Block'); /*inserting data into block -FTWET_SUM_Comments_By_Block*/ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'FTWET_SUM_Comments_By_Block',__file_format,__sheet_mnemonic,5); v_block:='FTWET_SUM_Comments_By_Block'; insert into mmt_staging2.FTWET_SUM_Comments_By_Block (dummy_f) values ('dummy'); execute 'update mmt_staging2.FTWET_SUM_Comments_By_Block set test_manager_comments= (select column3 from mmt_staging2.stg_process_table_FTWET_sum a where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''' and a.rank_tag=''FTWET_SUM_Manager_Comments'' and a.rank=1 ) where dummy_f=''dummy'''; delete from mmt_staging2.FTWET_SUM_Comments_By_Block where dummy_f is null ; execute 'update mmt_staging2.FTWET_SUM_Comments_By_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,'FTWET_SUM_Comments_By_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_FTWET_SUM_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_FTWET_SUM_Block', v_state, v_msg, v_detail, v_hint, v_context,'error'); return v_context; end $$ LANGUAGE plpgsql;