From a6bfd7c8e03a1c942c0de1bd7f9a9ecb010842be Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 17 Oct 2023 16:04:41 -0400 Subject: [PATCH] vault backup: 2023-10-17 16:04:41 --- sql/price_pool.sql | 157 +++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 157 insertions(+) create mode 100644 sql/price_pool.sql diff --git a/sql/price_pool.sql b/sql/price_pool.sql new file mode 100644 index 0000000..fefe86b --- /dev/null +++ b/sql/price_pool.sql @@ -0,0 +1,157 @@ +--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 ( + WITH + agg AS ( + SELECT + o.customer + ,o.chanwide + ,o.nursery_region + ,o.general_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 + 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 + WHERE + o.version <> '6/1 Order Book' + --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 + ,o.chanwide + ,o.nursery_region + ,o.general_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( + 'customer' ,CASE WHEN GROUPING(customer ) = 0 THEN customer END + ,'chanwide' ,CASE WHEN GROUPING(chanwide ) = 0 THEN chanwide END + ,'nursery_region' ,CASE WHEN GROUPING(nursery_region ) = 0 THEN nursery_region END + ,'general_region' ,CASE WHEN GROUPING(general_region ) = 0 THEN general_region END + --,'country' ,CASE WHEN GROUPING(country) = 0 THEN country END + ,'baseitem' ,CASE WHEN GROUPING(baseitem ) = 0 THEN baseitem END + ,'v1dataseg' ,CASE WHEN GROUPING(v1dataseg) = 0 THEN v1dataseg END + ,'v0dataseg' ,CASE WHEN GROUPING(v0dataseg) = 0 THEN v0dataseg END + ) + ) gset + ,oseas + ,sum(units ) units + ,sum(sales_usd) sales_usd + ,round(sum(sales_usd )/sum(units),5) price_usd + ,round(sum(target_price)/sum(units),5) target_price + ,jsonb_agg(DISTINCT coltier) coltier + FROM + agg + GROUP BY GROUPING SETS ( + -- oseas baseitem v0datseg chanwide customer region v1dataseg -- + (oseas, baseitem, v0dataseg, customer ) + ,(oseas, baseitem, customer, v1dataseg ) + ,(oseas, baseitem, v0dataseg, chanwide ) + ,(oseas, baseitem, v0dataseg, chanwide, nursery_region ) + ,(oseas, baseitem, v0dataseg, chanwide, general_region ) + ,(oseas, baseitem, chanwide, v1dataseg ) + ,(oseas, baseitem, v0dataseg, nursery_region ) + ,(oseas, baseitem, v0dataseg, general_region ) + ) + ) + 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 + --,oseas + --,units + --,sales_usd + --,price_usd + FROM + gsets + where + oseas IS NOT NULL + --AND gset @> jsonb_build_object('baseitem', 'XNS0T1G3') + GROUP BY + gset +) WITH DATA; + + +--UPDATE +-- rlarp.osm_stack o +--SET +-- pricing = o.pricing||jsonb_build_object('us_dirdrp',g.season) +--FROM +-- rlarp.price_pool g +--WHERE +-- o.version IN ('Actual','Quotes') +-- AND g.gset = jsonb_build_object('baseitem',o.baseitem,'v0dataseg',o.v0dataseg,'chanwide','D','general_region','US'); +-- +--UPDATE +-- rlarp.osm_stack o +--SET +-- pricing = o.pricing||jsonb_build_object('us_dirdrp_v1',g.season) +--FROM +-- rlarp.price_pool g +--WHERE +-- o.version IN ('Actual','Quotes') +-- AND g.gset = jsonb_build_object('baseitem',o.baseitem,'v0dataseg',v0dataseg,'v1dataseg',o.dataseg,'chanwide','D'); +--END +--$func$ + +--SELECT +-- jsonb_build_object('baseitem',o.baseitem,'v1dataseg',o.dataseg,'chanwide','D') +-- ,g.season +-- ,o.pricing||jsonb_build_object('us_dirdrp_v1',g.season) +--FROM +-- rlarp.osm_stack o +-- LEFT OUTER JOIN rlarp.price_pool g ON +-- g.gset = jsonb_build_object('baseitem',o.baseitem,'v0dataseg',v0dataseg,'v1dataseg',o.dataseg,'chanwide','D') +--WHERE +-- o.version IN ('Actual','Quotes') +-- AND o.baseitem = 'HSI06000' +--LIMIT 100