excel file version R3
This commit is contained in:
parent
86613ab0d6
commit
7ad6687cd3
31
api.ts
31
api.ts
@ -25,26 +25,29 @@ const client = new Client({
|
||||
await client.connect();
|
||||
|
||||
// Load SQL from file
|
||||
const query = await Deno.readTextFile("sql/hist.sql");
|
||||
const query = await Deno.readTextFile("sql/write_note.sql");
|
||||
|
||||
// Define a route to retrieve values from the database using parameters
|
||||
router.get('/price_info/part_cust/:partcode/:customer', async (ctx) => {
|
||||
router.get('/sales_walk/write_note/:ship_cust/:bucket/:notes', async (ctx) => {
|
||||
|
||||
const partcode = ctx.params.partcode; // Extract the partcode parameter from the route
|
||||
const customer = ctx.params.customer; // Extract the customer parameter from the route
|
||||
const bucket = ctx.params.bucket; // 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
|
||||
|
||||
//console.log(partcode)
|
||||
//console.log(customer)
|
||||
//console.log(bucket)
|
||||
//console.log(ship_cust)
|
||||
|
||||
const result = await client.queryObject({args: [partcode, customer], text: query} );
|
||||
const result = await client.queryObject({args: [ship_cust, bucket, notes], text: query} );
|
||||
|
||||
|
||||
const currentTime = Date.now();
|
||||
const dateObject = new Date(currentTime);
|
||||
const currentDateTime = dateObject.toLocaleString(); //Output: 2/20/2023, 7:41:42 AM
|
||||
console.log("posted: ", currentDateTime);
|
||||
|
||||
//ctx.response.body = result.rows;
|
||||
ctx.response.body = currentDateTime;
|
||||
|
||||
for (const row of result.rows) {
|
||||
if (typeof row.season === 'object' && row.season !== null) {
|
||||
for (const year in row.season) {
|
||||
console.log(`${year}: ` + row.season[year].price_usd)
|
||||
}
|
||||
}
|
||||
}
|
||||
});
|
||||
|
||||
app.use(router.routes());
|
||||
|
60
sql/hist.sql
60
sql/hist.sql
@ -1,60 +0,0 @@
|
||||
------------real history on target scenario------------
|
||||
WITH
|
||||
partcodes AS (
|
||||
SELECT
|
||||
item
|
||||
,'v1:' || COALESCE(i.coltier,'') || '.' || COALESCE(substring(i.branding,1,1),'') || '.' || coalesce(i.uomp,'') || '.' || coalesce(i.suffix,'') || '.' || coalesce(i.accs_ps,'') v1dataseg
|
||||
,_ds.dataseg v0dataseg
|
||||
,part_group
|
||||
FROM
|
||||
"CMS.CUSLG".itemm i
|
||||
LEFT OUTER JOIN rlarp.molds m ON
|
||||
m.stlc = i.stlc
|
||||
LEFT OUTER JOIN _ds ON
|
||||
_ds.colgrp = i.colgrp
|
||||
AND _ds.brand = i.branding
|
||||
WHERE
|
||||
i.item ~ $1
|
||||
AND part_group IS NOT NULL
|
||||
)
|
||||
,customers AS (
|
||||
SELECT
|
||||
dba
|
||||
FROM
|
||||
rlarp.cust c
|
||||
WHERE
|
||||
c.dba ~ $2
|
||||
)
|
||||
,allscenarios AS (
|
||||
SELECT DISTINCT
|
||||
jsonb_build_object('baseitem',part_group,'customer',dba) sc
|
||||
FROM
|
||||
partcodes
|
||||
CROSS JOIN customers
|
||||
)
|
||||
,v1scenarios AS (
|
||||
SELECT DISTINCT
|
||||
jsonb_build_object('baseitem',part_group,'customer',dba,'v1dataseg',v1dataseg) sc
|
||||
FROM
|
||||
partcodes
|
||||
CROSS JOIN customers
|
||||
)
|
||||
,v0scenarios AS (
|
||||
SELECT DISTINCT
|
||||
jsonb_build_object('baseitem',part_group,'customer',dba,'v0dataseg',v0dataseg) sc
|
||||
FROM
|
||||
partcodes
|
||||
CROSS JOIN customers
|
||||
)
|
||||
,hist AS (
|
||||
SELECT
|
||||
s.sc
|
||||
,p.gset
|
||||
,(SELECT string_agg(substring(ok,1,2),'') FROM (SELECT * FROM jsonb_object_keys(p.gset) jok(ok)) x ) agglevel
|
||||
,p.season
|
||||
FROM
|
||||
allscenarios s
|
||||
LEFT OUTER JOIN rlarp.price_pool_r1 p ON
|
||||
p.gset @> s.sc
|
||||
)
|
||||
SELECT * FROM hist
|
90
sql/pull.sql
Normal file
90
sql/pull.sql
Normal file
@ -0,0 +1,90 @@
|
||||
DROP VIEW IF EXISTS rlarp.sales_walk;
|
||||
DROP MATERIALIZED VIEW IF EXISTS rlarp.sales_walk_agg;
|
||||
|
||||
CREATE MATERIALIZED VIEW rlarp.sales_walk_agg AS
|
||||
WITH
|
||||
agg as (
|
||||
SELECT
|
||||
bill_dba
|
||||
,ship_dba
|
||||
,dsm
|
||||
--,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 = 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 = 'Quotes'),0) "Quotes"
|
||||
FROM
|
||||
rlarp.osm_stack os
|
||||
LEFT OUTER JOIN rlarp.molds m ON
|
||||
m.stlc = substring(os.product ,1,8)
|
||||
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
|
||||
--,os.glec
|
||||
--,m.biggroup
|
||||
--,os.priceg
|
||||
)
|
||||
SELECT * FROM agg;
|
||||
|
||||
CREATE OR REPLACE VIEW rlarp.sales_walk AS
|
||||
SELECT
|
||||
bill_dba
|
||||
,ship_dba
|
||||
,dsm
|
||||
--,glec
|
||||
--,biggroup
|
||||
--,priceg
|
||||
,"Actual 2023" shipments_2023
|
||||
,"Actual 2024" shipments_2024
|
||||
,"Open Ord" open_orders
|
||||
,"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'
|
||||
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
|
||||
FROM
|
||||
rlarp.sales_walk_agg agg
|
||||
LEFT OUTER JOIN rlarp.walk w ON
|
||||
w.ship_cust = agg.ship_dba
|
||||
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 TO PUBLIC;
|
||||
--,biggroup
|
7
sql/schema.pg.sql
Normal file
7
sql/schema.pg.sql
Normal file
@ -0,0 +1,7 @@
|
||||
CREATE TABLE IF NOT EXISTS rlarp.walk (
|
||||
ship_cust text PRIMARY KEY
|
||||
,bucket text
|
||||
,notes text
|
||||
);
|
||||
|
||||
GRANT ALL ON TABLE rlarp.walk TO PUBLIC;
|
11
sql/write_note.sql
Normal file
11
sql/write_note.sql
Normal file
@ -0,0 +1,11 @@
|
||||
MERGE INTO
|
||||
rlarp.walk w
|
||||
USING
|
||||
( SELECT $1 ship_cust, $2 bucket, $3 notes) as i ON
|
||||
i.ship_cust = w.ship_cust
|
||||
WHEN MATCHED THEN UPDATE SET
|
||||
bucket = i.bucket
|
||||
,notes = i.notes
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT (ship_cust, bucket, notes)
|
||||
VALUES (i.ship_cust, i.bucket, i.notes )
|
Loading…
Reference in New Issue
Block a user