diff --git a/procs/single_price_call.ms.sql b/procs/single_price_call.ms.sql index db3beb3..b5d826b 100644 --- a/procs/single_price_call.ms.sql +++ b/procs/single_price_call.ms.sql @@ -85,49 +85,56 @@ BEGIN bill VARCHAR(100), ship VARCHAR(100), part VARCHAR(100), - stlc VARCHAR(100), - partgroup VARCHAR(100), v1ds VARCHAR(100), vol NUMERIC(18,6), + ------------step 1 lookup scenario------------ + chan VARCHAR(50), + tier VARCHAR(50), + cust VARCHAR(100), + pltq NUMERIC(18,6), + plevel NVARCHAR(20), + stlc VARCHAR(100), + partgroup VARCHAR(100), part_v1ds VARCHAR(50), + v0ds VARCHAR(10), curstd_orig NUMERIC(20,5), futstd_orig NUMERIC(20,5), - v0ds VARCHAR(10), - curstd NUMERIC(20,5), - futstd NUMERIC(20,5), customized VARCHAR(100), - last_premium NUMERIC(20,5), - chan VARCHAR(50), - cust VARCHAR(100), - tier VARCHAR(50), - pltq NUMERIC(18,6), calculated_pallets numeric(20,0), exact_pallets numeric(20,5), - volume_range VARCHAR(100), - plevel NVARCHAR(20), - listprice NUMERIC(20,5), - listcode VARCHAR(10), - listprice_eff NUMERIC(20,5), - list_relevance NVARCHAR(100), + ----------- step 2 last price------------------ hist NVARCHAR(MAX), last_price NUMERIC(20,5), - last_qty NUMERIC(20,5), + last_source NVARCHAR(100), last_date DATE, + last_qty NUMERIC(20,5), + last_dataseg NVARCHAR(20), + last_v0ds VARCHAR(10), last_order NVARCHAR(10), last_quote NVARCHAR(10), - last_dataseg NVARCHAR(20), - last_source NVARCHAR(100), last_isdiff NVARCHAR(100), - last_v0ds VARCHAR(10), - last_price_norm NUMERIC(20,5), - last_premium_method VARCHAR(100), + ------------step 3 lookup target--------------- + tprice NUMERIC(20,5), + tprice_last NUMERIC(20,5), + tmath nvarchar(MAX), + volume_range VARCHAR(100), + ------------step 4 normalize last price-------- + curstd NUMERIC(20,5), + futstd NUMERIC(20,5), curstd_last NUMERIC(20,5), futstd_last NUMERIC(20,5), - tprice_last NUMERIC(20,5), - tprice NUMERIC(20,5), - tmath nvarchar(MAX), + last_premium NUMERIC(20,5), + last_price_norm NUMERIC(20,5), + last_premium_method VARCHAR(100), + ------------step 5 list price lookup----------- + listcode VARCHAR(10), + listprice NUMERIC(20,5), + listprice_eff NUMERIC(20,5), + list_relevance NVARCHAR(100), + ------------step 6 compute guidance------------ guidance_price NUMERIC(20,5), guidance_reason NVARCHAR(MAX), + ------------step 7 build json------------------ expl NVARCHAR(MAX), ui_json NVARCHAR(MAX) ); @@ -507,4 +514,4 @@ BEGIN -- Final: Return all calculated fields and JSON payloads. -------------------------------------------------------------------------------- SELECT guidance_price, ui_json FROM @queue; -END; \ No newline at end of file +END; diff --git a/procs/single_price_call.pg.sql b/procs/single_price_call.pg.sql index fdb2ab5..5fc76c6 100644 --- a/procs/single_price_call.pg.sql +++ b/procs/single_price_call.pg.sql @@ -92,12 +92,17 @@ RETURNS TABLE ( ui_json JSONB ) AS $$ DECLARE - _pltq NUMERIC; - _calculated_pallets INT; - _exact_pallets NUMERIC; + -----------input parameters-------------- + -- _bill + -- _ship + -- _part + -- _v1ds + -- _vol + ------------step 1 lookup scenario------------ _chan TEXT; _tier TEXT; _cust TEXT; + _pltq NUMERIC; _plevel TEXT; _partgroup TEXT; _stlc TEXT; @@ -105,36 +110,44 @@ DECLARE _v0ds TEXT; _curstd_orig NUMERIC; _futstd_orig NUMERIC; + _calculated_pallets INT; + _exact_pallets NUMERIC; + _customized TEXT := ''; + ----------- step 2 last price------------------ + _hist JSONB := '{}'::jsonb; + _last JSONB; + _last_price NUMERIC; + _last_source TEXT; + _last_date DATE; + _last_qty NUMERIC; + _last_dataseg TEXT; + _last_v0ds TEXT; + _last_order TEXT; + _last_quote TEXT; + _last_isdiff TEXT; + _last_part TEXT; + ------------step 3 lookup target--------------- + _tprice NUMERIC; + _tmath JSONB; + _volume_range TEXT; + _tprice_last NUMERIC; + ------------step 4 normalize last price-------- _curstd NUMERIC; _futstd NUMERIC; _curstd_last NUMERIC; _futstd_last NUMERIC; - _customized TEXT := ''; - _last_part TEXT; _last_premium NUMERIC; - _last_premium_method TEXT; _last_price_norm NUMERIC; - _last_isdiff TEXT; - _last_v0ds TEXT; - _tprice_last NUMERIC; - _tprice NUMERIC; - _tmath JSONB; - _volume_range TEXT; + _last_premium_method TEXT; + ------------step 5 list price lookup----------- _list_price NUMERIC; _list_code TEXT; _listprice_eff NUMERIC; _list_relevance TEXT; + ------------step 6 compute guidance------------ _guidance_price NUMERIC; _guidance_reason TEXT; - _hist JSONB := '{}'::jsonb; - _last JSONB; - _last_price NUMERIC; - _last_qty NUMERIC; - _last_dataseg TEXT; - _last_date DATE; - _last_order TEXT; - _last_quote TEXT; - _last_source TEXT; + ------------step 7 build json------------------ _expl JSONB := '{}'::jsonb; _ui_json JSONB := '{}'::jsonb; BEGIN @@ -142,7 +155,6 @@ BEGIN -- Step 1: Resolve customer metadata and part master data ------------------------------------------------------------------ SELECT - i.mpck, CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) @@ -150,11 +162,11 @@ BEGIN ELSE 'DRP' END ELSE 'DIR' - END, + END chan, CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIR' THEN bc.tier ELSE COALESCE(sc.tier, bc.tier) - END, + END tier, CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) @@ -162,7 +174,8 @@ BEGIN ELSE sc.dba END ELSE bc.dba - END, + END cust, + i.mpck, CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) @@ -170,80 +183,108 @@ BEGIN ELSE bc.plevel END ELSE bc.plevel - END, + END plevel, + substring(_part,1,8) stlc, i.partgroup, - substring(_part,1,8), - i.v1ds, - CASE substring(_v1ds,4,1) WHEN 'B' THEN 'B' ELSE 'C' END || CASE substring(_v1ds,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END, + i.v1ds part_v1ds, + CASE substring(_v1ds,4,1) WHEN 'B' THEN 'B' ELSE 'C' END || CASE substring(_v1ds,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END v0ds, i.curstdus, i.futstdus, FLOOR(_vol / NULLIF(i.mpck, 0)), ROUND(_vol / NULLIF(i.mpck, 0), 5) INTO - _pltq, _chan, _tier, _cust, _plevel, _partgroup, _stlc, _part_v1ds, _v0ds, _curstd_orig, _futstd_orig, _calculated_pallets, _exact_pallets - FROM rlarp.cust bc - LEFT JOIN rlarp.cust sc ON sc.code = _ship - LEFT JOIN "CMS.CUSLG".itemm i ON i.item = _part - WHERE bc.code = _bill; + _chan + ,_tier + ,_cust + ,_pltq + ,_plevel + ,_stlc + ,_partgroup + ,_part_v1ds + ,_v0ds + ,_curstd_orig + ,_futstd_orig + ,_calculated_pallets + ,_exact_pallets + FROM + rlarp.cust bc + LEFT JOIN rlarp.cust sc ON + sc.code = _ship + LEFT JOIN "CMS.CUSLG".itemm i ON + i.item = _part + WHERE + bc.code = _bill; -- Customized flag IF _part_v1ds IS NOT NULL AND _v1ds IS NOT NULL AND _part_v1ds <> _v1ds THEN _customized := 'Customized'; END IF; - RAISE NOTICE 'Debug Inputs => stlc: "%", v1ds: "%", chan: "%", tier: "%", pallets: "%" , pltq: "%"', - _stlc, _v1ds, _chan, _tier, _calculated_pallets, _pltq; + -- RAISE NOTICE 'Debug Inputs => stlc: "%", v1ds: "%", chan: "%", tier: "%", pallets: "%" , pltq: "%"', + -- _stlc, _v1ds, _chan, _tier, _calculated_pallets, _pltq; + + -------------------------------------------------------------------------------- + -- Step 3: Lookup Last Price + -------------------------------------------------------------------------------- + SELECT + lp.part_stats + INTO + _hist + FROM + pricequote.lastpricedetail lp + WHERE + lp.customer = _cust + AND lp.partgroup = _partgroup; + + _last := pricequote.pick_last_price_from_hist(_hist, _v1ds); + _last_price := (_last->>'price')::numeric; + _last_source := _last->>'source'; + _last_date := (_last->>'odate')::date; + _last_qty := (_last->>'qty')::numeric; + _last_dataseg := _last->>'datasegment'; + _last_v0ds := + CASE substring(_last_dataseg,4,1) WHEN 'B' THEN 'B' ELSE 'C' END || + CASE substring(_last_dataseg,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END; + _last_order := _last->>'ordnum'; + _last_quote := _last->>'quoten'; + IF _last_dataseg IS NOT NULL AND _v1ds IS NOT NULL AND _last_dataseg <> _v1ds THEN + _last_isdiff := 'Last Sale Diff Part'; + END IF; + _last_part := _last->>'part'; ------------------------------------------------------------------ -- Step 2: Target price logic (current and for last_dataseg) ------------------------------------------------------------------ - SELECT tp.price, to_json(tp.math), tp.vol::text - INTO _tprice, _tmath, _volume_range - FROM pricequote.target_prices tp - WHERE tp.stlc = _stlc + SELECT + tp.price + ,to_json(tp.math) + ,tp.vol::text + INTO + _tprice + ,_tmath + ,_volume_range + FROM + pricequote.target_prices tp + WHERE + tp.stlc = _stlc AND tp.ds = _v1ds AND tp.chan = _chan AND tp.tier = _tier AND tp.vol @> _calculated_pallets; - RAISE NOTICE 'Debug: tprice=%, tmath=%, volume_range=%', - _tprice, _tmath, _volume_range; + -- RAISE NOTICE 'Debug: tprice=%, tmath=%, volume_range=%', + -- _tprice, _tmath, _volume_range; - ------------------------------------------------------------------ - -- Step 3: Last sale/quote/volume/segment data - ------------------------------------------------------------------ - SELECT lp.part_stats INTO _hist - FROM pricequote.lastpricedetail lp - WHERE lp.customer = _cust - AND lp.partgroup = _partgroup; - - _last := pricequote.pick_last_price_from_hist(_hist, _v1ds); - _last_price := (_last->>'price')::numeric; - _last_qty := (_last->>'qty')::numeric; - _last_dataseg := _last->>'datasegment'; - _last_date := (_last->>'odate')::date; - _last_order := _last->>'ordnum'; - _last_quote := _last->>'quoten'; - _last_source := _last->>'source'; - _last_part := _last->>'part'; - - - - -- last_v0ds logic - _last_v0ds := - CASE substring(_last_dataseg,4,1) WHEN 'B' THEN 'B' ELSE 'C' END || - CASE substring(_last_dataseg,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END; - - -- last_isdiff logic - IF _last_dataseg IS NOT NULL AND _v1ds IS NOT NULL AND _last_dataseg <> _v1ds THEN - _last_isdiff := 'Last Sale Diff Part'; - END IF; -- Target price for last_dataseg - SELECT tp.price - INTO _tprice_last - FROM pricequote.target_prices tp - WHERE tp.stlc = _stlc + SELECT + tp.price + INTO + _tprice_last + FROM + pricequote.target_prices tp + WHERE + tp.stlc = _stlc AND tp.ds = _last_dataseg AND tp.chan = _chan AND tp.tier = _tier @@ -253,14 +294,26 @@ BEGIN -- Step 4: Cost data for normalization ------------------------------------------------------------------ -- Current/future standard for requested v1ds - SELECT curstdus, futstdus INTO _curstd, _futstd - FROM "CMS.CUSLG".itemm i - WHERE i.item = _part AND i.v1ds = _v1ds; + SELECT + curstdus, futstdus + INTO + _curstd, _futstd + FROM + "CMS.CUSLG".itemm i + WHERE + i.item = _part + AND i.v1ds = _v1ds; -- Current/future standard for last_dataseg - SELECT curstdus, futstdus INTO _curstd_last, _futstd_last - FROM "CMS.CUSLG".itemm i - WHERE i.item = _part AND i.v1ds = _last_dataseg; + SELECT + curstdus, futstdus + INTO + _curstd_last, _futstd_last + FROM + "CMS.CUSLG".itemm i + WHERE + i.item = _part + AND i.v1ds = _last_dataseg; ------------------------------------------------------------------ -- Step 5: Normalize last price if needed @@ -285,17 +338,24 @@ BEGIN ------------------------------------------------------------------ -- Step 6: List price logic ------------------------------------------------------------------ - SELECT pr.price::numeric(20,5), pr.jcplcd - INTO _list_price, _list_code - FROM "CMS.CUSLG".IPRCBHC i - JOIN pricequote.pricelist_ranged pr - ON pr.jcplcd = TRIM(i.jbplcd) - AND pr.jcpart = _part - AND _vol >= pr.vb_from - AND (_vol < pr.vb_to OR pr.vb_to IS NULL) - WHERE TRIM(i.jbplvl) = TRIM(_plevel) - AND CURRENT_DATE BETWEEN i.jbfdat AND i.jbtdat - ORDER BY pr.price ASC + SELECT + pr.price::numeric(20,5) + ,pr.jcplcd + INTO + _list_price + ,_list_code + FROM + "CMS.CUSLG".IPRCBHC i + JOIN pricequote.pricelist_ranged pr ON + pr.jcplcd = TRIM(i.jbplcd) + AND pr.jcpart = _part + AND _vol >= pr.vb_from + AND (_vol < pr.vb_to OR pr.vb_to IS NULL) + WHERE + TRIM(i.jbplvl) = TRIM(_plevel) + AND CURRENT_DATE BETWEEN i.jbfdat AND i.jbtdat + ORDER BY + pr.price ASC LIMIT 1; -- List price relevance @@ -310,8 +370,12 @@ BEGIN ------------------------------------------------------------------ -- Step 7: Compute guidance price and embed it ------------------------------------------------------------------ - SELECT gl.guidance_price, gl.guidance_reason - INTO _guidance_price, _guidance_reason + SELECT + gl.guidance_price + ,gl.guidance_reason + INTO + _guidance_price + ,_guidance_reason FROM pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date) gl; ------------------------------------------------------------------