DO $func$ DECLARE _clist_all text; --all columns _clist_sum text; --group away forecast iteration rows _clist_group text; --group away forecast iteration rows _clist_vol text; --volume columns scaled _clist_prc text; --price columns scaled _target_table text; _order_date text; _ship_date text; _order_status text; _version_col text; _iter_col text; _logid_col text; _units_col text; _value_col text; _sql text; BEGIN -----------------populate application variables-------------------------------------------- SELECT cname INTO _order_date FROM fc.target_meta WHERE appcol = 'order_date' ; SELECT cname INTO _ship_date FROM fc.target_meta WHERE appcol = 'ship_date' ; SELECT cname INTO _order_status FROM fc.target_meta WHERE appcol = 'order_status' ; SELECT cname INTO _units_col FROM fc.target_meta WHERE appcol = 'units' ; SELECT cname INTO _value_col FROM fc.target_meta WHERE appcol = 'value' ; SELECT cname INTO _version_col FROM fc.target_meta WHERE appcol = 'version' ; SELECT cname INTO _iter_col FROM fc.target_meta WHERE appcol = 'iter' ; SELECT cname INTO _logid_col FROM fc.target_meta WHERE appcol = 'logid' ; SELECT format('%I',max(schema))||'.'||format('%I',max(tname)) INTO _target_table FROM fc.target_meta; 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; RAISE NOTICE '_iter_col; %', _iter_col; RAISE NOTICE '_logid_col; %', _logid_col; -------------------------all columns ------------------------------------------------------ SELECT string_agg('o.'||format('%I',cname),E'\n ,' ORDER BY opos ASC) INTO _clist_all FROM fc.target_meta; -------------------------basemix sum columns----------------------------------------------- SELECT string_agg( --create the column reference CASE appcol WHEN 'units' THEN 'sum(o.'||format('%I',cname)||') AS '||format('%I',cname) WHEN 'value' THEN 'sum(o.'||format('%I',cname)||') AS '||format('%I',cname) WHEN 'cost' THEN 'sum(o.'||format('%I',cname)||') AS '||format('%I',cname) ---if basemix is used in price or volume, these columns are overridden anyways--- WHEN 'version' THEN '''app_forecast_name'' AS '||format('%I',_version_col) WHEN 'iter' THEN '''scale'' AS '||format('%I',_iter_col) WHEN 'logid' THEN '0::bigint AS '||format('%I',_logid_col) ELSE 'o.'||format('%I',cname) END --delimiter ,E'\n ,' --sort column ordinal ORDER BY opos ASC ) INTO _clist_sum FROM fc.target_meta; RAISE NOTICE 'sumation columns %', _clist_sum; -------------------------basemix group by columns------------------------------------------ SELECT string_agg( --create the column reference 'o.'||format('%I',cname) --delimiter ,E'\n ,' --sort column ordinal ORDER BY opos ASC ) INTO _clist_group FROM fc.target_meta WHERE COALESCe(appcol,'') NOT IN ('version','iter','logid','value','cost','units'); RAISE NOTICE 'sumation columns %', _clist_group; -------------------------all columns as-is except volume types which need scaled----------------------------------- SELECT string_agg( --create the column reference CASE appcol ----calculation should yield the value necessary to get to the target increment value------------ WHEN 'units' THEN 'round(o.'||format('%I',cname)||' * vscale.factor,5) AS '||format('%I',cname) WHEN 'value' THEN 'round(o.'||format('%I',cname)||' * vscale.factor,2) AS '||format('%I',cname) WHEN 'cost' THEN 'round(o.'||format('%I',cname)||' * vscale.factor,2) AS '||format('%I',cname) WHEN 'version' THEN '''app_forecast_name'' AS '||format('%I',_version_col) WHEN 'iter' THEN '''scale volume'' AS '||format('%I',_iter_col) WHEN 'logid' THEN '(SELECT id FROM ilog) AS '||format('%I',_logid_col) ELSE 'o.'||format('%I',cname) END --delimiter ,E'\n ,' --sort column ordinal ORDER BY opos ASC ) INTO _clist_vol FROM fc.target_meta; RAISE NOTICE ' all columns plus scale volume columns %', _clist_vol; -------------------------all columns with price types getting scaled----------------------------------- SELECT string_agg( --create the column reference CASE appcol WHEN 'units' THEN '0::numeric AS '||format('%I',cname) WHEN 'cost' THEN '0::numeric AS '||format('%I',cname) WHEN 'value' THEN $$round((CASE WHEN pscale.factor = 0 THEN o.$$||_units_col||$$ * pscale.mod_price ELSE o.$$||format('%I',cname)||' * pscale.factor END)::numeric,2) AS '||format('%I',cname) WHEN 'version' THEN '''app_forecast_name'' AS '||format('%I',_version_col) WHEN 'iter' THEN '''scale price'' AS '||format('%I',_iter_col) WHEN 'logid' THEN '(SELECT id FROM ilog) AS '||format('%I',_logid_col) ELSE 'o.'||format('%I',cname) END --delimiter ,E'\n ,' --sort column ordinal ORDER BY opos ASC ) INTO _clist_prc FROM fc.target_meta; 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 $$||format('%I',_iter_col)||$$ <> 'ACTUALS') total ,sum($$||_units_col||$$) FILTER (WHERE $$||format('%I',_iter_col)||$$ = 'baseline') base FROM $$||_target_table||$$ o WHERE app_where ) ,ilog AS ( INSERT INTO fc.log (doc) SELECT req.j FROM req RETURNING * ) ------need to group basemix and forego any detail iterations ,basemix AS ( SELECT $$||_clist_sum||$$ FROM $$||_target_table||$$ o WHERE app_where GROUP BY $$||_clist_group||$$ ), 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 ) ,volume_only AS ( SELECT $$||_clist_vol||$$ FROM basemix o CROSS JOIN vscale WHERE vscale.factor <> 0 ) ,volume AS ( SELECT * FROM volume_only UNION ALL SELECT * FROM basemix WHERE (SELECT factor FROM vscale) = 0 ) ,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 CASE WHEN (SELECT factor FROM vscale) = 0 --if the incoming volume dataset has just basemix data, then create an absolute factor and multiply by basemix THEN (SELECT pincr FROM target)/(SELECT sum($$||format('%I',_value_col)||$$) FROM volume) --if the incoming volume table already has an adjusment, just need to create a true-up factor --multiplying by the raw factor without adding 1 will work since this data set will be added to the volume data set ELSE ((SELECT pincr FROM target)-(SELECT sum($$||format('%I',_value_col)||$$) FROM volume))/(SELECT sum($$||format('%I',_value_col)||$$) FROM volume) END 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||$$ FROM volume o CROSS JOIN pscale WHERE pscale.factor <> 0 or pscale.mod_price <> 0 ) INSERT INTO $$||_target_table||$$ SELECT * FROM volume_only 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;