Files
MMT/deployment-20210427T103328Z-001/deployment/IHT/IHT version2/iht_ham_stg2.sql
2021-06-21 12:35:07 +05:30

848 lines
30 KiB
PL/PgSQL

drop function if exists mmt_staging2.fn_IHTHAM_HAM_block;
CREATE OR REPLACE FUNCTION mmt_staging2.fn_IHTHAM_HAM_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_IHTHAM_HAM_block
Function Desc: This function populates data into staging 2 block
File Format: IHT
Sheet Format: IHTHAM_HAM
Creation Date: March 25 2021
Updation Date:
Author: compegence team
Function Call: select mmt_staging2.fn_IHTHAM_HAM_block(p_client_id,p_function_id, p_file_format,
p_sheet_mnemonic, p_file_syspk)
Function call ex: select mmt_staging2.fn_IHTHAM_HAM_block(1,2,'IHT','IHTHAM_HAM',456)
***************************************************************/
SET search_path TO mmt_staging2;
/* to process multiple files - re-runnability*/
truncate table mmt_staging2.IHTHAM_HAM_h1_block;
truncate table mmt_staging2.IHTHAM_HAM_H1_Int;
truncate table mmt_staging2.IHTHAM_HAM_H1_block;
truncate table mmt_staging2.IHTHAM_HAM_Tyre_Details_Block;
truncate table mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int;
truncate table mmt_staging2.IHTHAM_HAM_Engine_RPM_Block;
truncate table mmt_staging2.IHTHAM_HAM_Tractor_Block;
truncate table mmt_staging2.IHTHAM_HAM_Weight_Block;
truncate table mmt_staging2.IHTHAM_HAM_Drawbar_Block;
truncate table mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block;
truncate table mmt_staging2.IHTHAM_HAM_Results_Block;
truncate table mmt_staging2.IHTHAM_HAM_Footer_Block;
truncate table mmt_staging2.stg_specific_table_IHTHAM_HAM;
truncate table mmt_staging2.stg_process_table_IHTHAM_HAM;
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 IHT */
execute 'insert into mmt_staging2.stg_specific_table_IHTHAM_HAM
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_IHTHAM_HAM set column15='Objective'
where column15 like 'Objective%';
update mmt_staging2.stg_specific_table_IHTHAM_HAM set column15='Acceptance criteria'
where column15 like 'Acceptance criteria%';
update mmt_staging2.stg_specific_table_IHTHAM_HAM set column3 = TRIM (TRAILING FROM column3 );
update mmt_staging2.stg_specific_table_IHTHAM_HAM 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_IHTHAM_HAM 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_IHTHAM_HAM 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_IHTHAM_HAM
select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag
from mmt_staging2.stg_specific_table_IHTHAM_HAM 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_IHTHAM_HAM
select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag
from mmt_staging2.stg_specific_table_IHTHAM_HAM 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_IHTHAM_HAM
select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag
from mmt_staging2.stg_specific_table_IHTHAM_HAM 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=''Atmospheric condition''
and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||'''';
execute 'insert into mmt_staging2.stg_process_table_IHTHAM_HAM
select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag
from mmt_staging2.stg_specific_table_IHTHAM_HAM 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=''Gear''
and b.file_format='''||p_file_format||''' and b.sheet_mnemonic='''||p_sheet_mnemonic||'''';
execute 'insert into mmt_staging2.stg_process_table_IHTHAM_HAM
select a.* , RANK () OVER ( ORDER BY row_number) as rank,b.rank_tag as rank_tag
from mmt_staging2.stg_specific_table_IHTHAM_HAM 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 column6 into __model from mmt_staging2.stg_process_table_IHTHAM_HAM a
where rank_tag='IHTHAM_HAM_H1' and trim(column3)='Tractor Model';
/*block starts - IHTHAM_HAM_H1_BLOCK */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_H1_BLOCK',__file_format,__sheet_mnemonic,1);
v_block:='IHTHAM_HAM_H1_BLOCK';
insert into mmt_staging2.IHTHAM_HAM_H1_INT (c1,c2)
select a.column3,column6 from mmt_staging2.stg_process_table_IHTHAM_HAM a where rank_tag='IHTHAM_HAM_H1';
insert into mmt_staging2.IHTHAM_HAM_H1_INT (c1,c2)
select a.column9,column12 from mmt_staging2.stg_process_table_IHTHAM_HAM a where rank_tag='IHTHAM_HAM_H1';
insert into mmt_staging2.IHTHAM_HAM_H1_INT (c1,c2)
select 'Objective',column15
from mmt_staging2.stg_process_table_IHTHAM_HAM a
where rank_tag='IHTHAM_HAM_H1'
and row_number=
(
select row_number+1 from
mmt_staging2.stg_process_table_IHTHAM_HAM a
where column15='Objective'
and rank_tag='IHTHAM_HAM_H1'
);
insert into mmt_staging2.IHTHAM_HAM_H1_INT (c1,c2)
select 'Acceptance criteria',column15
from mmt_staging2.stg_process_table_IHTHAM_HAM a
where rank_tag='IHTHAM_HAM_H1'
and row_number=
(
select row_number+1 from
mmt_staging2.stg_process_table_IHTHAM_HAM a
where column15='Acceptance criteria'
and rank_tag='IHTHAM_HAM_H1'
);
insert into mmt_staging2.IHTHAM_HAM_H1_INT (c1,c2)
select split_part(column3,':',1),split_part(column3,':',2)
from mmt_staging2.stg_process_table_IHTHAM_HAM
where rank_tag='IHTHAM_HAM_Results' and rank=49;
insert into mmt_staging2.IHTHAM_HAM_H1_INT (c1,c2)
select column3,column4
from mmt_staging2.stg_process_table_IHTHAM_HAM
where rank_tag='IHTHAM_HAM_Atmos_Cond' and rank=4;
update mmt_staging2.IHTHAM_HAM_H1_Int set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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.IHTHAM_HAM_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_Location,
Operator_Name,
Project_Group,
Test_standard_refer,
Objective,
Acceptance_Criteria,
Remarks,
condition
)
SELECT *
FROM crosstab(
'SELECT unnest(''{c2}''::text[]) AS col
, row_number() OVER ()
, unnest(ARRAY[c2::text]) AS val
FROM mmt_staging2.IHTHAM_HAM_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,a_20 text);
update mmt_staging2.IHTHAM_HAM_H1_Block
set Sample_Receipt_Date=case
when Sample_Receipt_Date like '%-%' then Sample_Receipt_Date::timestamptz
else date '1899-12-30' + Sample_Receipt_Date::int * interval '1' day
end;
update mmt_staging2.IHTHAM_HAM_H1_Block
set Test_Report_Date=case
when Test_Report_Date like '%-%' then Test_Report_Date::timestamptz
else date '1899-12-30' + Test_Report_Date::int * interval '1' day
end;
update mmt_staging2.IHTHAM_HAM_H1_Block
set Test_Start_Date=case
when Test_Report_Date like '%-%' then Test_Report_Date::timestamptz
else date '1899-12-30' + Test_Report_Date::int * interval '1' day
end;
update mmt_staging2.IHTHAM_HAM_H1_Block
set Test_End_Date=case
when Test_Report_Date like '%-%' then Test_Report_Date::timestamptz
else date '1899-12-30' + Test_Report_Date::int * interval '1' day
end;
delete from mmt_staging2.IHTHAM_HAM_H1_Block where dummy_f is null ;
update mmt_staging2.IHTHAM_HAM_H1_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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,'IHTHAM_HAM_H1_Block');
insert into mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
(
column3,column4,column5,column6,column8,column9 ,
column10,column11,column12,column13,
column14,column15,column16,column17,
column18,column19,column20,column21 ,
column22,rank
)
select
column3,column4,column5,column6,column8,column9,
column10,column11,column12,column13,
column14,column15,column16,column17,
column18,column19,column20,column21 ,
column22,rank
from mmt_staging2.stg_process_table_IHTHAM_HAM a
where rank_tag='IHTHAM_HAM_Engine_Tyre_Weight'
order by rank;
update mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_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 - IHTHAM_HAM_Tyre_Details_Block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Tyre_Details_Block',__file_format,__sheet_mnemonic,2);
v_block:='IHTHAM_HAM_Tyre_Details_Block';
insert into mmt_staging2.IHTHAM_HAM_Tyre_Details_Block
(
dummy_f,
Tyre_Details,
Tyre_Make,
Tyre_size,
Ply_Rating,
Load_Carrying_Capacity,
pressure_kg_cm2,
No_of_lug,
Number_of_no_load_lug_30m,
Lug_Height,
Dynamic_rolling_radius,
Wheel_rim_Make_size
)
SELECT *
FROM crosstab(
'SELECT unnest(''{column15,column20}''::text[]) AS col
, row_number() OVER ()
, unnest(ARRAY[column15::text,column20::text]) AS val
FROM mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int where rank between 4 and 14
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);
delete from mmt_staging2.IHTHAM_HAM_Tyre_Details_Block where dummy_f is null ;
update mmt_staging2.IHTHAM_HAM_Tyre_Details_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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,'IHTHAM_HAM_Tyre_Details_Block');
/*block starts - IHTHAM_HAM_Engine_RPM_Block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Engine_RPM_Block',__file_format,__sheet_mnemonic,3);
v_block:='IHTHAM_HAM_Engine_RPM_Block';
insert into mmt_staging2.IHTHAM_HAM_Engine_RPM_Block(dummy_f) values ('dummy');
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set low_idle_declared=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=2 and column3='Low Idle RPM')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set low_idle_observed=(select column8 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=2 and column3='Low Idle RPM')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set high_idle_declared=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=3 and column10='High Idle RPM')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set high_idle_observed=(select column8 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=3 and column3='High Idle RPM')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set rated_rpm_declared=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=4 and column3='Rated RPM')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set rated_rpm_observed=(select column8 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=4 and column3='Rated RPM')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block
set Engine_to_PTO_Ratio=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=5 and column3='Engine to PTO Ratio')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Engine_RPM_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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,'IHTHAM_HAM_Engine_RPM_Block');
/*block starts -IHTHAM_HAM_Drawbar_Block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Drawbar_Block',__file_format,__sheet_mnemonic,4);
v_block:='IHTHAM_HAM_Drawbar_Block';
insert into mmt_staging2.IHTHAM_HAM_Drawbar_Block(test_condition)
select distinct column6 from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank between 9 and 14;
insert into mmt_staging2.IHTHAM_HAM_Drawbar_Block(test_condition)
select distinct column8 from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank between 9 and 14;
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Required_pull_in_kg = (select column7
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='UB' and rank =9);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Required_Power_in_hp = (select column7
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='UB' and rank =10);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Actual_pull_in_kg = (select column7
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='UB' and rank =11);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set actual_power_in_hp = (select column7
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='UB' and rank =12);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Calculated_hitch_heigh_mm = (select column7
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='UB' and rank =13);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Actual_hitch_height_mm = (select column7
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='UB' and rank =14);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Required_pull_in_kg = (select column9
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='B' and rank =9);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Required_Power_in_hp = (select column9
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='B' and rank =10);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Actual_pull_in_kg = (select column9
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='B' and rank =11);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set actual_power_in_hp = (select column9
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='B' and rank =12);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Calculated_hitch_heigh_mm = (select column9
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='B' and rank =13);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block
set Actual_hitch_height_mm = (select column9
from mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where test_condition='B' and rank =14);
update mmt_staging2.IHTHAM_HAM_Drawbar_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_Drawbar_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,'IHTHAM_HAM_Drawbar_Block');
/*block starts - IHTHAM_HAM_Tractor_Block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Tractor_Block',__file_format,__sheet_mnemonic,5);
v_block:='IHTHAM_HAM_Tractor_Block';
insert into mmt_staging2.IHTHAM_HAM_Tractor_Block(dummy_f) values ('dummy');
update mmt_staging2.IHTHAM_HAM_Tractor_Block
set Wheel_Base_mm=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=5 and column3='Wheel Base (mm)')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Tractor_Block
set Engine_Power_hp=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=6 and column3='Engine Power hp')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Tractor_Block
set PTO_Power_hp=(select column6 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=7 and column3='PTO Power hp')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Tractor_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_Tractor_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,'IHTHAM_HAM_Tractor_Block');
/*block starts -IHTHAM_HAM_Weight_Block*/
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Weight_Block',__file_format,__sheet_mnemonic,6);
v_block:='IHTHAM_HAM_Weight_Block';
insert into mmt_staging2.IHTHAM_HAM_Weight_Block(dummy_f) values ('dummy');
update mmt_staging2.IHTHAM_HAM_Weight_Block
set test_condition=(select column10 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=2 )
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set test_condition=(select column10 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=3)
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set Front_weight=(select column13 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=2 and column14='Unballast')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set Front_weight=(select column13 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=3 and column14='Ballast')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set Rear_weight=(select column17 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=2 and column14='Unballast')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set Rear_weight=(select column17 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=3 and column14='Ballast')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set Total_weight=(select column21 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=2 and column14='Unballast')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block
set Total_weight=(select column21 from
mmt_staging2.IHTHAM_HAM_Engine_Tyre_Weight_Int
where rank=3 and column14='Ballast')
where dummy_f='dummy';
update mmt_staging2.IHTHAM_HAM_Weight_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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,'IHTHAM_HAM_Weight_Block');
/*block starts - IHTHAM_HAM_Atmos_Cond_Block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Atmos_Cond_Block',__file_format,__sheet_mnemonic,7);
v_block:='IHTHAM_HAM_Atmos_Cond_Block';
insert into mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block
(
dummy_f,
Ambient_temp_C,
humidity,
wind_velocity
)
SELECT *
FROM crosstab(
'SELECT unnest(''{column5}''::text[]) AS col
, row_number() OVER ()
, unnest(ARRAY[column5::text]) AS val
FROM mmt_staging2.stg_process_table_ihtham_ham
where rank_tag=''IHTHAM_HAM_Atmos_Cond'' and rank in (1,2,3)
ORDER BY generate_series(1,15),rank,2'
) t (col text,a_1 text,a_2 text,a_3 text);
update mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block
set date=
(select date '1899-12-30' + column8::int * interval '1' day
FROM mmt_staging2.stg_process_table_ihtham_ham
where column7='Date' and rank_tag='IHTHAM_HAM_Atmos_Cond' and rank =1);
update mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block
set start_time=
(select to_char(to_timestamp((column8::numeric)* 60),'HH12:MI')
FROM mmt_staging2.stg_process_table_ihtham_ham
where column7='Start Time' and rank_tag='IHTHAM_HAM_Atmos_Cond' and rank=2);
update mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block
set end_time=
(select to_char(to_timestamp((column8::numeric)* 60),'HH12:MI')
FROM mmt_staging2.stg_process_table_ihtham_ham
where column7='End time' and rank_tag='IHTHAM_HAM_Atmos_Cond' and rank=3);
delete from mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block where dummy_f is null ;
update mmt_staging2.IHTHAM_HAM_Atmos_Cond_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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,'IHTHAM_HAM_Atmos_Cond_Block');
/*block starts - IHTHAM_HAM_Results_Block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Results_Block',__file_format,__sheet_mnemonic,8);
v_block:='IHTHAM_HAM_Results_Block';
insert into mmt_staging2.IHTHAM_HAM_Results_Block
(
column3,column4,column5,column6,
column7,column8,column9,
column10,column11,column12,
column13,column14,column15,
column16,column17,column18,
column19,column20,column21,
column22,column23,column24,rank
)
select
column3,column4,column5,column6,
column7,column8,column9,
column10,column11,column12,
column13,column14,column15,
column16,column17,column18,
column19,column20,column21,
column22,column23,column24,rank
from mmt_staging2.stg_process_table_IHTHAM_HAM a
where rank_tag='IHTHAM_HAM_Results'
order by rank;
update mmt_staging2.IHTHAM_HAM_Results_Block
set ods_record =0 where rank in (1,2,49,50,51);
update mmt_staging2.IHTHAM_HAM_Results_Block
set column22= to_char((column22::numeric) * '24 hours'::interval,'HH12:MIPM')
where ods_record=1;
--select to_char((3.4722222222222654E-3) * '24 hours'::interval,'HH12:MI')
--select to_timestamp(cast('3.4722222222222654E-3' as real));
update mmt_staging2.IHTHAM_HAM_Results_Block
set column24= to_char((cast(column24 as real)) * '24 hours'::interval,'HH24:MI')
where ods_record=1;
update mmt_staging2.IHTHAM_HAM_Results_Block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_Results_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,'IHTHAM_HAM_Results_Block');
/*block starts - IHTHAM_HAM_Footer_block */
perform mmt_staging2.fn_jobctrl_block_begin(__client_id,__function_id,__file_syspk,
'IHTHAM_HAM_Footer_block',__file_format,__sheet_mnemonic,9);
v_block:='IHTHAM_HAM_Footer_block';
insert into mmt_staging2.IHTHAM_HAM_Footer_block(dummy_f) values ('dummy');
update mmt_staging2.IHTHAM_HAM_Footer_block a
set prepared_by=( select column7 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and trim(column3)='Prepared by' )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set reviewed_by=( select column7 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and trim(column3)='Reviewed by' )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set approved_by=( select column7 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and trim(column3)='Approved by' )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set comments=( select column3 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=5 )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set rev1=( select column3 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=6 )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set rev2=( select column9 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=6 )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set rev3=( select column18 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=6 )
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set replaces=( select column23 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=1)
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set revision_no=( select column23 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=2)
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set prepared_date=( select column19 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=1)
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set reviewed_date=( select column19 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=2)
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block a
set approved_date=( select column19 from mmt_staging2.stg_process_table_IHTHAM_HAM b
where b.rank_tag='IHTHAM_HAM_Footer'
and rank=3)
where dummy_F='dummy';
update mmt_staging2.IHTHAM_HAM_Footer_block set model=__model;
execute 'update mmt_staging2.IHTHAM_HAM_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,'IHTHAM_HAM_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_IHTHAM_HAM_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_IHTHAM_HAM_Block', v_state, v_msg, v_detail, v_hint, v_context,'error');
return v_context;
end
$$ LANGUAGE plpgsql;
select mmt_staging2.fn_IHTHAM_HAM_block(20,1,'IHTHAM','IHTHAM_HAM',887);