772 lines
29 KiB
Plaintext
772 lines
29 KiB
Plaintext
drop function if exists mmt_staging2.fn_FTHLG_SUM_Block ;
|
|
CREATE OR REPLACE FUNCTION mmt_staging2.fn_FTHLG_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;
|
|
declare v_query int;
|
|
|
|
begin
|
|
|
|
|
|
|
|
/***********************************************************************************
|
|
Function Name:fn_FTHLG_SUM_Block
|
|
Function Desc: This function populates data into staging2 blocks
|
|
File Format: FTHLG
|
|
Sheet Format: FTHLG_SUM
|
|
Creation Date:
|
|
Updation Date:
|
|
Author: compegence team
|
|
Function Call: select mmt_staging2.fn_fthlg_sum_block(20,1,'FTHLG','FTHLG_SUM',259);
|
|
************************************************************************************/
|
|
|
|
|
|
SET search_path TO mmt_staging2;
|
|
truncate mmt_staging2.FTHLG_SUM_Trac_H1_Block;
|
|
truncate mmt_staging2.FTHLG_SUM_Trail_Type_Block;
|
|
truncate mmt_staging2.FTHLG_SUM_Test_Condition_1_Block;
|
|
truncate mmt_staging2.FTHLG_SUM_Test_Condition_2_Block;
|
|
truncate mmt_staging2.FTHLG_SUM_Comments_By_Block;
|
|
truncate mmt_staging2.stg_specific_table_fthlg_sum;
|
|
truncate mmt_staging2.stg_process_table_fthlg_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 fthlg*/
|
|
|
|
execute 'insert into mmt_staging2.stg_specific_table_fthlg_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||'';
|
|
select count(*) into v_query from mmt_staging2.stg_specific_table_fthlg_sum;
|
|
|
|
|
|
/* trimming data */
|
|
update mmt_staging2.stg_specific_table_fthlg_sum set column2 = TRIM (TRAILING FROM column2 );
|
|
update mmt_staging2.stg_specific_table_fthlg_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 f1_source = replace(f1_source,''_1'','''')
|
|
where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||'''';
|
|
|
|
execute 'update mmt_ods.mmt_config a
|
|
set row_number_start=(select min(b.row_number)
|
|
from mmt_staging2.stg_specific_table_fthlg_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_fthlg_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||'''';
|
|
|
|
/* keyword match in config table*/
|
|
execute 'update mmt_ods.mmt_config a set f1_source = replace(f1_source,''_2'','''')
|
|
where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||'''';
|
|
|
|
execute 'update mmt_ods.mmt_config a
|
|
set row_number_start=(select min(b.row_number)
|
|
from mmt_staging2.stg_specific_table_fthlg_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_fthlg_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 b.file_format='''||p_file_format||''' and b.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 )
|
|
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_2'' 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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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=''Objective Of 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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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=''Trailer Type''
|
|
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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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_1:''
|
|
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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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 Engineer Comments_1''
|
|
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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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_1''
|
|
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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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_2:''
|
|
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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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 Engineer Comments_2''
|
|
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_fthlg_sum
|
|
select a.* , RANK () OVER ( ORDER BY row_number),b.rank_tag as rank_tag
|
|
from mmt_staging2.stg_specific_table_fthlg_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_2''
|
|
and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||'''
|
|
order by a.row_number';
|
|
|
|
|
|
|
|
/*inserting data into block -FTHLG_SUM_Trac_H1_Block*/
|
|
|
|
|
|
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
|
|
'FTHLG_SUM_Trac_H1_Block',__file_format,__sheet_mnemonic,1);
|
|
|
|
v_block:='FTHLG_SUM_Trac_H1_Block';
|
|
|
|
insert into mmt_staging2.FTHLG_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_fthlg_sum
|
|
where rank_tag='FTHLG_SUM_Trac_H1'
|
|
order by rank;
|
|
|
|
delete from mmt_staging2.FTHLG_SUM_Trac_H1_Block where tractor_model = '0';
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trac_H1_Block set ods_record=0 where rank in (1,2);
|
|
|
|
|
|
execute 'update mmt_staging2.FTHLG_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,'FTHLG_SUM_Trac_H1_Block');
|
|
|
|
|
|
/*inserting data into block -FTHLG_SUM_Trail_Type_Block*/
|
|
|
|
|
|
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
|
|
'FTHLG_SUM_Trail_Type_Block',__file_format,__sheet_mnemonic,2);
|
|
v_block:='FTHLG_SUM_Trail_Type_Block';
|
|
|
|
insert into mmt_staging2.FTHLG_SUM_Trail_Type_Block
|
|
(
|
|
Trailer_Type,
|
|
Tire_size_and_inflation_pressure_psi,
|
|
No_Of_Axle,
|
|
No_Of_Wheels,
|
|
Trailer_Gross_Weight_Kg,
|
|
Tractor_Rear_Wheel_Center_to_Hitch_Point_Center_Distance_mm,
|
|
Tractor_Hitch_Height_from_Ground_mm,
|
|
Trailer_hitch_Height_above_ground_level_mm,
|
|
Gradient_Slope_1_Degree,
|
|
Gradient_Slope_2_degree,
|
|
Tractor_Hitch_Type,
|
|
rank
|
|
)
|
|
select column2,column3,column4,column5,column6,column7,column8,column9,column10,column11,column12,rank
|
|
from mmt_staging2.stg_process_table_fthlg_sum
|
|
where rank_tag='FTHLG_SUM_Trail_Type'
|
|
order by rank;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trail_Type_Block set ods_record=0 where rank = 1;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trail_Type_Block a
|
|
set trailer_hitch_height_above_ground_level_mm= b.first_value from (SELECT
|
|
rank,trailer_hitch_height_above_ground_level_mm, value_partition, first_value(trailer_hitch_height_above_ground_level_mm) over (partition by value_partition order by rank)
|
|
FROM (
|
|
SELECT
|
|
rank,
|
|
trailer_hitch_height_above_ground_level_mm,
|
|
sum(case when trailer_hitch_height_above_ground_level_mm is null then 0 else 1 end) over (order by rank) as value_partition
|
|
FROM mmt_staging2.FTHLG_SUM_Trail_Type_Block where rank >= 2
|
|
ORDER BY rank asc
|
|
) as q) b where a.rank = b.rank;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trail_Type_Block a
|
|
set tractor_hitch_height_from_ground_mm= b.first_value from (SELECT
|
|
rank,tractor_hitch_height_from_ground_mm, value_partition, first_value(tractor_hitch_height_from_ground_mm) over (partition by value_partition order by rank)
|
|
FROM (
|
|
SELECT
|
|
rank,
|
|
tractor_hitch_height_from_ground_mm,
|
|
sum(case when tractor_hitch_height_from_ground_mm is null then 0 else 1 end) over (order by rank) as value_partition
|
|
FROM mmt_staging2.FTHLG_SUM_Trail_Type_Block where rank >= 2
|
|
ORDER BY rank ASC
|
|
) as q) b where a.rank = b.rank;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trail_Type_Block a
|
|
set gradient_slope_1_degree= b.first_value from (SELECT
|
|
rank,gradient_slope_1_degree, value_partition, first_value(gradient_slope_1_degree) over (partition by value_partition order by rank)
|
|
FROM (
|
|
SELECT
|
|
rank,
|
|
gradient_slope_1_degree,
|
|
sum(case when gradient_slope_1_degree is null then 0 else 1 end) over (order by rank) as value_partition
|
|
FROM mmt_staging2.FTHLG_SUM_Trail_Type_Block where rank >= 2
|
|
ORDER BY rank ASC
|
|
) as q) b where a.rank = b.rank;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trail_Type_Block a
|
|
set gradient_slope_2_degree= b.first_value from (SELECT
|
|
rank,gradient_slope_2_degree, value_partition, first_value(gradient_slope_2_degree) over (partition by value_partition order by rank)
|
|
FROM (
|
|
SELECT
|
|
rank,
|
|
gradient_slope_2_degree,
|
|
sum(case when gradient_slope_2_degree is null then 0 else 1 end) over (order by rank) as value_partition
|
|
FROM mmt_staging2.FTHLG_SUM_Trail_Type_Block where rank >= 2
|
|
ORDER BY rank ASC
|
|
) as q) b where a.rank = b.rank;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Trail_Type_Block a
|
|
set tractor_hitch_type= b.first_value from (SELECT
|
|
rank,tractor_hitch_type, value_partition, first_value(tractor_hitch_type) over (partition by value_partition order by rank)
|
|
FROM (
|
|
SELECT
|
|
rank,
|
|
tractor_hitch_type,
|
|
sum(case when tractor_hitch_type is null then 0 else 1 end) over (order by rank) as value_partition
|
|
FROM mmt_staging2.FTHLG_SUM_Trail_Type_Block where rank >= 2
|
|
ORDER BY rank ASC
|
|
) as q) b where a.rank = b.rank;
|
|
|
|
execute 'update mmt_staging2.FTHLG_SUM_Trail_Type_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,'FTHLG_SUM_Trail_Type_Block');
|
|
|
|
|
|
/*inserting data into block -FTHLG_SUM_Test_Condition_1_Block*/
|
|
|
|
|
|
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
|
|
'FTHLG_SUM_Test_Condition_1_Block',__file_format,__sheet_mnemonic,3);
|
|
|
|
v_block:='FTHLG_SUM_Test_Condition_1_Block';
|
|
|
|
insert into mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
(
|
|
dummy_f,
|
|
Test_Condition,
|
|
Test_Date,
|
|
Tractor_Model,
|
|
Fuel_consumption_Ltr_hr,
|
|
Mileage_Km_Ltr,
|
|
Average_speed_of_travel_kmph,
|
|
Total_distance_travelled_km,
|
|
Gear_used_on_Straight_Road,
|
|
Straight_road_RPM_Drop,
|
|
Gear_used_on_Up_Slope_1,
|
|
Up_Slope_RPM_Drop_1,
|
|
Gear_used_on_Up_Slope_2,
|
|
Up_Slope_RPM_Drop_2,
|
|
Gear_used_on_Down_Slope,
|
|
Down_Slope_RPM_Shoot_up,
|
|
M_M_Performance_compared_to_respective_competitor_tractors_is_better_and_is_poor_than_competitor,
|
|
Fuel_consumption_lit_hr_2,
|
|
Mileage_Km_Ltr_2,
|
|
M_M_Performance_in_compared_to_respective_competitor_tractors,
|
|
Fuel_consumption_lit_hr_3,
|
|
Mileage_Km_Ltr_3,
|
|
Engine_Smoke_on_Load,
|
|
Engine_acceleration_smoke,
|
|
Range_Gear_Shifting,
|
|
Speed_Gear_Shifting,
|
|
Tractor_Steer_ability,
|
|
Tractor_braking_performance,
|
|
Front_Visibility,
|
|
Implement_Accessibility,
|
|
Front_end_lifting_during_operation,
|
|
RPM_Recovery_Time,
|
|
Engine_Vibration,
|
|
Engine_Sound
|
|
)
|
|
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_FTHLG_sum where rank_tag=''FTHLG_SUM_Test_Condition_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,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);
|
|
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
set test_iterationnumber=1;
|
|
|
|
|
|
|
|
insert into mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
(
|
|
dummy_f,
|
|
Test_Condition,
|
|
Test_Date,
|
|
Tractor_Model,
|
|
Fuel_consumption_Ltr_hr,
|
|
Mileage_Km_Ltr,
|
|
Average_speed_of_travel_kmph,
|
|
Total_distance_travelled_km,
|
|
Gear_used_on_Straight_Road,
|
|
Straight_road_RPM_Drop,
|
|
Gear_used_on_Up_Slope_1,
|
|
Up_Slope_RPM_Drop_1,
|
|
Gear_used_on_Up_Slope_2,
|
|
Up_Slope_RPM_Drop_2,
|
|
Gear_used_on_Down_Slope,
|
|
Down_Slope_RPM_Shoot_up,
|
|
M_M_Performance_compared_to_respective_competitor_tractors_is_better_and_is_poor_than_competitor,
|
|
Fuel_consumption_lit_hr_2,
|
|
Mileage_Km_Ltr_2,
|
|
M_M_Performance_in_compared_to_respective_competitor_tractors,
|
|
Fuel_consumption_lit_hr_3,
|
|
Mileage_Km_Ltr_3,
|
|
Engine_Smoke_on_Load,
|
|
Engine_acceleration_smoke,
|
|
Range_Gear_Shifting,
|
|
Speed_Gear_Shifting,
|
|
Tractor_Steer_ability,
|
|
Tractor_braking_performance,
|
|
Front_Visibility,
|
|
Implement_Accessibility,
|
|
Front_end_lifting_during_operation,
|
|
RPM_Recovery_Time,
|
|
Engine_Vibration,
|
|
Engine_Sound
|
|
)
|
|
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_FTHLG_sum where rank_tag=''FTHLG_SUM_Test_Condition_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,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);
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
set test_iterationnumber=2
|
|
where test_iterationnumber is null;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_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.FTHLG_SUM_Test_Condition_1_Block
|
|
ORDER BY test_iterationnumber asc
|
|
) as q) b where a.test_iterationnumber = b.test_iterationnumber;
|
|
|
|
delete from mmt_staging2.FTHLG_SUM_Test_Condition_1_Block where tractor_model = '0' or
|
|
fuel_consumption_ltr_hr is NULL;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
set fuel_consumption_lit_hr_2=null where fuel_consumption_lit_hr_2 like '%indicates%';
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
set fuel_consumption_lit_hr_2=left(fuel_consumption_lit_hr_2,length(fuel_consumption_lit_hr_2)-3),
|
|
Mileage_Km_Ltr_2 = left(Mileage_Km_Ltr_2,length(Mileage_Km_Ltr_2)-3)
|
|
where fuel_consumption_lit_hr_2 notnull;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
set fuel_consumption_lit_hr_3=null where fuel_consumption_lit_hr_3 like '%indicates%';
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
set fuel_consumption_lit_hr_3 = left(fuel_consumption_lit_hr_3,length(fuel_consumption_lit_hr_3)-3),
|
|
Mileage_Km_Ltr_3 = left(Mileage_Km_Ltr_3,length(Mileage_Km_Ltr_3)-3)
|
|
where fuel_consumption_lit_hr_2 notnull;
|
|
|
|
delete from mmt_staging2.FTHLG_SUM_Test_Condition_1_Block where dummy_f is null ;
|
|
execute 'update mmt_staging2.FTHLG_SUM_Test_Condition_1_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,'FTHLG_SUM_Test_Condition_1_Block');
|
|
|
|
|
|
|
|
/*inserting data into block -FTHLG_SUM_Test_Condition_2_Block*/
|
|
|
|
|
|
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
|
|
'FTHLG_SUM_Test_Condition_2_Block',__file_format,__sheet_mnemonic,4);
|
|
v_block:='FTHLG_SUM_Test_Condition_2_Block';
|
|
|
|
insert into mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
(
|
|
dummy_f,
|
|
Test_Condition,
|
|
Test_Date,
|
|
Tractor_Model,
|
|
Fuel_consumption_Ltr_hr,
|
|
Mileage_Km_Ltr,
|
|
Average_speed_of_travel_kmph,
|
|
Total_distance_travelled_km,
|
|
Gear_used_on_Straight_Road,
|
|
Straight_road_RPM_Drop,
|
|
Gear_used_on_Up_Slope_1,
|
|
Up_Slope_RPM_Drop_1,
|
|
Gear_used_on_Up_Slope_2,
|
|
Up_Slope_RPM_Drop_2,
|
|
Gear_used_on_Down_Slope,
|
|
Down_Slope_RPM_Shoot_up,
|
|
M_M_Performance_compared_to_respective_competitor_tractors_is_better_and_is_poor_than_competitor,
|
|
Fuel_consumption_lit_hr_2,
|
|
Mileage_Km_Ltr_2,
|
|
M_M_Performance_in_compared_to_respective_competitor_tractors,
|
|
Fuel_consumption_lit_hr_3,
|
|
Mileage_Km_Ltr_3,
|
|
Engine_Smoke_on_Load,
|
|
Engine_acceleration_smoke,
|
|
Range_Gear_Shifting,
|
|
Speed_Gear_Shifting,
|
|
Tractor_Steer_ability,
|
|
Tractor_braking_performance,
|
|
Front_Visibility,
|
|
Implement_Accessibility,
|
|
Front_end_lifting_during_operation,
|
|
RPM_Recovery_Time,
|
|
Engine_Vibration,
|
|
Engine_Sound
|
|
)
|
|
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_FTHLG_sum where rank_tag=''FTHLG_SUM_Test_Condition_2''
|
|
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);
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set test_iterationnumber=3;
|
|
|
|
|
|
insert into mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
(
|
|
dummy_f,
|
|
Test_Condition,
|
|
Test_Date,
|
|
Tractor_Model,
|
|
Fuel_consumption_Ltr_hr,
|
|
Mileage_Km_Ltr,
|
|
Average_speed_of_travel_kmph,
|
|
Total_distance_travelled_km,
|
|
Gear_used_on_Straight_Road,
|
|
Straight_road_RPM_Drop,
|
|
Gear_used_on_Up_Slope_1,
|
|
Up_Slope_RPM_Drop_1,
|
|
Gear_used_on_Up_Slope_2,
|
|
Up_Slope_RPM_Drop_2,
|
|
Gear_used_on_Down_Slope,
|
|
Down_Slope_RPM_Shoot_up,
|
|
M_M_Performance_compared_to_respective_competitor_tractors_is_better_and_is_poor_than_competitor,
|
|
Fuel_consumption_lit_hr_2,
|
|
Mileage_Km_Ltr_2,
|
|
M_M_Performance_in_compared_to_respective_competitor_tractors,
|
|
Fuel_consumption_lit_hr_3,
|
|
Mileage_Km_Ltr_3,
|
|
Engine_Smoke_on_Load,
|
|
Engine_acceleration_smoke,
|
|
Range_Gear_Shifting,
|
|
Speed_Gear_Shifting,
|
|
Tractor_Steer_ability,
|
|
Tractor_braking_performance,
|
|
Front_Visibility,
|
|
Implement_Accessibility,
|
|
Front_end_lifting_during_operation,
|
|
RPM_Recovery_Time,
|
|
Engine_Vibration,
|
|
Engine_Sound
|
|
)
|
|
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_FTHLG_sum where rank_tag=''FTHLG_SUM_Test_Condition_2''
|
|
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);
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set test_iterationnumber=4
|
|
where test_iterationnumber is null;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_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.FTHLG_SUM_Test_Condition_2_Block
|
|
ORDER BY test_iterationnumber asc
|
|
) as q) b where a.test_iterationnumber = b.test_iterationnumber;
|
|
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set Test_Date=(select Test_Date from mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
where tractor_model='Mstar Alternate Approach')
|
|
where Test_Date='0' and tractor_model ='Mstar Alternate Approach';
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set Test_Date=(select Test_Date from mmt_staging2.FTHLG_SUM_Test_Condition_1_Block
|
|
where tractor_model='Mstar 57 hp BSIII A')
|
|
where Test_Date='0' and tractor_model ='Mstar 57 hp BSIII A';
|
|
|
|
delete from mmt_staging2.FTHLG_SUM_Test_Condition_2_Block where tractor_model = '0' or
|
|
fuel_consumption_ltr_hr is NULL;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set fuel_consumption_lit_hr_2=null where fuel_consumption_lit_hr_2 like '%indicates%';
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set fuel_consumption_lit_hr_2=left(fuel_consumption_lit_hr_2,length(fuel_consumption_lit_hr_2)-3),
|
|
Mileage_Km_Ltr_2 = left(Mileage_Km_Ltr_2,length(Mileage_Km_Ltr_2)-3)
|
|
where fuel_consumption_lit_hr_2 notnull;
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set fuel_consumption_lit_hr_3=null where fuel_consumption_lit_hr_3 like '%indicates%';
|
|
|
|
update mmt_staging2.FTHLG_SUM_Test_Condition_2_Block
|
|
set fuel_consumption_lit_hr_3 = left(fuel_consumption_lit_hr_3,length(fuel_consumption_lit_hr_3)-3),
|
|
Mileage_Km_Ltr_3 = left(Mileage_Km_Ltr_3,length(Mileage_Km_Ltr_3)-3)
|
|
where fuel_consumption_lit_hr_2 notnull;
|
|
|
|
|
|
delete from mmt_staging2.FTHLG_SUM_Test_Condition_2_Block where dummy_f is null ;
|
|
execute 'update mmt_staging2.FTHLG_SUM_Test_Condition_2_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,'FTHLG_SUM_Test_Condition_2_Block');
|
|
|
|
|
|
/*inserting data into block -FTHLG_SUM_Comments_By_Block*/
|
|
|
|
|
|
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
|
|
'FTHLG_SUM_Comments_By_Block',__file_format,__sheet_mnemonic,5);
|
|
v_block:='FTHLG_SUM_Comments_By_Block';
|
|
|
|
|
|
insert into mmt_staging2.FTHLG_SUM_Comments_By_Block (dummy_f) values
|
|
('dummy');
|
|
|
|
execute 'update mmt_staging2.FTHLG_SUM_Comments_By_Block set test_engineer_comments_1=
|
|
(select column3 from mmt_staging2.stg_process_table_fthlg_sum a
|
|
where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||'''
|
|
and a.rank_tag=''FTHLG_SUM_Engineer_Comments_1''
|
|
and rank=1 ) where dummy_f=''dummy''' ;
|
|
|
|
execute 'update mmt_staging2.FTHLG_SUM_Comments_By_Block set test_engineer_comments_2=
|
|
(select column3 from mmt_staging2.stg_process_table_fthlg_sum a
|
|
where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||'''
|
|
and a.rank_tag=''FTHLG_SUM_Engineer_Comments_2''
|
|
and rank=1 ) where dummy_f=''dummy''';
|
|
|
|
execute 'update mmt_staging2.FTHLG_SUM_Comments_By_Block set test_manager_comments_1=
|
|
(select column3 from mmt_staging2.stg_process_table_fthlg_sum a
|
|
where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||'''
|
|
and a.rank_tag=''FTHLG_SUM_Manager_Comments_1''
|
|
and rank=1 ) where dummy_f=''dummy''';
|
|
|
|
execute 'update mmt_staging2.FTHLG_SUM_Comments_By_Block set test_manager_comments_2=
|
|
(select column3 from mmt_staging2.stg_process_table_fthlg_sum a
|
|
where a.file_format='''||p_file_format||''' and a.sheet_mnemonic='''||p_sheet_mnemonic||'''
|
|
and a.rank_tag=''FTHLG_SUM_Manager_Comments_2''
|
|
and rank=1 ) where dummy_f=''dummy''';
|
|
|
|
|
|
|
|
delete from mmt_staging2.FTHLG_SUM_Comments_By_Block where dummy_f is null ;
|
|
|
|
execute 'update mmt_staging2.FTHLG_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,'FTHLG_SUM_Comments_By_Block');
|
|
|
|
if v_query>1 then
|
|
v_context := '';
|
|
perform mmt_staging2.mmt_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_format,__sheet_mnemonic ,null,'stg2', 'fn_FTHLG_SUM_Block', v_state, v_msg, v_detail, v_hint, v_context,'success');
|
|
else
|
|
v_context := 'data not present';
|
|
perform mmt_staging2.mmt_insert_db_error ( __client_id, __function_id, 1001, 'Compegence', __file_syspk ,__file_format,__sheet_mnemonic ,null,'stg2', 'fn_FTHLG_SUM_Block', v_state, v_msg, v_detail, v_hint, v_context,'error');
|
|
end if;
|
|
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_FTHLG_SUM_Block', v_state, v_msg, v_detail, v_hint, v_context,'error');
|
|
return v_context;
|
|
end
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
|