544 lines
		
	
	
		
			15 KiB
		
	
	
	
		
			PL/PgSQL
		
	
	
	
	
	
			
		
		
	
	
			544 lines
		
	
	
		
			15 KiB
		
	
	
	
		
			PL/PgSQL
		
	
	
	
	
	
--BEGIN;
 | 
						|
 | 
						|
WITH 
 | 
						|
------------------goal price increases---------------------
 | 
						|
incr AS (
 | 
						|
    SELECT * FROM (VALUES
 | 
						|
        ('110','PP','B',0.3),
 | 
						|
        ('110','PP','T',0.3),
 | 
						|
        ('110','PP','L',0.4),
 | 
						|
        ('110','PP','M',0.4),
 | 
						|
        ('110','PP','P',0.4),
 | 
						|
        ('110','PP','C',0.4),
 | 
						|
        ('210','PE','B',0.3),
 | 
						|
        ('210','PE','T',0.3),
 | 
						|
        ('210','PE','L',0.3),
 | 
						|
        ('210','PE','M',0.3),
 | 
						|
        ('210','PE','P',0.3),
 | 
						|
        ('210','PE','C',0.3),
 | 
						|
        ('310','PE','B',0.25),
 | 
						|
        ('310','PE','T',0.3),
 | 
						|
        ('310','PE','L',0.3),
 | 
						|
        ('310','PE','M',0.3),
 | 
						|
        ('310','PE','P',0.3),
 | 
						|
        ('310','PE','C',0.3),
 | 
						|
        ('310','PP','B',0.25),
 | 
						|
        ('310','PP','T',0.25),
 | 
						|
        ('310','PP','L',0.25),
 | 
						|
        ('310','PP','M',0.25),
 | 
						|
        ('310','PP','P',0.25),
 | 
						|
        ('310','PP','C',0.25),
 | 
						|
        ('310','PS','B',0.25),
 | 
						|
        ('310','PS','T',0.25),
 | 
						|
        ('310','PS','L',0.25),
 | 
						|
        ('310','PS','M',0.25),
 | 
						|
        ('310','PS','P',0.25),
 | 
						|
        ('310','PS','C',0.25),
 | 
						|
        ('320','PE','B',0.25),
 | 
						|
        ('320','PE','T',0.25),
 | 
						|
        ('320','PE','L',0.25),
 | 
						|
        ('320','PE','M',0.25),
 | 
						|
        ('320','PE','P',0.25),
 | 
						|
        ('320','PE','C',0.25),
 | 
						|
        ('320','PP','B',0.25),
 | 
						|
        ('320','PP','T',0.25),
 | 
						|
        ('320','PP','L',0.25),
 | 
						|
        ('320','PP','M',0.25),
 | 
						|
        ('320','PP','P',0.25),
 | 
						|
        ('320','PP','C',0.25),
 | 
						|
        ('910','PE','B',0.25),
 | 
						|
        ('910','PE','D',0.25),
 | 
						|
        ('910','PE','F',0.25),
 | 
						|
        ('910','PP','B',0.25),
 | 
						|
        ('910','PP','D',0.25),
 | 
						|
        ('910','PP','F',0.25),
 | 
						|
        ('910','PS','B',0.25),
 | 
						|
        ('910','PS','D',0.25),
 | 
						|
        ('910','PS','F',0.25),
 | 
						|
        ('610','','B',0.02),
 | 
						|
        ('610','','S',0.02),
 | 
						|
        ('610','','W',0.02)
 | 
						|
    ) x(MAJG,ASSC,COLTIER,RATE)
 | 
						|
)
 | 
						|
------------carve out pricing baseline data--------------------
 | 
						|
