328 lines
11 KiB
PL/PgSQL
328 lines
11 KiB
PL/PgSQL
DROP TABLE IF EXISTS pricequote.queue;
|
|
|
|
CREATE TABLE pricequote.queue (
|
|
bill TEXT,
|
|
ship TEXT,
|
|
part TEXT,
|
|
stlc TEXT,
|
|
v1ds TEXT,
|
|
vol NUMERIC,
|
|
chan TEXT,
|
|
cust TEXT,
|
|
tier TEXT,
|
|
pltq NUMERIC,
|
|
plevel TEXT,
|
|
last_price NUMERIC,
|
|
last_qty NUMERIC,
|
|
last_dataseg TEXT,
|
|
last_date DATE,
|
|
last_order TEXT,
|
|
last_quote TEXT,
|
|
last_source TEXT,
|
|
tprice NUMERIC,
|
|
tmath JSONB,
|
|
volume_range TEXT,
|
|
list_price NUMERIC,
|
|
list_code TEXT,
|
|
guidance_price NUMERIC,
|
|
guidance_reason TEXT,
|
|
expl JSONB,
|
|
ui_json JSONB,
|
|
partgroup TEXT
|
|
);
|
|
|
|
/*
|
|
====================================================================================
|
|
Script: matrix_guidance.pg.sql
|
|
Purpose: Batch pricing logic for sales matrix (PostgreSQL)
|
|
-----------------------------------------------------------------------------------
|
|
Description:
|
|
- Seeds a queue table with distinct pricing scenarios from rlarp.osm_stack
|
|
- Enriches each scenario with customer, channel, tier, pack quantity, and price level
|
|
- Looks up and applies target price, price history, list price, and guidance logic
|
|
- Builds a JSON explanation for each scenario
|
|
- Merges results back into the main sales matrix table
|
|
|
|
Inputs:
|
|
- Source table: rlarp.osm_stack
|
|
- Pricing reference tables: pricequote.target_prices, pricequote.lastpricedetail, pricequote.pricelist_ranged
|
|
- Customer/item reference: rlarp.cust, CMS.CUSLG.itemm, CMS.CUSLG.IPRCBHC
|
|
|
|
Outputs:
|
|
- Updates rlarp.osm_stack.pricing with a JSON explanation for each scenario
|
|
- All intermediate results are stored in pricequote.queue
|
|
|
|
Key Business Logic:
|
|
- Channel/tier/customer resolution based on bill/ship codes
|
|
- Target price and math lookup by segment, channel, tier, and volume
|
|
- Price history precedence and extraction via helper function
|
|
- List price selection: lowest valid price for the scenario
|
|
- Guidance logic: computed from target, last, and list prices
|
|
|
|
Dependencies:
|
|
- pricequote.guidance_logic (function)
|
|
- pricequote.pick_last_price_from_hist (function)
|
|
|
|
Notes:
|
|
- Designed for batch/matrix pricing updates
|
|
- Assumes all referenced tables and functions exist
|
|
- See also: single_price_call.pg.sql for single-row logic
|
|
====================================================================================
|
|
*/
|
|
|
|
CREATE INDEX idx_osm_stack_merge
|
|
ON rlarp.osm_stack (
|
|
bill_cust,
|
|
ship_cust,
|
|
part,
|
|
stlc,
|
|
dataseg,
|
|
qtyord
|
|
);
|
|
|
|
CREATE INDEX idx_queue_merge
|
|
ON pricequote.queue (
|
|
bill,
|
|
ship,
|
|
part,
|
|
stlc,
|
|
v1ds,
|
|
vol
|
|
);
|
|
|
|
|
|
--DROP PROCEDURE IF EXISTS pricequote.process_queue;
|
|
|
|
CREATE OR REPLACE PROCEDURE pricequote.process_queue()
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
BEGIN
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 1: Seed the queue table with distinct pricing scenarios
|
|
-----------------------------------------------------------------------
|
|
DELETE FROM pricequote.queue;
|
|
|
|
INSERT INTO pricequote.queue (bill, ship, part, stlc, v1ds, vol, expl)
|
|
SELECT DISTINCT
|
|
o.bill_cust AS bill,
|
|
o.ship_cust AS ship,
|
|
o.part,
|
|
o.stlc,
|
|
o.dataseg AS v1ds,
|
|
o.qtyord AS vol,
|
|
'{}'::jsonb AS expl
|
|
FROM rlarp.osm_stack o
|
|
WHERE
|
|
o.fs_line = '41010'
|
|
AND o.calc_status <> 'CANCELLED'
|
|
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
|
AND o.part IS NOT NULL
|
|
AND substring(o.glec, 1, 1) <= '2';
|
|
-- 44 seconds
|
|
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 2: Enrich customer, tier, channel, pack quantity, and level
|
|
-----------------------------------------------------------------------
|
|
MERGE INTO pricequote.queue q
|
|
USING (
|
|
SELECT
|
|
q.ctid,
|
|
-- Determine sales channel
|
|
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,
|
|
|
|
-- Determine pricing tier
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIR' THEN bc.tier
|
|
ELSE COALESCE(sc.tier, bc.tier)
|
|
END AS tier,
|
|
|
|
-- Resolve customer DBA name
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN bc.dba
|
|
ELSE sc.dba
|
|
END
|
|
ELSE bc.dba
|
|
END AS cust,
|
|
|
|
-- Pack quantity
|
|
i.mpck AS pltq,
|
|
|
|
-- Price level
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN sc.plevel
|
|
ELSE bc.plevel
|
|
END
|
|
ELSE bc.plevel
|
|
END AS plevel,
|
|
i.partgroup
|
|
FROM pricequote.queue q
|
|
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
|
|
) src
|
|
ON (q.ctid = src.ctid)
|
|
WHEN MATCHED THEN
|
|
UPDATE SET
|
|
chan = src.chan,
|
|
tier = src.tier,
|
|
cust = src.cust,
|
|
pltq = src.pltq,
|
|
plevel = src.plevel,
|
|
partgroup = src.partgroup;
|
|
-- 17 seconds
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 3: Apply target prices and embed target metadata
|
|
-----------------------------------------------------------------------
|
|
UPDATE pricequote.queue q
|
|
SET
|
|
tprice = tp.price,
|
|
expl = q.expl || jsonb_build_object(
|
|
'target_price', tp.price,
|
|
'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0)),
|
|
'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0), 5),
|
|
'volume range', tp.vol::TEXT,
|
|
'customer', q.cust,
|
|
'channel', q.chan,
|
|
'tier', TRIM(q.tier),
|
|
'target math', tp.math
|
|
)
|
|
FROM pricequote.target_prices tp
|
|
WHERE
|
|
tp.stlc = q.stlc
|
|
AND tp.ds = q.v1ds
|
|
AND tp.chan = q.chan
|
|
AND tp.tier = q.tier
|
|
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::int <@ tp.vol;
|
|
-- 20 seconds
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 4: Lookup price history and embed all relevant keys and precedence
|
|
-----------------------------------------------------------------------
|
|
-- Use the helper function to extract last price precedence and build JSON explanation as in single_price_call
|
|
UPDATE pricequote.queue q
|
|
SET
|
|
last_price = (last_json->>'price')::numeric,
|
|
last_qty = (last_json->>'qty')::numeric,
|
|
last_dataseg = last_json->>'datasegment',
|
|
last_date = (last_json->>'odate')::date,
|
|
last_order = last_json->>'ordnum',
|
|
last_quote = last_json->>'quoten',
|
|
last_source = last_json->>'source',
|
|
expl = q.expl || jsonb_build_object(
|
|
'last_price', (last_json->>'price')::numeric,
|
|
'last_qty', (last_json->>'qty')::numeric,
|
|
'last_dataseg', last_json->>'datasegment',
|
|
'last_source', last_json->>'source',
|
|
'last_date', (last_json->>'odate')::date,
|
|
'last_order', last_json->>'ordnum',
|
|
'last_quote', last_json->>'quoten'
|
|
)
|
|
FROM (
|
|
SELECT q.ctid, pricequote.pick_last_price_from_hist(lp.part_stats, q.v1ds) AS last_json
|
|
FROM pricequote.queue q
|
|
JOIN pricequote.lastpricedetail lp
|
|
ON lp.customer = q.cust AND lp.partgroup = q.partgroup
|
|
) sub
|
|
WHERE q.ctid = sub.ctid;
|
|
-- 2 minutes 36 seconds
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 5: Resolve best list price and insert it with list code
|
|
-----------------------------------------------------------------------
|
|
WITH ranked_prices AS (
|
|
SELECT
|
|
q.ctid,
|
|
pr.price,
|
|
pr.jcplcd,
|
|
ROW_NUMBER() OVER (PARTITION BY q.ctid ORDER BY pr.price ASC) AS rn
|
|
FROM pricequote.queue q
|
|
JOIN "CMS.CUSLG".IPRCBHC i
|
|
ON TRIM(i.jbplvl) = TRIM(q.plevel)
|
|
AND CURRENT_DATE BETWEEN i.jbfdat AND i.jbtdat
|
|
JOIN pricequote.pricelist_ranged pr
|
|
ON pr.jcplcd = TRIM(i.jbplcd)
|
|
AND pr.jcpart = q.part
|
|
AND q.vol >= pr.vb_from
|
|
AND q.vol < pr.vb_to
|
|
),
|
|
best_price AS (
|
|
SELECT * FROM ranked_prices WHERE rn = 1
|
|
)
|
|
UPDATE pricequote.queue q
|
|
SET
|
|
list_price = p.price,
|
|
list_code = p.jcplcd,
|
|
expl = q.expl || jsonb_build_object(
|
|
'list_price', p.price,
|
|
'list_code', p.jcplcd
|
|
)
|
|
FROM best_price p
|
|
WHERE q.ctid = p.ctid;
|
|
-- 15 seconds
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 6: Compute guidance price using logic function
|
|
-----------------------------------------------------------------------
|
|
UPDATE pricequote.queue q
|
|
SET
|
|
guidance_price = g.guidance_price,
|
|
guidance_reason = g.guidance_reason,
|
|
expl = q.expl || jsonb_build_object(
|
|
'guidance_price', g.guidance_price,
|
|
'guidance_reason', g.guidance_reason
|
|
)
|
|
FROM (
|
|
SELECT
|
|
q.ctid,
|
|
g.guidance_price,
|
|
g.guidance_reason
|
|
FROM pricequote.queue q
|
|
JOIN LATERAL pricequote.guidance_logic(
|
|
q.tprice,
|
|
q.last_price,
|
|
q.list_price,
|
|
q.last_date
|
|
) g ON TRUE
|
|
) g
|
|
WHERE q.ctid = g.ctid;
|
|
-- 27 seconds
|
|
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Step 7: merge the results back into sales matrix
|
|
-----------------------------------------------------------------------
|
|
UPDATE rlarp.osm_stack o
|
|
SET pricing = pricing || q.expl
|
|
FROM pricequote.queue q
|
|
WHERE
|
|
o.bill_cust = q.bill
|
|
AND o.ship_cust IS NOT DISTINCT FROM q.ship
|
|
AND o.part = q.part
|
|
AND o.stlc = q.stlc
|
|
AND o.dataseg = q.v1ds
|
|
AND o.qtyord = q.vol
|
|
AND o.fs_line = '41010'
|
|
AND o.calc_status <> 'CANCELLED'
|
|
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
|
AND o.part IS NOT NULL
|
|
AND substring(o.glec, 1, 1) <= '2';
|
|
-- 6 minutes 31 seconds
|
|
|
|
-----------------------------------------------------------------------
|
|
-- Done
|
|
-----------------------------------------------------------------------
|
|
RAISE NOTICE 'Queue processing complete.';
|
|
END;
|
|
$$;
|