-- Drop and recreate the target table 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 ); 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'; ----------------------------------------------------------------------- -- 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; ----------------------------------------------------------------------- -- 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; ----------------------------------------------------------------------- -- Step 4: Lookup price history and embed all relevant keys and precedence ----------------------------------------------------------------------- UPDATE pricequote.queue q SET last_price = COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'price')::numeric, (hist -> q.v1ds -> 'dss' ->> 'price')::numeric, (hist -> 'mrq' ->> 'price')::numeric, (hist -> 'mrs' ->> 'price')::numeric ), last_qty = COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'qty')::numeric, (hist -> q.v1ds -> 'dss' ->> 'qty')::numeric, (hist -> 'mrq' ->> 'qty')::numeric, (hist -> 'mrs' ->> 'qty')::numeric ), last_dataseg = COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'datasegment'), (hist -> q.v1ds -> 'dss' ->> 'datasegment'), (hist -> 'mrq' ->> 'datasegment'), (hist -> 'mrs' ->> 'datasegment') ), last_date = COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'odate')::date, (hist -> q.v1ds -> 'dss' ->> 'odate')::date, (hist -> 'mrq' ->> 'odate')::date, (hist -> 'mrs' ->> 'odate')::date ), last_order = COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'ordnum'), (hist -> q.v1ds -> 'dss' ->> 'ordnum'), (hist -> 'mrq' ->> 'ordnum'), (hist -> 'mrs' ->> 'ordnum') ), last_quote = COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'quoten'), (hist -> q.v1ds -> 'dss' ->> 'quoten'), (hist -> 'mrq' ->> 'quoten'), (hist -> 'mrs' ->> 'quoten') ), last_source = CASE WHEN (hist -> q.v1ds -> 'dsq' ->> 'price') IS NOT NULL THEN 'dsq' WHEN (hist -> q.v1ds -> 'dss' ->> 'price') IS NOT NULL THEN 'dss' WHEN (hist -> 'mrq' ->> 'price') IS NOT NULL THEN 'mrq' WHEN (hist -> 'mrs' ->> 'price') IS NOT NULL THEN 'mrs' ELSE NULL END, expl = q.expl || jsonb_build_object( 'last_price', COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'price')::numeric, (hist -> q.v1ds -> 'dss' ->> 'price')::numeric, (hist -> 'mrq' ->> 'price')::numeric, (hist -> 'mrs' ->> 'price')::numeric ), 'last_qty', COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'qty')::numeric, (hist -> q.v1ds -> 'dss' ->> 'qty')::numeric, (hist -> 'mrq' ->> 'qty')::numeric, (hist -> 'mrs' ->> 'qty')::numeric ), 'last_dataseg', COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'datasegment'), (hist -> q.v1ds -> 'dss' ->> 'datasegment'), (hist -> 'mrq' ->> 'datasegment'), (hist -> 'mrs' ->> 'datasegment') ), 'last_source', CASE WHEN (hist -> q.v1ds -> 'dsq' ->> 'price') IS NOT NULL THEN 'dsq' WHEN (hist -> q.v1ds -> 'dss' ->> 'price') IS NOT NULL THEN 'dss' WHEN (hist -> 'mrq' ->> 'price') IS NOT NULL THEN 'mrq' WHEN (hist -> 'mrs' ->> 'price') IS NOT NULL THEN 'mrs' ELSE NULL END, 'last_date', COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'odate')::date, (hist -> q.v1ds -> 'dss' ->> 'odate')::date, (hist -> 'mrq' ->> 'odate')::date, (hist -> 'mrs' ->> 'odate')::date ), 'last_order', COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'ordnum'), (hist -> q.v1ds -> 'dss' ->> 'ordnum'), (hist -> 'mrq' ->> 'ordnum'), (hist -> 'mrs' ->> 'ordnum') ), 'last_quote', COALESCE( (hist -> q.v1ds -> 'dsq' ->> 'quoten'), (hist -> q.v1ds -> 'dss' ->> 'quoten'), (hist -> 'mrq' ->> 'quoten'), (hist -> 'mrs' ->> 'quoten') ), 'mrs', hist -> 'mrs', 'mrq', hist -> 'mrq', 'lvs', hist -> 'lvs', 'lvq', hist -> 'lvq', 'dss', hist -> q.v1ds -> 'dss', 'dsq', hist -> q.v1ds -> 'dsq' ) FROM ( SELECT q.ctid, lp.part_stats AS hist FROM pricequote.queue q JOIN pricequote.lastpricedetail lp ON lp.customer = q.cust AND lp.partgroup = q.partgroup ) sub WHERE q.ctid = sub.ctid; ----------------------------------------------------------------------- -- 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; ----------------------------------------------------------------------- -- 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; ----------------------------------------------------------------------- -- 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'; ----------------------------------------------------------------------- -- Done ----------------------------------------------------------------------- RAISE NOTICE 'Queue processing complete.'; END; $$;