convert single price call to postgres function

This commit is contained in:
Paul Trowbridge 2025-07-29 02:01:59 -04:00
parent 328af4eaab
commit 90ba57ca9b
3 changed files with 240 additions and 0 deletions

View File

@ -0,0 +1,48 @@
CREATE OR REPLACE FUNCTION pricequote.guidance_logic(
_target_price NUMERIC(20,5),
_last_price NUMERIC(20,5),
_list_price NUMERIC(20,5)
)
RETURNS TABLE (
guidance_price NUMERIC(20,5),
guidance_reason TEXT
) AS $$
DECLARE
_price NUMERIC(20,5);
_reason TEXT := '';
_floored NUMERIC(20,5);
_capped NUMERIC(20,5);
BEGIN
IF _target_price IS NOT NULL AND _last_price IS NOT NULL THEN
_floored := GREATEST(_target_price, _last_price * 0.95);
_capped := LEAST(_floored, _last_price);
_price := LEAST(COALESCE(_list_price, 1e9), _capped);
IF _price = _last_price THEN
_reason := 'Cap at last price';
ELSE
_reason := 'Using target price';
IF _target_price < _last_price * 0.95 THEN
_reason := _reason || ', floored to 5% below last price';
END IF;
IF _target_price > _last_price THEN
_reason := _reason || ', capped to not exceed last price';
END IF;
IF _list_price IS NOT NULL AND _price = _list_price AND _target_price > _list_price THEN
_reason := _reason || ', capped to not exceed list price';
END IF;
END IF;
ELSIF _last_price IS NOT NULL THEN
_price := _last_price;
_reason := 'Last price - no target';
ELSE
_price := _target_price;
_reason := 'Target price - no prior sale';
END IF;
RETURN QUERY SELECT _price, _reason;
END;
$$ LANGUAGE plpgsql;

View File

@ -0,0 +1,189 @@
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
_bill TEXT,
_ship TEXT,
_part TEXT,
_stlc TEXT,
_v1ds TEXT,
_vol NUMERIC
)
RETURNS TABLE (
bill TEXT,
ship TEXT,
part TEXT,
stlc TEXT,
v1ds TEXT,
vol NUMERIC,
chan TEXT,
cust TEXT,
tier TEXT,
pltq NUMERIC,
plevel TEXT,
hist JSONB,
last_price NUMERIC,
last_date DATE,
last_order TEXT,
last_quote TEXT,
tprice NUMERIC,
guidance_price NUMERIC,
guidance_reason TEXT,
expl JSONB
) AS $$
DECLARE
_pltq NUMERIC;
_chan TEXT;
_tier TEXT;
_cust TEXT;
_plevel TEXT;
_tprice NUMERIC;
_last_price NUMERIC;
_last_date DATE;
_last_order TEXT;
_last_quote TEXT;
_list_price NUMERIC;
_list_code TEXT;
_hist JSONB := '{}'::jsonb;
_expl JSONB := '{}'::jsonb;
_guidance_price NUMERIC;
_guidance_reason TEXT;
BEGIN
------------------------------------------------------------------
-- Step 1: Resolve customer metadata
------------------------------------------------------------------
SELECT
i.mpck,
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,
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIR' THEN bc.tier
ELSE COALESCE(sc.tier, bc.tier)
END,
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,
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
INTO _pltq, _chan, _tier, _cust, _plevel
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;
------------------------------------------------------------------
-- Step 2: Target price logic
------------------------------------------------------------------
SELECT tp.price,
jsonb_build_object(
'source', 'target price',
'target_price', tp.price,
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),
'exact_pallets', ROUND(_vol / NULLIF(_pltq, 0), 5),
'volume range', tp.vol::TEXT,
'customer', _cust,
'channel', _chan,
'tier', TRIM(_tier),
'target math', tp.math
)
INTO _tprice, _expl
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;
------------------------------------------------------------------
-- Step 3: Last sale data
------------------------------------------------------------------
SELECT
(lp.dataseg_stats -> _v1ds) ->> 'price',
(lp.dataseg_stats -> _v1ds) ->> 'odate',
(lp.dataseg_stats -> _v1ds) ->> 'ordnum',
(lp.dataseg_stats -> _v1ds) ->> 'quoten',
lp.dataseg_stats
INTO
_last_price, _last_date, _last_order, _last_quote, _hist
FROM pricequote.lastprice lp
WHERE lp.customer = _cust
AND lp.partgroup = SUBSTRING(_part, 1, 8);
_expl := _expl || jsonb_build_object(
'last_price', _last_price,
'last_date', _last_date,
'last_order', _last_order,
'last_quote', _last_quote,
'full_history_________', _hist
);
------------------------------------------------------------------
-- Step 4: List price
------------------------------------------------------------------
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
WHERE TRIM(i.jbplvl) = TRIM(_plevel)
AND CURRENT_DATE BETWEEN i.jbfdat AND i.jbtdat
ORDER BY pr.price ASC
LIMIT 1;
_expl := _expl || jsonb_build_object(
'list_price', _list_price,
'list_code', _list_code
);
------------------------------------------------------------------
-- 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) gl;
_expl := _expl || jsonb_build_object(
'guidance_price', _guidance_price,
'guidance_reason', _guidance_reason
);
------------------------------------------------------------------
-- Final: Return row
------------------------------------------------------------------
RETURN QUERY
SELECT
_bill, _ship, _part, _stlc, _v1ds, _vol,
_chan, _cust, _tier, _pltq, _plevel,
_hist,
_last_price, _last_date, _last_order, _last_quote,
_tprice,
_guidance_price,
_guidance_reason,
_expl;
END;
$$ LANGUAGE plpgsql;

View File

@ -96,3 +96,6 @@ SELECT
vb_to,
price
FROM ranged;
CREATE INDEX pricelist_ranged_idx ON pricequote.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ;