commit: 2025-07-27 21:02:17
This commit is contained in:
parent
c58488e1b3
commit
a4f9a43195
69
new_targets/procs/process_queue_proc.pg.sql
Normal file
69
new_targets/procs/process_queue_proc.pg.sql
Normal file
@ -0,0 +1,69 @@
|
||||
CREATE OR REPLACE PROCEDURE pricequote.process_queue_proc()
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Set channel, tier, and pallet quantity
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE pricequote.price_queue s
|
||||
SET
|
||||
chan = cr.chan,
|
||||
tier = cr.tier,
|
||||
pltq = cr.mpck,
|
||||
cust = cr.cust
|
||||
FROM (
|
||||
SELECT
|
||||
q.bill,
|
||||
q.ship,
|
||||
q.part,
|
||||
i.mpck,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN 'WHS'
|
||||
ELSE 'DRP'
|
||||
END
|
||||
ELSE 'DIR'
|
||||
END AS chan,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE COALESCE(sc.tier, bc.tier)
|
||||
END AS tier,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.dba
|
||||
ELSE COALESCE(sc.dba, bc.dba)
|
||||
END AS cust
|
||||
FROM pricequote.price_queue q
|
||||
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
|
||||
LEFT JOIN "CMS.CUSLG".itemm i ON i.item = q.part
|
||||
) cr
|
||||
WHERE
|
||||
cr.bill = s.bill AND
|
||||
COALESCE(cr.ship, '') = COALESCE(s.ship, '') AND
|
||||
cr.part = s.part;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Set price and explanation from target_prices
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE pricequote.price_queue q
|
||||
SET
|
||||
price = tp.price,
|
||||
expl = jsonb_build_object(
|
||||
'source', 'target price',
|
||||
'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0))::INT,
|
||||
'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0), 5),
|
||||
'volume range', tp.vol
|
||||
)
|
||||
FROM pricequote.target_prices tp
|
||||
WHERE
|
||||
q.stlc = tp.stlc
|
||||
AND q.v1ds = tp.ds
|
||||
AND q.chan = tp.chan
|
||||
AND q.tier = tp.tier
|
||||
AND tp.vol @> FLOOR(q.vol / NULLIF(q.pltq, 0))::INT;
|
||||
|
||||
END;
|
||||
$$;
|
||||
|
@ -1,3 +1,5 @@
|
||||
DROP TABLE pricequote.price_queue CASCADE;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS pricequote.price_queue (
|
||||
id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY
|
||||
,bill TEXT
|
||||
@ -6,6 +8,7 @@ CREATE TABLE IF NOT EXISTS pricequote.price_queue (
|
||||
,stlc TEXT
|
||||
,v1ds TEXT
|
||||
,vol NUMERIC
|
||||
,cust TEXT
|
||||
,chan TEXT
|
||||
,tier TEXT
|
||||
,pltq NUMERIC
|
||||
|
@ -30,4 +30,4 @@ FROM
|
||||
WHERE
|
||||
gset @> '{"mold":"TFR001G0","v0ds":"BASE"}'
|
||||
AND agglevel ?| array['chan', 'mold', 'v0ds']
|
||||
AND NOT agglevel ?| array['cust','ghse'];
|
||||
-- AND NOT agglevel ?| array['cust','ghse'];
|
||||
|
@ -1,5 +1,5 @@
|
||||
SELECT
|
||||
rlarp.get_guidance(lq.billto, lq.shipto, lq.part, lq.units_each, 2024)
|
||||
(select gg.d from rlarp.get_guidance_dseg('DIAM0004','DIAM0004','AMK06000','v1:B..PLT..',5000,2026) gg(d))
|
||||
FROM
|
||||
pricequote.live_quotes lq
|
||||
LIMIT 100
|
||||
LIMIT 1
|
||||
|
@ -1,2 +1,2 @@
|
||||
--select gg.d from rlarp.get_guidance('DIAM0004','DIAM0004','AMK06000G18B054',5000,2024) gg(d);
|
||||
-- select gg.d from rlarp.get_guidance_dseg('DIAM0004','DIAM0004','AMK06000','v1:B..PLT..',5000,2026) gg(d);
|
||||
SELECT gg.d doc FROM rlarp.get_guidance_dseg($1,$2, $3,$4, $5, 2024) gg(d);
|
||||
|
@ -1,5 +1,5 @@
|
||||
WITH
|
||||
sel AS (select 'v1:P.P.PLT..' _v1ds, 'ALTMAN PLANTS' _cust, 'TFR001G0' _mold, 'D' _chan)
|
||||
sel AS (select 'v1:B..PLT..' _v1ds, 'ALTMAN PLANTS' _cust, 'XPR15CS1' _mold, 'D' _chan)
|
||||
,sort AS (
|
||||
SELECT
|
||||
p.agglevel
|
||||
|
23
sql/link_matrix.pg.sql
Normal file
23
sql/link_matrix.pg.sql
Normal file
@ -0,0 +1,23 @@
|
||||
-- DELETE FROM pricequote.price_queue;
|
||||
--
|
||||
-- ALTER SEQUENCE pricequote.price_queue_id_seq RESTART WITH 1;
|
||||
--
|
||||
-- INSERT INTO
|
||||
-- pricequote.price_queue (bill, ship, part, stlc, v1ds, vol, chan, tier)
|
||||
-- SELECT DISTINCT
|
||||
-- bill_cust, ship_cust, part, stlc, dataseg, qty, chan, customer_tier
|
||||
-- FROM
|
||||
-- rlarp.osm_stack;
|
||||
|
||||
|
||||
|
||||
UPDATE
|
||||
pricequote.price_queue q
|
||||
SET
|
||||
expl = COALESCE(q.expl, '{}'::jsonb) || jsonb_build_object('price history', l.dataseg_stats)
|
||||
FROM
|
||||
pricequote.lastprice l
|
||||
WHERE
|
||||
q.cust = l.customer
|
||||
AND q.stlc = l.partgroup;
|
||||
|
83
sql/make_hist.ms.sql
Normal file
83
sql/make_hist.ms.sql
Normal file
@ -0,0 +1,83 @@
|
||||
WITH srt AS (
|
||||
SELECT
|
||||
customer,
|
||||
mold,
|
||||
part,
|
||||
qty,
|
||||
ROUND(sales_usd / qty, 5) AS price,
|
||||
odate,
|
||||
oseas,
|
||||
ordnum,
|
||||
quoten,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, mold, part
|
||||
ORDER BY odate DESC
|
||||
) AS rn
|
||||
FROM rlarp.osm_stack
|
||||
WHERE
|
||||
version = 'Actual' AND
|
||||
customer IS NOT NULL AND
|
||||
fs_line = '41010' AND
|
||||
calc_status <> 'CANCELLED' AND
|
||||
qty <> 0 AND
|
||||
mold <> ''
|
||||
),
|
||||
json_rows AS (
|
||||
SELECT
|
||||
customer,
|
||||
mold,
|
||||
part,
|
||||
CONCAT(
|
||||
'"', part, '":',
|
||||
(
|
||||
SELECT qty, price, odate, ordnum, quoten
|
||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||
)
|
||||
) AS part_json
|
||||
FROM srt
|
||||
WHERE rn = 1
|
||||
)
|
||||
,onerow AS (
|
||||
SELECT
|
||||
customer,
|
||||
mold,
|
||||
CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats
|
||||
FROM json_rows
|
||||
GROUP BY customer, mold
|
||||
)
|
||||
SELECT * INTO #lastprice FROM onerow
|
||||
|
||||
SELECT count(*) FROM rlarp.osm_stack o INNER JOIN #lastprice l ON
|
||||
l.customer = o.customer AND o.mold = l.mold
|
||||
|
||||
SELECT * FROM #lastprice
|
||||
|
||||
SELECT
|
||||
o.ordnum,
|
||||
o.part,
|
||||
o.odate,
|
||||
lp.customer,
|
||||
lp.mold,
|
||||
p.[key] AS part, -- this is the part number
|
||||
j.qty,
|
||||
j.price,
|
||||
j.odate,
|
||||
j.ordnum,
|
||||
j.quoten
|
||||
FROM
|
||||
rlarp.osm_stack o
|
||||
LEFT OUTER JOIN #lastprice lp ON
|
||||
lp.customer = o.customer
|
||||
AND lp.mold = o.mold
|
||||
CROSS APPLY OPENJSON(lp.part_stats) AS p -- unpacks part keys
|
||||
CROSS APPLY OPENJSON(p.value)
|
||||
WITH (
|
||||
qty FLOAT,
|
||||
price FLOAT,
|
||||
odate DATE,
|
||||
ordnum INT,
|
||||
quoten INT
|
||||
) AS j
|
||||
WHERE
|
||||
o.customer = 'ALTMAN PLANTS'
|
||||
AND o.mold = 'XPR15CS1'
|
50
sql/make_hist.pg.sql
Normal file
50
sql/make_hist.pg.sql
Normal file
@ -0,0 +1,50 @@
|
||||
CREATE TABLE pricequote.lastprice AS (
|
||||
WITH
|
||||
--------SORT--------
|
||||
srt AS (
|
||||
SELECT
|
||||
customer
|
||||
,partgroup
|
||||
,dataseg
|
||||
,qtyord
|
||||
,ROUND(sales_usd/qty,5) price
|
||||
,odate
|
||||
,oseas
|
||||
,ordnum
|
||||
,quoten
|
||||
,row_number() OVER (PARTITION BY customer, partgroup, dataseg, version ORDER BY odate DESC) seq
|
||||
,version
|
||||
FROM
|
||||
rlarp.osm_stack
|
||||
WHERE
|
||||
version IN ('Actual','Quotes')
|
||||
AND customer IS NOT NULL
|
||||
AND fs_line = '41010'
|
||||
AND calc_status <> 'CANCELLED'
|
||||
-- AND customer = 'ALTMAN PLANTS'
|
||||
AND qty <> 0
|
||||
AND partgroup <> ''
|
||||
AND version = 'Actual'
|
||||
-- LIMIT 10000
|
||||
)
|
||||
,onerow AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
-- Latest per-dataseg sales wrapped as JSONB object
|
||||
jsonb_object_agg(
|
||||
dataseg,
|
||||
to_jsonb(srt)
|
||||
ORDER BY odate DESC
|
||||
) AS dataseg_stats
|
||||
FROM
|
||||
srt
|
||||
WHERE
|
||||
seq = 1
|
||||
-- AND customer = 'ALTMAN PLANTS'
|
||||
-- AND partgroup ~ 'XPR15CS'
|
||||
GROUP BY customer, partgroup
|
||||
-- ORDER BY customer, partgroup
|
||||
)
|
||||
SELECT * FROM onerow --WHERE customer = 'ALTMAN PLANTS' AND partgroup = 'XPR15CS1'
|
||||
) WITH DATA;
|
Loading…
Reference in New Issue
Block a user