diff --git a/procs/matrix_guidance.pg.sql b/procs/matrix_guidance.pg.sql index 6f92a9b..4f59283 100644 --- a/procs/matrix_guidance.pg.sql +++ b/procs/matrix_guidance.pg.sql @@ -1,247 +1,235 @@ +-- 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, - 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 + 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 ); -/* -==================================================================================== - 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 +CREATE INDEX IF NOT EXISTS idx_osm_stack_merge +ON rlarp.osm_stack (bill_cust, ship_cust, part, stlc, dataseg, qtyord); - 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 +CREATE INDEX IF NOT EXISTS idx_queue_merge +ON pricequote.queue (bill, ship, part, stlc, v1ds, vol); - 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 -); - - +-- 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 - - ----------------------------------------------------------------------- - -- Step 1: Seed the queue table with distinct pricing scenarios - ----------------------------------------------------------------------- + -------------------------------------------------------------------- + -- 1) Seed queue from matrix + -------------------------------------------------------------------- DELETE FROM pricequote.queue; - INSERT INTO pricequote.queue (bill, ship, part, stlc, v1ds, vol, expl) + INSERT INTO pricequote.queue (bill, ship, part, stlc, v1ds, vol, expl, ui_json) SELECT DISTINCT - o.bill_cust AS bill, - o.ship_cust AS ship, + o.bill_cust, + o.ship_cust, o.part, o.stlc, - o.dataseg AS v1ds, - o.qtyord AS vol, - '{}'::jsonb AS expl + o.dataseg, + o.qtyord, + '{}'::jsonb, + '{}'::jsonb FROM rlarp.osm_stack o - WHERE + 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 + AND SUBSTRING(o.glec, 1, 1) <= '2'; + -- 46 seconds - - ----------------------------------------------------------------------- - -- Step 2: Enrich customer, tier, channel, pack quantity, and level - ----------------------------------------------------------------------- + -------------------------------------------------------------------- + -- 2) Enrich: chan, tier, cust, pltq, plevel, partgroup (+stlc fix) + -------------------------------------------------------------------- MERGE INTO pricequote.queue q USING ( - SELECT + 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 + 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 + 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 + 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 + 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 - ) 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 + ) 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 - ----------------------------------------------------------------------- - -- Step 3: Apply target prices and embed target metadata - ----------------------------------------------------------------------- + -------------------------------------------------------------------- + -- 3) Scenario fields from item master: part_v1ds, v0ds, orig costs + -- + customized flag + -------------------------------------------------------------------- UPDATE pricequote.queue q - SET + 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 = lp.part_stats, + 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, 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 + ) x + JOIN pricequote.lastpricedetail lp ON TRUE + WHERE q.ctid = x.ctid; + + -------------------------------------------------------------------- + -- 5) Target (requested v1ds): tprice, tmath, volume_range + -------------------------------------------------------------------- + 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 - ) + tmath = tp.math, + volume_range = tp.vol::TEXT FROM pricequote.target_prices tp - WHERE + 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 + AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp.vol; - ----------------------------------------------------------------------- - -- 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 + -------------------------------------------------------------------- + -- 6) Target for last_dataseg (tprice_last) + -------------------------------------------------------------------- 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 + 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.vol / NULLIF(q.pltq, 0))::INT <@ tp2.vol; - ----------------------------------------------------------------------- - -- Step 5: Resolve best list price and insert it with list code - ----------------------------------------------------------------------- + -------------------------------------------------------------------- + -- 7) Cost data for requested v1ds and last_dataseg + -------------------------------------------------------------------- + UPDATE pricequote.queue q + SET + curstd = i_req.curstdus, + futstd = i_req.futstdus + FROM "CMS.CUSLG".itemm i_req + WHERE i_req.item = q.part AND i_req.v1ds = q.v1ds; + + UPDATE pricequote.queue q + SET + curstd_last = i_last.curstdus, + futstd_last = i_last.futstdus + FROM "CMS.CUSLG".itemm i_last + WHERE i_last.item = q.part AND i_last.v1ds = q.last_dataseg; + + -------------------------------------------------------------------- + -- 8) List price (lowest valid); allow open-ended ranges (vb_to IS NULL) + -------------------------------------------------------------------- WITH ranked_prices AS ( - SELECT + SELECT q.ctid, pr.price, pr.jcplcd, @@ -254,58 +242,230 @@ BEGIN ON pr.jcplcd = TRIM(i.jbplcd) AND pr.jcpart = q.part AND q.vol >= pr.vb_from - AND q.vol < pr.vb_to + 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 - list_price = p.price, - list_code = p.jcplcd, - expl = q.expl || jsonb_build_object( - 'list_price', p.price, - 'list_code', p.jcplcd - ) + SET + listprice = p.price, + listcode = p.jcplcd FROM best_price p WHERE q.ctid = p.ctid; - -- 15 seconds - ----------------------------------------------------------------------- - -- Step 6: Compute guidance price using logic function - ----------------------------------------------------------------------- + -------------------------------------------------------------------- + -- 9) Normalize last (when last_dataseg != v1ds) + effective list flags + -------------------------------------------------------------------- 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 + 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 q.curstd / q.curstd_last + 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; + -------------------------------------------------------------------- + -- 10) Guidance using normalized last + effective list + -------------------------------------------------------------------- + UPDATE pricequote.queue q + SET + guidance_price = g.guidance_price, + guidance_reason = g.guidance_reason + FROM LATERAL pricequote.guidance_logic(q.tprice, q.last_price_norm, q.listprice_eff, q.last_date) g + WHERE q.ctid IS NOT NULL; - ----------------------------------------------------------------------- - -- Step 7: merge the results back into sales matrix - ----------------------------------------------------------------------- + -------------------------------------------------------------------- + -- 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 + ), + '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 + ); + + -------------------------------------------------------------------- + -- 12) Merge back into matrix (store both expl and ui) + -------------------------------------------------------------------- UPDATE rlarp.osm_stack o - SET pricing = pricing || q.expl + SET pricing = pricing + || jsonb_build_object( + 'expl', q.expl, + 'ui', q.ui_json + ) FROM pricequote.queue q - WHERE + WHERE o.bill_cust = q.bill AND o.ship_cust IS NOT DISTINCT FROM q.ship AND o.part = q.part @@ -316,12 +476,8 @@ BEGIN 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 + AND SUBSTRING(o.glec, 1, 1) <= '2'; - ----------------------------------------------------------------------- - -- Done - ----------------------------------------------------------------------- RAISE NOTICE 'Queue processing complete.'; END; $$;