From fb5968343a83da78aab0e49343e20e1b5fa90655 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Thu, 25 Apr 2024 11:09:15 -0400 Subject: [PATCH] add last several months to price pool --- sql/livequotes.pg.sql | 2 +- sql/price_pool.sql | 72 ++++++++++++++++++++++++++++++++++++++++++- 2 files changed, 72 insertions(+), 2 deletions(-) diff --git a/sql/livequotes.pg.sql b/sql/livequotes.pg.sql index 44e68f1..6463ca1 100644 --- a/sql/livequotes.pg.sql +++ b/sql/livequotes.pg.sql @@ -1,6 +1,6 @@ set work_mem TO '4GB'; -DROP VIEW rlarp.live_quotes_review; +DROP VIEW IF EXISTS rlarp.live_quotes_review; CREATE VIEW rlarp.live_quotes_review AS WITH lq AS MATERIALIZED ( diff --git a/sql/price_pool.sql b/sql/price_pool.sql index 40717fc..7dea9f4 100644 --- a/sql/price_pool.sql +++ b/sql/price_pool.sql @@ -2,7 +2,7 @@ --LANGUAGE plpgsql AS --$func$ --BEGIN; ---DROP TABLE IF EXISTS rlarp.price_pool_dev; +DROP MATERIALIZED VIEW IF EXISTS rlarp.price_pool_dev CASCADE; --CREATE TABLE IF NOT EXISTS rlarp.price_pool_dev AS ( CREATE MATERIALIZED VIEW rlarp.price_pool_dev AS ( WITH @@ -76,6 +76,76 @@ CREATE MATERIALIZED VIEW rlarp.price_pool_dev AS ( HAVING round(sum(o.qty),0) > 0 AND round(sum(o.sales_usd)/sum(o.qty),5) > 0 + UNION ALL + 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 + ,0 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.odate >= current_date - '4 months'::interval + 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