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(app_units) FILTER (WHERE app_iter <> 'ACTUALS') total ,sum(app_units) FILTER (WHERE app_iter = 'baseline') base FROM fc.dcard 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 o.id ,o.logid ,o."Trans. Date" ,o."Post Date" ,o."Description" ,sum(o."Amount") AS "Amount" ,o."Category" ,o."Party" ,o."Reason" ,sum(o.app_units) AS app_units ,'app_forecast_name' AS app_version ,'scale' AS app_iter ,0::bigint AS app_logid FROM fc.dcard o WHERE app_where GROUP BY o.id ,o.logid ,o."Trans. Date" ,o."Post Date" ,o."Description" ,o."Category" ,o."Party" ,o."Reason" ), vscale AS ( SELECT (SELECT vincr FROM target) AS target_increment ,sum(app_units) AS units ,CASE WHEN sum(app_units) = 0 THEN 0 ELSE (SELECT vincr FROM target)/sum(app_units) END AS factor FROM basemix ) ,volume_only AS ( SELECT o.id ,o.logid ,o."Trans. Date" ,o."Post Date" ,o."Description" ,round(o."Amount" * vscale.factor,2) AS "Amount" ,o."Category" ,o."Party" ,o."Reason" ,round(o.app_units * vscale.factor,5) AS app_units ,'app_forecast_name' AS app_version ,'scale volume' AS app_iter ,(SELECT id FROM ilog) AS app_logid 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("Amount") AS value ,CASE WHEN (SELECT sum("Amount") 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("Amount") 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("Amount") FROM volume))/(SELECT sum("Amount") FROM volume) END END factor ,CASE WHEN (SELECT sum("Amount") FROM volume) = 0 THEN CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum("Amount") 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("Amount") FROM volume))/(SELECT sum(app_units) FROM volume) ELSE 0 END ELSE 0 END mod_price FROM volume ) ,pricing AS ( SELECT o.id ,o.logid ,o."Trans. Date" ,o."Post Date" ,o."Description" ,round((CASE WHEN pscale.factor = 0 THEN o.app_units * pscale.mod_price ELSE o."Amount" * pscale.factor END)::numeric,2) AS "Amount" ,o."Category" ,o."Party" ,o."Reason" ,0::numeric AS app_units ,'app_forecast_name' AS app_version ,'scale price' AS app_iter ,(SELECT id FROM ilog) AS app_logid FROM volume o CROSS JOIN pscale WHERE pscale.factor <> 0 or pscale.mod_price <> 0 ) ,ins AS ( INSERT INTO fc.dcard SELECT * FROM volume_only UNION ALL SELECT * FROM pricing RETURNING * ) SELECT count(*) num_rows FROM ins