Compare commits
9 Commits
032736f0e9
...
d129e5d0f6
Author | SHA1 | Date | |
---|---|---|---|
d129e5d0f6 | |||
4f33136a15 | |||
1faa832c5b | |||
4c926b63e6 | |||
4560c82903 | |||
b4e592bbf1 | |||
e0d32cf4cf | |||
e376a9df2e | |||
b7eb94202c |
@ -110,7 +110,8 @@ SELECT
|
||||
ship_date,
|
||||
ship_season,
|
||||
version,
|
||||
iter
|
||||
iter,
|
||||
tag
|
||||
FROM
|
||||
rlarp.osm_pool;
|
||||
|
||||
@ -118,7 +119,8 @@ FROM
|
||||
UPDATE
|
||||
RLARP.OSMFS_DEV O
|
||||
SET
|
||||
COLC = M.COLC
|
||||
STYC = M.STLC
|
||||
,COLC = M.COLC
|
||||
,COLGRP = M.COLGRP
|
||||
,COLTIER = M.COLTIER
|
||||
,COLSTAT = M.COLSTAT
|
||||
|
362
offline/account_plug.sql
Normal file
362
offline/account_plug.sql
Normal file
@ -0,0 +1,362 @@
|
||||
BEGIN;
|
||||
|
||||
WITH
|
||||
targ AS (
|
||||
SELECT
|
||||
account
|
||||
,segment
|
||||
,targv::numeric targv
|
||||
,targm::numeric targm
|
||||
,targv::numeric - targm::numeric targc
|
||||
FROM (VALUES
|
||||
('THE HOME DEPOT','17000000','3074775','Retail'),
|
||||
('L&L NURSERY SUPPLY INC','2350000','1323646','Retail'),
|
||||
('WAL-MART','0','0','Retail'),
|
||||
('FRED MEYER','2000000','856002','Retail'),
|
||||
('AMAZON.COM','1640000','1030332','Retail'),
|
||||
('BFG SUPPLY','1500000','836573','Retail'),
|
||||
('MENARDS','1638401','608147','Retail'),
|
||||
('ARETT SALES','1241808','664301','Retail'),
|
||||
('VM INNOVATIONS-NE','1000000','550614','Retail'),
|
||||
('CANADIAN TIRE CORP LTD','680606','47642','Retail'),
|
||||
('CANADIAN TIRE CORP LTD','319394','160394','Sustainable'),
|
||||
('ALLIANCE INTERNATIONAL LLC','500000','206602','Retail'),
|
||||
('OCEAN STATE JOBBERS','300000','155878','Retail'),
|
||||
('GRIFFIN','258240','118623','Retail'),
|
||||
('DO IT BEST','297067','177889','Retail'),
|
||||
('BWI','249061','117374','Retail'),
|
||||
('BRADLEY CALDWELL INC','226211','134560','Retail'),
|
||||
('PHILLIPS PET FOOD & SUPPLIES','194414','113853','Retail'),
|
||||
('ACE HARDWARE','195043','128460','Retail'),
|
||||
('EDDIS WHOLESALE GDN SUPPLIES','156305','76972','Retail'),
|
||||
('GARD N WISE','154657','83291','Retail'),
|
||||
('FOSTERS INC','154278','84043','Retail'),
|
||||
('GARDEN CENTRE GROUP CO-OP','148400','79640','Retail'),
|
||||
('TRUE VALUE','125272','66837','Retail'),
|
||||
('RONA INC (PICK UP)ACE CANADA','125154','49123','Retail'),
|
||||
('HB DAVIS SEED CO','103990','60800','Retail'),
|
||||
('BOMGAARS SUPPLY INC. RETAIL','96550','55201','Retail'),
|
||||
('CANAC MARQUIS GRENIER','84336','26284','Retail'),
|
||||
('LOWES','82640','33445','Retail'),
|
||||
('JENSEN DISTRIBUTION','79189','47567','Retail'),
|
||||
('EARL MAY SEED','77321','45084','Retail'),
|
||||
('INTERMOUNTAIN FARMERS ASSN','71161','25896','Retail'),
|
||||
('PEAVEY INDUSTRIES LP RET','63755','38070','Retail'),
|
||||
('SRC CORPORATION','62610','34107','Retail'),
|
||||
('HORIZON DISTRIBUTION INC','52200','29953','Retail'),
|
||||
('HALIFAX SEED CO INC','47859','23365','Retail'),
|
||||
('JAVIC STEIN GARDEN CENTER RET','47332','29831','Retail'),
|
||||
('TERIS SUPPLY SERVICES','46454','21876','Retail'),
|
||||
('LITTLE MOUNTAIN GREENHOUSES','0','0','Retail'),
|
||||
('WYATT QUARLES','45961','19806','Retail'),
|
||||
('KROGER ACCOUNTING SERVICES','0','0','Retail'),
|
||||
('AURORA WHOLESALERS, LLC','39005','1950','Retail'),
|
||||
('CIMARRON LUMBER CO','41255','29321','Retail'),
|
||||
('SKH WHOLESALE DIST','39498','22002','Retail'),
|
||||
('GREENHOUSE MEGASTORE','38481','22165','Retail'),
|
||||
('MEYER SEED CO.OF BALTIMORE INC','36907','21255','Retail'),
|
||||
('GREEN ISLAND DISTRIBUTORS INC.','36335','16598','Retail'),
|
||||
('ALASKA GDN & PET SUPPLY RET','34416','17673','Retail'),
|
||||
('CY GROWERS SUPPLIES LTD','33516','17268','Retail'),
|
||||
('PL ROHRER & BRO INC RET','32682','18721','Retail'),
|
||||
('CISCO COMPANIES (THE)','31294','16958','Retail'),
|
||||
('EXACTA SALES','29985','16997','Retail'),
|
||||
('CARLIN HORTICULTURAL SUPP','29766','17926','Retail'),
|
||||
('LEON KOROL COMPANY','27634','-20540','Retail'),
|
||||
('FAMILY TREE NURSERY','26732','14253','Retail'),
|
||||
('GREENHOUSE & GARDEN SUPPLY INC','28432','16180','Retail'),
|
||||
('MIKES GARDEN CENTER','24804','8682','Retail'),
|
||||
('HORTMARK','24148','14260','Retail'),
|
||||
('FLORIDA HARDWARE COMPANY','22952','13416','Retail'),
|
||||
('EARL''S FARM & GARDEN INC','20856','11680','Retail'),
|
||||
('MIZE FARM & GARDEN SUPPLY','20317','11079','Retail'),
|
||||
('HUMMERT INTERNATIONAL','19214','10602','Retail'),
|
||||
('BAYERS GARDEN SHOP','18177','11247','Retail'),
|
||||
('FEDERATED CO-OPERATIVES LTD','16347','9370','Retail'),
|
||||
('VANDENBERG BULB CO INC','15895','8533','Retail'),
|
||||
('RS GROWERS SUPPLY','15676','8691','Retail'),
|
||||
('PLANTERS SEED & SPICE RET','15395','8520','Retail'),
|
||||
('UNITED GARDEN CENTER','15303','8117','Retail'),
|
||||
('NORTH 40 OUTFITTERS','13975','9093','Retail'),
|
||||
('ERVA TOOL & DIE CO','13102','10114','Retail'),
|
||||
('NITRO-PHOS FERTILIZERS','12772','7397','Retail'),
|
||||
('OTTEN BROS','12390','6556','Retail'),
|
||||
('GROSOUTH','12229','5783','Retail'),
|
||||
('WAYFAIR LLC','10894','6861','Retail'),
|
||||
('PRINCE CORPORATION','10627','6478','Retail'),
|
||||
('BLISH-MIZE CO','10502','6181','Retail'),
|
||||
('UNITED GARDEN CENTERS RET','10323','5880','Retail'),
|
||||
('KC SCHAEFER SUPPLY','10176','5658','Retail'),
|
||||
('LIFOAM INDUSTRIES LLC','9922','1437','Retail'),
|
||||
('CARL BREHOB & SON','9909','4862','Retail'),
|
||||
('GPF CORPORATION','8497','4907','Retail'),
|
||||
('APACHE SEEDS LTD','7524','4823','Retail'),
|
||||
('PRO GROWER SUPPLY','7160','4488','Retail'),
|
||||
('ALTON GREENHOUSES','6282','4571','Retail'),
|
||||
('VG SUPPLY CO INC','6170','3302','Retail'),
|
||||
('PATRICK MORIN','5550','4185','Retail'),
|
||||
('PROFESSIONAL GARDENER CO','5534','3780','Retail'),
|
||||
('PREMIUM HORTICULTURAL SUPPLY','5260','2953','Retail'),
|
||||
('SCHROTH WHOLESALE SUPPLY CO.','4886','2841','Retail'),
|
||||
('WALDO & ASSOCIATES','4848','2662','Retail'),
|
||||
('SERRES STE-ELIE','4554','2217','Retail'),
|
||||
('JEAN H HENLE INC RET','4390','2596','Retail'),
|
||||
('GOLDCREST DIST','4203','2652','Retail'),
|
||||
('KEN VAN WINGERDEN GREENHOUSES','3934','2721','Retail'),
|
||||
('PASTANCH LLC','3558','2300','Retail'),
|
||||
('TESSMAN SEED','3490','1837','Retail'),
|
||||
('GEMMELLS GARDEN CENTRE INC','3356','2459','Retail'),
|
||||
('BELLE INVESTMENTS INC','2969','1901','Retail'),
|
||||
('BLUE STAR WHOLESALE','2870','1321','Retail'),
|
||||
('GLEN ECHO NURSERIES INC','2856','1358','Retail'),
|
||||
('Distribution','2856','1000','Retail'),
|
||||
('EZ GRO GARDEN','2770','970','Retail'),
|
||||
('ENVIROGREENERY PLANTS LLC','2759','1546','Retail'),
|
||||
('GERTENS GREENHOUSE','2669','934','Retail'),
|
||||
('KROGER (KRG LLC)','2363','1074','Retail'),
|
||||
('CINNABAR VALLEY','1873','1210','Retail'),
|
||||
('EDWARDS GREENHOUSE INC','1842','1179','Retail'),
|
||||
('DIRECT DISTRIBUTORS INC','1732','1140','Retail'),
|
||||
('YODERS PRODUCE','1295','514','Retail'),
|
||||
('ABC NURSERY LANDSCAPEMAIN','556','305','Retail'),
|
||||
('DUNN SALES & MARKETING, INC.','385','197','Retail'),
|
||||
('GARDENERS SUPPLY CO','375','263','Retail'),
|
||||
('FARMERS COOP','355','135','Retail'),
|
||||
('CROP PROD SERVICES INC','351','199','Retail'),
|
||||
('ARNOLDS GREENHOUSES','309','249','Retail'),
|
||||
('GEORGE''S FLOWERS','287','132','Retail'),
|
||||
('HJS WHOLESALE LTD','162','117','Retail'),
|
||||
('HOLMBERG FARMS INC','101','72','Retail'),
|
||||
('KINNEY BONDED','93','49','Retail'),
|
||||
('IRRIGATION PLUS INC','35','21','Retail'),
|
||||
('GLENKIRK ASSOCIATES INC','0','0','Retail'),
|
||||
('MILITARY PRODUCE GROUP LLC','0','0','Retail'),
|
||||
('WONDER SOIL','0','0','Retail'),
|
||||
('CHUCK BECK','0','0','Retail'),
|
||||
('MENARDS INC STORE 3256 RET','0','0','Retail'),
|
||||
('GREENSTAR PLANT-MANCHESTER','0','0','Retail'),
|
||||
('MAIN LINE POTTERY','0','0','Retail'),
|
||||
('PSR SALES INC','0','0','Retail'),
|
||||
('CLEVELAND FLORAL PRODUCTS INC','0','0','Retail'),
|
||||
('RACHEL BOWMAN','0','0','Retail'),
|
||||
('ENG SVCS & PROD','0','0','Retail'),
|
||||
('RITCHIE FEED & SEED','0','0','Retail'),
|
||||
('PARK SEED (DBA JPPA)','0','0','Retail'),
|
||||
('ART KNAPP','0','0','Retail'),
|
||||
('VARIETY WHOLESALE (9001)','0','0','Retail'),
|
||||
('ROY SIEMENS','0','0','Retail'),
|
||||
('MARC DESROSIERS','0','0','Retail'),
|
||||
('JIM REGER','0','0','Retail'),
|
||||
('MARK WILKINSON','0','0','Retail'),
|
||||
('SAN MARCOS GROWERS','0','0','Retail'),
|
||||
('GRANBYS GREENHOUSE','0','0','Retail'),
|
||||
('GIANT TIGERE STORES LIMITED','0','0','Retail'),
|
||||
('INTEGRITY SALES & DISTRIBUTION','0','0','Retail'),
|
||||
('GLOECKNER & CO. INC.','0','0','Retail'),
|
||||
('DORAN MARABLE','0','0','Retail'),
|
||||
('SEVEN OAKS PLANT SHOP INC','0','0','Retail'),
|
||||
('BURPEE GARDEN PRODUCTS RET','0','0','Retail'),
|
||||
('SHERRILL INC','0','0','Retail'),
|
||||
('PARKWAY GARDENS','0','0','Retail'),
|
||||
('GS DISTRIBUTION','0','0','Retail'),
|
||||
('GALES GARDEN CENTER','0','0','Retail'),
|
||||
('DAVE BODO','0','0','Retail'),
|
||||
('FLOWERLAND GARDEN CTR OF CLEVE','0','0','Retail'),
|
||||
('STACK-A-POTS','0','0','Retail'),
|
||||
('BEAUTIFUL LAND PRODUCTS','0','0','Retail'),
|
||||
('STRADERS','0','0','Retail'),
|
||||
('WESTLAND GREENHOUSES','0','0','Retail'),
|
||||
('SUNNYSIDE GREENHOUSES LTD. RET','0','0','Retail'),
|
||||
('DM COLOR EXPRESS','0','0','Retail'),
|
||||
('TERIS SVSC D''''APPROVISIONNEMNT','0','0','Retail'),
|
||||
('YONAS GREENHOUSES','0','0','Retail'),
|
||||
('FLORALIES JOUVENCE','0','0','Retail'),
|
||||
('ALECIA LATINI','0','0','Retail'),
|
||||
('AL PAR PEAT CO','0','0','Retail'),
|
||||
('IVAN VANDERDEEN','0','0','Retail'),
|
||||
('TIDBURY CREEK FARMS','0','0','Retail'),
|
||||
('AGRO PRODUCTS LIMITED','0','0','Retail'),
|
||||
('ALDI','0','0','Retail'),
|
||||
('MISC ACCT - (US )','0','0','Retail'),
|
||||
('TIMBERS MARKETING LLC','0','0','Retail'),
|
||||
('ALLEN STERLING AND LOTHROP','0','0','Retail'),
|
||||
('TINA PETTIGREW','0','0','Retail'),
|
||||
('TONY LANDINO','0','0','Retail'),
|
||||
('TRICIA PRICE','0','0','Retail'),
|
||||
('PEAK DISTRIBUTION LLC','0','0','Retail'),
|
||||
('DILLON SEED & SUPPLY','0','0','Retail'),
|
||||
('MENARDS INC STORE 3510 RET','0','0','Retail'),
|
||||
('PLANT BEST','0','0','Retail'),
|
||||
('DENVER WHOLESALE FLORISTS CO','0','0','Retail'),
|
||||
('TSC STORES LIMITED','0','0','Retail'),
|
||||
('CENTRAL GARDEN & PET','0','0','Retail'),
|
||||
('ESERRO','0','0','Retail'),
|
||||
('AMA PLASTICS','0','0','Retail'),
|
||||
('LITTLE MOUNTAIN GREENHOUSES U','0','0','Retail'),
|
||||
('PATAPSCO VALLEY SALES','0','0','Retail'),
|
||||
('UNITED HARDWARE','0','0','Retail'),
|
||||
('COLOUR PARADISE GRHS LTD','0','0','Retail'),
|
||||
('GARDEN RIDGE CORP','0','0','Retail'),
|
||||
('VARIETY DISTRIBUTORS INC','0','0','Retail'),
|
||||
('BLUE WATER BALTIMORE','0','0','Retail'),
|
||||
('LEE VALLEY TOOLS','0','0','Retail')
|
||||
) x(account,targv,targm,segment)
|
||||
)
|
||||
,factor AS (
|
||||
SELECT
|
||||
account
|
||||
,segment
|
||||
,targv
|
||||
,targm
|
||||
,targc
|
||||
,sum(value_usd) value_usd
|
||||
,sum(units) units
|
||||
,sum(cost_usd) cost_usd
|
||||
,round(CASE WHEN sum(value_usd) = 0 THEN 0 ELSE targv::numeric/sum(value_usd) END,5) vfactor
|
||||
,round(CASE WHEN sum(cost_usd) = 0 THEN 0 ELSE targc::numeric/sum(cost_usd) END,5) cfactor
|
||||
FROM
|
||||
targ t
|
||||
LEFT OUTER JOIN rlarp.osm_pool o ON
|
||||
o.billto_group = t.account
|
||||
AND o.segm = t.segment
|
||||
AND o.order_season = 2022
|
||||
GROUP BY
|
||||
account
|
||||
,segment
|
||||
,targv
|
||||
,targm
|
||||
,targc
|
||||
)
|
||||
--SELECT * FROM agg_curr
|
||||
----------------create a log entry--------------------
|
||||
,log AS (
|
||||
INSERT INTO
|
||||
rlarp.osm_log(doc)
|
||||
SELECT
|
||||
$${
|
||||
"message":"force accounts to match target total value and margin",
|
||||
"tag":"retail plug",
|
||||
"type":"build"
|
||||
}$$::jsonb doc
|
||||
RETURNING *
|
||||
)
|
||||
-------build adjustment rows collapsed for all iterations----------
|
||||
,dv AS (
|
||||
SELECT
|
||||
o.fspr
|
||||
,o.plnt ---master data
|
||||
,o.promo --history date mix
|
||||
,o.terms
|
||||
,o.bill_cust_descr --history cust mix
|
||||
,o.ship_cust_descr --history cust mix
|
||||
,o.dsm
|
||||
,o.quota_rep_descr --master data
|
||||
,o.director
|
||||
,o.billto_group --master data
|
||||
,o.shipto_group
|
||||
,o.chan --master data
|
||||
,o.chansub
|
||||
,o.chan_retail
|
||||
,o.part
|
||||
,o.part_descr
|
||||
,o.part_group
|
||||
,o.branding
|
||||
,o.majg_descr
|
||||
,o.ming_descr
|
||||
,o.majs_descr
|
||||
,o.mins_descr
|
||||
,o.segm
|
||||
,o.substance
|
||||
,o.fs_line --master data
|
||||
,o.r_currency --history cust mix
|
||||
,o.r_rate --master data
|
||||
,o.c_currency --master data
|
||||
,o.c_rate --master data
|
||||
,round(sum(o.units*s.cfactor - o.units ),2) units
|
||||
,round(sum(o.value_loc*s.vfactor - o.value_loc ),2) value_loc
|
||||
,round(sum(o.value_usd*s.vfactor - o.value_usd ),2) value_usd
|
||||
,round(sum(o.cost_loc*s.cfactor - o.cost_loc ),2) cost_loc
|
||||
,round(sum(o.cost_usd*s.cfactor - o.cost_usd ),2) cost_usd
|
||||
,o.calc_status --0
|
||||
,o.flag --0
|
||||
,o.order_date --history date mix
|
||||
,o.order_month
|
||||
,o.order_season
|
||||
,o.request_date --history date mix
|
||||
,o.request_month
|
||||
,o.request_season
|
||||
,o.ship_date --history date mix
|
||||
,o.ship_month
|
||||
,o.ship_season
|
||||
,'b22' aS version
|
||||
,'upload volume' iter
|
||||
,log.id
|
||||
,coalescE(log.doc->>'tag','') AS "tag"
|
||||
,log.doc->>'message' AS "comment"
|
||||
,log.doc->>'type' module
|
||||
FROM
|
||||
rlarp.osm_pool o
|
||||
INNER JOIN factor s ON
|
||||
s.account = o.billto_group
|
||||
CROSS JOIN log
|
||||
WHERE
|
||||
o.order_season = 2022
|
||||
AND o.segm = s.segment
|
||||
GROUP BY
|
||||
o.fspr
|
||||
,o.plnt ---master data
|
||||
,o.promo --history date mix
|
||||
,o.terms
|
||||
,o.bill_cust_descr --history cust mix
|
||||
,o.ship_cust_descr --history cust mix
|
||||
,o.dsm
|
||||
,o.quota_rep_descr --master data
|
||||
,o.director
|
||||
,o.billto_group --master data
|
||||
,o.shipto_group
|
||||
,o.chan --master data
|
||||
,o.chansub
|
||||
,o.chan_retail
|
||||
,o.part
|
||||
,o.part_descr
|
||||
,o.part_group
|
||||
,o.branding
|
||||
,o.majg_descr
|
||||
,o.ming_descr
|
||||
,o.majs_descr
|
||||
,o.mins_descr
|
||||
,o.segm
|
||||
,o.substance
|
||||
,o.fs_line --master data
|
||||
,o.r_currency --history cust mix
|
||||
,o.r_rate --master data
|
||||
,o.c_currency --master data
|
||||
,o.c_rate --master data
|
||||
,o.calc_status --0
|
||||
,o.flag --0
|
||||
,o.order_date --history date mix
|
||||
,o.order_month
|
||||
,o.order_season
|
||||
,o.request_date --history date mix
|
||||
,o.request_month
|
||||
,o.request_season
|
||||
,o.ship_date --history date mix
|
||||
,o.ship_month
|
||||
,o.ship_season
|
||||
,log.id
|
||||
,coalescE(log.doc->>'tag','')
|
||||
,log.doc->>'message'
|
||||
,log.doc->>'type'
|
||||
)
|
||||
INSERT INTO rlarp.osm_pool SELECT * FROM dv;
|
||||
--SELECT
|
||||
-- billto_group
|
||||
-- ,sum(value_usd) val
|
||||
-- ,sum(cost_usd) AS cost
|
||||
-- ,sum(units) units
|
||||
--FROM
|
||||
-- dv
|
||||
--GROUP BY
|
||||
-- billto_group
|
||||
|
||||
COMMIT;
|
@ -1,4 +1,4 @@
|
||||
--BEGIN;
|
||||
BEGIN;
|
||||
|
||||
WITH
|
||||
------------------goal price increases---------------------
|
||||
@ -77,6 +77,49 @@ incr AS (
|
||||
('C','P','COLOR PRINTED','Color','P')
|
||||
) x(colgrp, brand, dataseg, tcol, tbrand)
|
||||
)
|
||||
---customer dba assigned price levels---------
|
||||
,dbap AS (
|
||||
SELECT
|
||||
dba
|
||||
,jsonb_agg(DISTINCT plevel) plev
|
||||
,jsonb_agg(DISTINCT plcd) plist
|
||||
FROM
|
||||
rlarp.cust c
|
||||
INNER JOIN rlarp.sachdef sd ON
|
||||
sd.plev = c.plevel
|
||||
AND '2020-05-31' between sd.fdate AND sd.tdate
|
||||
WHERE
|
||||
pricing <> ''
|
||||
AND dba <> ''
|
||||
GROUP BY
|
||||
dba
|
||||
)
|
||||
----customer dba price list pricing------
|
||||
,plist AS (
|
||||
SELECT
|
||||
dbap.dba
|
||||
,dbap.plev
|
||||
,dbap.plist
|
||||
,jcplcd
|
||||
,jcpart
|
||||
,jcunit
|
||||
--,jcvoll
|
||||
-----just use the lowest volume price for the part-----
|
||||
,min(jcpric) jcpric
|
||||
FROM
|
||||
dbap
|
||||
INNER JOIN lgdat.iprcc cc ON
|
||||
dbap.plist ? cc.jcplcd
|
||||
WHERE
|
||||
jcunit = 'M'
|
||||
GROUP BY
|
||||
dbap.dba
|
||||
,dbap.plev
|
||||
,dbap.plist
|
||||
,jcplcd
|
||||
,jcpart
|
||||
,jcunit
|
||||
)
|
||||
------------carve out pricing baseline data--------------------
|
||||
,p AS (
|
||||
SELECT
|
||||
@ -138,7 +181,7 @@ incr AS (
|
||||
,o.shipgrp
|
||||
,o.odate DESC
|
||||
)
|
||||
--SELECT * FROM p WHERE account ~ 'AMERICAN HORT' and product = 'AZA06000.CBXX' and chgrp = 'W' order by rn ASC
|
||||
--SELECT * FROM p WHERE account ~ 'AMA P' and product = 'AMK06000.CBXX' order by rn ASC
|
||||
------------build global py asp------------------
|
||||
,baseline AS (
|
||||
SELECT
|
||||
@ -147,6 +190,7 @@ incr AS (
|
||||
,assc
|
||||
,chgrp
|
||||
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_gasp
|
||||
,round(sum(val_usd) FILTER (WHERE oseas = 2021)/sum(units) FILTER (WHERE oseas = 2021),5) cy_gasp
|
||||
FROM
|
||||
p
|
||||
GROUP BY
|
||||
@ -155,76 +199,7 @@ incr AS (
|
||||
,assc
|
||||
,chgrp
|
||||
)
|
||||
--SELECT
|
||||
-- p.product
|
||||
-- --,p.styc
|
||||
-- --,p.glec
|
||||
-- ,p.majg
|
||||
-- ,p.assc
|
||||
-- ,p.colgrp
|
||||
-- --,p.coltier
|
||||
-- --,p.sizc
|
||||
-- --,p.suffix
|
||||
-- ,p.chgrp
|
||||
-- ,p.account
|
||||
-- ,p.shipgrp
|
||||
-- --,bl.py_gasp
|
||||
-- ,sum(units) FILTER (WHERE oseas = 2020) py_units
|
||||
-- ,sum(units) FILTER (WHERE oseas = 2021) cy_units
|
||||
-- ,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp
|
||||
-- ,round(avg(price) FILTER (WHERE rn = 1),5) last_price
|
||||
-- ,max(odate) FILTER (WHERE rn = 1) last_order
|
||||
-- ,i.rate incr_rate
|
||||
-- ,CASE p.chgrp
|
||||
-- WHEN 'D' THEN .5
|
||||
-- ELSE CASE p.majg
|
||||
-- WHEN '610' THEN .02
|
||||
-- ElSE CASE p.colgrp
|
||||
-- WHEN 'B' THEN .15
|
||||
-- WHEN 'C' THEN .20
|
||||
-- ELSE 1
|
||||
-- END
|
||||
-- END
|
||||
-- END rate
|
||||
-- --,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL
|
||||
-- -- THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL
|
||||
-- -- THEN 'unknown'
|
||||
-- -- ELSE 'new'
|
||||
-- -- END
|
||||
-- -- ELSE CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL
|
||||
-- -- THEN 'lost'
|
||||
-- -- ELSE 'repeat'
|
||||
-- -- END
|
||||
-- --END flag
|
||||
--FROM
|
||||
-- p
|
||||
-- LEFT OUTER JOIN baseline bl ON
|
||||
-- bl.product = p.product
|
||||
-- AND bl.majg = p.majg
|
||||
-- AND bl.assc = p.assc
|
||||
-- AND bl.chgrp = p.chgrp
|
||||
-- LEFT OUTER JOIN incr i ON
|
||||
-- i.majg = p.majg
|
||||
-- AND i.assc = p.assc
|
||||
-- AND i.coltier = p.coltier
|
||||
-- AND p.glec <> '1RE'
|
||||
--WHERE
|
||||
-- p.account ~ 'AMERICAN HORT' and p.product = 'AZA06000.CBXX' and p.chgrp = 'W'
|
||||
--GROUP BY
|
||||
-- p.product
|
||||
-- --,p.styc
|
||||
-- --,p.glec
|
||||
-- ,p.majg
|
||||
-- ,p.assc
|
||||
-- --,p.coltier
|
||||
-- ,p.colgrp
|
||||
-- --,p.sizc
|
||||
-- --,p.suffix
|
||||
-- ,p.chgrp
|
||||
-- ,p.account
|
||||
-- ,p.shipgrp
|
||||
-- --,bl.py_gasp
|
||||
-- ,i.rate
|
||||
--SELECT * FROM baseline WHERE product = 'AMK06000.CBXX'
|
||||
----------calculate pricing as it sits in the forecast--------------
|
||||
,poolprice AS (
|
||||
SELECT
|
||||
@ -281,6 +256,7 @@ SELECT
|
||||
,p.account
|
||||
,p.shipgrp
|
||||
,bl.py_gasp
|
||||
,jsonb_agg(DISTINCT part) item
|
||||
,sum(units) FILTER (WHERE oseas = 2020) py_units
|
||||
,sum(units) FILTER (WHERE oseas = 2021) cy_units
|
||||
,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp
|
||||
@ -299,6 +275,7 @@ SELECT
|
||||
END
|
||||
END rate
|
||||
,ms.avg_price target
|
||||
,JSONB_AGG(DISTINCT plist.jcpric/1000) jcprice
|
||||
--,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL
|
||||
-- THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL
|
||||
-- THEN 'unknown'
|
||||
@ -334,6 +311,9 @@ FROM
|
||||
AND ms.data_segment = ds.dataseg
|
||||
AND ms.season = '2021'
|
||||
AND ms.region = 'ALL'
|
||||
LEFT OUTER JOIN plist ON
|
||||
plist.dba = p.account
|
||||
AND plist.jcpart = p.part
|
||||
GROUP BY
|
||||
p.productt
|
||||
,p.product
|
||||
@ -360,227 +340,242 @@ GROUP BY
|
||||
-- pivot p
|
||||
--)
|
||||
--SELECT * FROM test_unique where cnt > 1
|
||||
--SELECT * FROM pivot LIMIT 1000
|
||||
--------------join forecast price-------------------
|
||||
,fcp AS (
|
||||
SELECT
|
||||
pp.productt
|
||||
,pp.product
|
||||
,pp.majg
|
||||
,pp.quota_rep_descr
|
||||
,pp.order_season
|
||||
,pp.billto_group
|
||||
,pp.shipto_group
|
||||
,pp.fc_units
|
||||
,pp.fc_price
|
||||
,pp.iters
|
||||
,p.py_gasp
|
||||
,p.cy_units
|
||||
,p.py_asp
|
||||
,p.last_price
|
||||
,p.last_order
|
||||
,p.target
|
||||
,p.rate
|
||||
--need to link in targets pricing and price list for cap purposes---------
|
||||
--also need to link regional price lists so we don't blow past those------
|
||||
,COALESCE(py_asp,py_gasp) * (1 + rate) fc_price
|
||||
FROM
|
||||
poolprice pp
|
||||
LEFT OUTER JOIN pivot p ON
|
||||
pp.productt = p.productt
|
||||
AND pp.majg = p.majg
|
||||
AND pp.chgrp = p.chgrp
|
||||
AND pp.billto_group = p.account
|
||||
AND pp.shipto_group = p.shipgrp
|
||||
)
|
||||
SELECT * FROM fcp limit 100
|
||||
----------------create the new price-----------------
|
||||
--,adj AS (
|
||||
--SELECT
|
||||
-- p.product
|
||||
-- ,p.styc
|
||||
-- ,p.glec
|
||||
-- ,p.majg
|
||||
-- ,p.assc
|
||||
-- ,p.coltier
|
||||
-- ,p.sizc
|
||||
-- ,p.suffix
|
||||
-- ,p.account
|
||||
-- ,p.shipgrp
|
||||
-- ,p.py_gasp
|
||||
-- ,p.cy_units
|
||||
-- ,p.py_asp
|
||||
-- ,p.last_price
|
||||
-- ,p.last_order
|
||||
-- ,p.rate
|
||||
-- ,p.flag
|
||||
-- ,CASE p.flag
|
||||
-- ----------------------if repeat business then get to prior year + target %--------------------------------------------------------------
|
||||
-- WHEN 'repeat' THEN greatest(py_asp * COALESCE(1+rate,1) - last_price,0)
|
||||
-- WHEN 'lost' THEN greatest(py_asp * COALESCE(1+rate,1) - last_price,0)
|
||||
-- ----------------------if new business, move towards py_gasp + target % : lesser of py gloabl + target or last + target------------------
|
||||
-- WHEN 'new' THEN least(last_price * COALESCE(1+rate,1) - last_price,greatest(py_gasp * COALESCE(1+rate,1) - last_price,0))
|
||||
-- END price_increment
|
||||
--FROM
|
||||
-- pivot p
|
||||
--)
|
||||
--SELECT * FROM adj LIMIT 1000
|
||||
----------------create a log entry--------------------
|
||||
--,log AS (
|
||||
-- INSERT INTO
|
||||
-- rlarp.osm_log(doc)
|
||||
-- SELECT
|
||||
-- $${
|
||||
-- "message":"application of last price and target increases to all forecast orders",
|
||||
-- "tag":"last price",
|
||||
-- "type":"build"
|
||||
-- }$$::jsonb doc
|
||||
-- RETURNING *
|
||||
--)
|
||||
--,poolprice AS (
|
||||
--SELECT
|
||||
-- i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) product
|
||||
-- ,o.quota_rep_descr
|
||||
-- ,o.billto_group
|
||||
-- ,o.shipto_group
|
||||
-- ,order_season
|
||||
-- ,sum(units) units
|
||||
-- ,sum(value_loc) valloc
|
||||
-- ,sum(value_usd) valusd
|
||||
-- ,sum(o.value_loc)/sum(o.units) price
|
||||
-- ,jsonb_agg(DISTINCT iter) iters
|
||||
--FROM
|
||||
-- rlarp.osm_pool o
|
||||
-- ,rlarp.itemmv i
|
||||
--WHERE
|
||||
-- i.item = o.part
|
||||
-- --AND o.units <> 0
|
||||
-- ---only apply to 2022 orders----
|
||||
-- AND o.order_date >= '2021-06-01'
|
||||
-- --only include baseline stuff---
|
||||
-- AND segm <> 'Retail'
|
||||
--GROUP BY
|
||||
-- i.stlc||'.'||i.colgrp||substring(i.sizc,1,3)
|
||||
-- ,o.quota_rep_descr
|
||||
-- ,o.billto_group
|
||||
-- ,o.shipto_group
|
||||
-- ,order_season
|
||||
-- --AND iter <> 'upload price'
|
||||
--)
|
||||
--, pooladj AS (
|
||||
-- SELECT
|
||||
-- p.product
|
||||
-- ,p.quota_rep_descr
|
||||
-- ,p.billto_group
|
||||
-- ,p.shipto_group
|
||||
-- ,p.price
|
||||
,log AS (
|
||||
INSERT INTO
|
||||
rlarp.osm_log(doc)
|
||||
SELECT
|
||||
$${
|
||||
"message":"application of last price and target increases to all forecast orders",
|
||||
"tag":"last price",
|
||||
"type":"build"
|
||||
}$$::jsonb doc
|
||||
RETURNING *
|
||||
)
|
||||
---------collapse iterations-----------------------
|
||||
,collapse AS (
|
||||
SELECT
|
||||
o.fspr
|
||||
,o.plnt ---master data
|
||||
,o.promo --history date mix
|
||||
,o.terms
|
||||
,o.bill_cust_descr --history cust mix
|
||||
,o.ship_cust_descr --history cust mix
|
||||
,o.dsm
|
||||
,o.quota_rep_descr --master data
|
||||
,o.director
|
||||
,o.billto_group --master data
|
||||
,o.shipto_group
|
||||
,o.chan --master data
|
||||
,o.chansub
|
||||
,o.chan_retail
|
||||
,o.part
|
||||
,o.part_descr
|
||||
,i.stlc||'.'||i.coltier||substring(i.sizc,1,3) productt
|
||||
,o.part_group
|
||||
,o.branding
|
||||
,o.majg_descr
|
||||
,o.ming_descr
|
||||
,o.majs_descr
|
||||
,o.mins_descr
|
||||
,o.segm
|
||||
,o.substance
|
||||
,o.fs_line
|
||||
,o.r_currency
|
||||
,o.r_rate
|
||||
,o.c_currency
|
||||
,o.c_rate
|
||||
,SUM(o.units) units
|
||||
,SUM(o.value_loc) value_loc
|
||||
,SUM(o.value_usd) value_usd
|
||||
,SUM(o.value_loc)/SUM(o.units) price_loc
|
||||
,SUM(o.cost_loc) cost_loc
|
||||
,SUM(o.cost_usd) cost_usd
|
||||
,o.calc_status --0
|
||||
,o.flag --0
|
||||
,o.order_date --history date mix
|
||||
,o.order_month
|
||||
,o.order_season
|
||||
,o.request_date --history date mix
|
||||
,o.request_month
|
||||
,o.request_season
|
||||
,o.ship_date --history date mix
|
||||
,o.ship_month
|
||||
,o.ship_season
|
||||
FROM
|
||||
rlarp.osm_pool o
|
||||
--need to join to itemm to get the product from osm_pool
|
||||
,rlarp.itemmv i
|
||||
WHERE
|
||||
i.item = o.part
|
||||
GROUP BY
|
||||
o.fspr
|
||||
,o.plnt ---master data
|
||||
,o.promo --history date mix
|
||||
,o.terms
|
||||
,o.bill_cust_descr --history cust mix
|
||||
,o.ship_cust_descr --history cust mix
|
||||
,o.dsm
|
||||
,o.quota_rep_descr --master data
|
||||
,o.director
|
||||
,o.billto_group --master data
|
||||
,o.shipto_group
|
||||
,o.chan --master data
|
||||
,o.chansub
|
||||
,o.chan_retail
|
||||
,o.part
|
||||
,o.part_descr
|
||||
,i.stlc||'.'||i.coltier||substring(i.sizc,1,3)
|
||||
,o.part_group
|
||||
,o.branding
|
||||
,o.majg_descr
|
||||
,o.ming_descr
|
||||
,o.majs_descr
|
||||
,o.mins_descr
|
||||
,o.segm
|
||||
,o.substance
|
||||
,o.fs_line
|
||||
,o.r_currency
|
||||
,o.r_rate
|
||||
,o.c_currency
|
||||
,o.c_rate
|
||||
,o.calc_status --0
|
||||
,o.flag --0
|
||||
,o.order_date --history date mix
|
||||
,o.order_month
|
||||
,o.order_season
|
||||
,o.request_date --history date mix
|
||||
,o.request_month
|
||||
,o.request_season
|
||||
,o.ship_date --history date mix
|
||||
,o.ship_month
|
||||
,o.ship_season
|
||||
HAVING
|
||||
sum(o.units) <> 0
|
||||
)
|
||||
-------------build the iteration rows----------------
|
||||
,ins AS (
|
||||
SELECT
|
||||
o.fspr
|
||||
,o.plnt ---master data
|
||||
,o.promo --history date mix
|
||||
,o.terms
|
||||
,o.bill_cust_descr --history cust mix
|
||||
,o.ship_cust_descr --history cust mix
|
||||
,o.dsm
|
||||
,o.quota_rep_descr --master data
|
||||
,o.director
|
||||
,o.billto_group --master data
|
||||
,o.shipto_group
|
||||
,o.chan --master data
|
||||
,o.chansub
|
||||
,o.chan_retail
|
||||
,o.part
|
||||
,o.part_descr
|
||||
,o.part_group
|
||||
,o.branding
|
||||
,o.majg_descr
|
||||
,o.ming_descr
|
||||
,o.majs_descr
|
||||
,o.mins_descr
|
||||
,o.segm
|
||||
,o.substance
|
||||
,o.fs_line --master data
|
||||
,o.r_currency --history cust mix
|
||||
,o.r_rate --master data
|
||||
,o.c_currency --master data
|
||||
,o.c_rate --master data
|
||||
--,o.units
|
||||
,0::numeric units
|
||||
,greatest(
|
||||
round(least(
|
||||
least(
|
||||
COALESCE(a.py_asp,o.price_loc),
|
||||
COALESCE(a.py_gasp,a.target)
|
||||
) * (1 + a.rate),
|
||||
(a.jcprice->>0)::numeric
|
||||
)*o.units - o.value_loc,2)
|
||||
,0) AS value_loc
|
||||
,greatest(
|
||||
round((least(
|
||||
least(
|
||||
COALESCE(a.py_asp,o.price_loc),
|
||||
COALESCE(a.py_gasp,a.target)
|
||||
) * (1 + a.rate),
|
||||
(a.jcprice->>0)::numeric
|
||||
)*o.units - o.value_loc) * r_rate,2)
|
||||
,0) AS value_usd
|
||||
----debug---
|
||||
--,least(
|
||||
-- least(
|
||||
-- COALESCE(a.py_asp,o.price_loc),
|
||||
-- COALESCE(a.py_gasp,a.target)
|
||||
-- ) * (1 + a.rate),
|
||||
-- (a.jcprice->>0)::numeric
|
||||
--) AS rev_price
|
||||
--,o.units
|
||||
--,o.value_loc
|
||||
--,o.value_usd
|
||||
--,o.price_loc
|
||||
--,a.last_price
|
||||
--,a.target
|
||||
--,a.jcprice
|
||||
--,a.rate
|
||||
--,a.py_asp
|
||||
--,a.py_gasp
|
||||
-----------
|
||||
,0::numeric cost_loc
|
||||
,0::numeric cost_usd
|
||||
,o.calc_status --0
|
||||
,o.flag --0
|
||||
,o.order_date --history date mix
|
||||
,o.order_month
|
||||
,o.order_season
|
||||
,o.request_date --history date mix
|
||||
,o.request_month
|
||||
,o.request_season
|
||||
,o.ship_date --history date mix
|
||||
,o.ship_month
|
||||
,o.ship_season
|
||||
--,o.version
|
||||
---this iteration has to be listed in the master template file in order to be effectively included---
|
||||
,'b22' AS version
|
||||
,'upload price' iter
|
||||
,log.id
|
||||
,COALESCE(log.doc->>'tag','') "tag"
|
||||
,log.doc->>'message' "comment"
|
||||
,log.doc->>'type' module
|
||||
-----------debug columns---------
|
||||
--,value_usd/units price
|
||||
--,a.py_gasp
|
||||
--,a.rate
|
||||
--,a.last_price
|
||||
--,a.price_increment
|
||||
-- FROM
|
||||
-- poolprice p
|
||||
-- ,adj a
|
||||
-- WHERE
|
||||
-- a.product = p.product
|
||||
-- AND a.account = p.billto_group
|
||||
-- AND a.shipgrp = p.shipto_group
|
||||
--)
|
||||
--SELECT * FROM pooladj WHERE product ~ 'STG06000' AND shipto_group = 'BWI' limit 100
|
||||
----SELECT * FROM poolprice WHERE product ~ 'TCA06600' AND shipto_group = 'BWI' AND quota_rep_descr = 'BRYAN HILL' LIMIT 1000
|
||||
---------------build the iteration rows----------------
|
||||
----,ins AS (
|
||||
----SELECT
|
||||
---- o.fspr
|
||||
---- ,o.plnt ---master data
|
||||
---- ,o.promo --history date mix
|
||||
---- ,o.terms
|
||||
---- ,o.bill_cust_descr --history cust mix
|
||||
---- ,o.ship_cust_descr --history cust mix
|
||||
---- ,o.dsm
|
||||
---- ,o.quota_rep_descr --master data
|
||||
---- ,o.director
|
||||
---- ,o.billto_group --master data
|
||||
---- ,o.shipto_group
|
||||
---- ,o.chan --master data
|
||||
---- ,o.chansub
|
||||
---- ,o.chan_retail
|
||||
---- ,o.part
|
||||
---- ,o.part_descr
|
||||
---- ,o.part_group
|
||||
---- ,o.branding
|
||||
---- ,o.majg_descr
|
||||
---- ,o.ming_descr
|
||||
---- ,o.majs_descr
|
||||
---- ,o.mins_descr
|
||||
---- ,o.segm
|
||||
---- ,o.substance
|
||||
---- ,o.fs_line --master data
|
||||
---- ,o.r_currency --history cust mix
|
||||
---- ,o.r_rate --master data
|
||||
---- ,o.c_currency --master data
|
||||
---- ,o.c_rate --master data
|
||||
---- ,0::numeric units
|
||||
---- ,ROUND(o.units * (a.price_increment/o.r_rate),2) value_loc
|
||||
---- ,ROUND(o.units * a.price_increment,2) value_usd
|
||||
---- ,0::numeric cost_loc
|
||||
---- ,0::numeric cost_usd
|
||||
---- ,o.calc_status --0
|
||||
---- ,o.flag --0
|
||||
---- ,o.order_date --history date mix
|
||||
---- ,o.order_month
|
||||
---- ,o.order_season
|
||||
---- ,o.request_date --history date mix
|
||||
---- ,o.request_month
|
||||
---- ,o.request_season
|
||||
---- ,o.ship_date --history date mix
|
||||
---- ,o.ship_month
|
||||
---- ,o.ship_season
|
||||
---- ,o.version
|
||||
---- ---this iteration has to be listed in the master template file in order to be effectively included---
|
||||
---- ,'upload price' iter
|
||||
---- ,log.id
|
||||
---- ,COALESCE(log.doc->>'tag','') "tag"
|
||||
---- ,log.doc->>'message' "comment"
|
||||
---- ,log.doc->>'type' module
|
||||
---- -----------debug columns---------
|
||||
---- --,value_usd/units price
|
||||
---- --,a.py_gasp
|
||||
---- --,a.rate
|
||||
---- --,a.last_price
|
||||
---- --,a.price_increment
|
||||
----FROM
|
||||
---- rlarp.osm_pool o
|
||||
---- ,rlarp.itemmv i
|
||||
---- ,adj a
|
||||
---- ,log
|
||||
----WHERE
|
||||
---- i.item = o.part
|
||||
---- AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,1,3)
|
||||
---- AND a.account = o.billto_group
|
||||
---- AND a.shipgrp = o.shipto_group
|
||||
---- AND a.price_increment <> 0
|
||||
---- AND o.units <> 0
|
||||
---- ---only apply to 2022 orders----
|
||||
---- AND o.order_date >= '2021-06-01'
|
||||
---- --only include baseline stuff---
|
||||
---- AND iter <> 'upload price'
|
||||
----)
|
||||
---------------aggregate the impact------------
|
||||
------SELECT * FROM ins limit 10000
|
||||
------SELECT
|
||||
------ order_season
|
||||
------ ,sum(value_loc) val_loc
|
||||
------ ,sum(value_usd) val_usd
|
||||
------FROM
|
||||
------ ins
|
||||
------GROUP BY
|
||||
------ order_season;
|
||||
----,del AS (
|
||||
---- DELETE FROM rlarp.osm_pool WHERE iter = 'upload price' RETURNING *
|
||||
----)
|
||||
----INSERT INTO
|
||||
---- rlarp.osm_pool
|
||||
----SELECT * FROM ins;
|
||||
----
|
||||
----COMMIT;
|
||||
FROM
|
||||
collapse o
|
||||
--need to join to itemm to get the product from osm_pool
|
||||
--,fcp a
|
||||
,pivot a
|
||||
,log
|
||||
WHERE
|
||||
-- a.productt = o.productt
|
||||
--AND a.quota_rep_descr = o.quota_rep_descr
|
||||
--AND a.majg = SUBSTRING(o.majg_descr,1,3)
|
||||
--AND a.billto_group = o.billto_group
|
||||
--AND a.shipto_group = o.shipto_group
|
||||
--AND a.chgrp = substring(o.chan,1,1)
|
||||
---only apply to 2022 orders----
|
||||
---join p
|
||||
a.productt = o.productt
|
||||
AND a.majg = SUBSTRING(o.majg_descr,1,3)
|
||||
AND a.chgrp = substring(o.chan,1,1)
|
||||
AND a.account = o.billto_group
|
||||
AND a.shipgrp = o.shipto_group
|
||||
AND o.order_date >= '2021-06-01'
|
||||
AND o.segm <> 'Retail'
|
||||
)
|
||||
--SELECT order_season, order_month, sum(value_usd) from ins group by order_season, order_month;
|
||||
INSERT INTO rlarp.osm_pool SELECT * FROM ins;
|
||||
-----------aggregate the impact------------
|
||||
|
||||
COMMIT;
|
||||
|
Loading…
Reference in New Issue
Block a user