pivot_forecast/routes/baseline/gen_baseline.sql

205 lines
5.9 KiB
SQL

DO
$func$
DECLARE
_clist text;
_clist_inc text;
_ytdbody text;
_order_date text;
_ship_date text;
_order_status text;
_actpy text;
_sql text;
_baseline text;
_date_funcs jsonb;
_perd_joins text;
_interval interval;
_target_table text;
_version_col text;
/*----------------parameters listing--------------
app_baseline_from_date
app_baseline_to_date
app_first_forecast_date
app_openorder_cutoff
app_openstatus_code
app_plug_fromdate
app_plug_todate
------------------------------------------------*/
BEGIN
-----------------populate application variables--------------------------------------------
SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'order_date') INTO _order_date;
SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'ship_date') INTO _ship_date;
SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'order_status') INTO _order_status;
SELECT format('%I',max(schema))||'.'||format('%I',max(tname)) INTO _target_table FROM fc.target_meta;
--the target interval
SELECT interval '1 year' INTO _interval;
SELECT cname INTO _version_col FROM fc.target_meta WHERE appcol = 'version';
SELECT jsonb_agg(func) INTO _date_funcs FROM fc.target_meta WHERE dtype = 'date' AND appcol is NOT null;
--create table join for each date based func in target_meta joining to fc.perd static table
--the join, though, should be based on the target date, which is needs an interval added to get to the target
SELECT
string_agg(
'LEFT OUTER JOIN fc.perd '||func||' ON'||
$$
$$||'(o.'||format('%I',cname)||' + interval '||format('%L',_interval) ||' )::date <@ '||func||'.drange'
,E'\n')
INTO
_perd_joins
FROM
fc.target_meta
WHERE
dtype = 'date'
AND func IS NOT NULL;
raise notice '%',_perd_joins;
-------------------------------build a column list-----------------------------------------
SELECT
string_agg('o.'||format('%I',cname),E'\n ,' ORDER BY opos ASC)
INTO
_clist
FROM
fc.target_meta
WHERE
COALESCE(appcol,'') NOT IN ('version','iter','logid');
raise notice '%',_clist;
---------------------------build column to increment dates---------------------------------
SELECT
string_agg(
CASE
--if you're dealing with a date function...
WHEN _date_funcs ? func THEN
CASE
--...but it's not the date itself...
WHEN appcol IS NULL THEN
--...pull the associated date field from perd table
'perd.'||m.fcol
--...and it's the primary key date...
ELSE
--use the date key but increment by the target interval
--this assumes that the primary key for the func is a date, but it has to be or it wont join anyways
'o.'||format('%I',cname)||' + interval '||format('%L',_interval) ||' AS '||format('%I',cname)
END
ELSE
'o.'||format('%I',cname)
END
,E'\n ,' ORDER BY opos ASC
)
INTO
_clist_inc
FROM
fc.target_meta m
WHERE
COALESCE(appcol,'') NOT IN ('version','iter','logid');
RAISE NOTICE 'DATES INCREMENTED: %',_clist_inc;
--------------------------------------clone the actual baseline-----------------------------------------------
SELECT
$$SELECT
$$::text||
_clist||
$$
,'forecast_name' "version"
,'actuals' iter
,null::bigint app_logid
FROM
$$||_target_table||$$ o
WHERE
(
--base period orders booked....
$$||format('%I',_order_date)||$$ BETWEEN 'app_baseline_from_date'::date AND 'app_baseline_to_date'::date
--...or any open orders currently booked before cutoff....
OR ($$||format('%I',_order_status)||$$ IN (app_openstatus_code) and $$||format('%I',_order_date)||$$ <= 'app_openorder_cutoff'::date)
--...or anything that shipped in that period
OR ($$||format('%I',_ship_date)||$$ BETWEEN 'app_baseline_from_date'::date AND 'app_baseline_to_date'::date)
)
--be sure to pre-exclude unwanted items, like canceled orders, non-gross sales, and short-ships
$$::text
INTO
_ytdbody;
RAISE NOTICE '_ytdbody %', _ytdbody;
------------------------------------pull a plug from actuals to create a full year baseline------------------
SELECT
$$SELECT
$$||_clist_inc||
$$
,'forecast_name' "version"
,'plug' iter
,null::bigint app_logid
FROM
$$||_target_table||' o'||E'\n'||_perd_joins||$$
WHERE
$$||format('%I',_order_date)||$$ BETWEEN 'app_plug_fromdate'::date AND 'app_plug_todate'::date
--be sure to pre-exclude unwanted items, like canceled orders, non-gross sales, and short-ships
$$
INTO
_actpy;
RAISE NOTICE '_actpf %',_actpy;
------------------------------copy a full year and increment by 1 year for the baseline-------------------------
SELECT
--$$INSERT INTO
-- fc.live
$$,incr AS (
SELECT
$$||_clist_inc||
$$
,'forecast_name' "version"
,'baseline' iter
,null::bigint app_logid
FROM
baseline o$$||E'\n'||_perd_joins||$$
)
,ins AS (
INSERT INTO
$$||_target_table||$$
SELECT
*
FROM
incr i
WHERE
i.$$||format('%I',_order_date)||$$ >= 'app_first_forecast_date'::date$$||$$
OR i.$$||format('%I',_ship_date)||$$ >= 'app_first_forecast_date'::date$$||$$
RETURNING *
)
SELECT COUNT(*) num_rows FROM ins$$
--any orders in the forecast period, or any sales in the forecast period (from open orders)
INTO
_baseline;
RAISE NOTICE '_baseline %',_baseline;
------------------------------stack the sql into the final format------------------------------------------------
SELECT
$$DELETE FROM $$||_target_table||$$ WHERE $$||_version_col||$$ = 'forecast_name';
WITH
baseline AS (
$$||_ytdbody||
$$UNION ALL
$$||_actpy
||$$)
$$||_baseline
INTO
_sql;
RAISE NOTICE '_sql %',_sql;
INSERT INTO fc.sql SELECT 'baseline', _sql ON CONFLICT ON CONSTRAINT sql_pkey DO UPDATE SET t = EXCLUDED.t;
END
$func$;
---SELECT * FROM fc.sql;