Files
Retail_ETL_Control_Scripts/sql/data_rollup_v1.0.sql
2021-11-10 03:46:16 +00:00

75 lines
3.4 KiB
SQL
Executable File

update fw_ods.fw_ods_monthly ods
set d4l1_date = new_date,
d4l1_yyyy = new_year,
d4l1_qq = new_quarter,
d4l1_mm = new_month,
d4l1_yyyymm = new_yyyymm::int,
update_timestamp = now()
from
(
with tbl_results as (
with tbl as (
select date_trunc('month', max(d4l1_date))::date max_d4l1 from fw_ods.fw_ods_monthly where client_id = 10
)
select (EXTRACT(year FROM age(now(),max_d4l1))*12 + EXTRACT(month FROM age(now(),max_d4l1))-1) num_month from tbl
)
select distinct d4l1_date, (d4l1_date + num_month * interval '1 months')::date new_date,
date_part('year', (d4l1_date + num_month * interval '1 months')::date) new_year,
date_part('quarter', (d4l1_date + num_month * interval '1 months')::date) new_quarter,
date_part('month', (d4l1_date + num_month * interval '1 months')::date) new_month,
concat(date_part('year', (d4l1_date + num_month * interval '1 months')::date),lpad(date_part('month', (d4l1_date + num_month * interval '1 months')::date)::varchar,2,'0')) new_yyyymm
from fw_ods.fw_ods_monthly a, tbl_results b where client_id = 10
) new
where ods.d4l1_date = new.d4l1_date and ods.client_id = 10;
/* update fw_ods_viz_data_generic data excluding waterfall data */
update fw_ods.fw_ods_viz_data_generic ods
set from_date = new_date_from,
to_date = new_date_to,
update_timestamp = now()
from
(
with tbl_results as (
with tbl as (
select date_trunc('month', max(from_date))::date max_d4l1 from fw_ods.fw_ods_viz_data_generic where client_id = 10 and viztype_name <> 'Waterfall'
)
select (EXTRACT(year FROM age(now(),max_d4l1))*12 + EXTRACT(month FROM age(now(),max_d4l1))-1) num_month from tbl
)
select distinct from_date, to_date,
(from_date + num_month * interval '1 months')::date new_date_from,
(to_date + num_month * interval '1 months')::date new_date_to
from fw_ods.fw_ods_viz_data_generic a, tbl_results b where client_id = 10 and viztype_name <> 'Waterfall'
) new
where ods.from_date = new.from_date and ods.to_date = new.to_date and ods.client_id = 10 and viztype_name <> 'Waterfall';
/* update waterfall data */
update fw_ods.fw_ods_viz_data_generic ods
set from_date = new_date_from,
to_date = new_date_to,
update_timestamp = now()
from
(
with tbl_results as (
with tbl as (
select date_trunc('month', max(from_date))::date max_d4l1 from fw_ods.fw_ods_viz_data_generic where client_id = 10 and viztype_name= 'Waterfall'
)
select (EXTRACT(year FROM age(now(),max_d4l1))*12 + EXTRACT(month FROM age(now(),max_d4l1))-1) num_month from tbl
)
select distinct from_date, to_date,
(from_date + num_month * interval '1 months')::date new_date_from,
(to_date + num_month * interval '1 months')::date new_date_to
from fw_ods.fw_ods_viz_data_generic a, tbl_results b where client_id = 10 and viztype_name= 'Waterfall'
) new
where ods.from_date = new.from_date and ods.to_date = new.to_date and ods.client_id = 10 and viztype_name= 'Waterfall';
update fw_ods.fw_ods_viz_data_generic ods
set va1 = concat(EXTRACT(year FROM from_date),'-', lpad(EXTRACT(month FROM from_date)::text,2,'0')),
va2 = concat(EXTRACT(year FROM (from_date - 1 * interval '1 months')::date),'-', lpad(EXTRACT(month FROM (from_date - 1 * interval '1 months')::date)::text,2,'0'))
where client_id =10 and viztype_name= 'Waterfall';
update fw_core.fw_jobctl_runschedule_jobstep set end_status_note ='retail_update_completed', end_status='success',end_time = now() where job_script_type = 'sql' and latest_runschedule_flag='1' and job_name= 'Retail Data Update';