Files
mmt_sql/onetime/dataloadfunctions/Drawbar/DBSTD_TEST_ods.sql
2021-07-02 08:40:37 +00:00

863 lines
20 KiB
PL/PgSQL
Executable File

drop function if exists staging2.fn_dbstd_test_trx;
CREATE OR REPLACE FUNCTION staging2.fn_dbstd_test_trx(p_client_id int,p_function_id int, p_file_mnemonic text,
p_file_sheet_mnemonic text, p_file_syspk int)
RETURNS text AS $$
declare __test_instance_id int;
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 __test_instance_tractor_id int;
declare __make text;
declare __model text;
declare err_state text;
declare err_msg text;
declare err_detail text;
declare err_hint text;
declare err_context text;
declare _error int;
declare __test_master_id int;
begin
/************************************************************
Function Name:fn_dbstd_test_trx
Function Desc: This function populates data into ODS
File Format: DBSTD
Sheet Format: DBSTD_TEST
Creation Date: March 25 2021
Updation Date:
Author: compegence team
Function Call: select staging.fn_dbstd_test_trx()
***************************************************************/
SET search_path TO staging2;
select syspk from transactional.test_master into __test_master_id where test_type ='Drawbar';
/* ODS */
insert into transactional.test_instance
(
client_id,
function_id,
file_syspk,
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,
acceptance_criteria,
objective_of_test,
date_of_test,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
test_request_no,
date '1899-12-30' + sample_receipt_date::numeric * interval '1' day as sample_receipt_date ,
test_report_no,
generation,
customer_name,
test_engineer,
date '1899-12-30' + test_report_date::numeric * interval '1' day as test_report_date ,
no_of_sample,
date '1899-12-30' + test_start_date::numeric* interval '1' day as test_start_date ,
date '1899-12-30' + test_end_date::numeric* interval '1' day as test_end_date ,
tractor_sr_no,
test_standard_refer,
test_location,
operator_name,
project_group,
objective,
acceptance_criteria,
current_date,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_h1_block;
update transactional.test_instance a
set test_condition=b.c2
from staging2.dbstd_test_test_condition_block b
where a.file_syspk=b.file_syspk;
update transactional.test_instance
set test_file_name =(select a.file_name from staging1.staging_generic_table a where file_syspk = __file_syspk limit 1)
where file_syspk = __file_syspk;
/* ODS */
insert into transactional.test_instance_engine_info
(client_id,function_id,file_syspk,tractor_model,tractor_make,low_idle_declared,low_idle_observed,high_idle_declared,high_idle_observed,file_mnemonic,
file_sheet_mnemonic)
select client_id,function_id,file_syspk,make,model,low_idle_declared,low_idle_observed::numeric,high_idle_declared,high_idle_observed::numeric,file_mnemonic,file_sheet_mnemonic
from staging2.DBSTD_test_engine_RPM_RPM_block;
update transactional.test_instance_engine_info a
set engine_to_pto_ratio_540_pto=b.engine_to_pto_ratio::numeric,engine_power_hp = b.engine_power_hp::numeric,
pto_power_hp = b.pto_power_hp::numeric
from
staging2.dbstd_test_engine_rpm_engine_to_pto_block b
where a.file_syspk=b.file_syspk;
update transactional.test_instance_engine_info a
set engine_cylinder_stroke_mm=b.stroke::numeric,engine_cylinder_bore_mm=b.bore::numeric,engine_cylinder_no=b.number::numeric,
engine_cylinder_capacity_ltr=regexp_replace(b.capacity,'[^0-9]', '', 'g')::int
from staging2.dbstd_test_tractor_specifications_cylinders_block b
where a.file_syspk=b.file_syspk;
update transactional.test_instance_engine_info a
set engine_serial_no=serial_no,engine_type=type,rated_rpm=rated_speed::numeric,engine_make=b.make_in_block ,engine_model = b.model_in_block
from staging2.dbstd_test_tractor_specifications_engine_details_block b
where a.file_syspk=b.file_syspk;
/*ODS */
insert into transactional.test_instance_tractor_info
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
wheel_base_mm,
tractor_engine_hp,
pto_power_hp,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
wheel_base_mm::numeric,
engine_power_hp::numeric,
pto_power_hp::numeric,
file_mnemonic,
file_sheet_mnemonic
from dbstd_test_engine_rpm_engine_to_pto_block;
update transactional.test_instance_tractor_info a
set
steering_type=b.steering_type,
transmission_type=clutch_type,
transmission_disc_diam=diameter_of_disc_mm
from staging2.dbstd_test_transmission_clutch_block b
where a.file_syspk=b.file_syspk;
/*ODS */
insert into transactional.test_instance_drawbar_info
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
drawbar_type,
required_pull_in_kg,
actual_pull_in_kg,
required_power_in_hp,
actual_power_in_hp,
calculated_hitch_height_mm,
actual_hitch_height_mm,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
pull_type,
required_pull_in_kg::numeric ,
actual_pull_in_kg::numeric ,
required_power_in_hp::numeric,
actual_power_in_hp::numeric ,
calculated_hitch_height_mm::numeric,
actual_hitch_height_mm::numeric ,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_engine_rpm_required_pull_block;
update transactional.test_instance_drawbar_info a
set weight_front_kg = front::numeric ,
weight_rear_kg = rear::numeric ,
weight_total_kg = total::numeric
from staging2.dbstd_test_engine_rpm_weight_block b
where b.weight_kg='Unballast'
and a.drawbar_type='UB'
and a.file_syspk=b.file_syspk;
update transactional.test_instance_drawbar_info a
set weight_front_kg = front::numeric ,
weight_rear_kg = rear::numeric ,
weight_total_kg = total::numeric
from staging2.dbstd_test_engine_rpm_weight_block b
where b.weight_kg='Ballast'
and a.drawbar_type='B'
and a.file_syspk=b.file_syspk;
update transactional.test_instance_drawbar_info a
set test_condition=b.test_condition,
drawbar_type_info=b.type,
height_above_ground_max_mm=b.height_above_ground_max_mm::numeric,
height_above_ground_min_mm=b.height_above_ground_min_mm::numeric,
position_related_to_pto=b.position_related_to_pto,
wheel_base=b.wheel_base
from staging2.dbstd_test_transmission_drawbar_block b
where a.drawbar_type=b.test_condition
and a.file_syspk=b.file_syspk;
update transactional.test_instance_drawbar_info set drawbar_type_name='UnBallasted' where drawbar_type='UB';
update transactional.test_instance_drawbar_info set drawbar_type_name='Ballasted' where drawbar_type='B';
/* ODS */
insert into transactional.test_instance_tyre_info
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
tyre_type,
tyre_make,
tyre_size,
tyre_ply_rating,
tyre_load_carrying_capacity,
tyre_pressure_kg_per_cm2,
tyre_number_of_lug,
tyre_number_of_no_load_lug_30m,
tyre_lug_height,
tyre_dynamic_rolling_radius_mm,
tyre_wheel_rim_make_and_size,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
dummy_f,
tyre_make,
size,
ply_rating::numeric,
load_carrying_capacity_in_kg,
pressure_kg_cm2::numeric,
number_of_lug::numeric,
number_of_no_load_lug_30m::numeric,
lug_height::numeric,
dynamic_rolling_radius_mm::numeric,
wheel_rim_make_size ,
file_mnemonic,
file_sheet_mnemonic
from staging2.DBSTD_test_engine_RPM_tyre_details_block ;
/* ODS */
insert into transactional.drawbar_perf_results_summary
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
gear_number_and_range,
travel_speed_km_per_hr,
drawbar_power_kw,
drawbar_power_hp,
drawbar_pull_kgf,
drawbar_pull_kn,
engine_speed_min_1,
fan_speed_min_1,
wheel_slip_pct_front,
no_of_load_lugs_front,
wheel_slip_pct_rear,
fuel_consumption_l_per_h,
fuel_consumption_kg_per_kwh,
fuel_consumption_g_per_kwh,
fuel_consumption_kwh_per_l,
temp_engine_oil_c,
temp_trans_oil_c,
temp_coolant_c,
temp_fuel_in_c,
temp_fuel_out_c,
atm_conditions_rh_pct,
atm_conditions_temp_c,
atm_conditions_pressure_kpa,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
c1,
c2::numeric,
c3::numeric,
c4::numeric,
c5::numeric,
c6::numeric,
c7::numeric,
c8::numeric,
c9::numeric,
c10::numeric,
c11::numeric,
c12::numeric,
c13::numeric,
c14::numeric,
c15::numeric,
c16::numeric,
c17::numeric,
c18::numeric,
c19::numeric,
c20::numeric,
c21::numeric,
c22::numeric,
c23::numeric,
file_mnemonic,
file_sheet_mnemonic
from staging2.dbstd_test_drawbar_performance_selected_summary_block;
/* ODS */
insert into transactional.drawbar_perf_results
(client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
gear_number_and_range,
travel_speed_km_per_hr,
drawbar_power_kw,
drawbar_power_hp,
drawbar_pull_kgf,
drawbar_pull_kn,
engine_speed_min_1,
fan_speed_min_1,
wheel_slip_pct_front,
no_of_load_lugs_front,
wheel_slip_pct_rear,
fuel_consumption_l_per_h,
fuel_consumption_kg_per_kwh,
fuel_consumption_g_per_kwh,
fuel_consumption_kwh_per_l,
temp_engine_oil_c,
temp_trans_oil_c,
temp_coolant_c,
temp_fuel_in_c,
temp_fuel_out_c,
atm_conditions_rh_pct,
atm_conditions_temp_c,
atm_conditions_pressure_kpa,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
c1,
c2::numeric,
c3::numeric,
c4::numeric,
c5::numeric,
c6::numeric,
c7::numeric,
c8::numeric,
c9::numeric,
c10::numeric,
c11::numeric,
c12::numeric,
c13::numeric,
c14::numeric,
c15::numeric,
c16::numeric,
c17::numeric,
c18::numeric,
c19::numeric,
c20::numeric,
c21::numeric,
c22::numeric,
c23::numeric,
file_mnemonic,
file_sheet_mnemonic
from staging2.dbstd_test_drawbar_performance_gear_performance_block;
/* ODS */
insert into transactional.test_instance_equipment_info
(client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
srl_no,instrument_name,instrument_serial_no,calibration_due_date,file_mnemonic,
file_sheet_mnemonic)
select
client_id,
function_id,
file_syspk,
make,
model,
s_no::numeric,
instruments,
instruments_no,
date '1899-12-30' + cali_due_date::numeric * interval '1' day as cali_due_date ,
file_mnemonic,
file_sheet_mnemonic
from staging2.DBSTD_test_test_equipment_used_block;
/* ODS */
insert into transactional.test_instance_measurement_uncertainty
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
load_cell,
rpm_meter,
speed,
fuel_flow_meter,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
load_cell,
rpm_meter,
speed,
fuel_flow_meter ,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_measurement_uncertainty_block;
/* ODS */
insert into transactional.test_instance_tractor_info_misc
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
capacity_of_fuel_tank_ltr,
make_type_and_model_of_injection_pump,
manufacturers_production_setting,
make_type_and_model_of_injectors,
make_type_and_model_of_magneto_coil_and_distributor,
make_type_and_model_of_carburetor,
ignition_or_injection_timing,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
regexp_replace(capacity_of_fuel_tank_lit,'[^0-9]', '', 'g')::numeric,
make_type_and_model_of_injection_pump,
manufacturer_production_setting,
make_type_and_model_of_injectors,
make_type_and_model_of_magneto_coil_and_distributor,
make_type_and_model_of_carburetor,
ignition_or_injection_timing_manual_or_automatic,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_tractor_specifications_fuel_and_injection_block;
update transactional.test_instance_tractor_info_misc a
set aircleaner_make_model=b.make_and_model
from staging2.dbstd_test_tractor_specifications_cleaner_block b
where b.cleaner_type='Air cleaner'
and a.file_syspk=b.file_syspk;
update transactional.test_instance_tractor_info_misc a
set aircleaner_type=b.type
from staging2.dbstd_test_tractor_specifications_cleaner_block b
where cleaner_type='Air cleaner'
and a.file_syspk=b.file_syspk;
update transactional.test_instance_tractor_info_misc a
set precleaner_make_model=b.make_and_model
from staging2.dbstd_test_tractor_specifications_cleaner_block b
where cleaner_type='Precleaner (if fitted)'
and a.file_syspk=b.file_syspk;
update transactional.test_instance_tractor_info_misc a
set precleaner_type=b.type
from staging2.dbstd_test_tractor_specifications_cleaner_block b
where cleaner_type='Precleaner (if fitted)'
and a.file_syspk=b.file_syspk;
update staging2.dbstd_test_transmission_speed_chart_block a
set tyre_condition=b.descr
from staging2.dbstd_test_transmission_speed_chart_desc_block b
where a.file_syspk=b.file_syspk;
/* ODS */
insert into transactional.test_instance_gear_speed_chart
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
forward_reverse,
gear,
speed_kmph,
tyre_condition,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
'forward',
gear,
cast(coalesce(nullif(forward,''),'0') as numeric),
tyre_condition,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_transmission_speed_chart_block;
/* ODs */
insert into transactional.test_instance_gear_speed_chart
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
forward_reverse,
gear,
speed_kmph,
tyre_condition,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
'reverse',
gear,
cast(coalesce(nullif(reverse,''),'0') as numeric),
tyre_condition,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_transmission_speed_chart_block;
/* ODS */
insert into transactional.Test_instance_wheels_info
(client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
steered_driving_wheel,
location_of_driving_wheel,
make_of_tyres,
wheel_types,
wheel_size,
maximum_permissible_load_kg,
ply_rating,
track_width_max_mm,
track_width_min_mm,
inflation_pressure_kg_per_cm2,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
dummy_f,
location_of_driving_wheel,
make_of_tyres,
types,
size,
regexp_replace(maximum_permissible_load_kg,'[^0-9]', '', 'g')::int,
regexp_replace(ply_rating,'[^0-9]', '', 'g')::int,
track_width_max_mm::numeric,
track_width_min_mm::numeric,
inflation_pressure_kg_cm2::numeric,
file_mnemonic,
file_sheet_mnemonic
from staging2.dbstd_test_transmission_wheels_block;
update staging2.dbstd_test_transmission_wheels_block a
set location_of_driving_wheel=(select location_of_driving_wheel from
staging2.dbstd_test_transmission_wheels_block b where location_of_driving_wheel is not null)
where location_of_driving_wheel is null;
/* ODS */
insert into transactional.Test_instance_fuel_lubricant_info
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
trade_name,
fuel_lubricant_type,
octane_per_cetane_number,
viscocity,
density_at_15c,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
trade_name,
type,
octane_cetane_number::numeric,
viscosity,
density_at_15c,
file_mnemonic,
file_sheet_mnemonic
from
staging2.dbstd_test_transmission_fuel_lubricant_block ;
/* ODS */
insert into transactional.drawbar_perf_observations
(
client_id,
function_id,
file_syspk,
tractor_make,
tractor_model,
test_parameter ,
acceptance_criteria ,
observation ,
remarks ,
file_mnemonic,
file_sheet_mnemonic
)
select
client_id,
function_id,
file_syspk,
make,
model,
parameter,
acceptance_criteria ,
observations,
remarks ,
file_mnemonic,
file_sheet_mnemonic
from staging2.dbstd_test_remarks_block;
update transactional.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_template_rev_no=b.revision_no,
report_template_rev_Date=b.rev3,
report_template_no=b.rev1,
report_title=b.comments,
test_master_id = __test_master_id
from staging2.dbstd_test_remarks_footer_block b
where a.file_syspk=b.file_syspk;
select file_syspk into __file_syspk from staging2.dbstd_test_h1_block;
select syspk into __test_instance_id from transactional.test_instance where file_syspk =__file_syspk;
select syspk into __test_instance_tractor_id from transactional.test_instance_tractor_info where file_syspk =__file_syspk;
update transactional.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_template_rev_no=b.revision_no,
report_template_rev_Date=b.rev3,
report_template_no=b.rev1,
report_title=b.comments,
test_tractor_id = __test_instance_tractor_id,
test_master_id = __test_master_id
from staging2.dbstd_test_remarks_footer_block b
where a.file_syspk=b.file_syspk;
update transactional.test_instance_engine_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_tractor_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_drawbar_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_tyre_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.drawbar_perf_results_summary
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.drawbar_perf_results
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_equipment_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_measurement_uncertainty
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_tractor_info_misc
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.test_instance_gear_speed_chart
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.Test_instance_wheels_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.Test_instance_fuel_lubricant_info
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.drawbar_perf_observations
set test_instance_id=__test_instance_id
where file_syspk=__file_syspk;
update transactional.drawbar_perf_observations
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.drawbar_perf_results_summary
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.drawbar_perf_results
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_engine_info
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_drawbar_info
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_tyre_info
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_equipment_info
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_measurement_uncertainty
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_tractor_info_misc
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.test_instance_gear_speed_chart
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.Test_instance_wheels_info
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
update transactional.Test_instance_fuel_lubricant_info
set test_instance_tractor_id=__test_instance_tractor_id
where file_syspk=__file_syspk;
err_context := '';
perform fw_core.fn_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_mnemonic,__file_sheet_mnemonic ,null,'trx', 'fn_DBSTD_test_block', err_state, err_msg, err_detail, err_hint, err_context,'success');
return err_context;
EXCEPTION when OTHERS then
GET STACKED DIAGNOSTICS
err_state = returned_sqlstate,
err_msg = message_text,
err_detail = pg_exception_detail,
err_hint = pg_exception_hint,
err_context = pg_exception_context;
perform fw_core.fn_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_mnemonic,__file_sheet_mnemonic ,null,'trx', 'fn_DBSTD_test_block', err_state, err_msg, err_detail, err_hint, err_context,'error');
return err_context;
end
$$ LANGUAGE plpgsql;