drop function if exists mmt_staging2.fn_IHT_NST_ODS; CREATE OR REPLACE FUNCTION mmt_staging2.fn_IHT_NST_ODS() RETURNS void AS $$ declare __test_instance_id int; declare __file_syspk int; declare __model text; declare __make text; begin /************************************************************ Function Name:fn_IHT_NST_ODS Function Desc: This function populates data into ODS File Format: IHT Sheet Format: IHT_NST Creation Date: Updation Date: Author: compegence team Function Call: select mmt_staging2.fn_IHT_NST_ODS() ***************************************************************/ delete from mmt_ods.test_instance where test_file_sheet_format='IHT_NST'; delete from mmt_ods.test_instance_engine_info where test_file_sheet_format='IHT_NST'; delete from mmt_ods.test_instance_tyre_info where test_file_sheet_format='IHT_NST'; delete from mmt_ods.test_instance_atmospheric_info where test_file_sheet_format='IHT_NST'; delete from mmt_ods.iht_noise_measurement_results where test_file_sheet_format='IHT_NST'; delete from mmt_ods.iht_noise_measurement_test where test_file_sheet_format='IHT_NST'; delete from mmt_ods.test_instance_tractor_info where test_file_sheet_format='IHT_NST'; insert into mmt_ods.test_instance ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, job_order_no, sample_receipt_date, test_report_no, generation, customer_name, test_engineer, test_report_date, no_of_sample, test_start_date, test_end_date, tractor_sr_no, test_standard_ref, test_location_name, test_operator, project_group, objective_of_test, test_condition ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, Test_Request_no, date '1899-12-30' + sample_receipt_date::int * interval '1' day as Sample_Receipt_Date, Test_report_No, Generation, Customer_Name, Test_Engineer, date '1899-12-30' + Test_Report_Date::int * interval '1' day as Test_Report_Date, No_of_Sample, date '1899-12-30' + Test_Start_Date::int * interval '1' day as Test_Start_Date, date '1899-12-30' + Test_End_Date::int * interval '1' day as Test_End_Date, Tractor_Sr_No, Test_Standard_Refer, Test_facility, Operator_Name, Project_Group, Objective, Condition from mmt_staging2.IHT_NST_H1_block; update mmt_ods.test_instance a set report_prepared_by=b.prepared_by, report_reviewed_by=b.reviewed_by, report_approved_by=b.approved_by, report_template_replaces=b.replaces, report_title=b.comments, report_template_no=b.rev1, report_template_rev_date=b.rev2, report_template_rev_no= b.rev3 from mmt_staging2.iht_nst_footer_block b where a.test_file_sheet_format='IHT_NST'; insert into mmt_ods.test_instance_tyre_info ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, tyre_type, tyre_make, tyre_size, tyre_ply_rating, tyre_load_carrying_capacity, tyre_wheel_rim_make_and_size ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, tyre_details, tyre_make, tyre_size, ply_rating::numeric , load_carrying_capacity, wheel_rim_make_size from mmt_staging2.iht_nst_tyre_details_block; insert into mmt_ods.test_instance_engine_info ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, low_idle_declared, low_idle_observed, high_idle_declared, high_idle_observed, rated_rpm, rated_rpm_observed, engine_to_pto_ratio_540_pto ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, low_idle_declared, low_idle_observed::numeric, high_idle_declared, high_idle_observed::numeric, rated_rpm_declared::numeric, rated_rpm_observed::numeric, engine_to_pto_ratio from mmt_staging2.iht_nst_engine_rpm_block; insert into mmt_ods.test_instance_tractor_info ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, weight_reactions_front_kg, tractor_weight_front_observed_kg, tractor_weight_front_remark, weight_reactions_rear_kg, tractor_weight_rear_observed_kg, tractor_weight_rear_remark, tractor_weight_total_kg, tractor_weight_total_observed_kg, tractor_weight_total_remark ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, front_weight_declared::numeric , front_weight_observed::numeric, front_weight_remark, rear_weight_declared::numeric, rear_weight_observed::numeric, rear_weight_remark, total_weight_declared::numeric, total_weight_observed::numeric, total_weight_remark from mmt_staging2.iht_nst_weight_block; /*block */ insert into mmt_ods.test_instance_atmospheric_info ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, ambient_temp_c, humidity_pct, pressure_kpa, background_noise_dba, wind_velocity_kmph ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, ambient_temp_c::numeric, humidity::numeric, pressure_kpa::numeric, background_noise::numeric, wind_velocity from mmt_staging2.iht_nst_atmos_cond_block; insert into mmt_ods.iht_noise_measurement_results ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_type, test_mode, gear, noise_level_1_db_a, noise_level_2_db_a, noise_level_3_db_a ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, column1, column2, column3, column4::numeric, column5::numeric, column6::numeric from mmt_staging2.iht_nst_stand_noise_block where ods_record=1; update mmt_ods.iht_noise_measurement_results set test_condition = (select column4 from mmt_staging2.iht_nst_stand_noise_block where rank=3); insert into mmt_ods.iht_noise_measurement_test ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_condition, test_type, test_mode ) select client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_condition, test_type, test_mode from mmt_ods.iht_noise_measurement_results where test_type='BY STANDARD NOISE'; update mmt_ods.iht_noise_measurement_test set acceptance_criteria=b.acceptance_criteria, remarks =b.remarks from mmt_staging2.iht_nst_stand_noise_block b where b.column1 ='BY STANDARD NOISE' and test_type='BY STANDARD NOISE'; insert into mmt_ods.iht_noise_measurement_results ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_type, test_mode, gear, noise_level_1_db_a, noise_level_2_db_a, noise_level_3_db_a ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, column1, column2, column3, column7::numeric, column8::numeric, column9::numeric from mmt_staging2.iht_nst_stand_noise_block where ods_record=1; update mmt_ods.iht_noise_measurement_results set test_condition = (select column7 from mmt_staging2.iht_nst_stand_noise_block where rank=3) where test_condition is null; insert into mmt_ods.iht_noise_measurement_test ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_condition, test_type, test_mode ) select client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_condition, test_type, test_mode from mmt_ods.iht_noise_measurement_results where test_type='BY STANDARD NOISE'; update mmt_ods.iht_noise_measurement_test set acceptance_criteria=b.acceptance_criteria, remarks =b.remarks from mmt_staging2.iht_nst_stand_noise_block b where b.column1 ='BY STANDARD NOISE' and test_type='BY STANDARD NOISE'; insert into mmt_ods.iht_noise_measurement_results ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_type, test_mode, gear, load_kg, speed_kmph, speed_rpm, noise_level_1_db_a, noise_level_2_db_a, noise_level_3_db_a ) select client_id, function_id, file_syspk, file_format, sheet_mnemonic, make,model, column1, column2, column3, column4::numeric, column5::numeric, column6::numeric, column7::numeric, column8::numeric, column9::numeric from mmt_staging2.iht_nst_oel_noise_block where ods_record=1; insert into mmt_ods.iht_noise_measurement_test ( client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_condition, test_type, test_mode ) select client_id, function_id, test_file_ref_no, test_file_format, test_file_sheet_format, tractor_make, tractor_model, test_condition, test_type, test_mode from mmt_ods.iht_noise_measurement_results where test_type ='OEL Noise'; update mmt_ods.iht_noise_measurement_test set acceptance_criteria=b.acceptance_criteria, remarks =b.remarks from mmt_staging2.iht_nst_oel_noise_block b where b.column1 ='OEL Noise' and test_type='OEL Noise'; delete from mmt_ods.iht_noise_measurement_test a using mmt_ods.iht_noise_measurement_test b where (a.syspk < b.syspk and a.test_condition is not null and a.test_condition =b.test_condition and a.test_mode =b.test_mode and a.test_type=b.test_type) or (a.syspk < b.syspk and a.test_condition is null and a.test_mode =b.test_mode and a.test_type=b.test_type); update mmt_ods.iht_noise_measurement_results a set noise_measurement_id =(select syspk from mmt_ods.iht_noise_measurement_test b where (a.test_condition =b.test_condition and a.test_condition is not null and a.test_mode =b.test_mode and a.test_type=b.test_type) or (a.test_condition is null and a.test_mode =b.test_mode and a.test_type=b.test_type)); select file_syspk into __file_syspk from mmt_staging2.IHT_NST_H1_block; select syspk into __test_instance_id from mmt_ods.test_instance where test_file_ref_no =__file_syspk; select tractor_model into __model from mmt_ods.test_instance where test_file_ref_no =__file_syspk; select tractor_make into __make from mmt_ods.test_instance where test_file_ref_no =__file_syspk; update mmt_ods.test_instance_engine_info set test_instance_id=__test_instance_id, tractor_model =__model, tractor_make=__make where test_file_ref_no=__file_syspk; update mmt_ods.test_instance_tyre_info set test_instance_id=__test_instance_id, tractor_model =__model, tractor_make=__make where test_file_ref_no=__file_syspk; update mmt_ods.test_instance_tractor_info set test_instance_id=__test_instance_id, tractor_model =__model, tractor_make=__make where test_file_ref_no=__file_syspk; update mmt_ods.test_instance_atmospheric_info set test_instance_id=__test_instance_id, tractor_model =__model, tractor_make=__make where test_file_ref_no=__file_syspk; update mmt_ods.iht_noise_measurement_results set test_instance_id=__test_instance_id, tractor_model =__model, tractor_make=__make where test_file_ref_no=__file_syspk; update mmt_ods.iht_noise_measurement_test set test_instance_id=__test_instance_id, tractor_model =__model, tractor_make=__make where test_file_ref_no=__file_syspk; end $$ LANGUAGE plpgsql;