diff --git a/retail_model/script/fw_time_metrics.sql b/retail_model/script/fw_time_metrics.sql new file mode 100644 index 0000000..15adcf1 --- /dev/null +++ b/retail_model/script/fw_time_metrics.sql @@ -0,0 +1,325 @@ +CREATE OR REPLACE FUNCTION retail_saas.fw_time_metrics(client_id integer, function_id integer, granular_level character varying DEFAULT 'd1l01_name'::character varying, as_of_date date DEFAULT CURRENT_DATE) + RETURNS text + LANGUAGE plpgsql +AS $function$ +declare + +_query_string varchar; +_query_insert varchar; +_select_clause varchar; +_main_where_clause varchar; +_where_clause varchar; +_group_by_clause varchar; +_order_by_clause varchar; +_as_of_date date; +_as_of_prev_mth_date date; +_as_of_prev_year_date date; +_as_of_prev_year_prev_mth_date date; +_prev_month int; +_cy_prev_yyyymm int; +_py_prev_yyyymm int; +_granular_level varchar; + +_message_text varchar; +_returned_sqlstate varchar; +_error_message_text varchar; + +begin + + _select_clause := ''; + _query_insert := ''; + _main_where_clause := ' where '; + + select as_of_date into _as_of_date; + select _as_of_date - interval '1 month' into _as_of_prev_mth_date; + select _as_of_date - interval '1 year' into _as_of_prev_year_date; + select _as_of_prev_year_date - interval '1 month' into _as_of_prev_year_prev_mth_date; + + select date_part('month', _as_of_date) -1 into _prev_month; + select concat(date_part('year', _as_of_prev_mth_date), lpad(date_part('month', _as_of_prev_mth_date)::text,2,'0')) into _cy_prev_yyyymm; + select concat(date_part('year', _as_of_prev_year_prev_mth_date), lpad(date_part('month', _as_of_prev_year_prev_mth_date)::text,2,'0')) into _py_prev_yyyymm; + + if (client_id is not null) then + _main_where_clause := _main_where_clause || ' client_id = ' || client_id; + else + return 'Client ID is not specified, please check'; + end if; + + if (function_id is not null) then + _main_where_clause := _main_where_clause || ' and function_id = ' || function_id; + else + return 'Function ID is not specified, please check'; + end if; + + if (granular_level = 'd1l01_name') then + _granular_level := 'd1l01_id, ' || granular_level; + elseif (granular_level = 'd3_unique_id_name') then + _granular_level := 'd3_unique_id, ' || granular_level; + elseif (granular_level = 'd4_unique_id_name') then + _granular_level := 'd4_unique_id, ' || granular_level; + elseif (granular_level = 'd5_unique_id_name') then + _granular_level := 'd5_unique_id, ' || granular_level; + elseif (granular_level = 'd3_region') then + _granular_level := granular_level; + else + _granular_level := null; + end if; + + if (_granular_level is not null) then + _group_by_clause := ' group by client_id, function_id, ' || _granular_level; + else + return 'Granular level is not specified, please check'; + end if; + + _query_insert := 'INSERT INTO retail_saas.fw_time_metrics (client_id, function_id, as_of_date, metric_type, granular_level'; + _query_insert := _query_insert || ', sale_amt, cost_amt, sale_units, margin_amt, '; + _query_insert := _query_insert || _granular_level || ')'; + + /* current year current month - month to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''CYCM_MTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_date || '''::date)'; + _where_clause := _where_clause || ' and date_mm = date_part(''month'', ''' || _as_of_date || '''::date)'; + _where_clause := _where_clause || ' and date_dd <= date_part(''day'', ''' || _as_of_date || '''::date)'; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'CYCM_MTD execution error'; + execute(_query_string); + + /* current year previous month - month to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''CYPM_MTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_prev_mth_date || '''::date)'; + _where_clause := _where_clause || ' and date_mm = date_part(''month'', ''' || _as_of_prev_mth_date || '''::date)'; + _where_clause := _where_clause || ' and date_dd <= date_part(''day'', ''' || _as_of_prev_mth_date || '''::date)'; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'CYPM_MTD execution error'; + execute(_query_string); + + /* previous year current month - month to date */ + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''PYCM_MTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_prev_year_date || '''::date)'; + _where_clause := _where_clause || ' and date_mm = date_part(''month'', ''' || _as_of_prev_year_date || '''::date)'; + _where_clause := _where_clause || ' and date_dd <= date_part(''day'', ''' || _as_of_prev_year_date || '''::date)'; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'PYCM_MTD execution error'; + execute(_query_string); + + /* previous year previous month - month to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''PYPM_MTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_prev_year_prev_mth_date || '''::date)'; + _where_clause := _where_clause || ' and date_mm = date_part(''month'', ''' || _as_of_prev_year_prev_mth_date || '''::date)'; + _where_clause := _where_clause || ' and date_dd <= date_part(''day'', ''' || _as_of_prev_year_prev_mth_date || '''::date)'; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'PYPM_MTD execution error'; + execute(_query_string); + + /* current year - year to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''CY_YTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_date || '''::date)'; + _where_clause := _where_clause || ' and date_field <= ''' || _as_of_date || ''''; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'CY_YTD execution error'; + execute(_query_string); + + + /* previous year - year to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''PY_YTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_prev_year_date || '''::date)'; + _where_clause := _where_clause || ' and date_field <= ''' || _as_of_prev_year_date || ''''; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'PY_YTD execution error'; + execute(_query_string); + + /* current financial year - year to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''CFY_YTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_fy_yyyy = date_part(''year'', ''' || _as_of_date || '''::date)'; + _where_clause := _where_clause || ' and date_field <= ''' || _as_of_date || ''''; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'CFY_YTD execution error'; + execute(_query_string); + + + /* previous financial year - year to date */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''PFY_YTD'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_fy_yyyy = date_part(''year'', ''' || _as_of_prev_year_date || '''::date)'; + _where_clause := _where_clause || ' and date_field <= ''' || _as_of_prev_year_date || ''''; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'PFY_YTD execution error'; + execute(_query_string); + + /* year on year */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''YOY'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', sum(m1208) sale_amt, sum(m1209) cost_amt, sum(m1203) sale_units, sum(m1208) - sum(m1209) margin_amt'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_field > ''' || _as_of_prev_year_date || ''''; /** excluding previous year current date **/ + _where_clause := _where_clause || ' and date_field <= ''' || _as_of_date || ''''; /** including current year current date **/ + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'YOY execution error'; + execute(_query_string); + + /* current year - average sales per month for completed month (till previous month) */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''CY_ASM'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round(sum(m1208)/' || _prev_month || ',2) else 0 end avg_sale'; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round(sum(m1209)/' || _prev_month || ',2) else 0 end avg_cost'; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round(sum(m1203)/' || _prev_month || ',2) else 0 end avg_quantity'; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round((sum(m1208) - sum(m1209))/' || _prev_month || ',2) else 0 end avg_margin'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_date || '''::date)'; + _where_clause := _where_clause || ' and date_yyyymm <= ' || _cy_prev_yyyymm; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'CY_ASM execution error'; + + execute(_query_string); + + /* previous year - average sales per month for completed month (till previous month) */ + + _query_string := ''; + _select_clause := ''; + _where_clause := ''; + + _select_clause := _select_clause || 'select client_id, function_id, ''' || _as_of_date || ''' as_of_date, ''PY_ASM'' metric_type, ''' || granular_level || ''''; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round(sum(m1208)/' || _prev_month || ',2) else 0 end avg_sale'; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round(sum(m1209)/' || _prev_month || ',2) else 0 end avg_cost'; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round(sum(m1203)/' || _prev_month || ',2) else 0 end avg_quantity'; + _select_clause := _select_clause || ', case when ' || _prev_month || ' <> 0 then round((sum(m1208) - sum(m1209))/' || _prev_month || ',2) else 0 end avg_margin'; + _select_clause := _select_clause || ', ' || _granular_level; + _select_clause := _select_clause || ' from retail_saas.fw_ods_daily'; + + _where_clause := _main_where_clause || ' and date_yyyy = date_part(''year'', ''' || _as_of_prev_year_date || '''::date)'; + _where_clause := _where_clause || ' and date_yyyymm <= ' || _py_prev_yyyymm; + + _query_string := _query_string || _select_clause || _where_clause || _group_by_clause; + _query_string := _query_insert || ' ' || _query_string || ';'; + + _error_message_text := 'PY_ASM execution error'; + execute(_query_string); + + return 'Success'; + + --return _query_string ; + exception when others then + _message_text := ''; + _returned_sqlstate := ''; + + GET STACKED DIAGNOSTICS _message_text = MESSAGE_TEXT, + _returned_sqlstate = RETURNED_SQLSTATE; + return 'Failed: ' || _error_message_text || ' - ' || _returned_sqlstate || ' : ' || _message_text; + + +end + +$function$ +; diff --git a/retail_model/table/fw_time_metrics.sql b/retail_model/table/fw_time_metrics.sql new file mode 100644 index 0000000..f80789d --- /dev/null +++ b/retail_model/table/fw_time_metrics.sql @@ -0,0 +1,27 @@ +-- DROP TABLE fw_time_metrics; + +CREATE TABLE fw_time_metrics ( + syspk bigserial not null, + client_id fw_num_dimid not null, + function_id fw_num_dimid not null, + as_of_date fw_date not null, + metric_type fw_text not null, + granular_level fw_text, + sale_amt fw_num_metric default 0, + cost_amt fw_num_metric default 0, + sale_units fw_num_metric default 0, + margin_amt fw_num_metric default 0, + d1l01_name fw_text, -- prod_category + d3_unique_id_name fw_text, -- retailer + d3_region fw_text, -- region + d4_unique_id_name fw_text, -- salesman + d5_unique_id_name fw_text, -- customer + created_by_appuser fw_text default current_user, + updated_by_appuser fw_text default current_user, + created_by_dbuser fw_text default current_user, + updated_by_dbuser fw_text default current_user, + create_time fw_timestamp default current_timestamp, + update_time fw_timestamp default current_timestamp, + CONSTRAINT fw_time_metrics_syspk_pkey PRIMARY KEY (syspk) +); +