handle price change on no base sales

This commit is contained in:
fleetside72 2019-04-03 03:00:38 -04:00
parent 8cb6b843ba
commit 833ec511c1
2 changed files with 82 additions and 9 deletions

View File

@ -194,7 +194,21 @@ SELECT
SELECT SELECT
(SELECT incr::numeric FROM target) incr (SELECT incr::numeric FROM target) incr
,(SELECT sum(fb_val_loc * r_rate) FROM basemix) base ,(SELECT sum(fb_val_loc * r_rate) FROM basemix) base
,(SELECT incr::numeric FROM target)/(SELECT sum(fb_val_loc *r_rate) FROM basemix) factor ,CASE WHEN (SELECT sum(fb_val_loc * r_rate) FROM basemix) = 0 THEN
0
ELSE
((SELECT incr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM basemix))/(SELECT sum(fb_val_loc * r_rate) FROM basemix)
END factor
,CASE WHEN (SELECT sum(fb_val_loc * r_rate) FROM basemix) = 0 THEN
CASE WHEN ((SELECT incr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM basemix)) <> 0 THEN
--if the base value is -0- but the target value hasn't been achieved, derive a price to apply
((SELECT incr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM basemix))/(SELECT sum(fb_qty) FROM basemix)
ELSE
0
END
ELSE
0
END mod_price
) )
,final AS ( ,final AS (
SELECT SELECT
@ -301,14 +315,16 @@ SELECT
,b.mod_chansub ,b.mod_chansub
,b.quota_rep_descr ,b.quota_rep_descr
,b.director_descr ,b.director_descr
,(b.fb_val_loc*s.factor)::numeric value_loc ,(CASE WHEN s.factor = 0 THEN b.fb_qty * s.mod_price/b.r_rate ELSE b.fb_val_loc*s.factor END)::numeric value_loc
,(b.fb_val_loc*s.factor*r_rate)::numeric value_usd ,(CASE WHEN s.factor = 0 THEN b.fb_qty * s.mod_price ELSE b.fb_val_loc*s.factor END)::numeric value_usd
,0 cost_loc ,0 cost_loc
,0 cost_usd ,0 cost_usd
,0 units ,0 units
FROM FROM
basemix b basemix b
CROSS JOIN scale s CROSS JOIN scale s
WHERE
s.factor <> 0 or s.mod_price <> 0
) )
--select sum(value_usd), count(*) from final --select sum(value_usd), count(*) from final
, ins AS ( , ins AS (

View File

@ -1,5 +1,41 @@
WITH WITH
target AS (select target_vol vincr, target_prc pincr) target AS (select target_vol vincr, target_prc pincr)
,testv AS (
SELECT
sum(fb_qty) tot
,sum(fb_qty) FILTER (WHERE iter = 'copy') base
,sum(fb_qty) FILTER (WHERE iterdef->>'type' = 'new basket') newpart
FROM
rlarp.osm_fcpool
WHERE
-----------------scenario----------------------------
where_clause
-----------------additional params-------------------
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
AND adj_orderdate <= adj_shipdate
)
,flagv AS (
SELECT
tot
,base
,newpart
,CASE WHEN tot = 0 THEN
CASE WHEN base = 0 THEN
CASE WHEN newpart = 0 THEN
'unclean data. tested -> does not exist'
ELSE
'scale new part'
END
ELSE
'scale copy'
END
ELSE
'scale all'
END flag
FROM
testv
)
,basemix AS ( ,basemix AS (
SELECT SELECT
plnt ---master data plnt ---master data
@ -76,8 +112,8 @@ target AS (select target_vol vincr, target_prc pincr)
,adj_orderdate --history ,adj_orderdate --history
,adj_requestdate --history ,adj_requestdate --history
,adj_shipdate --history ,adj_shipdate --history
,'b20' "version" --calculated ,null::text "version" --calculated
,'adjustment' iter --calculated ,null::text iter --calculated
---------------ui columns------------------------- ---------------ui columns-------------------------
,order_season ,order_season
,order_month ,order_month
@ -114,6 +150,11 @@ target AS (select target_vol vincr, target_prc pincr)
-----------------scenario---------------------------- -----------------scenario----------------------------
where_clause where_clause
-----------------additional params------------------- -----------------additional params-------------------
AND CASE (SELECT flag FROM flagv)
WHEN 'scale all' THEN true
WHEN 'scale copy' THEN iter = 'copy'
WHEN 'scale new part' THEN iterdef->>'type' = 'new basket'
END
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
AND adj_orderdate <= adj_shipdate AND adj_orderdate <= adj_shipdate
GROUP BY GROUP BY
@ -315,7 +356,21 @@ target AS (select target_vol vincr, target_prc pincr)
SELECT SELECT
(SELECT pincr::numeric FROM target) incr (SELECT pincr::numeric FROM target) incr
,(SELECT sum(fb_val_loc * r_rate) FROM volume) base ,(SELECT sum(fb_val_loc * r_rate) FROM volume) base
,((SELECT pincr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM volume))/(SELECT sum(fb_val_loc * r_rate) FROM volume) factor ,CASE WHEN (SELECT sum(fb_val_loc * r_rate) FROM volume) = 0 THEN
0
ELSE
((SELECT pincr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM volume))/(SELECT sum(fb_val_loc * r_rate) FROM volume)
END factor
,CASE WHEN (SELECT sum(fb_val_loc * r_rate) FROM volume) = 0 THEN
CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) 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(fb_val_loc * r_rate) FROM volume))/(SELECT sum(fb_qty) FROM volume)
ELSE
0
END
ELSE
0
END mod_price
) )
--select * from pscale --select * from pscale
,pricing AS ( ,pricing AS (
@ -423,14 +478,16 @@ target AS (select target_vol vincr, target_prc pincr)
,b.mod_chansub ,b.mod_chansub
,b.quota_rep_descr ,b.quota_rep_descr
,b.director_descr ,b.director_descr
,(b.fb_val_loc*s.factor)::numeric value_loc ,(CASE WHEN s.factor = 0 THEN b.fb_qty * s.mod_price/b.r_rate ELSE b.fb_val_loc*s.factor END)::numeric value_loc
,(b.fb_val_loc*s.factor*r_rate)::numeric value_usd ,(CASE WHEN s.factor = 0 THEN b.fb_qty * s.mod_price ELSE b.fb_val_loc*s.factor END)::numeric value_usd
,0 cost_loc ,0 cost_loc
,0 cost_usd ,0 cost_usd
,0 units ,0 units
FROM FROM
volume b volume b
CROSS JOIN pscale s CROSS JOIN pscale s
WHERE
s.factor <> 0 or s.mod_price <> 0
) )
--select sum(value_usd), sum(fb_qty) from pricing --select sum(value_usd), sum(fb_qty) from pricing
, ins AS ( , ins AS (