504 lines
16 KiB
PL/PgSQL
504 lines
16 KiB
PL/PgSQL
/*
|
|
====================================================================================
|
|
Script: single_price_call.pg.sql
|
|
Purpose: Single price call logic for a specific scenario (PostgreSQL)
|
|
-----------------------------------------------------------------------------------
|
|
Description:
|
|
- Accepts a single pricing scenario (bill, ship, part, v1ds, vol)
|
|
- Enriches with customer, channel, tier, pack quantity, price level, and part group
|
|
- Looks up and applies target price, price history, list price, and guidance logic
|
|
- Builds a JSON explanation and UI JSON for the scenario
|
|
|
|
Inputs:
|
|
- bill, ship, part, v1ds, vol (function arguments)
|
|
- Reference tables: pricequote.target_prices, pricequote.lastpricedetail, pricequote.pricelist_ranged
|
|
- Customer/item reference: rlarp.cust, CMS.CUSLG.itemm, CMS.CUSLG.IPRCBHC
|
|
|
|
Outputs:
|
|
- Returns a single enriched row with all pricing and explanation fields
|
|
|
|
Key Business Logic:
|
|
- Channel/tier/customer resolution based on bill/ship codes
|
|
- Target price and math lookup by segment, channel, tier, and volume
|
|
- Price history precedence and extraction via helper function
|
|
- List price selection: lowest valid price for the scenario
|
|
- Guidance logic: computed from target, last, and list prices
|
|
|
|
Dependencies:
|
|
- pricequote.guidance_logic (function)
|
|
- pricequote.pick_last_price_from_hist (function)
|
|
|
|
Notes:
|
|
- Designed for single-row pricing queries (API or UI)
|
|
- Assumes all referenced tables and functions exist
|
|
- 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,
|
|
_part 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,
|
|
partgroup 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,
|
|
last_price NUMERIC,
|
|
last_qty NUMERIC,
|
|
last_dataseg TEXT,
|
|
last_date DATE,
|
|
last_order TEXT,
|
|
last_quote TEXT,
|
|
last_source TEXT,
|
|
tprice NUMERIC,
|
|
tmath JSONB,
|
|
volume_range TEXT,
|
|
listprice NUMERIC,
|
|
listcode TEXT,
|
|
listprice_eff NUMERIC,
|
|
list_relevance TEXT,
|
|
guidance_price NUMERIC,
|
|
guidance_reason TEXT,
|
|
expl JSONB,
|
|
ui_json JSONB
|
|
) AS $$
|
|
DECLARE
|
|
-----------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;
|
|
_part_v1ds TEXT;
|
|
_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;
|
|
_last_premium NUMERIC;
|
|
_last_price_norm NUMERIC;
|
|
_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;
|
|
------------step 7 build json------------------
|
|
_expl JSONB := '{}'::jsonb;
|
|
_ui_json JSONB := '{}'::jsonb;
|
|
BEGIN
|
|
------------------------------------------------------------------
|
|
-- Step 1: Resolve customer metadata and part master data
|
|
------------------------------------------------------------------
|
|
SELECT
|
|
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 chan,
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIR' THEN bc.tier
|
|
ELSE COALESCE(sc.tier, bc.tier)
|
|
END tier,
|
|
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 cust,
|
|
i.mpck,
|
|
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 plevel,
|
|
substring(_part,1,8) stlc,
|
|
i.partgroup,
|
|
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
|
|
_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;
|
|
|
|
--------------------------------------------------------------------------------
|
|
-- 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
|
|
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;
|
|
|
|
|
|
-- 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: 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;
|
|
|
|
-- 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 := 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
|
|
_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;
|
|
|
|
-- List price relevance
|
|
IF _customized <> '' THEN
|
|
_listprice_eff := NULL;
|
|
_list_relevance := 'Ignore - Customized';
|
|
ELSE
|
|
_listprice_eff := _list_price;
|
|
_list_relevance := '';
|
|
END IF;
|
|
|
|
------------------------------------------------------------------
|
|
-- 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',
|
|
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
|
|
);
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 9: Build UI JSON (panels)
|
|
------------------------------------------------------------------
|
|
_ui_json := jsonb_build_object(
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', 'History',
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', CASE WHEN _last_price IS NOT NULL THEN 'Last Sale: ' || _last_date ELSE 'No Recent' END,
|
|
'value', COALESCE(_last_price,0),
|
|
'type', 'currency',
|
|
'note', CASE WHEN _last_price IS NOT NULL THEN _last_source ||
|
|
CASE WHEN COALESCE(_last_order, '0') = '0' THEN ' Qt# ' || COALESCE(_last_quote, '') ELSE ' Ord# ' || COALESCE(_last_order, '') END
|
|
ELSE NULL END
|
|
)
|
|
)
|
|
),
|
|
jsonb_build_object(
|
|
'label', 'List',
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', 'List:' || COALESCE(_list_code, ''),
|
|
'value', _list_price,
|
|
'type', 'currency',
|
|
'note', _list_relevance
|
|
)
|
|
)
|
|
),
|
|
jsonb_build_object(
|
|
'label', 'Target Support',
|
|
'details', _tmath
|
|
),
|
|
jsonb_build_object(
|
|
'label', 'Guidance',
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', 'Price',
|
|
'value', _guidance_price,
|
|
'type', 'currency',
|
|
'note', _guidance_reason
|
|
)
|
|
)
|
|
)
|
|
),
|
|
'data', _expl
|
|
);
|
|
|
|
------------------------------------------------------------------
|
|
-- Final: Return row
|
|
------------------------------------------------------------------
|
|
RETURN QUERY
|
|
SELECT
|
|
_bill, _ship, _part, _stlc, _v1ds, _vol,
|
|
_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, _listprice_eff, _list_relevance,
|
|
_guidance_price, _guidance_reason,
|
|
_expl, _ui_json;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|