drop function if exists mmt_staging2.fn_IHTNST_NST_block; CREATE OR REPLACE FUNCTION mmt_staging2.fn_IHTNST_NST_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_IHTNST_NST_block Function Desc: This function populates data into staging 2 block File Format: IHTNST Sheet Format: IHTNST_NST Creation Date: March 25 2021 Updation Date: Author: compegence team Function Call: select mmt_staging2.fn_IHTNST_NST_block(p_client_id,p_function_id, p_file_format, p_sheet_mnemonic, p_file_syspk) Function call ex: select mmt_staging2.fn_IHTNST_NST_block(1,2,'IHTNST','IHTNST_NST',456) ***************************************************************/ SET search_path TO mmt_staging2; /* to process multiple files - re-runnability*/ truncate table mmt_staging2.IHTNST_NST_h1_block; truncate table mmt_staging2.IHTNST_NST_H1_Int; truncate table mmt_staging2.IHTNST_NST_H1_block; truncate table mmt_staging2.IHTNST_NST_Tyre_Details_Block; truncate table mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int; truncate table mmt_staging2.IHTNST_NST_Engine_RPM_Block; truncate table mmt_staging2.IHTNST_NST_Weight_Block; truncate table mmt_staging2.IHTNST_NST_Atmos_Cond_Block; truncate table mmt_staging2.IHTNST_NST_STAND_Noise_Block; truncate table mmt_staging2.IHTNST_NST_OEL_Noise_Block; truncate table mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block; truncate table mmt_staging2.IHTNST_NST_Footer_Block; truncate table mmt_staging2.stg_specific_table_IHTNST_NST; truncate table mmt_staging2.stg_process_table_IHTNST_NST; 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 IHTNST */ execute 'insert into mmt_staging2.stg_specific_table_IHTNST_NST 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_IHTNST_NST set column8='Objective' where column8 like 'Objective%'; update mmt_staging2.stg_specific_table_IHTNST_NST set column8='Condition' where column8 like 'Condition%'; update mmt_staging2.stg_specific_table_IHTNST_NST set column3='Remarks' where column3 like 'Remarks%'; update mmt_staging2.stg_specific_table_IHTNST_NST set column7='Acceptance Criteria' where column7 like 'Acceptance Criteria%'; update mmt_staging2.stg_specific_table_IHTNST_NST set column3 = TRIM (TRAILING FROM column3 ); update mmt_staging2.stg_specific_table_IHTNST_NST 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_IHTNST_NST b where trim(upper(F1_modified))=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_IHTNST_NST a set is_rownumber_fetched=1 from mmt_ods.mmt_config b where trim(upper(F1_modified))=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||''''; 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||''''; /* update config files for row numbers start, end */ 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 and file_format='''||p_file_format||''' and sheet_mnemonic='''||p_sheet_mnemonic||''' ) 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 ,run_time=current_timestamp where f1_modified =''Prepared by'' and a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||''''; /* tagging ranks*/ execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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 Request No'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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=''Tyre Details'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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=''Engine RPM'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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=''BY STANDER’S NOISE'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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=''OEL Noise without Load'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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=''OEL Noise with Load'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; execute 'insert into mmt_staging2.stg_process_table_IHTNST_NST select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag from mmt_staging2.stg_specific_table_IHTNST_NST 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=''Prepared by'' and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||''''; /*selecting tractor model*/ select column4 into __model from mmt_staging2.stg_process_table_IHTNST_nst a where rank_tag='IHTNST_NST_H1' and trim(column3)='Tractor Model'; /*block starts - IHTNST_NST_H1_BLOCK */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_H1_BLOCK',__file_format,__sheet_mnemonic,1); v_block:='IHTNST_NST_H1_BLOCK'; insert into mmt_staging2.IHTNST_NST_H1_INT (c1,c2) select a.column3,column4 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_H1'; insert into mmt_staging2.IHTNST_NST_H1_INT (c1,c2) select a.column6,column7 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_H1'; insert into mmt_staging2.IHTNST_NST_H1_INT (c1,c2) select 'Objective',column8 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_H1' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column8='Objective' and rank_tag='IHTNST_NST_H1' ); insert into mmt_staging2.IHTNST_NST_H1_INT (c1,c2) select 'Condition',column8 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_Tyre_Details' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column8='Condition' and rank_tag='IHTNST_NST_Tyre_Details' ); insert into mmt_staging2.IHTNST_NST_H1_INT (c1,c2) select 'Test Purpose',column6 from mmt_staging2.stg_process_table_IHTNST_NST a where column3='Test Purpose' and rank_tag ='IHTNST_NST_Engine_RPM_Atmos'; update mmt_staging2.IHTNST_NST_H1_Int set model=__model; execute 'update mmt_staging2.IHTNST_NST_H1_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||''''; insert into mmt_staging2.IHTNST_NST_H1_Block ( dummy_f, Test_Request_no, Sample_Receipt_Date, Test_report_No, Tractor_Model, Generation, Customer_Name, Test_Engineer, Test_Report_Date, No_of_Sample, Test_Start_Date, Test_End_Date, Tractor_Sr_No, Test_Facility, Operator_Name, Project_Group, Test_standard_refer, Objective, condition, Test_Purpose ) SELECT * FROM crosstab( 'SELECT unnest(''{c2}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[c2::text]) AS val FROM mmt_staging2.IHTNST_NST_H1_INT 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, 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); delete from mmt_staging2.IHTNST_NST_H1_Block where dummy_f is null ; update mmt_staging2.IHTNST_NST_H1_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_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,'IHTNST_NST_H1_Block'); /*block starts - IHTNST_NST_Tyre_Details_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_Tyre_Details_Block',__file_format,__sheet_mnemonic,2); v_block:='IHTNST_NST_Tyre_Details_Block'; insert into mmt_staging2.IHTNST_NST_Tyre_Details_Block ( dummy_f, Tyre_Details, Tyre_Make, Tyre_size, Ply_Rating, Load_Carrying_Capacity, Wheel_rim_Make_size ) SELECT * FROM crosstab( 'SELECT unnest(''{column4,column6}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[column4::text,column6::text]) AS val FROM mmt_staging2.stg_process_table_IHTNST_NST where rank_tag=''IHTNST_NST_Tyre_Details'' 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); update mmt_staging2.IHTNST_NST_Tyre_Details_Block set ply_rating =replace(ply_rating,' Ply',''); delete from mmt_staging2.IHTNST_NST_Tyre_Details_Block where dummy_f is null ; update mmt_staging2.IHTNST_NST_Tyre_Details_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_Tyre_Details_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,'IHTNST_NST_Tyre_Details_Block'); /* inserting Engine_RPM_Atmos_INT */ insert into mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int ( column3,column4,column5,column6,column7, column8,column9,rank ) select column3,column4,column5,column6,column7, column8,column9,rank from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_Engine_RPM_Atmos' order by rank; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column8=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=9) where rank=5; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column6 = null where rank=9; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column9=(select column7 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=9) where rank=5; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column7=null where rank=9; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column8=(select column8 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=9)where rank=6; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column8 =null where rank=9; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column9=(select column9 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=9)where rank=6; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set column9 =null where rank=9; update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int set model=__model; execute 'update mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_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||''''; /*block starts - IHTNST_NST_Engine_RPM_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_Engine_RPM_Block',__file_format,__sheet_mnemonic,3); v_block:='IHTNST_NST_Engine_RPM_Block'; insert into mmt_staging2.IHTNST_NST_Engine_RPM_Block(dummy_f) values ('dummy'); update mmt_staging2.IHTNST_NST_Engine_RPM_Block set low_idle_declared=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=2 and column3='Low Idle RPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set low_idle_observed=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=2 and column3='Low Idle RPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set high_idle_declared=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=3 and column3='High IdleRPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set high_idle_observed=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=3 and column3='High IdleRPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set rated_rpm_declared=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=4 and column3='Rated RPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set rated_rpm_observed=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=4 and column3='Rated RPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set Engine_to_PTO_Ratio=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=9 and column3='Engine to PTO Ratio') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set low_idle_remark= (select column7 FROM mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=2 and column3='Low Idle RPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set high_idle_remark= (select column7 FROM mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=3 and column3='High IdleRPM') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Engine_RPM_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_Engine_RPM_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,'IHTNST_NST_Engine_RPM_Block'); /*block starts -IHTNST_NST_Weight_Block*/ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_Weight_Block',__file_format,__sheet_mnemonic,4); v_block:='IHTNST_NST_Weight_Block'; insert into mmt_staging2.IHTNST_NST_Weight_Block(dummy_f) values ('dummy'); update mmt_staging2.IHTNST_NST_Weight_Block set Front_weight_declared=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=6 and column3='Front') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set Front_weight_observed=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=6 and column3='Front') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set Rear_weight_declared=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=7 and column3='Rear') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set Rear_weight_observed=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=7 and column3='Rear') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set Total_weight_declared=(select column4 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=8 and column3='Total') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set Total_weight_observed=(select column6 from mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=8 and column3='Total') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set front_weight_remark= (select column7 FROM mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=6 and column3='Front') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set rear_weight_remark= (select column7 FROM mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=7 and column3='Rear') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set total_weight_remark= (select column7 FROM mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank=8 and column3='Total') where dummy_f='dummy'; update mmt_staging2.IHTNST_NST_Weight_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_Weight_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,'IHTNST_NST_Weight_Block'); /*block starts - IHTNST_NST_Atmos_Cond_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_Atmos_Cond_Block',__file_format,__sheet_mnemonic,5); v_block:='IHTNST_NST_Atmos_Cond_Block'; insert into mmt_staging2.IHTNST_NST_Atmos_Cond_Block ( dummy_f, Ambient_temp_C, humidity, Pressure_kPa, Background_Noise, wind_velocity ) SELECT * FROM crosstab( 'SELECT unnest(''{column9}''::text[]) AS col , row_number() OVER () , unnest(ARRAY[column9::text]) AS val FROM mmt_staging2.IHTNST_NST_Engine_RPM_Atmos_Int where rank between 2 and 6 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); delete from mmt_staging2.IHTNST_NST_Atmos_Cond_Block where dummy_f is null ; update mmt_staging2.IHTNST_NST_Atmos_Cond_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_Atmos_Cond_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,'IHTNST_NST_Atmos_Cond_Block'); /*block starts - IHTNST_NST_STAND_Noise_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_STAND_Noise_Block',__file_format,__sheet_mnemonic,6); v_block:='IHTNST_NST_STAND_Noise_Block'; insert into mmt_staging2.IHTNST_NST_STAND_Noise_Block ( column3,column4,column5,column6,column7, column8,column9,rank ) select column3,column4,column5,column6,column7, column8,column9,rank from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_STAND_Noise' order by rank; update mmt_staging2.IHTNST_NST_STAND_Noise_Block set column2=column3 where column4 is null and rank in (2,6); update mmt_staging2.IHTNST_NST_STAND_Noise_Block set column1=column3 where column4 is null and rank =1; update mmt_staging2.IHTNST_NST_STAND_Noise_Block a set column1= b.first_value from (SELECT rank, column1, value_partition, first_value(column1) over (partition by value_partition order by rank) FROM ( SELECT rank, column1, sum(case when column1 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.IHTNST_NST_STAND_Noise_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.IHTNST_NST_STAND_Noise_Block a set column2= b.first_value from (SELECT rank, column2, value_partition, first_value(column2) over (partition by value_partition order by rank) FROM ( SELECT rank, column2, sum(case when column2 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.IHTNST_NST_STAND_Noise_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.IHTNST_NST_STAND_Noise_Block set ods_record=0 where rank <>5; update mmt_staging2.IHTNST_NST_STAND_Noise_Block set remarks=(select column3 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_STAND_Noise' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column3='Remarks' and rank_tag='IHTNST_NST_STAND_Noise' )); update mmt_staging2.IHTNST_NST_STAND_Noise_Block set acceptance_criteria=(select column7 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_STAND_Noise' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column7='Acceptance Criteria' and rank_tag='IHTNST_NST_STAND_Noise' )); update mmt_staging2.IHTNST_NST_STAND_Noise_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_STAND_Noise_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,'IHTNST_NST_STAND_Noise_Block'); /*block starts - IHTNST_NST_OEL_Noise_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_OEL_Noise_Block',__file_format,__sheet_mnemonic,7); v_block:='IHTNST_NST_OEL_Noise_Block'; insert into mmt_staging2.IHTNST_NST_OEL_Noise_Block ( column3,column4,column5,column6,column7, column8,column9,rank ) select column3,column4,column5,column6,column7, column8,column9,rank from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_OEL_Noise' order by rank; update mmt_staging2.IHTNST_NST_OEL_Noise_Block set column2=column3 where column4 is null and rank in (2,8,14); update mmt_staging2.IHTNST_NST_OEL_Noise_Block set column1=column3 where column4 is null and rank =1; update mmt_staging2.IHTNST_NST_OEL_Noise_Block a set column1= b.first_value from (SELECT rank, column1, value_partition, first_value(column1) over (partition by value_partition order by rank) FROM ( SELECT rank, column1, sum(case when column1 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.IHTNST_NST_OEL_Noise_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.IHTNST_NST_OEL_Noise_Block a set column2= b.first_value from (SELECT rank, column2, value_partition, first_value(column2) over (partition by value_partition order by rank) FROM ( SELECT rank, column2, sum(case when column2 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.IHTNST_NST_OEL_Noise_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.IHTNST_NST_OEL_Noise_Block set ods_record=0 where rank in (1,2,3,4,8,9,10,14,15,16,17,18); update mmt_staging2.IHTNST_NST_OEL_Noise_Block set remarks=(select column3 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_OEL_Noise' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column3='Remarks' and rank_tag='IHTNST_NST_OEL_Noise' )); update mmt_staging2.IHTNST_NST_OEL_Noise_Block set acceptance_criteria=(select column7 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_OEL_Noise' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column7='Acceptance Criteria' and rank_tag='IHTNST_NST_OEL_Noise' )); update mmt_staging2.IHTNST_NST_OEL_Noise_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_OEL_Noise_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,'IHTNST_NST_OEL_Noise_Block'); /*block starts - IHTNST_NST_OEL_Noise_Block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_OEL_Noise_Load_Block',__file_format,__sheet_mnemonic,8); v_block:='IHTNST_NST_OEL_Noise_Load_Block'; insert into mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block ( column3,column4,column5,column6,column7, column8,column9,rank ) select column3,column4,column5,column6,column7, column8,column9,rank from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_OEL_Noise_Load' order by rank; update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block set column2=column3 where column4 is null and rank in (2,5,11); update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block set column1=column3 where column4 is null and rank =1; update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block a set column1= b.first_value from (SELECT rank, column1, value_partition, first_value(column1) over (partition by value_partition order by rank) FROM ( SELECT rank, column1, sum(case when column1 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block a set column2= b.first_value from (SELECT rank, column2, value_partition, first_value(column2) over (partition by value_partition order by rank) FROM ( SELECT rank, column2, sum(case when column2 is null then 0 else 1 end) over (order by rank) as value_partition FROM mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block ORDER BY rank ASC ) as q) b where a.rank = b.rank; update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block set ods_record=0 where rank not in (8,9,10,14,15,16); update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block set remarks=(select column3 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_OEL_Noise_Load' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column3='Remarks' and rank_tag='IHTNST_NST_OEL_Noise_Load' )); update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block set acceptance_criteria=(select column7 from mmt_staging2.stg_process_table_IHTNST_NST a where rank_tag='IHTNST_NST_OEL_Noise_Load' and row_number= ( select row_number+1 from mmt_staging2.stg_process_table_IHTNST_NST a where column7='Acceptance Criteria' and rank_tag='IHTNST_NST_OEL_Noise_Load' )); update mmt_staging2.IHTNST_NST_OEL_Noise_Load_Block set model=__model; execute 'update mmt_staging2.IHTNST_NST_OEL_Noise_Load_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,'IHTNST_NST_OEL_Noise_Load_Block'); /*block starts - IHTNST_NST_Footer_block */ perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk, 'IHTNST_NST_Footer_block',__file_format,__sheet_mnemonic,9); v_block:='IHTNST_NST_Footer_block'; insert into mmt_staging2.IHTNST_NST_Footer_block(dummy_f) values ('dummy'); update mmt_staging2.IHTNST_NST_Footer_block a set prepared_by=( select column4 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and trim(column3)='Prepared by' ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set reviewed_by=( select column4 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and trim(column3)='Reviewed by' ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set approved_by=( select column4 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and trim(column3)='Approved by' ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set comments=( select column3 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=5 ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set rev1=( select column3 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=6 ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set rev2=( select column5 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=6 ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set rev3=( select column8 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=6 ) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set replaces=( select column9 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=1) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set revision_no=( select column9 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=2) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set prepared_date=( select column8 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=1) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set reviewed_date=( select column8 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=2) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block a set approved_date=( select column8 from mmt_staging2.stg_process_table_IHTNST_NST b where b.rank_tag='IHTNST_NST_Footer' and rank=3) where dummy_F='dummy'; update mmt_staging2.IHTNST_NST_Footer_block set model=__model; execute 'update mmt_staging2.IHTNST_NST_Footer_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,'IHTNST_NST_Footer_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_IHTNST_NST_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_IHTNST_NST_Block', v_state, v_msg, v_detail, v_hint, v_context,'error'); return v_context; end $$ LANGUAGE plpgsql; select mmt_staging2.fn_IHTNST_NST_block(20,1,'IHTNST','IHTNST_NST',885);