use a helper function with no intermediate pasring to get best anchor price

This commit is contained in:
Paul Trowbridge 2025-08-07 00:45:52 -04:00
parent 3468ba1faf
commit ee653c5bba
2 changed files with 40 additions and 67 deletions

View File

@ -0,0 +1,26 @@
CREATE OR REPLACE FUNCTION pricequote.pick_last_price_from_hist(
hist JSONB,
v1ds TEXT
)
RETURNS JSONB AS $$
DECLARE
dsq JSONB := (hist -> v1ds) -> 'dsq';
dss JSONB := (hist -> v1ds) -> 'dss';
mrq JSONB := hist -> 'mrq';
mrs JSONB := hist -> 'mrs';
result JSONB;
BEGIN
IF dsq IS NOT NULL AND (dsq->>'price') IS NOT NULL AND (dsq->>'odate')::date > (CURRENT_DATE - INTERVAL '1 year') THEN
result := dsq || jsonb_build_object('source', 'dsq');
ELSIF dss IS NOT NULL AND (dss->>'price') IS NOT NULL AND (dss->>'odate')::date > (CURRENT_DATE - INTERVAL '1 year') THEN
result := dss || jsonb_build_object('source', 'dss');
ELSIF mrq IS NOT NULL AND (mrq->>'price') IS NOT NULL THEN
result := mrq || jsonb_build_object('source', 'mrq');
ELSIF mrs IS NOT NULL AND (mrs->>'price') IS NOT NULL THEN
result := mrs || jsonb_build_object('source', 'mrs');
ELSE
result := NULL;
END IF;
RETURN result;
END;
$$ LANGUAGE plpgsql IMMUTABLE;

View File

@ -1,5 +1,3 @@
-- DROP FUNCTION IF EXISTS pricequote.single_price_call() CASCADE;
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
_bill TEXT,
_ship TEXT,
@ -54,13 +52,7 @@ DECLARE
_guidance_price NUMERIC;
_guidance_reason TEXT;
_hist JSONB := '{}'::jsonb;
-- Last sale/quote/volume/segment fields
_mrs JSONB;
_mrq JSONB;
_lvs JSONB;
_lvq JSONB;
_dss JSONB;
_dsq JSONB;
-- No intermediate price history variables needed
-- Precedence chain
_last_price NUMERIC;
@ -139,59 +131,20 @@ BEGIN
WHERE lp.customer = _cust
AND lp.partgroup = _partgroup;
-- Extract top-level keys
_mrs := _hist -> 'mrs';
_mrq := _hist -> 'mrq';
_lvs := _hist -> 'lvs';
_lvq := _hist -> 'lvq';
-- No extraction of price history keys needed; handled in helper
-- Extract per-datasegment block matching the input v1ds
_dss := (_hist -> _v1ds) -> 'dss';
_dsq := (_hist -> _v1ds) -> 'dsq';
-- Precedence chain for last_price, etc.
_last_price := COALESCE(
(_dsq->>'price')::numeric,
(_dss->>'price')::numeric,
(_mrq->>'price')::numeric,
(_mrs->>'price')::numeric
);
_last_qty := COALESCE(
(_dsq->>'qty')::numeric,
(_dss->>'qty')::numeric,
(_mrq->>'qty')::numeric,
(_mrs->>'qty')::numeric
);
_last_dataseg := COALESCE(
_dsq->>'datasegment',
_dss->>'datasegment',
_mrq->>'datasegment',
_mrs->>'datasegment'
);
_last_date := COALESCE(
(_dsq->>'odate')::date,
(_dss->>'odate')::date,
(_mrq->>'odate')::date,
(_mrs->>'odate')::date
);
_last_order := COALESCE(
_dsq->>'ordnum',
_dss->>'ordnum',
_mrq->>'ordnum',
_mrs->>'ordnum'
);
_last_quote := COALESCE(
_dsq->>'quoten',
_dss->>'quoten',
_mrq->>'quoten',
_mrs->>'quoten'
);
_last_source := CASE
WHEN _dsq->>'price' IS NOT NULL THEN 'dsq'
WHEN _dss->>'price' IS NOT NULL THEN 'dss'
WHEN _mrq->>'price' IS NOT NULL THEN 'mrq'
WHEN _mrs->>'price' IS NOT NULL THEN 'mrs'
ELSE NULL
-- 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;
------------------------------------------------------------------
@ -234,12 +187,6 @@ BEGIN
'last_date', _last_date,
'last_order', _last_order,
'last_quote', _last_quote,
'mrs', _mrs,
'mrq', _mrq,
'lvs', _lvs,
'lvq', _lvq,
'dss', _dss,
'dsq', _dsq,
'target_price', _tprice,
'target_math', _tmath,
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),