mising pieces

This commit is contained in:
Paul Trowbridge 2022-04-09 02:28:53 -04:00
parent a29e5e54f3
commit 342e0824c5

View File

@ -11,6 +11,8 @@ DECLARE
_order_status text;
_actpy text;
_sql text;
_target_table text;
_version_col text;
_baseline text;
_date_funcs jsonb;
_perd_joins text;
@ -27,7 +29,18 @@ SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'ship_date') INTO _ship_
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
@ -35,7 +48,10 @@ INTO
FROM
fc.target_meta
WHERE
func NOT IN ('version');
COALESCE(appcol,'') NOT IN ('version','iter','logid');
RAISE NOTICE 'all columns %', _clist;
-------------------------all columns except volume scale-----------------------------------
SELECT
string_agg(
@ -52,7 +68,9 @@ INTO
FROM
fc.target_meta
WHERE
func NOT IN ('version');
COALESCE(appcol,'') NOT IN ('version','iter','logid');
RAISE NOTICE ' all columns plus scale volume columns %', _clist_vol;
-------------------------all columns except volume scale-----------------------------------
SELECT
@ -73,7 +91,9 @@ INTO
FROM
fc.target_meta
WHERE
func NOT IN ('version');
COALESCE(appcol,'') NOT IN ('version','iter','logid');
RAISE NOTICE 'all columns plus scale price %', _clist_prc;
SELECT
---------$$app_req$$ will hold the request body--------------------
@ -81,8 +101,8 @@ $$WITH
req AS (SELECT $$||'$$app_req$$::jsonb j)'||$$
,target AS (
SELECT
(req.j->>'vincr')::numeric vincr --volume
,(req.j->>'pincr')::numeric pincr --price
(req.j->>'app_vincr')::numeric vincr --volume
,(req.j->>'app_pincr')::numeric pincr --price
FROM
req
)
@ -92,7 +112,7 @@ req AS (SELECT $$||'$$app_req$$::jsonb j)'||$$
sum($$||_units_col||$$) FILTER (WHERE version <> 'ACTUALS') total
,sum($$||_units_col||$$) FILTER (WHERE iter = 'baseline') base
FROM
fc.live
$$||_target_table||$$ o
WHERE
app_where
)
@ -100,7 +120,7 @@ req AS (SELECT $$||'$$app_req$$::jsonb j)'||$$
SELECT
$$||_clist||$$
FROM
fc.live o
$$||_target_table||$$ o
WHERE
app_where
),
@ -108,7 +128,7 @@ vscale AS (
SELECT
(SELECT vincr FROM target) AS target_increment
,sum($$||_units_col||') AS units'||$$
,(SELECT vincr FROM target)/sum($$||_units_col||$$) AS factor
,CASE WHEN sum($$||_units_col||$$) = 0 THEN 0 ELSE (SELECT vincr FROM target)/sum($$||_units_col||$$) END AS factor
FROM
basemix
)
@ -123,7 +143,7 @@ vscale AS (
,volume AS (
SELECT
$$||_clist_vol||$$
,'forecast name' AS version
,'app_forecast_name' AS version
,'scale vol' AS iter
FROM
basemix o
@ -132,18 +152,18 @@ FROM
,pscale AS (
SELECT
(SELECT pincr FROM target) AS target_increment
,sum($$||_value_col||') AS value'||$$
,CASE WHEN (SELECT sum($$||_value_col||$$) FROM volume) = 0 THEN
,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($$||_value_col||$$) FROM volume))/(SELECT sum($$||_value_col||$$) FROM volume)
((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($$||_value_col||$$) FROM volume) = 0 THEN
CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum($$||_value_col||$$) FROM volume)) <> 0 THEN
,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($$||_value_col||$$) FROM volume))/(SELECT sum($$||_units_col||$$) FROM volume)
((SELECT pincr::numeric FROM target) - (SELECT sum($$||format('%I',_value_col)||$$) FROM volume))/(SELECT sum($$||format('%I',_units_col)||$$) FROM volume)
ELSE
0
END
@ -156,7 +176,7 @@ FROM
,pricing AS (
SELECT
$$||_clist_prc||$$
,'forecast name' AS version
,'app_forecast_name' AS version
,'scale price' AS iter
FROM
volume o
@ -165,7 +185,7 @@ WHERE
pscale.factor <> 0 or pscale.mod_price <> 0
)
INSERT INTO
fc.live
$$||_target_table||$$ o
SELECT
*
FROM