Compare commits

..

2 Commits

Author SHA1 Message Date
10ca238010 commit: 2025-08-08 17:36:58 2025-08-08 17:36:58 -04:00
68921d9a7f suggested changes 2025-08-08 09:33:20 -04:00
4 changed files with 208 additions and 69 deletions

View File

@ -1,10 +1,10 @@
EXEC pricing.single_price_call
@bill = 'GRIF0001',
@ship = 'GRIF0001',
@part = 'XNS0T1G3G18B096',
@v1ds = 'v1:B.L.PLT..',
@vol = 9600;
@bill = 'FARM0001',
@ship = 'KEYB0001',
@part = 'HZP3E100E21D050',
@v1ds = 'v1:T..PLT..',
@vol = 50000;
SELECT
@ -45,4 +45,15 @@ FROM
,q.units_each
) p
WHERE
qstat LIKE 'Submitted%'
qstat LIKE 'Submitted%'
SELECT
*
FROM pricequote.single_price_call(
'GRIF0001',
'GRIF0001',
'XNS0T1G3G18B096',
'v1:B..PLT..',
9600
) f

12
example_usage.pg.sql Normal file
View File

@ -0,0 +1,12 @@
SELECT
*
FROM pricequote.single_price_call(
'FARM0001',
'KEYB0001',
'HZP3E100E21D050',
'v1:L..BDL..',
50000
) f
SELECT * FROM pricequote.target_prices tp WHERE tp.stlc = 'HZP3E100' AND ds = 'v1:T..PLT..' and chan = 'DRP' and tier = '1' and vol @> 1;

View File

@ -466,7 +466,7 @@ BEGIN
RTRIM(SUBSTRING(value,1,18)) AS label,
TRY_CAST(SUBSTRING(value,23,7) AS NUMERIC(20,5))
+ CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END AS value,
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'Percentage' END AS type,
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'Percent' END AS type,
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'Price' ELSE 'Premium' END AS note
FROM OPENJSON(q.expl, '$.target_math')
WITH (value NVARCHAR(MAX) '$')
@ -497,5 +497,5 @@ BEGIN
--------------------------------------------------------------------------------
-- Final: Return all calculated fields and JSON payloads.
--------------------------------------------------------------------------------
SELECT * FROM @queue;
SELECT guidance_price, ui_json FROM @queue;
END;

View File

