price_api/sql/price_pool.sql

176 lines
7.0 KiB
PL/PgSQL

--CREATE OR REPLACE PROCEDURE rlarp.price_pool()
--LANGUAGE plpgsql AS
--$func$
--BEGIN;
--DROP TABLE IF EXISTS rlarp.price_pool_dev;
--CREATE TABLE IF NOT EXISTS rlarp.price_pool_dev AS (
CREATE MATERIALIZED VIEW rlarp.price_pool_dev AS (
WITH
agg AS (
SELECT
o.customer
,substring(o.version,1,1) version
,o.chanwide
,o.nursery_region
,c.greenhouse_region
,m.part_group baseitem
,m.majg
,m.assc
,i.coltier
,'v1:' || rtrim(COALESCE(i.coltier, ''))|| '.' || rtrim(substring(COALESCE(i.branding, ''), 1, 1))|| '.' || rtrim(COALESCE(i.uomp, ''))|| '.' || rtrim(COALESCE(i.suffix, ''))|| '.' || rtrim(COALESCE(i.accs_ps, '')) v1dataseg
,_ds.dataseg v0dataseg
,o.oseas oseas
,round(sum(o.qty),0) units
,round(sum(o.sales_usd),0) sales_usd
,round(sum(COALESCE(tp.target_price,tq.target_price) * o.qty),2) target_price
,count(DISTINCT o.ordnum) ordcount
FROM
rlarp.osm_stack o
INNER JOIN "CMS.CUSLG".itemm i ON
i.item = o.part
LEFT OUTER JOIN rlarp.molds m ON
m.stlc = i.stlc
LEFT OUTER JOIN _ds ON
_ds.colgrp = o.colgrp
AND _ds.brand = substring(i.branding,1,1)
LEFT OUTER JOIN pricequote.market_setavgprice tp ON
tp.season = (SELECT ssyr FROM rlarp.gld where drange @> current_date)
AND tp.country = 'ALL'
AND tp.geo = 'ALL'
AND tp.region = 'ALL'
AND tp.mold = i.stlc
AND tp.chan = 'DISTRIB DROP SHIP'
AND tp.data_segment = 'v1:' || rtrim(COALESCE(i.coltier, ''))|| '.' || rtrim(substring(COALESCE(i.branding, ''), 1, 1))|| '.' || rtrim(COALESCE(i.uomp, ''))|| '.' || rtrim(COALESCE(i.suffix, ''))|| '.' || rtrim(COALESCE(i.accs_ps, ''))
LEFT OUTER JOIN pricequote.market_setavgprice tq ON
tq.season = (SELECT ssyr FROM rlarp.gld where drange @> current_date)
AND tq.country = 'ALL'
AND tq.geo = 'ALL'
AND tq.region = 'ALL'
AND tq.mold = i.stlc
AND tq.chan = 'DISTRIB DROP SHIP'
AND tq.data_segment = _ds.dataseg
LEFT OUTER JOIN rlarp.cust c ON
c.code = CASE o.chan WHEN 'DIR' THEN o.bill_cust ELSE o.ship_cust END
WHERE
o.version IN ('Actual','Quotes')
AND o.oseas >= 2015
AND o.dsm <> 'PW'
--AND o.part like 'SQL035%'
--AND o.calc_status <> 'CANCELED'
--AND o.fs_line = '41010'
--AND o.dsm <> 'PW'
--AND i.coltier <> 'C'
GROUP BY
o.customer
,substring(o.version,1,1)
,o.chanwide
,o.nursery_region
,c.greenhouse_region
,m.part_group
,m.majg
,m.assc
,i.coltier
,'v1:' || rtrim(COALESCE(i.coltier, ''))|| '.' || rtrim(substring(COALESCE(i.branding, ''), 1, 1))|| '.' || rtrim(COALESCE(i.uomp, ''))|| '.' || rtrim(COALESCE(i.suffix, ''))|| '.' || rtrim(COALESCE(i.accs_ps, ''))
,_ds.dataseg
,o.oseas
HAVING
round(sum(o.qty),0) > 0
AND round(sum(o.sales_usd)/sum(o.qty),5) > 0
)
,gsets AS (
SELECT
jsonb_strip_nulls(
jsonb_build_object(
'cust' ,customer
,'vers' ,version
,'chan' ,chanwide
,'nurs' ,nursery_region
,'ghse' ,greenhouse_region
,'mold' ,baseitem
,'v1ds' ,v1dataseg
,'v0ds' ,v0dataseg
)
) gset
,version
,oseas
,sum(units ) units
,sum(sales_usd) sales_usd
,round(sum(sales_usd )/sum(units),5) price_usd
,round(sum(target_price)/sum(units) FILTER (WHERE COALESCE(target_price,0) <> 0 ),5) target_price
,jsonb_agg(DISTINCT coltier) coltier
,count(DISTINCT customer) custcount
,sum(ordcount) ordcount
FROM
agg
GROUP BY
version
,GROUPING SETS (
-- oseas version, baseitem v0datseg chanwide customer region v1dataseg --
(oseas, version, baseitem, chanwide, v0dataseg, customer )
,(oseas, version, baseitem, chanwide, customer, v1dataseg )
,(oseas, version, baseitem, chanwide, v0dataseg )
,(oseas, version, baseitem, chanwide, v0dataseg, nursery_region )
,(oseas, version, baseitem, chanwide, v0dataseg, greenhouse_region )
,(oseas, version, baseitem, chanwide, v1dataseg )
,(oseas, version, baseitem, chanwide, v0dataseg, nursery_region )
,(oseas, version, baseitem, chanwide, v0dataseg, greenhouse_region )
)
)
,find_stats AS (
SELECT
gset
,jsonb_object_agg(oseas,jsonb_build_object('units',units,'sales_usd',sales_usd,'price_usd',price_usd,'target_price',target_price)) season
,(SELECT JSONB_AGG(k.v ORDER BY k.v ASC) FROM jsonb_object_keys(gset) k(v)) agglevel
,round(avg(custcount),1) avgcustcount
,round(avg(ordcount) ,1) avgordcount
,round(avg(units) ,0) avgunits
,round(avg(target_price),5) avgtargetprice
,min(oseas) FILTER (WHERE oseas BETWEEN 2020 AND 2023)::text early_season
,min(oseas) FILTER (WHERE oseas >= 2024)::text recent_season
,max(oseas) FILTER (WHERE oseas >= 2020)::text last_season
--,oseas
--,units
--,sales_usd
--,price_usd
FROM
gsets
WHERE
oseas IS NOT NULL
--AND gset @> jsonb_build_object('mold', 'XNS0T1G3')
GROUP BY
gset
)
SELECT
gset
,season
,agglevel
,jsonb_build_object(
'avgcustcount'
,avgcustcount
,'avgordcount'
,avgordcount
,'avgunits'
,avgunits
,'avgtargetprice'
,avgtargetprice
,'early_season'
,early_season::int
,'early_price'
,(season->early_season->>'price_usd')::numeric
,'recent_season'
,recent_season::int
,'recent_price'
,(season->recent_season->>'price_usd')::numeric
,'last_season'
,last_season::int
,'last_price'
,(season->last_season->>'price_usd')::numeric
) stats
FROM
find_stats
--LIMIT 1000
) WITH DATA;
create index ppd_gset on rlarp.price_pool_dev using gin (gset);
--END;