From 865325bd7d6cf74700dd9a75e3cb0a0720389d93 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Mon, 11 Sep 2023 11:00:44 -0400 Subject: [PATCH] updates --- sql/pull.sql | 14 ++--- sql/segment_summary.sql | 121 ++++++++++++++++++++++++++++++++++++++++ 2 files changed, 128 insertions(+), 7 deletions(-) create mode 100644 sql/segment_summary.sql diff --git a/sql/pull.sql b/sql/pull.sql index acff223..8b62701 100644 --- a/sql/pull.sql +++ b/sql/pull.sql @@ -1,5 +1,5 @@ DROP VIEW IF EXISTS rlarp.sales_walk; -DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_agg; +DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_agg ; CREATE MATERIALIZED VIEW rlarp.sales_walk_agg AS WITH @@ -11,9 +11,9 @@ SELECT --,os.glec --,m.biggroup --,os.priceg - ,COALESCE(sum(pounds) filter (WHERE sseas = 2023 AND version = 'Actual'),0) "Actual 2023" + ,COALESCE(sum(pounds) filter (WHERE sseas = 2023 AND version = 'Actual' AND SUBSTRING(smon,1,2) <= '08'),0) "Actual 2023" ,COALESCE(sum(pounds) filter (WHERE sseas = 2024 AND version = 'Actual'),0) "Actual 2024" - ,COALESCE(sum(pounds) filter (WHERE version = 'Actual' AND ostatus LIKE 'Open%'),0) "Open Ord" + ,COALESCE(sum(pounds) filter (WHERE version = 'Actual' AND ostatus LIKE 'Open%' AND rseas <= 2024),0) "Open Ord" ,COALESCE(sum(pounds) filter (WHERE version = 'Quotes'),0) "Quotes" FROM rlarp.osm_stack os @@ -56,14 +56,14 @@ SELECT --,priceg ,"Actual 2023" shipments_2023 ,"Actual 2024" shipments_2024 - ,"Open Ord" open_orders + ,"Open Ord" open_orders_2024 ,"Quotes" quotes ,CASE WHEN "Actual 2023" > 0 THEN CASE WHEN "Actual 2024" = 0 AND "Open Ord" = 0 AND "Quotes" = 0 THEN 'No Activity' - WHEN "Actual 2024" = 0 AND ("Open Ord" > 0 OR "Quotes" > 0) THEN 'Open Ord OR Quoted' - WHEN "Actual 2024" < "Actual 2023" THEN 'Reduced' - WHEN "Actual 2024" >= "Actual 2023" THEN 'Increased' + WHEN "Actual 2024" = 0 AND "Open Ord" = 0 AND "Quotes" > 0 THEN 'Quoted Only' + WHEN ("Actual 2024" + "Open Ord") < "Actual 2023" THEN 'Reduced' + WHEN ("Actual 2024" + "Open Ord") >= "Actual 2023" THEN 'Increased' END ELSE CASE diff --git a/sql/segment_summary.sql b/sql/segment_summary.sql new file mode 100644 index 0000000..0aa3763 --- /dev/null +++ b/sql/segment_summary.sql @@ -0,0 +1,121 @@ +DROP VIEW IF EXISTS rlarp.sales_walk_seg; +DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_seg_agg; + +CREATE MATERIALIZED VIEW rlarp.sales_walk_seg_agg AS +WITH +SEG AS ( + SELECT + x.GLEC + ,x.SEGM + FROM + ( + VALUES + ('1CU','Sustainable'), + ('1SU','Sustainable'), + ('1GR','Greenhouse'), + ('1NU','Nursery'), + ('1RE','Retail'), + ('2WI','Greenhouse'), + ('3BM','Other'), + ('3CO','Other'), + ('3PE','Other'), + ('3PP','Other'), + ('4CO','Other'), + ('4RA','Other'), + ('9MI','Other'), + ('9SA','Other'), + ('9TO','Other') + ) X(GLEC, SEGM) +) +,agg as ( +SELECT + bill_dba + ,ship_dba + ,dsm + ,s.segm + ,m.biggroup + --,os.priceg + ,COALESCE(sum(pounds) filter (WHERE sseas = 2023 AND version = 'Actual' AND SUBSTRING(smon,1,2) <= '08'),0) "Actual 2023" + ,COALESCE(sum(pounds) filter (WHERE sseas = 2024 AND version = 'Actual'),0) "Actual 2024" + ,COALESCE(sum(pounds) filter (WHERE version = 'Actual' AND ostatus LIKE 'Open%' AND rseas <= 2024),0) "Open Ord" + ,COALESCE(sum(pounds) filter (WHERE version = 'Quotes'),0) "Quotes" +FROM + rlarp.osm_stack os + LEFT OUTER JOIN rlarp.molds m ON + m.stlc = substring(os.product ,1,8) + LEFT OUTER JOIN seg s ON + s.glec = os.glec +WHERE + ( + ( + sseas IN (2023,2024) + AND version = 'Actual' + AND ostatus = 'Shipped' + ) + OR ( + version = 'Quotes' + AND odate >= '2023-05-01'::date + ) + OR (ostatus LIKE 'Open%') + ) + AND calc_status <> 'CANCELED' + AND substring(os.glec,1,1) <= '2' + AND os.fs_line = '41010' + AND COALESCE(ship_dba,'') <> '' +GROUP BY + bill_dba + ,ship_dba + ,dsm + ,s.segm + ,m.biggroup + --,os.priceg +) +SELECT * FROM agg; + +CREATE OR REPLACE VIEW rlarp.sales_walk_seg AS +SELECT + agg.bill_dba + ,agg.ship_dba + ,agg.dsm + ,agg.segm + ,agg.biggroup + --,priceg + ,"Actual 2023" shipments_2023 + ,"Actual 2024" shipments_2024 + ,"Open Ord" open_orders_2024 + ,"Quotes" quotes + ,CASE WHEN "Actual 2023" > 0 + THEN CASE + WHEN "Actual 2024" = 0 AND "Open Ord" = 0 AND "Quotes" = 0 THEN 'No Activity' + WHEN "Actual 2024" = 0 AND "Open Ord" = 0 AND "Quotes" > 0 THEN 'Quoted Only' + WHEN ("Actual 2024" + "Open Ord") < "Actual 2023" THEN 'Reduced' + WHEN ("Actual 2024" + "Open Ord") >= "Actual 2023" THEN 'Increased' + END + ELSE + CASE + WHEN "Actual 2024" = 0 AND "Open Ord" = 0 AND "Quotes" > 0 THEN 'Incremental Quoted' + WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won' + END + END flag + ,COALESCE(w.bucket,'None') bucket + ,COALESCE(w.notes,'-') notes + ,sw.flag flag_cust +FROM + rlarp.sales_walk_seg_agg agg + LEFT OUTER JOIN rlarp.walk w ON + w.ship_cust = agg.ship_dba + LEFT OUTER JOIN rlarp.sales_walk sw ON + sw.bill_dba = agg.bill_dba + AND sw.ship_dba = agg.ship_dba + AND sw.dsm = agg.dsm +WHERE + "Actual 2023" <> 0 + OR ("Actual 2024") <> 0 + OR ("Open Ord") <> 0 + OR ("Quotes") <> 0 +ORDER BY + dsm + ,"Actual 2024" + "Actual 2023" + "Open Ord" + "Quotes" desc; + +GRANT SELECT ON rlarp.sales_walk_seg TO PUBLIC; + --,biggroup