Compare commits

...

3 Commits

8 changed files with 492 additions and 61 deletions

12
api.ts
View File

@ -28,11 +28,13 @@ await client.connect();
const query = await Deno.readTextFile("sql/write_note.sql"); const query = await Deno.readTextFile("sql/write_note.sql");
// Define a route to retrieve values from the database using parameters // 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 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 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 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(bucket)
//console.log(ship_cust) //console.log(ship_cust)
@ -74,8 +76,8 @@ router.post('/sales_walk/flag_cust', async (ctx) => {
if (ctx.request.hasBody) { if (ctx.request.hasBody) {
const body = JSON.parse(bodyText); const body = JSON.parse(bodyText);
console.log("Body JSON:", body); console.log("Body JSON:", body);
const { ship_cust, bucket, notes } = body; // Destructure the needed values from the JSON const { bill_cust, ship_cust, bucket, attainment, notes } = body; // Destructure the needed values from the JSON
const result = await client.queryObject({args: [ship_cust, bucket, notes], text: query} ); const result = await client.queryObject({args: [bill_cust, ship_cust, bucket, attainment, notes], text: query} );
} }
} catch (error) { } catch (error) {
@ -91,6 +93,6 @@ app.use(router.routes());
app.use(router.allowedMethods()); app.use(router.allowedMethods());
// Start the server // Start the server
console.log('Server is running on http://localhost:8085'); console.log('Server is running on http://localhost:8086');
await app.listen({ port: 8085 }); await app.listen({ port: 8086 });

View File

@ -1,10 +1,10 @@
[Unit] [Unit]
Description=Deno API Sales Walk Description=Deno API Sales Walk v2
After=network.target After=network.target
[Service] [Service]
ExecStart=/home/ptrowbridge/.deno/bin/deno run --allow-all /opt/sales_bridge/api.ts ExecStart=/home/ptrowbridge/.deno/bin/deno run --allow-all /opt/sales_bridge_2/api.ts
WorkingDirectory=/opt/sales_bridge WorkingDirectory=/opt/sales_bridge_2
Restart=always Restart=always
User=ptrowbridge User=ptrowbridge

View File

@ -1,20 +1,82 @@
WITH x AS ( WITH
SELECT act as (
version, SELECT
oseas, bill_dba
customer, ,ship_dba
sum(sales_usd), ,dsm
sum(pounds) --,os.glec
--string_agg(distinct mold,', ') --,m.biggroup
FROM b --,os.priceg
left outer join rlarp.molds m ON ,COALESCE(sum(pounds) filter (WHERE sseas = 2023 AND version = 'Actual' AND SUBSTRING(smon,1,2) <= '08'),0) "Actual 2023"
m.stlc = b.mold ,COALESCE(sum(pounds) filter (WHERE sseas = 2024 AND version = 'Actual'),0) "Actual 2024"
WHERE ,COALESCE(sum(pounds) filter (WHERE version = 'Actual' AND ostatus LIKE 'Open%' AND rseas <= 2024),0) "Open Ord"
oseas = 2024 ,COALESCE(sum(pounds) filter (WHERE version = 'Quotes'),0) "Quotes"
AND version = 'Forecats' FROM
GROUP BY rlarp.osm_stack os
version, LEFT OUTER JOIN rlarp.molds m ON
oseas, m.stlc = substring(os.product ,1,8)
customer 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 X ,bgt AS (
SELECT
bill_dba
,ship_dba
,dsm
,sum(sales_usd) sales
,sum(pounds) pounds
--string_agg(distinct mold,', ')
FROM
rlarp.osm_stack
WHERE
version = 'Budget'
AND oseas = '2024'
GROUP BY
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(bgt.pounds ) "Budget 2024"
,SUM(act."Actual 2023") "Actual 2023"
,SUM(act."Actual 2024") "Actual 2024"
,SUM(act."Open Ord" ) "Open Ord"
,SUM(act."Quotes" ) "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

23
sql/excel_query.sql Normal file
View File

@ -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

113
sql/prep_budget.sql Normal file
View File

@ -0,0 +1,113 @@
DELETE FROM rlarp.osmp where version = 'b24r1';
INSERT INTO
rlarp.osmp
SELECT
ordnum
,NULL::integer
,NULL::integer
,NULL::integer
,invnum
,NULL::integer
,quoten
,NULL::integer
,NULL::date
,NULL::date
,NULL::date
,NULL::date
,NULL::date
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,NULL::jsonb
,NULL::text
,plnt
,promo
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,bill_class
,substring(bill_cust,1,8)
,NULL::text
,NULL::text
,ship_class
,substring(ship_cust,1,8)
,NULL::text
,NULL::text
,NULL::text
,bill_dba
,ship_dba
,geo
,chan
,chansub
,NULL::text
,NULL::text
,NULL::text
,bill_ctry
,bill_prov
,bill_post
,dest_ctry
,dest_prov
,dest_post
,part
,mold
,substring(colcd,1,3)
,colgrp
,substring(coltierd,1,1)
,NULL::text
,sizc
,uomp
,substring(suffixd,1,position(' -' IN suffixd))
,accs_ps
,brnd
,substring(majgd,1,3)
,substring(mingd,1,3)
,substring(majsd,1,3)
,substring(minsd,1,3)
,NULL::text
,NULL::text
,glec
,NULL::text
,clss
,NULL::text
,NULL::text
,NULL::text
,NULL::text
,case when coalesce(qty,0) = 0 then 0 else pounds/qty end
,pallets
,plcd
,TRIM(fs_line)
,'US'
,1
,'US'
,1
,qty
,sales_usd
,NULL::numeric
,NULL::numeric
,NULL::numeric
,NULL::numeric
,stdcost_usd
,stdcost_cur_usd
,NULL::numeric
,calc_status
,flag
,odate
,oseas
,sdate
,sseas
,rdate
,rseas
,pdate
,pseas
,'b24r1'
,iter
FROM
public.b;

View File

@ -8,22 +8,25 @@ sales_walk_seg
CREATE TABLE IF NOT EXISTS rlarp.walk ( CREATE TABLE IF NOT EXISTS rlarp.walk_r1 (
ship_cust text PRIMARY KEY bill_cust text
,ship_cust text
,bucket text ,bucket text
,attainment numeric
,notes text ,notes text
,PRIMARY KEY (bill_cust, ship_cust)
); );
GRANT ALL ON TABLE rlarp.walk TO PUBLIC; GRANT ALL ON TABLE rlarp.walk_r1 TO PUBLIC;
DROP VIEW IF EXISTS rlarp.sales_walk; DROP VIEW IF EXISTS rlarp.sales_walk_r1_seg;
DROP VIEW IF EXISTS rlarp.sales_walk_seg; DROP VIEW IF EXISTS rlarp.sales_walk_r1;
------------------------------------------sales walk agg--------------------------------------------------- ------------------------------------------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 WITH
agg as ( act as (
SELECT SELECT
bill_dba bill_dba
,ship_dba ,ship_dba
@ -32,9 +35,9 @@ SELECT
--,m.biggroup --,m.biggroup
--,os.priceg --,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 = 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 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 = '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 version = 'Quotes'),0) "Quotes"
FROM FROM
rlarp.osm_stack os rlarp.osm_stack os
LEFT OUTER JOIN rlarp.molds m ON LEFT OUTER JOIN rlarp.molds m ON
@ -64,10 +67,49 @@ GROUP BY
--,m.biggroup --,m.biggroup
--,os.priceg --,os.priceg
) )
,bgt AS (
SELECT
bill_dba
,ship_dba
,dsm
,sum(sales_usd) sales
,sum(pounds) pounds
--string_agg(distinct mold,', ')
FROM
rlarp.osm_stack
WHERE
version = 'Budget'
AND oseas = '2024'
GROUP BY
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------------------------------------------------------- ------------------------------------------sales walk-------------------------------------------------------
CREATE OR REPLACE VIEW rlarp.sales_walk AS CREATE OR REPLACE VIEW rlarp.sales_walk_r1 AS
SELECT SELECT
bill_dba bill_dba
,ship_dba ,ship_dba
@ -75,6 +117,7 @@ SELECT
--,glec --,glec
--,biggroup --,biggroup
--,priceg --,priceg
,"Budget 2024" budget_2024
,"Actual 2023" shipments_2023 ,"Actual 2023" shipments_2023
,"Actual 2024" shipments_2024 ,"Actual 2024" shipments_2024
,"Open Ord" open_orders_2024 ,"Open Ord" open_orders_2024
@ -92,28 +135,33 @@ SELECT
WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won' WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won'
END END
END flag END flag
,COALESCE(w.bucket,'None') bucket ,COALESCE(w.bucket,a.bucket,'None') bucket
,COALESCE(w.notes,'-') notes ,COALESCE(w.attainment,0) attainment
,COALESCE(w.notes,a.notes,'-') notes
FROM FROM
rlarp.sales_walk_agg agg rlarp.sales_walk_r1_agg agg
LEFT OUTER JOIN rlarp.walk w ON 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 w.ship_cust = agg.ship_dba
AND w.bill_cust = agg.bill_dba
WHERE WHERE
"Actual 2023" <> 0 "Budget 2024" <> 0
OR "Actual 2023" <> 0
OR ("Actual 2024") <> 0 OR ("Actual 2024") <> 0
OR ("Open Ord") <> 0 OR ("Open Ord") <> 0
OR ("Quotes") <> 0 OR ("Quotes") <> 0
ORDER BY ORDER BY
dsm 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 --,biggroup
------------------------------------------sales walk seg agg----------------------------------------------- ------------------------------------------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 WITH
SEG AS ( SEG AS (
SELECT SELECT
@ -149,6 +197,7 @@ SELECT
,s.segm ,s.segm
,m.biggroup ,m.biggroup
--,os.priceg --,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 = 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 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 = 'Actual' AND ostatus LIKE 'Open%' AND rseas <= 2024),0) "Open Ord"
@ -171,6 +220,7 @@ WHERE
AND odate >= '2023-05-01'::date AND odate >= '2023-05-01'::date
) )
OR (ostatus LIKE 'Open%') OR (ostatus LIKE 'Open%')
OR (version = 'Budget')
) )
AND calc_status <> 'CANCELED' AND calc_status <> 'CANCELED'
AND substring(os.glec,1,1) <= '2' AND substring(os.glec,1,1) <= '2'
@ -189,7 +239,7 @@ GROUP BY
SELECT * FROM agg; SELECT * FROM agg;
------------------------------------------sales walk seg--------------------------------------------------- ------------------------------------------sales walk seg---------------------------------------------------
CREATE OR REPLACE VIEW rlarp.sales_walk_seg AS CREATE OR REPLACE VIEW rlarp.sales_walk_r1_seg AS
SELECT SELECT
agg.bill_dba agg.bill_dba
,agg.ship_dba ,agg.ship_dba
@ -199,10 +249,12 @@ SELECT
,agg.segm ,agg.segm
,agg.biggroup ,agg.biggroup
--,priceg --,priceg
,"Budget 2024" budget_2024
,"Actual 2023" shipments_2023 ,"Actual 2023" shipments_2023
,"Actual 2024" shipments_2024 ,"Actual 2024" shipments_2024
,"Open Ord" open_orders_2024 ,"Open Ord" open_orders_2024
,"Quotes" quotes ,"Quotes" quotes
,"Budget 2024" * COALESCE(w.attainment,0) available_to_win
,CASE WHEN "Actual 2023" > 0 ,CASE WHEN "Actual 2023" > 0
THEN CASE 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 'No Activity'
@ -216,25 +268,30 @@ SELECT
WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won' WHEN "Actual 2024" > 0 OR "Open Ord" > 0 THEN 'Incremental Won'
END END
END flag END flag
,COALESCE(w.bucket,'None') bucket ,COALESCE(w.bucket,a.bucket,'None') bucket
,COALESCE(w.notes,'-') notes ,COALESCE(w.attainment,0) attainment
,COALESCE(w.notes,a.notes,'-') notes
,sw.flag flag_cust ,sw.flag flag_cust
FROM FROM
rlarp.sales_walk_seg_agg agg rlarp.sales_walk_r1_seg_agg agg
LEFT OUTER JOIN rlarp.walk w ON 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 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 sw.bill_dba = agg.bill_dba
AND sw.ship_dba = agg.ship_dba AND sw.ship_dba = agg.ship_dba
AND sw.dsm = agg.dsm AND sw.dsm = agg.dsm
WHERE WHERE
"Actual 2023" <> 0 "Budget 2024" <> 0
OR "Actual 2023" <> 0
OR ("Actual 2024") <> 0 OR ("Actual 2024") <> 0
OR ("Open Ord") <> 0 OR ("Open Ord") <> 0
OR ("Quotes") <> 0 OR ("Quotes") <> 0
ORDER BY ORDER BY
dsm 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 --,biggroup

172
sql/snap_rep.sql Normal file
View File

@ -0,0 +1,172 @@
----------------------------SET BILL-TO REP------------------------------------
UPDATE
public.b S
SET
BILL_REP = C.BVSALM
,BILL_CLASS = C.BVCLAS
FROM
LGDAT.CUST C
WHERE
C.BVCUST = S.BILL_CUST
AND (
COALESCE(S.BILL_REP,'') <> C.BVSALM
OR COALESCE(S.BILL_CLASS,'') <> C.BVCLAS
);
----------------------------SET SHIP-TO REP------------------------------------
UPDATE
public.b S
SET
SHIP_REP = C.BVSALM
,SHIP_CLASS = C.BVCLAS
FROM
LGDAT.CUST C
WHERE
C.BVCUST = S.SHIP_CUST
AND (
COALESCE(S.SHIP_REP,'') <> C.BVSALM
OR COALESCE(S.SHIP_CLASS,'') <> C.BVCLAS
);
----------------------------SET BILLTO GROUP------------------------------------
UPDATE
public.b O
SET
BILL_DBA = CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END
FROM
LGDAT.CUST C
WHERE
C.BVCUST = O.BILL_CUST
AND CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END <> O.ACCOUNT;
----------------------------SET SHIPTO GROUP------------------------------------
UPDATE
public.b O
SET
SHIP_DBA = CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END
FROM
LGDAT.CUST C
WHERE
C.BVCUST = O.SHIP_CUST
AND CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END <> O.SHIPGRP;
---------------------------SET GEOGRAPHY----------------------------------------
UPDATE
public.b o
SET
geo = t.geo
FROM
rlarp.ffterr t
WHERE
t.CTRY = o.DEST_CTRY
AND t.PROV = o.DEST_PROV
AND o.GEO <> t.GEO;
---------------------------SET CHANNEL-----------------------------------------
UPDATE
public.b
SET
CHAN = CASE SUBSTRING(BILL_CLASS,2,3)
--if the bill to class is ditsributor, then it's either warehouse or drop
WHEN 'DIS' THEN
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
CASE SUBSTRING(SHIP_CLASS,2,3)
WHEN 'DIS' THEN 'WHS'
ELSE 'DRP'
END
--CASE WHEN RTRIM(SUBSTRING(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTRING(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END
--everything else does not involve a distributor and is considered direct
ELSE 'DIR'
END,
CHANSUB = CASE SUBSTRING(BILL_CLASS,2,3)
WHEN 'DIS' THEN
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
CASE SUBSTRING(SHIP_CLASS,2,3)
WHEN 'DIS' THEN 'WHS'
ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END
END
WHEN 'MAS' THEN 'RMN'
WHEN 'NAT' THEN 'RMN'
ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END
END
WHERE
COALESCE(CHAN,'') <> CASE SUBSTRING(BILL_CLASS,2,3)
--if the bill to class is ditsributor, then it's either warehouse or drop
WHEN 'DIS' THEN
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
CASE SUBSTRING(SHIP_CLASS,2,3)
WHEN 'DIS' THEN 'WHS'
ELSE 'DRP'
END
--CASE WHEN RTRIM(SUBSTRING(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTRING(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END
--everything else does not involve a distributor and is considered direct
ELSE 'DIR'
END
OR
COALESCE(CHANSUB,'') <> CASE SUBSTRING(BILL_CLASS,2,3)
WHEN 'DIS' THEN
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
CASE SUBSTRING(SHIP_CLASS,2,3)
WHEN 'DIS' THEN 'WHS'
ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END
END
WHEN 'MAS' THEN 'RMN'
WHEN 'NAT' THEN 'RMN'
ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END
END;
---------------------------SET QUOTA REP---------------------------------------
UPDATE
public.b S
SET
DSM = CR.QUOTA_REP
FROM
(
SELECT DISTINCT
VERSION,
COALESCE(GLEC,'') GLEC,
SUBSTRING(mingd,1,3),
BILL_CUST,
SHIP_CUST,
------------quota rep column--------------
CASE WHEN COALESCE(SUBSTRING(mingd,1,3),'') = 'B52' THEN 'PW' ELSE
--if the gl expense code is 1RE use the retail rep assigned to the bill-to customer if available
CASE WHEN COALESCE(glec,'') = '1RE' AND COALESCE(cu.currep,'') <> '' THEN
cu.currep
--default logic
ELSE
CASE SUBSTR(bill_class,2,3)
WHEN 'DIS' THEN
ship_rep
ELSE
bill_rep
END
END
END QUOTA_REP
FROM
public.b S
LEFT OUTER JOIN LGDAT.CUST ON
BVCUST = BILL_CUST
LEFT OUTER JOIN lgpgm.usrcust cu ON
cu.cucust = s.bill_cust
) CR
WHERE
CR.VERSION = S.VERSION
AND CR.GLEC = COALESCE(S.GLEC,'')
AND CR.SUBSTRING(mingd,1,3) = S.SUBSTRING(mingd,1,3)
AND CR.BILL_CUST = S.BILL_CUST
AND CR.SHIP_CUST = S.SHIP_CUST
AND COALESCE(S.DSM,'') <> CR.QUOTA_REP;

View File

@ -1,11 +1,13 @@
MERGE INTO MERGE INTO
rlarp.walk w rlarp.walk_r1 w
USING 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 i.ship_cust = w.ship_cust
AND i.bill_cust = w.bill_cust
WHEN MATCHED THEN UPDATE SET WHEN MATCHED THEN UPDATE SET
bucket = i.bucket bucket = i.bucket
,attainment = i.attainment::numeric
,notes = i.notes ,notes = i.notes
WHEN NOT MATCHED THEN WHEN NOT MATCHED THEN
INSERT (ship_cust, bucket, notes) INSERT (bill_cust, ship_cust, bucket, attainment, notes)
VALUES (i.ship_cust, i.bucket, i.notes ) VALUES (bill_cust,i.ship_cust, i.bucket, i.attainment::numeric, i.notes )