pivot_forecast/routes/scale/gen_scale.sql
2022-04-09 02:28:53 -04:00

210 lines
5.9 KiB
SQL

DO
$func$
DECLARE
_clist text;
_clist_vol text;
_clist_prc text;
_clist_inc text;
_ytdbody text;
_order_date text;
_ship_date text;
_order_status text;
_actpy text;
_sql text;
_target_table text;
_version_col text;
_baseline text;
_date_funcs jsonb;
_perd_joins text;
_interval interval;
_units_col text;
_value_col text;
BEGIN
-----------------populate application variables--------------------------------------------
--need a handler if any of these are not specified--
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 (SELECT cname FROM fc.target_meta WHERE appcol = 'units') INTO _units_col;
SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'value') INTO _value_col;
SELECT format('%I',max(schema))||'.'||format('%I',max(tname)) INTO _target_table FROM fc.target_meta;
SELECT cname INTO _version_col FROM fc.target_meta WHERE appcol = 'version';
RAISE NOTICE '_order_date; %', _order_date;
RAISE NOTICE '_ship_date; %', _ship_date;
RAISE NOTICE '_order_status;%', _order_status;
RAISE NOTICE '_units_col; %', _units_col;
RAISE NOTICE '_value_col; %', _value_col;
RAISE NOTICE '_target_table;%', _target_table;
RAISE NOTICE '_version_col; %', _version_col;
-------------------------all columns ------------------------------------------------------
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 'all columns %', _clist;
-------------------------all columns except volume scale-----------------------------------
SELECT
string_agg(
--create the column reference
'o.'||format('%I',cname)||
CASE WHEN appcol IN ('units', 'value', 'cost') THEN ' * vscale.factor AS '||format('%I',cname) ELSE '' END,
--delimiter
E'\n ,'
--sort column ordinal
ORDER BY opos ASC
)
INTO
_clist_vol
FROM
fc.target_meta
WHERE
COALESCE(appcol,'') NOT IN ('version','iter','logid');
RAISE NOTICE ' all columns plus scale volume columns %', _clist_vol;
-------------------------all columns except volume scale-----------------------------------
SELECT
string_agg(
--create the column reference
CASE
WHEN appcol IN ('units', 'cost') THEN '0::numeric'
WHEN appcol IN ('value') THEN $$(CASE WHEN pscale.factor = 0 THEN o.$$||_units_col||$$ * pscale.mod_price ELSE o.$$||format('%I',cname)||' * pscale.factor END)::numeric AS '||_value_col
ELSE 'o.'||format('%I',cname)
END,
--delimiter
E'\n ,'
--sort column ordinal
ORDER BY opos ASC
)
INTO
_clist_prc
FROM
fc.target_meta
WHERE
COALESCE(appcol,'') NOT IN ('version','iter','logid');
RAISE NOTICE 'all columns plus scale price %', _clist_prc;
SELECT
---------$$app_req$$ will hold the request body--------------------
$$WITH
req AS (SELECT $$||'$$app_req$$::jsonb j)'||$$
,target AS (
SELECT
(req.j->>'app_vincr')::numeric vincr --volume
,(req.j->>'app_pincr')::numeric pincr --price
FROM
req
)
-----this block is supposed to test for new products that might not be in baseline etc-------
,test AS (
SELECT
sum($$||_units_col||$$) FILTER (WHERE version <> 'ACTUALS') total
,sum($$||_units_col||$$) FILTER (WHERE iter = 'baseline') base
FROM
$$||_target_table||$$ o
WHERE
app_where
)
,basemix AS (
SELECT
$$||_clist||$$
FROM
$$||_target_table||$$ o
WHERE
app_where
),
vscale AS (
SELECT
(SELECT vincr FROM target) AS target_increment
,sum($$||_units_col||') AS units'||$$
,CASE WHEN sum($$||_units_col||$$) = 0 THEN 0 ELSE (SELECT vincr FROM target)/sum($$||_units_col||$$) END AS factor
FROM
basemix
)
,ilog AS (
INSERT INTO
fc.log (doc)
SELECT
req.j
FROM
req
)
,volume AS (
SELECT
$$||_clist_vol||$$
,'app_forecast_name' AS version
,'scale vol' AS iter
FROM
basemix o
CROSS JOIN vscale
)
,pscale AS (
SELECT
(SELECT pincr FROM target) AS target_increment
,sum($$||format('%I',_value_col)||') AS value'||$$
,CASE WHEN (SELECT sum($$||format('%I',_value_col)||$$) FROM volume) = 0 THEN
--if the base value is -0- scaling will not work, need to generate price, factor goes to -0-
0
ELSE
--if the target dollar value still does not match the target increment, make this adjustment
((SELECT pincr FROM target)-(SELECT sum($$||format('%I',_value_col)||$$) FROM volume))/(SELECT sum($$||format('%I',_value_col)||$$) FROM volume)
END factor
,CASE WHEN (SELECT sum($$||format('%I',_value_col)||$$) FROM volume) = 0 THEN
CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum($$||format('%I',_value_col)||$$) FROM volume)) <> 0 THEN
--if the base value is -0- but the target value hasn't been achieved, derive a price to apply
((SELECT pincr::numeric FROM target) - (SELECT sum($$||format('%I',_value_col)||$$) FROM volume))/(SELECT sum($$||format('%I',_units_col)||$$) FROM volume)
ELSE
0
END
ELSE
0
END mod_price
FROM
volume
)
,pricing AS (
SELECT
$$||_clist_prc||$$
,'app_forecast_name' AS version
,'scale price' AS iter
FROM
volume o
CROSS JOIN pscale
WHERE
pscale.factor <> 0 or pscale.mod_price <> 0
)
INSERT INTO
$$||_target_table||$$ o
SELECT
*
FROM
volume
UNION ALL
SELECT
*
FROM
pricing
$$
INTO
_sql;
RAISE NOTICE '%', _sql;
INSERT INTO fc.sql SELECT 'scale', _sql ON CONFLICT (cmd) DO UPDATE SET t = EXCLUDED.t;
END
$func$;
---SELECT * FROM fc.sql;