@ -34,6 +34,9 @@
- See also: matrix_guidance.pg.sql for batch/matrix logic
====================================================================================
*/
DROP FUNCTION pricequote.single_price_call(text,text,text,text,numeric);
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
_bill TEXT,
_ship TEXT,
@ -54,7 +57,21 @@ RETURNS TABLE (
pltq NUMERIC,
plevel TEXT,
partgroup TEXT,
-- history JSONB,
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,
@ -67,6 +84,8 @@ RETURNS TABLE (
volume_range TEXT,
listprice NUMERIC,
listcode TEXT,
listprice_eff NUMERIC,
list_relevance TEXT,
guidance_price NUMERIC,
guidance_reason TEXT,
expl JSONB,
@ -74,23 +93,40 @@ RETURNS TABLE (
) AS $$
DECLARE
_pltq NUMERIC;
_calculated_pallets INT;
_exact_pallets NUMERIC;
_chan TEXT;
_tier TEXT;
_cust TEXT;
_plevel TEXT;
_partgroup TEXT;
_stlc 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;
_tprice NUMERIC;
_tmath JSONB;
_volume_range TEXT;
_list_price NUMERIC;
_list_code TEXT;
_listprice_eff NUMERIC;
_list_relevance TEXT;
_guidance_price NUMERIC;
_guidance_reason TEXT;
_hist JSONB := '{}'::jsonb;
-- No intermediate price history variables needed
-- Precedence chain
_last JSONB;
_last_price NUMERIC;
_last_qty NUMERIC;
_last_dataseg TEXT;
@ -102,7 +138,7 @@ DECLARE
_ui_json JSONB := '{}'::jsonb;
BEGIN
------------------------------------------------------------------
-- Step 1: Resolve customer metadata
-- Step 1: Resolve customer metadata and part master data
------------------------------------------------------------------
SELECT
i.mpck,
@ -135,94 +171,159 @@ BEGIN
ELSE bc.plevel
END,
i.partgroup,
substring(_part,1,8)
INTO _pltq, _chan, _tier, _cust, _plevel, _partgroup, _stlc
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.curstdus,
i.futstdus,
FLOOR(_vol / NULLIF(_pltq, 0)),
ROUND(_vol / NULLIF(_pltq, 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;
-- 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;
------------------------------------------------------------------
-- Step 2: Target price logic
-- Step 2: Target price logic (current and for last_dataseg)
------------------------------------------------------------------
SELECT tp.price,
to_json(tp.math),
tp.vol::text
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 FLOOR(_vol / NULLIF(_pltq, 0))::int <@ tp.vol;
AND tp.vol @> _calculated_pallets;
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
SELECT lp.part_stats INTO _hist
FROM pricequote.lastpricedetail lp
WHERE lp.customer = _cust
AND lp.partgroup = _partgroup;
-- No extraction of price history keys needed; handled in helper
_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';
-- Use helper function to select the best last price point and extract attributes
DECLARE
_last JSONB;
BEGIN
_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';
END;
-- 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
AND tp.ds = _last_dataseg
AND tp.chan = _chan
AND tp.tier = _tier
AND FLOOR(_vol / NULLIF(_pltq, 0))::int <@ tp.vol;
------------------------------------------------------------------
-- Step 4: List price
-- Step 4: Cost data for normalization
------------------------------------------------------------------
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)
-- 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;
-- 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;
------------------------------------------------------------------
-- Step 5: Normalize last price if needed
------------------------------------------------------------------
IF _last_isdiff IS NOT NULL THEN
IF _tprice_last IS NOT NULL AND _tprice IS NOT NULL AND _tprice_last <> 0 THEN
_last_premium := _tprice / _tprice_last;
_last_price_norm := ROUND(_last_price * (_tprice / _tprice_last), 5);
_last_premium_method := 'Target Price Ratio';
ELSIF _curstd_last IS NOT NULL AND _curstd IS NOT NULL AND _curstd_last <> 0 THEN
_last_premium := _curstd / _curstd_last;
_last_price_norm := ROUND(_last_price * (_curstd / _curstd_last), 5);
_last_premium_method := 'Cost Ratio';
ELSE
_last_price_norm := _last_price;
_last_premium_method := 'Unknown';
END IF;
ELSE
_last_price_norm := _last_price;
END IF;
------------------------------------------------------------------
-- 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
LIMIT 1;
------------------------------------------------------------------
-- Step 5: Compute guidance price and embed it
------------------------------------------------------------------
SELECT
gl.guidance_price, gl.guidance_reason
INTO
_guidance_price, _guidance_reason
FROM
pricequote.guidance_logic(_tprice, _last_price, _list_price, _last_date) gl;
-- List price relevance
IF _customized <> '' THEN
_listprice_eff := NULL;
_list_relevance := 'Ignore - Customized';
ELSE
_listprice_eff := _list_price;
_list_relevance := '';
END IF;
------------------------------------------------------------------
-- Step 6: Build explanation JSON
-- Step 7: Compute guidance price and embed it
------------------------------------------------------------------
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;
------------------------------------------------------------------
-- Step 8: Build explanation JSON
------------------------------------------------------------------
_expl := jsonb_build_object(
'last_price', _last_price,
'last_qty', _last_qty,
'last_dataseg', _last_dataseg,
'last_v0ds', _last_v0ds,
'last_source', _last_source,
'last_date', _last_date,
'last_order', _last_order,
'last_quote', _last_quote,
'last_isdiff', _last_isdiff,
'tprice_last', _tprice_last,
'target_price', _tprice,
'target_math', _tmath,
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),
@ -230,16 +331,30 @@ BEGIN
'customer', _cust,
'channel', _chan,
'tier', TRIM(_tier),
'list_price', _list_price,
'list_code', _list_code,
'part_v1ds', _part_v1ds,
'curstd_orig', _curstd_orig,
'futstd_orig', _futstd_orig,
'v0ds', _v0ds,
'curstd', _curstd,
'futstd', _futstd,
'curstd_last', _curstd_last,
'futstd_last', _futstd_last,
'customized', _customized,
'last_premium', _last_premium,
'last_premium_method', _last_premium_method,
'last_price_norm', _last_price_norm,
'listcode', _list_code,
'listprice', _list_price,
'listprice_eff', _listprice_eff,
'list_relevance', _list_relevance,
'guidance_price', _guidance_price,
'guidance_reason', _guidance_reason
);
------------------------------------------------------------------
-- Step 7: Build UI JSON (optional, similar to MSSQL)
-- Step 9: Build UI JSON (panels)
------------------------------------------------------------------
_ui_json := jsonb_build_object(
_ui_json := jsonb_build_object(
'details', jsonb_build_array(
jsonb_build_object(
'label', 'History',
@ -261,13 +376,13 @@ BEGIN
'label', 'List:' || COALESCE(_list_code, ''),
'value', _list_price,
'type', 'currency',
'note', _plevel
'note', _list_relevance
)
)
),
jsonb_build_object(
'label', 'Target Support',
'details', _tmath -- You may need to transform this to match the MSSQL panel
'details', _tmath
),
jsonb_build_object(
'label', 'Guidance',
@ -290,11 +405,12 @@ BEGIN
RETURN QUERY
SELECT
_bill, _ship, _part, _stlc, _v1ds, _vol,
_chan, _cust, _tier, _pltq, _plevel, _partgroup,
-- _hist,
_chan, _cust, _tier, _pltq, _plevel, _partgroup, _part_v1ds, _v0ds,
_curstd_orig, _futstd_orig, _curstd, _futstd, _curstd_last, _futstd_last,
_customized, _last_premium, _last_premium_method, _last_price_norm, _last_isdiff, _last_v0ds, _tprice_last,
_last_price, _last_qty, _last_dataseg, _last_date, _last_order, _last_quote, _last_source,
_tprice, _tmath, _volume_range,
_list_price, _list_code,
_list_price, _list_code, _listprice_eff, _list_relevance,
_guidance_price, _guidance_reason,
_expl, _ui_json;
END;