CY_ASM and PY_ASM added
This commit is contained in:
258
retail_model/script/fw_ods_metrics.sql
Normal file
258
retail_model/script/fw_ods_metrics.sql
Normal file
@@ -0,0 +1,258 @@
|
||||
CREATE OR REPLACE FUNCTION fw_ods_metrics (
|
||||
client_id in int,
|
||||
function_id in int,
|
||||
granular_level in varchar default 'd1l01_name',
|
||||
as_of_date in 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;
|
||||
_target_table varchar;
|
||||
_from_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;
|
||||
|
||||
_message_text varchar;
|
||||
_returned_sqlstate varchar;
|
||||
_error_message_text varchar;
|
||||
|
||||
begin
|
||||
|
||||
_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 is not null) then
|
||||
_group_by_clause := ' group by client_id, function_id, ' || granular_level;
|
||||
end if;
|
||||
|
||||
/* current year current month - month to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''CYCM_MTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* current year previous month - month to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''CYPM_MTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* previous year current month - month to date */
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''PYCM_MTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* previous year previous month - month to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''PYPM_MTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* current year - year to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''CY_YTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* previous year - year to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''PY_YTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* current financial year - year to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''CFY_YTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* previous financial year - year to date */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''PFY_YTD'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* year on year */
|
||||
|
||||
_query_string := '';
|
||||
_select_clause := '';
|
||||
_where_clause := '';
|
||||
|
||||
_select_clause := _select_clause || 'select client_id, function_id, ''YOY'' metric_type';
|
||||
_select_clause := _select_clause || ', sum(m1208) total_sale, sum(m1209) total_cost, sum(m1203) total_quantity';
|
||||
_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 || ';';
|
||||
|
||||
/* 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, ''CY_ASM'' metric_type';
|
||||
_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 || ', ' || 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 || ';';
|
||||
|
||||
/* 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, ''PY_ASM'' metric_type';
|
||||
_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 || ', ' || 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 || ';';
|
||||
|
||||
return _query_string ;
|
||||
exception when others then
|
||||
_message_text := '';
|
||||
_returned_sqlstate := '';
|
||||
_error_message_text := '';
|
||||
|
||||
GET STACKED DIAGNOSTICS _message_text = MESSAGE_TEXT,
|
||||
_returned_sqlstate = RETURNED_SQLSTATE;
|
||||
return 'Failed: ' || _error_message_text || ' - ' || _returned_sqlstate || ' : ' || _message_text;
|
||||
|
||||
|
||||
end
|
||||
$function$
|
||||
;
|
||||
Reference in New Issue
Block a user