Compare commits
5 Commits
849d176ad0
...
ab5808d1e8
Author | SHA1 | Date | |
---|---|---|---|
ab5808d1e8 | |||
e04021caa1 | |||
fe2145b7d2 | |||
10ca238010 | |||
68921d9a7f |
@ -1,14 +1,20 @@
|
||||
|
||||
EXEC pricing.single_price_call
|
||||
@bill = 'FARM0001',
|
||||
@ship = 'KEYB0001',
|
||||
@part = 'HZP3E100E21D050',
|
||||
@v1ds = 'v1:T..BDL..',
|
||||
@vol = 50000;
|
||||
|
||||
EXEC pricing.single_price_call
|
||||
@bill = 'GRIF0001',
|
||||
@ship = 'GRIF0001',
|
||||
@part = 'XNS0T1G3G18B096',
|
||||
@v1ds = 'v1:B.L.PLT..',
|
||||
@part = 'XNS0T1G3G18B96',
|
||||
@v1ds = 'v1:B..PLT..',
|
||||
@vol = 9600;
|
||||
|
||||
|
||||
SELECT
|
||||
*
|
||||
guidance_price, ui_json
|
||||
FROM pricing.single_price_call_fn(
|
||||
'GRIF0001',
|
||||
'GRIF0001',
|
||||
@ -46,3 +52,14 @@ FROM
|
||||
) p
|
||||
WHERE
|
||||
qstat LIKE 'Submitted%'
|
||||
|
||||
|
||||
SELECT
|
||||
*
|
||||
FROM pricequote.single_price_call(
|
||||
'GRIF0001',
|
||||
'GRIF0001',
|
||||
'XNS0T1G3G18B096',
|
||||
'v1:B..PLT..',
|
||||
9600
|
||||
) f
|
10
example_usage.pg.sql
Normal file
10
example_usage.pg.sql
Normal file
@ -0,0 +1,10 @@
|
||||
SELECT
|
||||
*
|
||||
FROM pricequote.single_price_call(
|
||||
'FARM0001',
|
||||
'KEYB0001',
|
||||
'HZP3E100E21D050',
|
||||
'v1:T..BDL..',
|
||||
50000
|
||||
) f
|
||||
|
@ -85,47 +85,56 @@ BEGIN
|
||||
bill VARCHAR(100),
|
||||
ship VARCHAR(100),
|
||||
part VARCHAR(100),
|
||||
stlc VARCHAR(100),
|
||||
partgroup VARCHAR(100),
|
||||
v1ds VARCHAR(100),
|
||||
vol NUMERIC(18,6),
|
||||
------------step 1 lookup scenario------------
|
||||
chan VARCHAR(50),
|
||||
tier VARCHAR(50),
|
||||
cust VARCHAR(100),
|
||||
pltq NUMERIC(18,6),
|
||||
plevel NVARCHAR(20),
|
||||
stlc VARCHAR(100),
|
||||
partgroup VARCHAR(100),
|
||||
part_v1ds VARCHAR(50),
|
||||
v0ds VARCHAR(10),
|
||||
curstd_orig NUMERIC(20,5),
|
||||
futstd_orig NUMERIC(20,5),
|
||||
v0ds VARCHAR(10),
|
||||
curstd NUMERIC(20,5),
|
||||
futstd NUMERIC(20,5),
|
||||
customized VARCHAR(100),
|
||||
last_premium NUMERIC(20,5),
|
||||
chan VARCHAR(50),
|
||||
cust VARCHAR(100),
|
||||
tier VARCHAR(50),
|
||||
pltq NUMERIC(18,6),
|
||||
volume_range VARCHAR(100),
|
||||
plevel NVARCHAR(20),
|
||||
listprice NUMERIC(20,5),
|
||||
listcode VARCHAR(10),
|
||||
listprice_eff NUMERIC(20,5),
|
||||
list_relevance NVARCHAR(100),
|
||||
calculated_pallets numeric(20,0),
|
||||
exact_pallets numeric(20,5),
|
||||
----------- step 2 last price------------------
|
||||
hist NVARCHAR(MAX),
|
||||
last_price NUMERIC(20,5),
|
||||
last_qty NUMERIC(20,5),
|
||||
last_source NVARCHAR(100),
|
||||
last_date DATE,
|
||||
last_qty NUMERIC(20,5),
|
||||
last_dataseg NVARCHAR(20),
|
||||
last_v0ds VARCHAR(10),
|
||||
last_order NVARCHAR(10),
|
||||
last_quote NVARCHAR(10),
|
||||
last_dataseg NVARCHAR(20),
|
||||
last_source NVARCHAR(100),
|
||||
last_isdiff NVARCHAR(100),
|
||||
last_v0ds VARCHAR(10),
|
||||
last_price_norm NUMERIC(20,5),
|
||||
last_premium_method VARCHAR(100),
|
||||
------------step 3 lookup target---------------
|
||||
tprice NUMERIC(20,5),
|
||||
tprice_last NUMERIC(20,5),
|
||||
tmath nvarchar(MAX),
|
||||
volume_range VARCHAR(100),
|
||||
------------step 4 normalize last price--------
|
||||
curstd NUMERIC(20,5),
|
||||
futstd NUMERIC(20,5),
|
||||
curstd_last NUMERIC(20,5),
|
||||
futstd_last NUMERIC(20,5),
|
||||
tprice_last NUMERIC(20,5),
|
||||
tprice NUMERIC(20,5),
|
||||
tmath nvarchar(MAX),
|
||||
last_premium NUMERIC(20,5),
|
||||
last_price_norm NUMERIC(20,5),
|
||||
last_premium_method VARCHAR(100),
|
||||
------------step 5 list price lookup-----------
|
||||
listcode VARCHAR(10),
|
||||
listprice NUMERIC(20,5),
|
||||
listprice_eff NUMERIC(20,5),
|
||||
list_relevance NVARCHAR(100),
|
||||
------------step 6 compute guidance------------
|
||||
guidance_price NUMERIC(20,5),
|
||||
guidance_reason NVARCHAR(MAX),
|
||||
------------step 7 build json------------------
|
||||
expl NVARCHAR(MAX),
|
||||
ui_json NVARCHAR(MAX)
|
||||
);
|
||||
@ -175,15 +184,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 +248,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 +395,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
|
||||
@ -466,7 +482,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 +513,5 @@ BEGIN
|
||||
--------------------------------------------------------------------------------
|
||||
-- Final: Return all calculated fields and JSON payloads.
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT * FROM @queue;
|
||||
SELECT guidance_price, ui_json FROM @queue;
|
||||
END;
|
@ -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,45 +84,77 @@ RETURNS TABLE (
|
||||
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
|
||||
_pltq NUMERIC;
|
||||
-----------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;
|
||||
_hist JSONB := '{}'::jsonb;
|
||||
-- No intermediate price history variables needed
|
||||
|
||||
-- Precedence chain
|
||||
_last_price NUMERIC;
|
||||
_last_qty NUMERIC;
|
||||
_last_dataseg TEXT;
|
||||
_last_date DATE;
|
||||
_last_order TEXT;
|
||||
_last_quote TEXT;
|
||||
_last_source TEXT;
|
||||
------------step 7 build json------------------
|
||||
_expl JSONB := '{}'::jsonb;
|
||||
_ui_json JSONB := '{}'::jsonb;
|
||||
BEGIN
|
||||
------------------------------------------------------------------
|
||||
-- Step 1: Resolve customer metadata
|
||||
-- Step 1: Resolve customer metadata and part master data
|
||||
------------------------------------------------------------------
|
||||
SELECT
|
||||
i.mpck,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
@ -113,11 +162,11 @@ BEGIN
|
||||
ELSE 'DRP'
|
||||
END
|
||||
ELSE 'DIR'
|
||||
END,
|
||||
END chan,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE COALESCE(sc.tier, bc.tier)
|
||||
END,
|
||||
END tier,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
@ -125,7 +174,8 @@ BEGIN
|
||||
ELSE sc.dba
|
||||
END
|
||||
ELSE bc.dba
|
||||
END,
|
||||
END cust,
|
||||
i.mpck,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
@ -133,113 +183,264 @@ BEGIN
|
||||
ELSE bc.plevel
|
||||
END
|
||||
ELSE bc.plevel
|
||||
END,
|
||||
END plevel,
|
||||
substring(_part,1,8) stlc,
|
||||
i.partgroup,
|
||||
substring(_part,1,8)
|
||||
INTO _pltq, _chan, _tier, _cust, _plevel, _partgroup, _stlc
|
||||
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;
|
||||
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
|
||||
-- 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
|
||||
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 3: Last sale/quote/volume/segment data
|
||||
-- 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
|
||||
lp.part_stats
|
||||
pr.price::numeric(20,5)
|
||||
,pr.jcplcd
|
||||
INTO
|
||||
_hist
|
||||
FROM pricequote.lastpricedetail lp
|
||||
WHERE lp.customer = _cust
|
||||
AND lp.partgroup = _partgroup;
|
||||
|
||||
-- No extraction of price history keys needed; handled in helper
|
||||
|
||||
-- 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;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 4: List price
|
||||
------------------------------------------------------------------
|
||||
SELECT
|
||||
pr.price::numeric(20,5), pr.jcplcd
|
||||
INTO
|
||||
_list_price, _list_code
|
||||
_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
|
||||
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
|
||||
------------------------------------------------------------------
|
||||
_expl := jsonb_build_object(
|
||||
'last_price', _last_price,
|
||||
'last_qty', _last_qty,
|
||||
'last_dataseg', _last_dataseg,
|
||||
'last_source', _last_source,
|
||||
'last_date', _last_date,
|
||||
'last_order', _last_order,
|
||||
'last_quote', _last_quote,
|
||||
'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),
|
||||
'list_price', _list_price,
|
||||
'list_code', _list_code,
|
||||
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 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 +462,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 +491,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;
|
||||
|
Loading…
Reference in New Issue
Block a user