Merge branch 'bugfix/div0'
This commit is contained in:
		
						commit
						8cf8490887
					
				
							
								
								
									
										4
									
								
								index.js
									
									
									
									
									
								
							
							
						
						
									
										4
									
								
								index.js
									
									
									
									
									
								
							| @ -196,7 +196,7 @@ server.post('/addmonth_v', bodyParser.json(), function (req, res) { | ||||
|         console.log(req.body); | ||||
|         //console.log(args);
 | ||||
|         sql = sql.replace(new RegExp("scenario = target_scenario",'g'),w); | ||||
|         sql = sql.replace(new RegExp("target_increment",'g'),req.body.amount); | ||||
|         sql = sql.replace(new RegExp("target_increment",'g'),req.body.qty); | ||||
|         sql = sql.replace(new RegExp("target_month",'g'),req.body.month); | ||||
|         sql = sql.replace(new RegExp("replace_version",'g'),req.body.scenario.version); | ||||
|         sql = sql.replace(new RegExp("replace_source",'g'),req.body.source); | ||||
| @ -272,7 +272,7 @@ server.post('/scale_v', bodyParser.json(), function (req, res) { | ||||
|         console.log(req.body); | ||||
|         //console.log(args);
 | ||||
|         sql = sql.replace(new RegExp("where_clause",'g'),w); | ||||
|         sql = sql.replace(new RegExp("target_increment",'g'),req.body.amount); | ||||
|         sql = sql.replace(new RegExp("incr_qty",'g'),req.body.qty); | ||||
|         sql = sql.replace(new RegExp("replace_version",'g'),req.body.scenario.version); | ||||
|         sql = sql.replace(new RegExp("replace_source",'g'),req.body.source); | ||||
|         sql = sql.replace(new RegExp("replace_iterdef",'g'),JSON.stringify(req.body)); | ||||
|  | ||||
| @ -7,6 +7,58 @@ target_month | ||||
| 
 | ||||
| WITH  | ||||
| target AS (select target_increment incr) | ||||
| ,testv AS ( | ||||
|     SELECT | ||||
|         sum(fb_qty) tot | ||||
|         ,sum(fb_qty) FILTER (WHERE iter = 'copy') base | ||||
|         ,COALESCE(sum(fb_qty) FILTER (WHERE iterdef->>'type' = 'new basket'),0) newpart | ||||
|         ,sum(fb_val_loc *r_rate) totsales | ||||
|         ,sum(fb_val_loc *r_rate) FILTER (WHERE iter = 'copy') basesales | ||||
|         ,COALESCE(sum(fb_val_loc *r_rate) FILTER (WHERE iterdef->>'type' = 'new basket'),0) newpartsales | ||||
|     FROM | ||||
|         rlarp.osm_fcpool | ||||
|     WHERE | ||||
|         -----------------scenario---------------------------- | ||||
|         scenario = target_scenario | ||||
|         -----------------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 | ||||
|         ,CASE WHEN totsales = 0 THEN | ||||
|             CASE WHEN basesales = 0 THEN | ||||
|                 CASE WHEN newpartsales = 0 THEN | ||||
|                     'no price' | ||||
|                 ELSE | ||||
|                     'scale new part' | ||||
|                 END | ||||
|             ELSE | ||||
|                 'scale copy' | ||||
|             END | ||||
|         ELSE | ||||
|             'scale all' | ||||
|         END flagsales | ||||
|     FROM | ||||
|         testv | ||||
| ) | ||||
| ,GLD AS ( | ||||
| 	SELECT  | ||||
| 		N1COMP COMP | ||||
| @ -56,7 +108,7 @@ target AS (select target_increment incr) | ||||
|         ,orderdate | ||||
|         ,requestdate | ||||
|         ,shipdate | ||||
|         ,sum(value_usd) value_usd | ||||
|         ,sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) value_usd | ||||
|     FROM | ||||
|         rlarp.osm_fcpool | ||||
|         LEFT OUTER JOIN mseq ON | ||||
| @ -66,7 +118,11 @@ target AS (select target_increment incr) | ||||
|         scenario = target_scenario | ||||
|         -----------------additional params------------------- | ||||
|         AND version = 'b20' | ||||
|         AND iter = 'copy' | ||||
|         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 adj_orderdate <= adj_shipdate | ||||
|     GROUP BY | ||||
| @ -78,7 +134,7 @@ target AS (select target_increment incr) | ||||
|         ,requestdate | ||||
|         ,shipdate | ||||
|     HAVING | ||||
|         sum(value_usd) <> 0 | ||||
|         sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) <> 0 | ||||
| ) | ||||
| --select * from alldates | ||||
| ,dom AS ( | ||||
| @ -249,6 +305,11 @@ SELECT | ||||
|         -----------------scenario---------------------------- | ||||
|         scenario = target_scenario | ||||
|         -----------------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 adj_orderdate <= adj_shipdate | ||||
|     GROUP BY | ||||
| @ -315,8 +376,8 @@ SELECT | ||||
| ,scale AS ( | ||||
|     SELECT | ||||
|         (SELECT incr::numeric FROM target) incr | ||||
|         ,(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 | ||||
|         ,(SELECT sum(fb_qty) FROM basemix) base | ||||
|         ,(SELECT incr::numeric FROM target)/(SELECT sum(fb_qty) FROM basemix) factor | ||||
| ) | ||||
| ,final AS ( | ||||
| SELECT | ||||
|  | ||||
| @ -3,6 +3,58 @@ WITH | ||||
| the volume must be expressed in terms of units, since that is what it will be scaling | ||||
| */ | ||||
| target AS (select target_volume vincr, target_price pincr) | ||||
| ,testv AS ( | ||||
|     SELECT | ||||
|         sum(fb_qty) tot | ||||
|         ,sum(fb_qty) FILTER (WHERE iter = 'copy') base | ||||
|         ,COALESCE(sum(fb_qty) FILTER (WHERE iterdef->>'type' = 'new basket'),0) newpart | ||||
|         ,sum(fb_val_loc *r_rate) totsales | ||||
|         ,sum(fb_val_loc *r_rate) FILTER (WHERE iter = 'copy') basesales | ||||
|         ,COALESCE(sum(fb_val_loc *r_rate) FILTER (WHERE iterdef->>'type' = 'new basket'),0) newpartsales | ||||
|     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 | ||||
|         ,CASE WHEN totsales = 0 THEN | ||||
|             CASE WHEN basesales = 0 THEN | ||||
|                 CASE WHEN newpartsales = 0 THEN | ||||
|                     'no price' | ||||
|                 ELSE | ||||
|                     'scale new part' | ||||
|                 END | ||||
|             ELSE | ||||
|                 'scale copy' | ||||
|             END | ||||
|         ELSE | ||||
|             'scale all' | ||||
|         END flagsales | ||||
|     FROM | ||||
|         testv | ||||
| ) | ||||
| ,GLD AS ( | ||||
| 	SELECT  | ||||
| 		N1COMP COMP | ||||
| @ -52,7 +104,7 @@ target AS (select target_volume vincr, target_price pincr) | ||||
|         ,orderdate | ||||
|         ,requestdate | ||||
|         ,shipdate | ||||
|         ,sum(value_usd) value_usd | ||||
|         ,sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) value_usd | ||||
|     FROM | ||||
|         rlarp.osm_fcpool | ||||
|         LEFT OUTER JOIN mseq ON | ||||
| @ -61,6 +113,11 @@ target AS (select target_volume vincr, target_price pincr) | ||||
|         -----------------scenario---------------------------- | ||||
|         where_clause | ||||
|         -----------------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 adj_orderdate <= adj_shipdate | ||||
|     GROUP BY | ||||
| @ -72,7 +129,7 @@ target AS (select target_volume vincr, target_price pincr) | ||||
|         ,requestdate | ||||
|         ,shipdate | ||||
|     HAVING | ||||
|         sum(value_usd) <> 0 | ||||
|         sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) <> 0 | ||||
| ) | ||||
| --select * from alldates | ||||
| ,dom AS ( | ||||
| @ -245,6 +302,11 @@ SELECT | ||||
|         -----------------scenario---------------------------- | ||||
|         where_clause | ||||
|         -----------------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 adj_orderdate <= adj_shipdate | ||||
|     GROUP BY | ||||
| @ -445,8 +507,21 @@ WHERE | ||||
|     SELECT | ||||
|         (SELECT pincr::numeric FROM target) incr | ||||
|         ,(SELECT sum(fb_val_loc * r_rate) FROM volume) base | ||||
|         --(target_sales - current_state)/current state = adjustment factor | ||||
|         ,((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 | ||||
| ) | ||||
| ,price AS ( | ||||
| SELECT | ||||
| @ -552,14 +627,16 @@ SELECT | ||||
|     ,b.mod_chansub | ||||
|     ,b.quota_rep_descr | ||||
|     ,b.director_descr | ||||
|     ,b.fb_val_loc*p.factor value_loc | ||||
|     ,b.fb_val_loc*p.factor*r_rate value_usd | ||||
|     ,(CASE WHEN p.factor = 0 THEN b.fb_qty * p.mod_price/b.r_rate ELSE b.fb_val_loc*p.factor END)::numeric value_loc | ||||
|     ,(CASE WHEN p.factor = 0 THEN b.fb_qty * p.mod_price ELSE b.fb_val_loc*p.factor END)::numeric value_usd | ||||
|     ,0 cost_loc | ||||
|     ,0 cost_usd | ||||
|     ,0 units | ||||
| FROM | ||||
|     volume b | ||||
|     CROSS JOIN pscale p | ||||
|     WHERE | ||||
|         p.factor <> 0 or p.mod_price <> 0 | ||||
| ) | ||||
| , ins AS ( | ||||
|     INSERT INTO rlarp.osm_fcpool (SELECT * FROM price UNION ALL SELECT * FROM volume) RETURNING * | ||||
|  | ||||
| @ -193,8 +193,22 @@ SELECT | ||||
| ,scale AS ( | ||||
|     SELECT | ||||
|         (SELECT incr::numeric FROM target) incr | ||||
|         ,(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 | ||||
|         ,(SELECT sum(fb_val_loc * r_rate) FROM basemix) base | ||||
|         ,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 ( | ||||
| SELECT | ||||
| @ -301,14 +315,16 @@ SELECT | ||||
|     ,b.mod_chansub | ||||
|     ,b.quota_rep_descr | ||||
|     ,b.director_descr | ||||
|     ,(b.fb_val_loc*s.factor)::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/b.r_rate ELSE b.fb_val_loc*s.factor END)::numeric value_loc | ||||
|     ,(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_usd | ||||
|     ,0 units | ||||
| FROM | ||||
|     basemix b | ||||
|     CROSS JOIN scale s | ||||
| WHERE | ||||
|     s.factor <> 0 or s.mod_price <> 0 | ||||
| ) | ||||
| --select sum(value_usd), count(*) from final | ||||
| , ins AS ( | ||||
|  | ||||
| @ -1,5 +1,42 @@ | ||||
| WITH  | ||||
| target AS (select target_increment incr) | ||||
| target AS (select incr_qty qincr) | ||||
| ,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 | ||||
| ) | ||||
| --ever need receive a target of -0- qty but value <> 0? | ||||
| ,basemix AS ( | ||||
| SELECT | ||||
|         plnt          ---master data  | ||||
| @ -76,8 +113,8 @@ SELECT | ||||
|         ,adj_orderdate          --history  | ||||
|         ,adj_requestdate          --history  | ||||
|         ,adj_shipdate          --history  | ||||
|         ,'b20' "version"          --calculated  | ||||
|         ,'adjustment' iter          --calculated  | ||||
|         ,null::text "version"          --calculated  | ||||
|         ,null::text iter          --calculated  | ||||
|         ---------------ui columns------------------------- | ||||
|         ,order_season | ||||
|         ,order_month | ||||
| @ -114,6 +151,11 @@ SELECT | ||||
|         -----------------scenario---------------------------- | ||||
|         where_clause | ||||
|         -----------------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 adj_orderdate <= adj_shipdate | ||||
|     GROUP BY | ||||
| @ -190,12 +232,14 @@ SELECT | ||||
|         ,quota_rep_descr | ||||
|         ,director_descr | ||||
| ) | ||||
| --SELECT * FROM basemix | ||||
| ,scale AS ( | ||||
|     SELECT | ||||
|         (SELECT incr::numeric FROM target) incr | ||||
|         (SELECT qincr::numeric FROM target) incr | ||||
|         ,(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 | ||||
|         ,(SELECT qincr FROM target)/(SELECT SUM(fb_qty) FROM basemix) factor | ||||
| ) | ||||
| --select * from scale | ||||
| ,final AS ( | ||||
| SELECT | ||||
|     b.plnt          --master data  | ||||
|  | ||||
| @ -1,5 +1,41 @@ | ||||
| WITH  | ||||
| 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 ( | ||||
|     SELECT | ||||
|         plnt          ---master data  | ||||
| @ -76,8 +112,8 @@ target AS (select target_vol vincr, target_prc pincr) | ||||
|         ,adj_orderdate          --history  | ||||
|         ,adj_requestdate          --history  | ||||
|         ,adj_shipdate          --history  | ||||
|         ,'b20' "version"          --calculated  | ||||
|         ,'adjustment' iter          --calculated  | ||||
|         ,null::text "version"          --calculated  | ||||
|         ,null::text iter          --calculated  | ||||
|         ---------------ui columns------------------------- | ||||
|         ,order_season | ||||
|         ,order_month | ||||
| @ -114,6 +150,11 @@ target AS (select target_vol vincr, target_prc pincr) | ||||
|         -----------------scenario---------------------------- | ||||
|         where_clause | ||||
|         -----------------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 adj_orderdate <= adj_shipdate | ||||
|     GROUP BY | ||||
| @ -315,7 +356,21 @@ target AS (select target_vol vincr, target_prc pincr) | ||||
|     SELECT | ||||
|         (SELECT pincr::numeric FROM target) incr | ||||
|         ,(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 | ||||
| ,pricing AS ( | ||||
| @ -423,14 +478,16 @@ target AS (select target_vol vincr, target_prc pincr) | ||||
|         ,b.mod_chansub | ||||
|         ,b.quota_rep_descr | ||||
|         ,b.director_descr | ||||
|         ,(b.fb_val_loc*s.factor)::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/b.r_rate ELSE b.fb_val_loc*s.factor END)::numeric value_loc | ||||
|         ,(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_usd | ||||
|         ,0 units | ||||
|     FROM | ||||
|         volume b | ||||
|         CROSS JOIN pscale s | ||||
|     WHERE | ||||
|         s.factor <> 0 or s.mod_price <> 0 | ||||
| ) | ||||
| --select sum(value_usd), sum(fb_qty) from pricing | ||||
| , ins AS ( | ||||
|  | ||||
		Loading…
	
		Reference in New Issue
	
	Block a user