work on broken target linkage

This commit is contained in:
Paul Trowbridge 2025-08-10 23:01:48 -04:00
parent 10ca238010
commit fe2145b7d2
2 changed files with 77 additions and 46 deletions

View File

@ -101,6 +101,8 @@ BEGIN
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),
@ -175,15 +177,17 @@ BEGIN
ELSE bc.plevel
END,
stlc = substring(q.part,1,8),
partgroup = i.partgroup,
part_v1ds = i.v1ds,
partgroup = TRIM(i.partgroup),
part_v1ds = TRIM(i.v1ds),
v0ds =
CASE substring(q.v1ds,4,1) WHEN 'B' THEN 'B' ELSE 'C' END
+ CASE substring(q.v1ds,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END,
curstd_orig = i.curstdus,
futstd_orig = i.futstdus,
customized = CASE WHEN i.v1ds IS NOT NULL AND q.v1ds IS NOT NULL AND i.v1ds <> q.v1ds
THEN 'Customized' ELSE '' END
THEN 'Customized' ELSE '' END,
calculated_pallets = FLOOR(q.vol / NULLIF(i.mpck, 0)),
exact_pallets = CAST(ROUND(q.vol / NULLIF(i.mpck, 0), 5) AS NUMERIC(20,5))
FROM @queue q
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
@ -237,18 +241,18 @@ BEGIN
AND q.v1ds = tp.ds
AND q.chan = tp.chan
AND q.tier = tp.tier
AND FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tp.lower_bound
AND q.calculated_pallets >= tp.lower_bound
AND (
tp.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tp.upper_bound
tp.upper_bound IS NULL OR q.calculated_pallets < tp.upper_bound
)
LEFT JOIN pricing.target_prices tpl ON
q.stlc = tpl.stlc
AND q.last_dataseg = tpl.ds
AND q.chan = tpl.chan
AND q.tier = tpl.tier
AND FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tpl.lower_bound
AND q.calculated_pallets >= tpl.lower_bound
AND (
tpl.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tpl.upper_bound
tpl.upper_bound IS NULL OR q.calculated_pallets < tpl.upper_bound
);
--------------------------------------------------------------------------------
@ -384,11 +388,16 @@ BEGIN
,q.tprice_last AS tprice_last
,q.tprice AS target_price
,JSON_QUERY(q.tmath) AS target_math
,FLOOR(q.vol / NULLIF(q.pltq, 0)) AS calculated_pallets
,CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,5)) AS exact_pallets
,q.calculated_pallets AS calculated_pallets
,q.exact_pallets AS exact_pallets
,q.cust AS customer
,q.chan AS channel
,q.part AS part
,q.stlc AS stlc
,TRIM(q.tier) AS tier
,q.vol AS vol
,q.pltq AS pltq
,q.v1ds AS v1ds
,q.part_v1ds AS part_v1ds
,q.curstd_orig AS curstd_orig
,q.futstd_orig AS futstd_orig

View File

@ -110,6 +110,7 @@ DECLARE
_curstd_last NUMERIC;
_futstd_last NUMERIC;
_customized TEXT := '';
_last_part TEXT;
_last_premium NUMERIC;
_last_premium_method TEXT;
_last_price_norm NUMERIC;
@ -176,8 +177,8 @@ BEGIN
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)
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
@ -224,6 +225,9 @@ BEGIN
_last_order := _last->>'ordnum';
_last_quote := _last->>'quoten';
_last_source := _last->>'source';
_last_part := _last->>'part';
-- last_v0ds logic
_last_v0ds :=
@ -263,7 +267,7 @@ BEGIN
------------------------------------------------------------------
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_premium := ROUND(_tprice / _tprice_last,5);
_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
@ -313,40 +317,58 @@ BEGIN
------------------------------------------------------------------
-- 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)),
'exact_pallets', ROUND(_vol / NULLIF(_pltq, 0), 5),
'customer', _cust,
'channel', _chan,
'tier', TRIM(_tier),
'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,
_expl :=
jsonb_build_object(
'last',
jsonb_build_object(
'last_part', _last_part,
'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,
'last_premium', _last_premium,
'last_premium_method', _last_premium_method,
'last_price_norm', _last_price_norm,
'tprice_last', _tprice_last
),
'scenario',
jsonb_build_object(
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),
'exact_pallets', ROUND(_vol / NULLIF(_pltq, 0), 5),
'customer', _cust,
'channel', _chan,
'tier', TRIM(_tier),
'v1ds', _v1ds,
'v0ds', _v0ds,
'part_v1ds', _part_v1ds,
'customized', _customized
),
'cost',
jsonb_build_object(
'curstd_orig', _curstd_orig,
'futstd_orig', _futstd_orig,
'curstd_last', _curstd_last,
'futstd_last', _futstd_last,
'curstd', _curstd,
'futstd', _futstd
),
'targets',
jsonb_build_object(
'target_price', _tprice,
'target_math', _tmath
),
'list',
jsonb_build_object(
'listcode', _list_code,
'listprice', _list_price,
'listprice_eff', _listprice_eff,
'list_relevance', _list_relevance
),
'guidance_price', _guidance_price,
'guidance_reason', _guidance_reason
);