diff --git a/api.ts b/api.ts index 3bd8239..f5294da 100644 --- a/api.ts +++ b/api.ts @@ -28,11 +28,13 @@ await client.connect(); const query = await Deno.readTextFile("sql/write_note.sql"); // Define a route to retrieve values from the database using parameters -router.get('/sales_walk/write_note/:ship_cust/:bucket/:notes', async (ctx) => { +router.get('/sales_walk/write_note/:bill_cust/:ship_cust/:bucket/:attainment/:notes', async (ctx) => { const bucket = ctx.params.bucket; // Extract the bucket parameter from the route + const attainment= ctx.params.attainment; // Extract the bucket parameter from the route const notes = ctx.params.notes; // Extract the bucket parameter from the route const ship_cust = ctx.params.ship_cust; // Extract the ship_cust parameter from the route + const bill_cust = ctx.params.bill_cust; // Extract the ship_cust parameter from the route //console.log(bucket) //console.log(ship_cust) @@ -74,8 +76,8 @@ router.post('/sales_walk/flag_cust', async (ctx) => { if (ctx.request.hasBody) { const body = JSON.parse(bodyText); console.log("Body JSON:", body); - const { ship_cust, bucket, notes } = body; // Destructure the needed values from the JSON - const result = await client.queryObject({args: [ship_cust, bucket, notes], text: query} ); + const { bill_cust, ship_cust, bucket, attainment, notes } = body; // Destructure the needed values from the JSON + const result = await client.queryObject({args: [bill_cust, ship_cust, bucket, attainment, notes], text: query} ); } } catch (error) { @@ -91,6 +93,6 @@ app.use(router.routes()); app.use(router.allowedMethods()); // Start the server -console.log('Server is running on http://localhost:8085'); -await app.listen({ port: 8085 }); +console.log('Server is running on http://localhost:8086'); +await app.listen({ port: 8086 }); diff --git a/sales_walk.service b/sales_walk_2.service similarity index 64% rename from sales_walk.service rename to sales_walk_2.service index 92b7da5..dff3e4d 100644 --- a/sales_walk.service +++ b/sales_walk_2.service @@ -1,10 +1,10 @@ [Unit] -Description=Deno API Sales Walk +Description=Deno API Sales Walk v2 After=network.target [Service] -ExecStart=/home/ptrowbridge/.deno/bin/deno run --allow-all /opt/sales_bridge/api.ts -WorkingDirectory=/opt/sales_bridge +ExecStart=/home/ptrowbridge/.deno/bin/deno run --allow-all /opt/sales_bridge_2/api.ts +WorkingDirectory=/opt/sales_bridge_2 Restart=always User=ptrowbridge diff --git a/sql/excel_query.sql b/sql/excel_query.sql new file mode 100644 index 0000000..4c33415 --- /dev/null +++ b/sql/excel_query.sql @@ -0,0 +1,23 @@ +SELECT + sw.bill_dba, + sw.ship_dba, + sw.dsm, + sw.budget_2024, + sw.shipments_2023, + sw.shipments_2024, + sw.open_orders_2024, + sw.quotes, + --(shipments_2024 + open_orders_2024) - shipments_2023 yoy_delta, + (shipments_2024 + open_orders_2024) - budget_2024 yoy_delta, + sw.flag, + sw.bucket, + sw.attainment, + sw.notes +FROM + rlarp.sales_walk_r1 sw +WHERE + (sw.dsm = ?) +ORDER BY + sw.shipments_2023 desc, + shipments_2024 + open_orders_2024 desc, + quotes desc diff --git a/sql/prep_budget.sql b/sql/prep_budget.sql index 4c1caeb..84d1194 100644 --- a/sql/prep_budget.sql +++ b/sql/prep_budget.sql @@ -83,7 +83,7 @@ SELECT ,case when coalesce(qty,0) = 0 then 0 else pounds/qty end ,pallets ,plcd - ,fs_line + ,TRIM(fs_line) ,'US' ,1 ,'US' diff --git a/sql/schema.pg.sql b/sql/schema.pg.sql index cd3a4dd..8f5c469 100644 --- a/sql/schema.pg.sql +++ b/sql/schema.pg.sql @@ -8,20 +8,23 @@ sales_walk_seg -CREATE TABLE IF NOT EXISTS rlarp.walk ( - ship_cust text PRIMARY KEY +CREATE TABLE IF NOT EXISTS rlarp.walk_r1 ( + bill_cust text + ,ship_cust text ,bucket text + ,attainment numeric ,notes text + ,PRIMARY KEY (bill_cust, ship_cust) ); -GRANT ALL ON TABLE rlarp.walk TO PUBLIC; -DROP VIEW IF EXISTS rlarp.sales_walk; -DROP VIEW IF EXISTS rlarp.sales_walk_seg; +GRANT ALL ON TABLE rlarp.walk_r1 TO PUBLIC; +DROP VIEW IF EXISTS rlarp.sales_walk_r1_seg; +DROP VIEW IF EXISTS rlarp.sales_walk_r1; ------------------------------------------sales walk agg--------------------------------------------------- -DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_agg ; +DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_r1_agg ; -CREATE MATERIALIZED VIEW rlarp.sales_walk_agg AS +CREATE MATERIALIZED VIEW rlarp.sales_walk_r1_agg AS WITH act as ( SELECT @@ -32,9 +35,9 @@ SELECT --,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" + ,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 @@ -69,27 +72,44 @@ GROUP BY bill_dba ,ship_dba ,dsm - ,sum(sales_usd) - ,sum(pounds) + ,sum(sales_usd) sales + ,sum(pounds) pounds --string_agg(distinct mold,', ') - FROM b - left outer join rlarp.molds m ON - m.stlc = b.mold - WHERE - oseas = 2024 - AND version = 'Forecats' + FROM + rlarp.osm_stack + WHERE + version = 'Budget' + AND oseas = '2024' GROUP BY - version, - oseas, - customer + bill_dba + ,ship_dba + ,dsm ) ,agg AS ( SELECT + COALESCE(act.bill_dba,TRIM(bgt.bill_dba)) bill_dba + ,COALESCE(act.ship_dba,TRIM(bgt.ship_dba)) ship_dba + ,COALESCE(act.dsm ,TRIM(bgt.dsm )) dsm + ,SUM(COALESCE(bgt.pounds ,0)) "Budget 2024" + ,SUM(COALESCE(act."Actual 2023",0)) "Actual 2023" + ,SUM(COALESCE(act."Actual 2024",0)) "Actual 2024" + ,SUM(COALESCE(act."Open Ord" ,0)) "Open Ord" + ,SUM(COALESCE(act."Quotes" ,0)) "Quotes" + FROM + act + FULL OUTER JOIN bgt ON + TRIM(bgt.bill_dba) = act.bill_dba + AND TRIM(bgt.ship_dba) = act.ship_dba + AND TRIM(bgt.dsm ) = act.dsm + GROUP BY + COALESCE(act.bill_dba,TRIM(bgt.bill_dba)) + ,COALESCE(act.ship_dba,TRIM(bgt.ship_dba)) + ,COALESCE(act.dsm ,TRIM(bgt.dsm )) ) -SELECT * FROM agg +SELECT * FROM agg; ------------------------------------------sales walk------------------------------------------------------- -CREATE OR REPLACE VIEW rlarp.sales_walk AS +CREATE OR REPLACE VIEW rlarp.sales_walk_r1 AS SELECT bill_dba ,ship_dba @@ -97,6 +117,7 @@ SELECT --,glec --,biggroup --,priceg + ,"Budget 2024" budget_2024 ,"Actual 2023" shipments_2023 ,"Actual 2024" shipments_2024 ,"Open Ord" open_orders_2024 @@ -114,28 +135,33 @@ SELECT WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won' END END flag - ,COALESCE(w.bucket,'None') bucket - ,COALESCE(w.notes,'-') notes + ,COALESCE(w.bucket,a.bucket,'None') bucket + ,COALESCE(w.attainment,0) attainment + ,COALESCE(w.notes,a.notes,'-') notes FROM - rlarp.sales_walk_agg agg - LEFT OUTER JOIN rlarp.walk w ON + rlarp.sales_walk_r1_agg agg + LEFT OUTER JOIN rlarp.walk a ON + a.ship_cust = agg.ship_dba + LEFT OUTER JOIN rlarp.walk_r1 w ON w.ship_cust = agg.ship_dba + AND w.bill_cust = agg.bill_dba WHERE - "Actual 2023" <> 0 + "Budget 2024" <> 0 + OR "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; + ,"Budget 2024" + "Actual 2024" + "Actual 2023" + "Open Ord" + "Quotes" desc; -GRANT SELECT ON rlarp.sales_walk TO PUBLIC; +GRANT SELECT ON rlarp.sales_walk_r1 TO PUBLIC; --,biggroup ------------------------------------------sales walk seg agg----------------------------------------------- -DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_seg_agg; +DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_r1_seg_agg; -CREATE MATERIALIZED VIEW rlarp.sales_walk_seg_agg AS +CREATE MATERIALIZED VIEW rlarp.sales_walk_r1_seg_agg AS WITH SEG AS ( SELECT @@ -171,6 +197,7 @@ SELECT ,s.segm ,m.biggroup --,os.priceg + ,COALESCE(sum(pounds) filter (WHERE oseas = 2024 AND version = 'Budget'),0) "Budget 2024" ,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" @@ -193,6 +220,7 @@ WHERE AND odate >= '2023-05-01'::date ) OR (ostatus LIKE 'Open%') + OR (version = 'Budget') ) AND calc_status <> 'CANCELED' AND substring(os.glec,1,1) <= '2' @@ -211,7 +239,7 @@ GROUP BY SELECT * FROM agg; ------------------------------------------sales walk seg--------------------------------------------------- -CREATE OR REPLACE VIEW rlarp.sales_walk_seg AS +CREATE OR REPLACE VIEW rlarp.sales_walk_r1_seg AS SELECT agg.bill_dba ,agg.ship_dba @@ -221,10 +249,12 @@ SELECT ,agg.segm ,agg.biggroup --,priceg + ,"Budget 2024" budget_2024 ,"Actual 2023" shipments_2023 ,"Actual 2024" shipments_2024 ,"Open Ord" open_orders_2024 ,"Quotes" quotes + ,"Budget 2024" * COALESCE(w.attainment,0) available_to_win ,CASE WHEN "Actual 2023" > 0 THEN CASE WHEN "Actual 2024" = 0 AND "Open Ord" = 0 AND "Quotes" = 0 THEN 'No Activity' @@ -238,25 +268,30 @@ SELECT WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won' END END flag - ,COALESCE(w.bucket,'None') bucket - ,COALESCE(w.notes,'-') notes + ,COALESCE(w.bucket,a.bucket,'None') bucket + ,COALESCE(w.attainment,0) attainment + ,COALESCE(w.notes,a.notes,'-') notes ,sw.flag flag_cust FROM - rlarp.sales_walk_seg_agg agg - LEFT OUTER JOIN rlarp.walk w ON + rlarp.sales_walk_r1_seg_agg agg + LEFT OUTER JOIN rlarp.walk a ON + a.ship_cust = agg.ship_dba + LEFT OUTER JOIN rlarp.walk_r1 w ON w.ship_cust = agg.ship_dba - LEFT OUTER JOIN rlarp.sales_walk sw ON + AND w.bill_cust = agg.bill_dba + LEFT OUTER JOIN rlarp.sales_walk_r1 sw ON sw.bill_dba = agg.bill_dba AND sw.ship_dba = agg.ship_dba AND sw.dsm = agg.dsm WHERE - "Actual 2023" <> 0 + "Budget 2024" <> 0 + OR "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; + ,"Budget 2024" + "Actual 2024" + "Actual 2023" + "Open Ord" + "Quotes" desc; -GRANT SELECT ON rlarp.sales_walk_seg TO PUBLIC; +GRANT SELECT ON rlarp.sales_walk_r1_seg TO PUBLIC; --,biggroup diff --git a/sql/write_note.sql b/sql/write_note.sql index 082f139..8d918ad 100644 --- a/sql/write_note.sql +++ b/sql/write_note.sql @@ -1,11 +1,13 @@ MERGE INTO - rlarp.walk w + rlarp.walk_r1 w USING - ( SELECT $1 ship_cust, $2 bucket, $3 notes) as i ON + ( SELECT $1 bill_cust, $2 ship_cust, $3 bucket, $4 attainment, $5 notes) as i ON i.ship_cust = w.ship_cust + AND i.bill_cust = w.bill_cust WHEN MATCHED THEN UPDATE SET bucket = i.bucket + ,attainment = i.attainment::numeric ,notes = i.notes WHEN NOT MATCHED THEN - INSERT (ship_cust, bucket, notes) - VALUES (i.ship_cust, i.bucket, i.notes ) + INSERT (bill_cust, ship_cust, bucket, attainment, notes) + VALUES (bill_cust,i.ship_cust, i.bucket, i.attainment::numeric, i.notes )