,p AS (
 | 
						|
    SELECT
 | 
						|
         o.part
 | 
						|
        ,o.styc||'.'||o.colgrp||substring(o.sizc,1,3) product
 | 
						|
        ,o.glec
 | 
						|
        ,o.styc
 | 
						|
        ,o.majg
 | 
						|
        ,i.assc
 | 
						|
        ,o.coltier
 | 
						|
        ,o.colgrp
 | 
						|
        ,o.sizc
 | 
						|
        ,i.suffix
 | 
						|
        ,substring(o.chan,1,1) chgrp
 | 
						|
        ,o.account
 | 
						|
        ,o.shipgrp
 | 
						|
        ,o.fb_qty units
 | 
						|
        ,o.fb_val_loc*r_rate val_usd
 | 
						|
        ,round(o.fb_val_loc/o.fb_qty,10) AS price
 | 
						|
        ,o.odate
 | 
						|
        ,o.oseas
 | 
						|
        ,row_number() OVER (PARTITION BY o.styc||'.'||o.colgrp||substring(o.sizc,1,3),o.account, o.shipgrp ORDER BY o.odate DESC) rn
 | 
						|
    FROM
 | 
						|
        rlarp.osm_dev o
 | 
						|
        INNER JOIN rlarp.itemmv i ON
 | 
						|
            i.item = o.part
 | 
						|
    WHERE
 | 
						|
        ---exclude R&A's
 | 
						|
        o.fs_line = '41010'    
 | 
						|
        ---exclude canceled orders
 | 
						|
        AND o.calc_status <> 'CANCELED'
 | 
						|
        ---exclude quotes
 | 
						|
        AND o.version = 'ACTUALS'
 | 
						|
        ---only finished goods
 | 
						|
        AND substring(o.glec,1,1) <= '2'
 | 
						|
        ---exclude blank parts
 | 
						|
        AND COALESCE(o.part,'') <> ''
 | 
						|
        ---must have a quantity
 | 
						|
        AND o.fb_qty <> 0
 | 
						|
        ---must have a price
 | 
						|
        AND o.fb_val_loc <> 0
 | 
						|
        ---must come from and order
 | 
						|
        AND o.odate IS NOT NULL
 | 
						|
        ---exclude samples
 | 
						|
        AND o.bill_class <> 'SALE'
 | 
						|
        ---only use recent history
 | 
						|
        AND o.oseas >= 2020
 | 
						|
        ---only for direct and drop
 | 
						|
        --AND o.chan IN ('DIR','DRP')
 | 
						|
    ORDER BY
 | 
						|
         o.part
 | 
						|
        ,o.styc
 | 
						|
        ,o.coltier
 | 
						|
        ,o.sizc
 | 
						|
        ,i.suffix
 | 
						|
        ,o.account
 | 
						|
        ,o.shipgrp
 | 
						|
        ,o.odate DESC
 | 
						|
)
 | 
						|
SELECT * FROM p WHERE account ~ 'AMERICAN HORT' and product = 'AZA06000.CBXX' and chgrp = 'W' order by rn ASC
 | 
						|
 | 
						|
------------build global py asp------------------
 | 
						|
,baseline AS (
 | 
						|
    SELECT
 | 
						|
        product
 | 
						|
        ,majg
 | 
						|
        ,assc
 | 
						|
        ,chgrp
 | 
						|
        ,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_gasp
 | 
						|
    FROM
 | 
						|
        p
 | 
						|
    GROUP BY
 | 
						|
        product
 | 
						|
        ,majg
 | 
						|
        ,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
 | 
						|
 | 
						|
 | 
						|
 | 
						|
----------calculate pricing as it sits in the forecast--------------
 | 
						|
,poolprice AS (
 | 
						|
SELECT
 | 
						|
    i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) product
 | 
						|
    ,o.quota_rep_descr
 | 
						|
    ,substring(majg,1,3) majg
 | 
						|
    ,substring(chan,1,1) chgrp
 | 
						|
    ,o.billto_group
 | 
						|
    ,o.shipto_group
 | 
						|
    ,order_season
 | 
						|
    ,round(sum(units)                   ,2) fc_units
 | 
						|
    --,round(sum(value_loc)               ,2) valloc
 | 
						|
    --,round(sum(value_usd)               ,2) valusd
 | 
						|
    ,round(sum(o.value_loc)/sum(o.units),5) fc_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
 | 
						|
    ,substring(majg,1,3)
 | 
						|
    ,substring(chan,1,1)
 | 
						|
    ,o.billto_group
 | 
						|
    ,o.shipto_group
 | 
						|
    ,order_season
 | 
						|
    --AND iter <> 'upload price'
 | 
						|
HAVING
 | 
						|
    sum(o.units) <> 0
 | 
						|
)
 | 
						|
----------pivot the pricing out into columns per customer/product--------
 | 
						|
,pivot AS (
 | 
						|
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
 | 
						|
    ,CASE p.chgrp
 | 
						|
        WHEN 'D' THEN i.rate
 | 
						|
        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'
 | 
						|
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
 | 
						|
)
 | 
						|
,test_unique AS (
 | 
						|
SELECT
 | 
						|
    p.*
 | 
						|
    ,count(*) OVER (partition by product, chgrp, account, shipgrp) cnt
 | 
						|
FROM
 | 
						|
   pivot p
 | 
						|
)
 | 
						|
SELECT * FROM test_unique where cnt > 1
 | 
						|
--------------join forecast price-------------------
 | 
						|
--,fcp AS (
 | 
						|
--    SELECT
 | 
						|
--         pp.product
 | 
						|
--        ,pp.quota_rep_descr
 | 
						|
--        ,pp.order_season
 | 
						|
--        ,pp.billto_group
 | 
						|
--        ,pp.shipto_group
 | 
						|
--        ,p.py_gasp
 | 
						|
--        ,p.cy_units
 | 
						|
--        ,p.py_asp
 | 
						|
--        ,p.last_price
 | 
						|
--        ,p.last_order
 | 
						|
--        ,p.rate
 | 
						|
--        ,p.flag
 | 
						|
--        ,pp.fc_units
 | 
						|
--        ,pp.fc_price
 | 
						|
--        ,pp.iters
 | 
						|
--    FROM    
 | 
						|
--        poolprice pp
 | 
						|
--        LEFT OUTER JOIN pivot p ON
 | 
						|
--                pp.product                = p.product
 | 
						|
--            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
 | 
						|
--       ,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;
 |