diff --git a/new_targets/procs/guidance_logic.pg.sql b/new_targets/procs/guidance_logic.pg.sql index c5e98cf..49dc279 100644 --- a/new_targets/procs/guidance_logic.pg.sql +++ b/new_targets/procs/guidance_logic.pg.sql @@ -13,9 +13,14 @@ DECLARE _reason TEXT := ''; _floored NUMERIC(20,5); _capped NUMERIC(20,5); - _is_last_recent BOOLEAN := _last_date IS NOT NULL AND _last_date > CURRENT_DATE - INTERVAL '2 years'; + _use_last_price BOOLEAN := FALSE; BEGIN - IF _target_price IS NOT NULL AND _last_price IS NOT NULL AND _is_last_recent THEN + -- Evaluate whether last price is recent enough + IF _last_price IS NOT NULL AND _last_date IS NOT NULL AND _last_date > CURRENT_DATE - INTERVAL '2 years' THEN + _use_last_price := TRUE; + END IF; + + IF _target_price IS NOT NULL AND _use_last_price THEN _floored := GREATEST(_target_price, _last_price * 0.95); _capped := LEAST(_floored, _last_price); _price := LEAST(COALESCE(_list_price, 1e9), _capped); @@ -35,17 +40,33 @@ BEGIN END IF; END IF; - ELSIF _last_price IS NOT NULL AND _is_last_recent THEN + ELSIF _use_last_price THEN _price := _last_price; _reason := 'Last price - no target'; ELSIF _target_price IS NOT NULL THEN _price := _target_price; - _reason := 'Target price - no prior sale'; + + IF _last_price IS NOT NULL AND _last_date IS NOT NULL THEN + _reason := format( + 'Last price ignored (too old: %s), using target price', + to_char(_last_date, 'YYYY-MM-DD') + ); + ELSE + _reason := 'Target price - no prior sale'; + END IF; ELSE _price := NULL; - _reason := 'No pricing available'; + + IF _last_price IS NOT NULL AND _last_date IS NOT NULL THEN + _reason := format( + 'Last price ignored (too old: %s), no pricing available', + to_char(_last_date, 'YYYY-MM-DD') + ); + ELSE + _reason := 'No pricing available'; + END IF; END IF; RETURN QUERY SELECT _price, _reason; diff --git a/new_targets/scripts/matrix_guidance.pg.sql b/new_targets/scripts/matrix_guidance.pg.sql new file mode 100644 index 0000000..e9e96aa --- /dev/null +++ b/new_targets/scripts/matrix_guidance.pg.sql @@ -0,0 +1,238 @@ +-- 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_date DATE, + last_order TEXT, + last_quote TEXT, + tprice NUMERIC, + list_price NUMERIC, + list_code TEXT, + guidance_price NUMERIC, + guidance_reason TEXT, + expl JSONB +); + + + +--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 + 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; + + ----------------------------------------------------------------------- + -- 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 most recent price history and embed it + ----------------------------------------------------------------------- + UPDATE pricequote.queue q + SET + last_price = ((lp.dataseg_stats -> q.v1ds)::jsonb ->> 'price')::numeric, + last_date = ((lp.dataseg_stats -> q.v1ds)::jsonb ->> 'odate')::date, + last_order = (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'ordnum', + last_quote = (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'quoten', + expl = q.expl || jsonb_build_object( + 'last_price', ((lp.dataseg_stats -> q.v1ds)::jsonb ->> 'price')::numeric, + 'last_date', (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'odate', + 'last_order', (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'ordnum', + 'last_quote', (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'quoten' + ) + FROM pricequote.lastprice lp + WHERE + lp.customer = q.cust + AND lp.partgroup = SUBSTRING(q.part, 1, 8); + + ----------------------------------------------------------------------- + -- 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; + + ----------------------------------------------------------------------- + -- Done + ----------------------------------------------------------------------- + RAISE NOTICE 'Queue processing complete.'; +END; +$$;