-- Recreate queue with columns matching single_price_call outputs 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, partgroup TEXT, part_v1ds TEXT, v0ds TEXT, curstd_orig NUMERIC, futstd_orig NUMERIC, curstd NUMERIC, futstd NUMERIC, curstd_last NUMERIC, futstd_last NUMERIC, customized TEXT, last_premium NUMERIC, last_premium_method TEXT, last_price_norm NUMERIC, last_isdiff TEXT, last_v0ds TEXT, tprice_last NUMERIC, last_price NUMERIC, last_qty NUMERIC, last_dataseg TEXT, last_date DATE, last_order TEXT, last_quote TEXT, last_source TEXT, hist JSONB, tprice NUMERIC, tmath JSONB, volume_range TEXT, listprice NUMERIC, listcode TEXT, listprice_eff NUMERIC, list_relevance TEXT, guidance_price NUMERIC, guidance_reason TEXT, expl JSONB, ui_json JSONB ); CREATE INDEX IF NOT EXISTS idx_osm_stack_merge ON rlarp.osm_stack (bill_cust, ship_cust, part, stlc, dataseg, qtyord); CREATE INDEX IF NOT EXISTS idx_queue_merge ON pricequote.queue (bill, ship, part, stlc, v1ds, vol); -- Batch procedure mirroring single_price_call logic (4-space indentation) --DROP PROCEDURE IF EXISTS pricequote.process_queue; CREATE OR REPLACE PROCEDURE pricequote.process_queue() LANGUAGE plpgsql AS $$ BEGIN -------------------------------------------------------------------- -- 1) Seed queue from matrix -------------------------------------------------------------------- DELETE FROM pricequote.queue; INSERT INTO pricequote.queue (bill, ship, part, stlc, v1ds, vol, expl, ui_json) SELECT DISTINCT o.bill_cust, o.ship_cust, o.part, o.stlc, o.dataseg, o.qtyord, '{}'::jsonb, '{}'::jsonb 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'; -- 46 seconds -------------------------------------------------------------------- -- 2) Enrich: chan, tier, cust, pltq, plevel, partgroup (+stlc fix) -------------------------------------------------------------------- MERGE INTO pricequote.queue q USING ( SELECT q.ctid, 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 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) WHEN 'DIS' THEN bc.dba ELSE sc.dba END ELSE bc.dba END AS cust, i.mpck AS pltq, 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 AS partgroup, SUBSTRING(q.part, 1, 8) AS stlc_fix 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 ) s ON (q.ctid = s.ctid) WHEN MATCHED THEN UPDATE SET chan = s.chan, tier = s.tier, cust = s.cust, pltq = s.pltq, plevel = s.plevel, partgroup = s.partgroup, stlc = COALESCE(q.stlc, s.stlc_fix); -- 16 seconds -------------------------------------------------------------------- -- 3) Scenario fields from item master: part_v1ds, v0ds, orig costs -- + customized flag -------------------------------------------------------------------- UPDATE pricequote.queue q SET part_v1ds = i0.v1ds, v0ds = (CASE SUBSTRING(q.v1ds, 4, 1) WHEN 'B' THEN 'B' ELSE 'C' END) || (CASE SUBSTRING(q.v1ds, 6, 1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END), curstd_orig = i0.curstdus, futstd_orig = i0.futstdus, customized = CASE WHEN i0.v1ds IS NOT NULL AND q.v1ds IS NOT NULL AND i0.v1ds <> q.v1ds THEN 'Customized' ELSE '' END FROM "CMS.CUSLG".itemm i0 WHERE i0.item = q.part; -- 16 seconds -------------------------------------------------------------------- -- 4) History: store hist, extract last_* with precedence helper -------------------------------------------------------------------- UPDATE pricequote.queue q SET hist = x.part_stats, -- from the correlated subquery last_price = (j->>'price')::NUMERIC, last_qty = (j->>'qty')::NUMERIC, last_dataseg = j->>'datasegment', last_date = (j->>'odate')::DATE, last_order = j->>'ordnum', last_quote = j->>'quoten', last_source = j->>'source', last_isdiff = CASE WHEN (j->>'datasegment') IS NOT NULL AND q.v1ds IS NOT NULL AND (j->>'datasegment') <> q.v1ds THEN 'Last Sale Diff Part' END, last_v0ds = (CASE SUBSTRING(j->>'datasegment', 4, 1) WHEN 'B' THEN 'B' ELSE 'C' END) || (CASE SUBSTRING(j->>'datasegment', 6, 1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END) FROM ( SELECT q2.ctid, lp2.part_stats, pricequote.pick_last_price_from_hist(lp2.part_stats, q2.v1ds) AS j FROM pricequote.queue q2 JOIN pricequote.lastpricedetail lp2 ON lp2.customer = q2.cust AND lp2.partgroup = q2.partgroup ) AS x WHERE q.ctid = x.ctid; -- 2 min 3 sec -------------------------------------------------------------------- -- 5) Target (requested v1ds): tprice, tmath, volume_range -------------------------------------------------------------------- UPDATE pricequote.queue q SET tprice = tp.price, tmath = to_json(tp.math), volume_range = tp.vol::TEXT 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; -- 22 seconds -------------------------------------------------------------------- -- 6) Target for last_dataseg (tprice_last) -------------------------------------------------------------------- UPDATE pricequote.queue q SET tprice_last = tp2.price FROM pricequote.target_prices tp2 WHERE q.last_dataseg IS NOT NULL AND tp2.stlc = q.stlc AND tp2.ds = q.last_dataseg AND tp2.chan = q.chan AND tp2.tier = q.tier AND FLOOR(q.last_qty / NULLIF(q.pltq, 0))::INT <@ tp2.vol; -- 17 sec -------------------------------------------------------------------- -- 7) Cost data for requested v1ds and last_dataseg -------------------------------------------------------------------- UPDATE pricequote.queue q SET curstd = CASE WHEN COALESCE(q.customized,'') = '' THEN q.curstd_orig ELSE COALESCE(s.v1_cur, s.v0_cur) END, futstd = CASE WHEN COALESCE(q.customized,'') = '' THEN q.futstd_orig ELSE COALESCE(s.v1_fut, s.v0_fut) END, curstd_last = CASE WHEN COALESCE(q.last_isdiff,'') = '' THEN q.curstd_orig ELSE COALESCE(s.v1l_cur, s.v0l_cur) END, futstd_last = CASE WHEN COALESCE(q.last_isdiff,'') = '' THEN q.futstd_orig ELSE COALESCE(s.v1l_fut, s.v0l_fut) END FROM ( SELECT q2.ctid, v1.curstdus AS v1_cur, v1.futstdus AS v1_fut, v0.curstdus AS v0_cur, v0.futstdus AS v0_fut, v1l.curstdus AS v1l_cur, v1l.futstdus AS v1l_fut, v0l.curstdus AS v0l_cur, v0l.futstdus AS v0l_fut FROM pricequote.queue q2 LEFT JOIN rlarp.cost_v1ds v1 ON v1.stlc = q2.stlc AND v1.v1ds = q2.v1ds LEFT JOIN rlarp.cost_v0ds v0 ON v0.stlc = q2.stlc AND v0.v0ds = q2.v0ds LEFT JOIN rlarp.cost_v1ds v1l ON v1l.stlc = q2.stlc AND v1l.v1ds = q2.last_dataseg LEFT JOIN rlarp.cost_v0ds v0l ON v0l.stlc = q2.stlc AND v0l.v0ds = q2.last_v0ds ) AS s WHERE q.ctid = s.ctid; -- 28 seconds -------------------------------------------------------------------- -- 8) List price (lowest valid); allow open-ended ranges (vb_to IS NULL) -------------------------------------------------------------------- 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 OR pr.vb_to IS NULL) ), best_price AS ( SELECT * FROM ranked_prices WHERE rn = 1 ) UPDATE pricequote.queue q SET listprice = p.price, listcode = p.jcplcd FROM best_price p WHERE q.ctid = p.ctid; -- 18 seconds -------------------------------------------------------------------- -- 9) Normalize last (when last_dataseg != v1ds) + effective list flags -------------------------------------------------------------------- UPDATE pricequote.queue q SET last_premium = CASE WHEN q.last_isdiff IS NOT NULL AND q.tprice_last IS NOT NULL AND q.tprice IS NOT NULL AND q.tprice_last <> 0 THEN ROUND(q.tprice / q.tprice_last, 5) WHEN q.last_isdiff IS NOT NULL AND q.curstd_last IS NOT NULL AND q.curstd IS NOT NULL AND q.curstd_last <> 0 THEN ROUND(q.curstd / q.curstd_last,5) END, last_premium_method = CASE WHEN q.last_isdiff IS NOT NULL AND q.tprice_last IS NOT NULL AND q.tprice IS NOT NULL AND q.tprice_last <> 0 THEN 'Target Price Ratio' WHEN q.last_isdiff IS NOT NULL AND q.curstd_last IS NOT NULL AND q.curstd IS NOT NULL AND q.curstd_last <> 0 THEN 'Cost Ratio' WHEN q.last_isdiff IS NOT NULL THEN 'Unknown' END, last_price_norm = CASE WHEN q.last_isdiff IS NOT NULL AND q.tprice_last IS NOT NULL AND q.tprice IS NOT NULL AND q.tprice_last <> 0 THEN ROUND(q.last_price * (q.tprice / q.tprice_last), 5) WHEN q.last_isdiff IS NOT NULL AND q.curstd_last IS NOT NULL AND q.curstd IS NOT NULL AND q.curstd_last <> 0 THEN ROUND(q.last_price * (q.curstd / q.curstd_last), 5) ELSE q.last_price END, listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END, list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END; -- 21 seconds -------------------------------------------------------------------- -- 10) Guidance using normalized last + effective list -------------------------------------------------------------------- UPDATE pricequote.queue q SET guidance_price = s.guidance_price, guidance_reason = s.guidance_reason FROM ( SELECT q2.ctid, g.guidance_price, g.guidance_reason FROM pricequote.queue q2 JOIN LATERAL pricequote.guidance_logic( q2.tprice, q2.last_price_norm, q2.listprice_eff, q2.last_date, .05, 1.0, 1.0 ) g ON TRUE ) s WHERE q.ctid = s.ctid; -- 31 seconds -------------------------------------------------------------------- -- 11) Build expl and ui_json identical to single_price_call -------------------------------------------------------------------- UPDATE pricequote.queue q SET expl = jsonb_build_object( 'last', jsonb_build_object( 'last_part', (pricequote.pick_last_price_from_hist(q.hist, q.v1ds)->>'part'), 'last_price', q.last_price, 'last_qty', q.last_qty, 'last_dataseg', q.last_dataseg, 'last_v0ds', q.last_v0ds, 'last_source', q.last_source, 'last_date', q.last_date, 'last_order', q.last_order, 'last_quote', q.last_quote, 'last_isdiff', q.last_isdiff, 'last_premium', q.last_premium, 'last_premium_method', q.last_premium_method, 'last_price_norm', q.last_price_norm, 'tprice_last', q.tprice_last ), 'scenario', jsonb_build_object( 'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0)), 'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0), 5), 'customer', q.cust, 'channel', q.chan, 'tier', TRIM(q.tier), 'v1ds', q.v1ds, 'v0ds', q.v0ds, 'part_v1ds', q.part_v1ds, 'customized', q.customized ), 'cost', jsonb_build_object( 'curstd_orig', q.curstd_orig, 'futstd_orig', q.futstd_orig, 'curstd_last', q.curstd_last, 'futstd_last', q.futstd_last, 'curstd', q.curstd, 'futstd', q.futstd ), 'targets', jsonb_build_object( 'target_price', q.tprice, 'target_math', q.tmath, 'volume_range', q.volume_range ), 'list', jsonb_build_object( 'listcode', q.listcode, 'listprice', q.listprice, 'listprice_eff', q.listprice_eff, 'list_relevance', q.list_relevance ), 'guidance_price', q.guidance_price, 'guidance_reason', q.guidance_reason ), ui_json = jsonb_build_object( 'details', jsonb_build_array( jsonb_build_object( 'label', 'History', 'details', jsonb_build_array( jsonb_build_object( 'label', CASE WHEN q.last_price IS NOT NULL THEN 'Last Sale: ' || q.last_date ELSE 'No Recent' END, 'value', COALESCE(q.last_price, 0), 'type', 'currency', 'note', CASE WHEN q.last_price IS NOT NULL THEN CASE q.last_source WHEN 'mrq' THEN 'Recent similar ' || (pricequote.pick_last_price_from_hist(q.hist, q.v1ds)->>'part') || ' qty: ' || q.last_qty WHEN 'mrs' THEN 'Recent similar ' || (pricequote.pick_last_price_from_hist(q.hist, q.v1ds)->>'part') || ' qty: ' || q.last_qty WHEN 'dsq' THEN 'Last quote qty: ' || q.last_qty WHEN 'dss' THEN 'Last sale qty: ' || q.last_qty ELSE '' END || CASE WHEN COALESCE(q.last_order, '0') = '0' THEN ' Qt# ' || COALESCE(q.last_quote, '') ELSE ' Ord# ' || COALESCE(q.last_order, '') END END ) ) || CASE WHEN COALESCE(q.last_premium, 1) <> 1 THEN jsonb_build_array( jsonb_build_object( 'label', 'Price Difference', 'value', q.last_premium, 'type', 'percent', 'note', q.last_premium_method ) ) ELSE '[]'::jsonb END || CASE WHEN COALESCE(q.last_premium, 1) <> 1 THEN jsonb_build_array( jsonb_build_object( 'label', 'Adjusted Price', 'value', q.last_price_norm, 'type', 'currency', 'note', 'normalized to ' || q.v1ds ) ) ELSE '[]'::jsonb END ), jsonb_build_object( 'label', 'List', 'details', jsonb_build_array( jsonb_build_object( 'label', 'List:' || COALESCE(q.listcode, ''), 'value', q.listprice, 'type', 'currency', 'note', q.list_relevance ) ) ), jsonb_build_object( 'label', 'Target Calculation', 'details', ( SELECT jsonb_agg( jsonb_build_object( 'label', CASE WHEN v <> '' THEN RTRIM(SUBSTRING(v, 1, 18)) ELSE 'No Target' END, 'value', CASE WHEN v <> '' THEN SUBSTRING(v, 23, 7)::NUMERIC(20,5) + CASE SUBSTRING(v, 19, 1) WHEN '+' THEN 0 ELSE -1 END ELSE 0 END, 'type', CASE WHEN v <> '' THEN CASE SUBSTRING(v, 19, 1) WHEN '+' THEN 'currency' ELSE 'Percent' END ELSE '' END, 'note', CASE WHEN v <> '' THEN CASE SUBSTRING(v, 19, 1) WHEN '+' THEN 'Price' ELSE 'Premium' END ELSE '' END ) ) FROM jsonb_array_elements_text(COALESCE(q.tmath, '[""]'::jsonb)) AS t(v) ) || CASE WHEN q.tprice IS NULL THEN '[]'::jsonb ELSE jsonb_build_object('label', 'Price', 'value', COALESCE(q.tprice, 0), 'type', 'currency', 'note', 'Total') END ), jsonb_build_object( 'label', 'Guidance', 'details', jsonb_build_array( jsonb_build_object( 'label', 'Price', 'value', COALESCE(q.guidance_price, 0), 'type', 'currency', 'note', COALESCE(q.guidance_reason, '') ) ) ) ), 'data', q.expl ); -- 2 minutes 33 seconds -------------------------------------------------------------------- -- 12) Merge back into matrix (store both expl and ui) -------------------------------------------------------------------- UPDATE rlarp.osm_stack o SET pricing = pricing || jsonb_build_object( 'expl', q.expl, 'ui', q.ui_json ) 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'; -- 9 minutes 35 seconds RAISE NOTICE 'Queue processing complete.'; END; $$;