Lots of cleanup here too, removing large swaths of code that are no longer needed. Many improvements the Excel workbook, which is kept in Teams, not git. These changes may or may not have had accompanying VBA changes.
300 lines
8.5 KiB
SQL
300 lines
8.5 KiB
SQL
WITH
|
|
target AS (select incr_qty qincr)
|
|
,testv AS (
|
|
SELECT
|
|
sum(units) tot
|
|
,sum(units) FILTER (WHERE iter IN ('copy','plan','diff')) base
|
|
,sum(units) FILTER (WHERE module = 'new basket') newpart
|
|
FROM
|
|
rlarp.osm_pool p
|
|
WHERE
|
|
-----------------scenario----------------------------
|
|
where_clause
|
|
-----------------additional params-------------------
|
|
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
|
|
AND order_date <= ship_date
|
|
)
|
|
,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
|
|
fspr
|
|
,plnt ---master data
|
|
,promo --history date mix
|
|
,terms
|
|
,bill_cust_descr --history cust mix
|
|
,ship_cust_descr --history cust mix
|
|
,dsm
|
|
,quota_rep_descr --master data
|
|
,director
|
|
,billto_group --master data
|
|
,shipto_group
|
|
,chan --master data
|
|
,chansub
|
|
,chan_retail
|
|
,part
|
|
,part_descr
|
|
,part_group
|
|
,branding
|
|
,majg_descr
|
|
,ming_descr
|
|
,majs_descr
|
|
,mins_descr
|
|
,segm
|
|
,substance
|
|
,fs_line --master data
|
|
,r_currency --history cust mix
|
|
,r_rate --master data
|
|
,c_currency --master data
|
|
,c_rate --master data
|
|
,sum(coalesce(units,0)) units --history value
|
|
,sum(coalesce(value_loc,0)) value_loc --history value
|
|
,sum(coalesce(value_usd,0)) value_usd --0
|
|
,sum(coalesce(cost_loc,0)) cost_loc --history part mix
|
|
,sum(coalesce(cost_usd,0)) cost_usd
|
|
,sum(coalesce(pounds,0)) pounds
|
|
,calc_status --0
|
|
,flag --0
|
|
,order_date --history date mix
|
|
,order_month
|
|
,order_season
|
|
,request_date --history date mix
|
|
,request_month
|
|
,request_season
|
|
,ship_date --history date mix
|
|
,ship_month
|
|
,ship_season
|
|
FROM
|
|
rlarp.osm_pool
|
|
WHERE
|
|
-----------------scenario----------------------------
|
|
where_clause
|
|
-----------------additional params-------------------
|
|
AND CASE (SELECT flag FROM flagv)
|
|
WHEN 'scale all' THEN true
|
|
WHEN 'scale copy' THEN iter IN ('copy','plan','diff')
|
|
WHEN 'scale new part' THEN module = 'new basket'
|
|
END
|
|
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
|
|
AND order_date <= ship_date
|
|
GROUP BY
|
|
fspr
|
|
,plnt ---master data
|
|
,promo --history date mix
|
|
,terms
|
|
,bill_cust_descr --history cust mix
|
|
,ship_cust_descr --history cust mix
|
|
,dsm
|
|
,quota_rep_descr --master data
|
|
,director
|
|
,billto_group --master data
|
|
,shipto_group
|
|
,chan --master data
|
|
,chansub
|
|
,chan_retail
|
|
,part
|
|
,part_descr
|
|
,part_group
|
|
,branding
|
|
,majg_descr
|
|
,ming_descr
|
|
,majs_descr
|
|
,mins_descr
|
|
,segm
|
|
,substance
|
|
,fs_line --master data
|
|
,r_currency --history cust mix
|
|
,r_rate --master data
|
|
,c_currency --master data
|
|
,c_rate --master data
|
|
,calc_status --0
|
|
,flag --0
|
|
,order_date --history date mix
|
|
,order_month
|
|
,order_season
|
|
,request_date --history date mix
|
|
,request_month
|
|
,request_season
|
|
,ship_date --history date mix
|
|
,ship_month
|
|
,ship_season
|
|
)
|
|
--SELECT * FROM basemix
|
|
,scale AS (
|
|
SELECT
|
|
(SELECT qincr::numeric FROM target) incr
|
|
,(SELECT sum(value_loc *r_rate) FROM basemix) base
|
|
,(SELECT qincr FROM target)/(SELECT SUM(units) FROM basemix) factor
|
|
)
|
|
--select * from scale
|
|
,log AS (
|
|
INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING *
|
|
)
|
|
,final AS (
|
|
SELECT
|
|
fspr
|
|
,plnt ---master data
|
|
,promo --history date mix
|
|
,terms
|
|
,bill_cust_descr --history cust mix
|
|
,ship_cust_descr --history cust mix
|
|
,dsm
|
|
,quota_rep_descr --master data
|
|
,director
|
|
,billto_group --master data
|
|
,shipto_group
|
|
,chan --master data
|
|
,chansub
|
|
,chan_retail
|
|
,part
|
|
,part_descr
|
|
,part_group
|
|
,branding
|
|
,majg_descr
|
|
,ming_descr
|
|
,majs_descr
|
|
,mins_descr
|
|
,segm
|
|
,substance
|
|
,fs_line --master data
|
|
,r_currency --history cust mix
|
|
,r_rate --master data
|
|
,c_currency --master data
|
|
,c_rate --master data
|
|
,round(units*s.factor ,2) units
|
|
,round(value_loc*s.factor,2) value_loc
|
|
,round(value_usd*s.factor,2) value_usd
|
|
,round(cost_loc*s.factor ,2) cost_loc
|
|
,round(cost_usd*s.factor ,2) cost_usd
|
|
,calc_status --0
|
|
,flag --0
|
|
,order_date --history date mix
|
|
,order_month
|
|
,order_season
|
|
,request_date --history date mix
|
|
,request_month
|
|
,request_season
|
|
,ship_date --history date mix
|
|
,ship_month
|
|
,ship_season
|
|
,'replace_version' "version"
|
|
,'replace_source'||' volume' iter
|
|
,log.id
|
|
,COALESCE(log.doc->>'tag','') "tag"
|
|
,log.doc->>'message' "comment"
|
|
,log.doc->>'type' module
|
|
,round(pounds*s.factor, 2) pounds
|
|
FROM
|
|
basemix b
|
|
CROSS JOIN scale s
|
|
CROSS JOIN log
|
|
)
|
|
--select sum(value_usd), count(*) from final
|
|
, ins AS (
|
|
INSERT INTO rlarp.osm_pool SELECT * FROM final RETURNING *
|
|
)
|
|
,insagg AS (
|
|
SELECT
|
|
---------customer info-----------------
|
|
bill_cust_descr
|
|
,billto_group
|
|
,ship_cust_descr
|
|
,shipto_group
|
|
,quota_rep_descr
|
|
,director
|
|
,segm
|
|
,substance
|
|
,chan
|
|
,chansub
|
|
---------product info------------------
|
|
,majg_descr
|
|
,ming_descr
|
|
,majs_descr
|
|
,mins_descr
|
|
--,brand
|
|
--,part_family
|
|
,part_group
|
|
,branding
|
|
--,color
|
|
,part_descr
|
|
---------dates-------------------------
|
|
,order_season
|
|
,order_month
|
|
,ship_season
|
|
,ship_month
|
|
,request_season
|
|
,request_month
|
|
,promo
|
|
,version
|
|
,iter
|
|
,logid
|
|
,tag
|
|
,comment
|
|
--------values-------------------------
|
|
,sum(value_loc) value_loc
|
|
,sum(value_usd) value_usd
|
|
,sum(cost_loc) cost_loc
|
|
,sum(cost_usd) cost_usd
|
|
,sum(units) units
|
|
,sum(pounds) pounds
|
|
FROM
|
|
ins
|
|
GROUP BY
|
|
---------customer info-----------------
|
|
bill_cust_descr
|
|
,billto_group
|
|
,ship_cust_descr
|
|
,shipto_group
|
|
,quota_rep_descr
|
|
,director
|
|
,segm
|
|
,substance
|
|
,chan
|
|
,chansub
|
|
---------product info------------------
|
|
,majg_descr
|
|
,ming_descr
|
|
,majs_descr
|
|
,mins_descr
|
|
--,brand
|
|
--,part_family
|
|
,part_group
|
|
,branding
|
|
--,color
|
|
,part_descr
|
|
---------dates-------------------------
|
|
,order_season
|
|
,order_month
|
|
,ship_season
|
|
,ship_month
|
|
,request_season
|
|
,request_month
|
|
,promo
|
|
,version
|
|
,iter
|
|
,logid
|
|
,tag
|
|
,comment
|
|
)
|
|
SELECT json_agg(row_to_json(insagg)) x from insagg
|