return last part code; factor last qty into normalization, better notes on the last price sourcing
This commit is contained in:
parent
7f990ab611
commit
49748383ff
@ -1,4 +1,3 @@
|
||||
|
||||
-- JSON-based helper function for last price selection
|
||||
CREATE OR ALTER FUNCTION pricing.pick_last_price_from_hist_json (
|
||||
@part_stats NVARCHAR(MAX),
|
||||
@ -11,7 +10,8 @@ RETURNS @result TABLE (
|
||||
qty NUMERIC(20,5),
|
||||
dataseg NVARCHAR(100),
|
||||
ord NVARCHAR(20),
|
||||
quote NVARCHAR(20)
|
||||
quote NVARCHAR(20),
|
||||
part NVARCHAR(100)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
@ -27,27 +27,27 @@ BEGIN
|
||||
WITH (mrq NVARCHAR(MAX) AS JSON, mrs NVARCHAR(MAX) AS JSON) flags;
|
||||
|
||||
-- Helper to extract fields from a JSON object
|
||||
DECLARE @dsq_price NUMERIC(20,5), @dsq_date DATE, @dsq_qty NUMERIC(20,5), @dsq_dataseg NVARCHAR(100), @dsq_ord NVARCHAR(20), @dsq_quote NVARCHAR(20);
|
||||
DECLARE @dss_price NUMERIC(20,5), @dss_date DATE, @dss_qty NUMERIC(20,5), @dss_dataseg NVARCHAR(100), @dss_ord NVARCHAR(20), @dss_quote NVARCHAR(20);
|
||||
DECLARE @mrq_price NUMERIC(20,5), @mrq_date DATE, @mrq_qty NUMERIC(20,5), @mrq_dataseg NVARCHAR(100), @mrq_ord NVARCHAR(20), @mrq_quote NVARCHAR(20);
|
||||
DECLARE @mrs_price NUMERIC(20,5), @mrs_date DATE, @mrs_qty NUMERIC(20,5), @mrs_dataseg NVARCHAR(100), @mrs_ord NVARCHAR(20), @mrs_quote NVARCHAR(20);
|
||||
DECLARE @dsq_price NUMERIC(20,5), @dsq_date DATE, @dsq_qty NUMERIC(20,5), @dsq_dataseg NVARCHAR(100), @dsq_ord NVARCHAR(20), @dsq_quote NVARCHAR(20), @dsq_part NVARCHAR(100);
|
||||
DECLARE @dss_price NUMERIC(20,5), @dss_date DATE, @dss_qty NUMERIC(20,5), @dss_dataseg NVARCHAR(100), @dss_ord NVARCHAR(20), @dss_quote NVARCHAR(20), @dss_part NVARCHAR(100);
|
||||
DECLARE @mrq_price NUMERIC(20,5), @mrq_date DATE, @mrq_qty NUMERIC(20,5), @mrq_dataseg NVARCHAR(100), @mrq_ord NVARCHAR(20), @mrq_quote NVARCHAR(20), @mrq_part NVARCHAR(100);
|
||||
DECLARE @mrs_price NUMERIC(20,5), @mrs_date DATE, @mrs_qty NUMERIC(20,5), @mrs_dataseg NVARCHAR(100), @mrs_ord NVARCHAR(20), @mrs_quote NVARCHAR(20), @mrs_part NVARCHAR(100);
|
||||
|
||||
IF @dsq IS NOT NULL
|
||||
SELECT @dsq_price = price, @dsq_date = odate, @dsq_qty = qty, @dsq_dataseg = datasegment, @dsq_ord = ordnum, @dsq_quote = quoten
|
||||
SELECT @dsq_price = price, @dsq_date = odate, @dsq_qty = qty, @dsq_dataseg = datasegment, @dsq_ord = ordnum, @dsq_quote = quoten, @dsq_part = part
|
||||
FROM OPENJSON(@dsq)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
IF @dss IS NOT NULL
|
||||
SELECT @dss_price = price, @dss_date = odate, @dss_qty = qty, @dss_dataseg = datasegment, @dss_ord = ordnum, @dss_quote = quoten
|
||||
SELECT @dss_price = price, @dss_date = odate, @dss_qty = qty, @dss_dataseg = datasegment, @dss_ord = ordnum, @dss_quote = quoten, @dss_part = part
|
||||
FROM OPENJSON(@dss)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
IF @mrq IS NOT NULL
|
||||
SELECT @mrq_price = price, @mrq_date = odate, @mrq_qty = qty, @mrq_dataseg = datasegment, @mrq_ord = ordnum, @mrq_quote = quoten
|
||||
SELECT @mrq_price = price, @mrq_date = odate, @mrq_qty = qty, @mrq_dataseg = datasegment, @mrq_ord = ordnum, @mrq_quote = quoten, @mrq_part = part
|
||||
FROM OPENJSON(@mrq)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
IF @mrs IS NOT NULL
|
||||
SELECT @mrs_price = price, @mrs_date = odate, @mrs_qty = qty, @mrs_dataseg = datasegment, @mrs_ord = ordnum, @mrs_quote = quoten
|
||||
SELECT @mrs_price = price, @mrs_date = odate, @mrs_qty = qty, @mrs_dataseg = datasegment, @mrs_ord = ordnum, @mrs_quote = quoten, @mrs_part = part
|
||||
FROM OPENJSON(@mrs)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
|
||||
-- Use the same selection logic as before
|
||||
-- 1. Prefer the most recent of dss/dsq if either is within the age threshold
|
||||
@ -55,9 +55,9 @@ BEGIN
|
||||
OR (@dss_date IS NOT NULL AND @dss_date > @age_threshold)
|
||||
BEGIN
|
||||
IF @dsq_date IS NOT NULL AND (@dss_date IS NULL OR @dsq_date >= @dss_date) AND @dsq_date > @age_threshold
|
||||
INSERT INTO @result VALUES (@dsq_price, 'dsq', @dsq_date, @dsq_qty, @dsq_dataseg, @dsq_ord, @dsq_quote);
|
||||
INSERT INTO @result VALUES (@dsq_price, 'dsq', @dsq_date, @dsq_qty, @dsq_dataseg, @dsq_ord, @dsq_quote, @dsq_part);
|
||||
ELSE IF @dss_date IS NOT NULL AND @dss_date > @age_threshold
|
||||
INSERT INTO @result VALUES (@dss_price, 'dss', @dss_date, @dss_qty, @dss_dataseg, @dss_ord, @dss_quote);
|
||||
INSERT INTO @result VALUES (@dss_price, 'dss', @dss_date, @dss_qty, @dss_dataseg, @dss_ord, @dss_quote, @dss_part);
|
||||
RETURN;
|
||||
END
|
||||
|
||||
@ -65,25 +65,25 @@ BEGIN
|
||||
IF (@mrq_date IS NOT NULL OR @mrs_date IS NOT NULL)
|
||||
BEGIN
|
||||
IF @mrq_date IS NOT NULL AND (@mrs_date IS NULL OR @mrq_date >= @mrs_date)
|
||||
INSERT INTO @result VALUES (@mrq_price, 'mrq', @mrq_date, @mrq_qty, @mrq_dataseg, @mrq_ord, @mrq_quote);
|
||||
INSERT INTO @result VALUES (@mrq_price, 'mrq', @mrq_date, @mrq_qty, @mrq_dataseg, @mrq_ord, @mrq_quote, @mrq_part);
|
||||
ELSE IF @mrs_date IS NOT NULL
|
||||
INSERT INTO @result VALUES (@mrs_price, 'mrs', @mrs_date, @mrs_qty, @mrs_dataseg, @mrs_ord, @mrs_quote);
|
||||
INSERT INTO @result VALUES (@mrs_price, 'mrs', @mrs_date, @mrs_qty, @mrs_dataseg, @mrs_ord, @mrs_quote, @mrs_part);
|
||||
RETURN;
|
||||
END
|
||||
|
||||
-- 3. If all are at least as old as the threshold, pick the least oldest price available
|
||||
DECLARE @best_price NUMERIC(20,5) = NULL, @best_source NVARCHAR(10) = NULL, @best_date DATE = NULL, @best_qty NUMERIC(20,5) = NULL, @best_dataseg NVARCHAR(100) = NULL, @best_ord NVARCHAR(20) = NULL, @best_quote NVARCHAR(20) = NULL;
|
||||
DECLARE @best_price NUMERIC(20,5) = NULL, @best_source NVARCHAR(10) = NULL, @best_date DATE = NULL, @best_qty NUMERIC(20,5) = NULL, @best_dataseg NVARCHAR(100) = NULL, @best_ord NVARCHAR(20) = NULL, @best_quote NVARCHAR(20) = NULL, @best_part NVARCHAR(100) = NULL;
|
||||
IF @dsq_date IS NOT NULL
|
||||
SELECT @best_price = @dsq_price, @best_source = 'dsq', @best_date = @dsq_date, @best_qty = @dsq_qty, @best_dataseg = @dsq_dataseg, @best_ord = @dsq_ord, @best_quote = @dsq_quote;
|
||||
SELECT @best_price = @dsq_price, @best_source = 'dsq', @best_date = @dsq_date, @best_qty = @dsq_qty, @best_dataseg = @dsq_dataseg, @best_ord = @dsq_ord, @best_quote = @dsq_quote, @best_part = @dsq_part;
|
||||
IF @dss_date IS NOT NULL AND (@best_date IS NULL OR @dss_date > @best_date)
|
||||
SELECT @best_price = @dss_price, @best_source = 'dss', @best_date = @dss_date, @best_qty = @dss_qty, @best_dataseg = @dss_dataseg, @best_ord = @dss_ord, @best_quote = @dss_quote;
|
||||
SELECT @best_price = @dss_price, @best_source = 'dss', @best_date = @dss_date, @best_qty = @dss_qty, @best_dataseg = @dss_dataseg, @best_ord = @dss_ord, @best_quote = @dss_quote, @best_part = @dss_part;
|
||||
IF @mrq_date IS NOT NULL AND (@best_date IS NULL OR @mrq_date > @best_date)
|
||||
SELECT @best_price = @mrq_price, @best_source = 'mrq', @best_date = @mrq_date, @best_qty = @mrq_qty, @best_dataseg = @mrq_dataseg, @best_ord = @mrq_ord, @best_quote = @mrq_quote;
|
||||
SELECT @best_price = @mrq_price, @best_source = 'mrq', @best_date = @mrq_date, @best_qty = @mrq_qty, @best_dataseg = @mrq_dataseg, @best_ord = @mrq_ord, @best_quote = @mrq_quote, @best_part = @mrq_part;
|
||||
IF @mrs_date IS NOT NULL AND (@best_date IS NULL OR @mrs_date > @best_date)
|
||||
SELECT @best_price = @mrs_price, @best_source = 'mrs', @best_date = @mrs_date, @best_qty = @mrs_qty, @best_dataseg = @mrs_dataseg, @best_ord = @mrs_ord, @best_quote = @mrs_quote;
|
||||
SELECT @best_price = @mrs_price, @best_source = 'mrs', @best_date = @mrs_date, @best_qty = @mrs_qty, @best_dataseg = @mrs_dataseg, @best_ord = @mrs_ord, @best_quote = @mrs_quote, @best_part = @mrs_part;
|
||||
|
||||
IF @best_price IS NOT NULL
|
||||
INSERT INTO @result VALUES (@best_price, @best_source, @best_date, @best_qty, @best_dataseg, @best_ord, @best_quote);
|
||||
INSERT INTO @result VALUES (@best_price, @best_source, @best_date, @best_qty, @best_dataseg, @best_ord, @best_quote, @best_part);
|
||||
|
||||
RETURN;
|
||||
END
|
||||
|
@ -132,6 +132,7 @@ BEGIN
|
||||
listprice NUMERIC(20,5),
|
||||
listprice_eff NUMERIC(20,5),
|
||||
list_relevance NVARCHAR(100),
|
||||
list_from BIGINT,
|
||||
------------step 6 compute guidance------------
|
||||
guidance_price NUMERIC(20,5),
|
||||
guidance_reason NVARCHAR(MAX),
|
||||
@ -259,9 +260,9 @@ BEGIN
|
||||
AND q.last_dataseg = tpl.ds
|
||||
AND q.chan = tpl.chan
|
||||
AND q.tier = tpl.tier
|
||||
AND q.calculated_pallets >= tpl.lower_bound
|
||||
AND (q.last_qty/q.pltq) >= tpl.lower_bound
|
||||
AND (
|
||||
tpl.upper_bound IS NULL OR q.calculated_pallets < tpl.upper_bound
|
||||
tpl.upper_bound IS NULL OR (q.last_qty/q.pltq) < tpl.upper_bound
|
||||
);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
@ -338,7 +339,9 @@ BEGIN
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol
|
||||
ORDER BY p.price ASC
|
||||
) AS rn
|
||||
) AS rn,
|
||||
p.vb_from,
|
||||
p.vb_to
|
||||
FROM @queue q
|
||||
INNER JOIN CMSInterfaceIn."CMS.CUSLG".IPRCBHC i
|
||||
ON TRIM(i.jbplvl) = TRIM(q.plevel)
|
||||
@ -355,6 +358,7 @@ BEGIN
|
||||
,listprice = rp.price
|
||||
,listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END
|
||||
,list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END
|
||||
,list_from = vb_from
|
||||
FROM @queue q
|
||||
JOIN ranked_prices rp
|
||||
ON q.bill = rp.bill
|
||||
@ -450,7 +454,14 @@ BEGIN
|
||||
----------------------label------------------------------------------------
|
||||
CASE
|
||||
WHEN q.last_price IS NOT NULL
|
||||
THEN 'Last Sale: ' + ISNULL(CONVERT(varchar(10), q.last_date, 120), '')
|
||||
THEN
|
||||
CASE ISNULL(q.last_source, '')
|
||||
WHEN 'mrq' THEN 'Similar Quote'
|
||||
WHEN 'mrs' THEN 'Similar Sale'
|
||||
WHEN 'dsq' THEN 'Last Sale'
|
||||
WHEN 'dss' THEN 'Last Quote'
|
||||
ELSE ''
|
||||
END
|
||||
ELSE 'No Recent'
|
||||
END AS label,
|
||||
----------------------value------------------------------------------------
|
||||
@ -462,21 +473,24 @@ BEGIN
|
||||
WHEN q.last_price IS NOT NULL THEN
|
||||
CONCAT(
|
||||
CASE ISNULL(q.last_source, '')
|
||||
WHEN 'mrq' THEN 'Recent similar ' + last_part
|
||||
WHEN 'mrs' THEN 'Recent similar ' + last_part
|
||||
WHEN 'dsq' THEN 'Last quote'
|
||||
WHEN 'dss' THEN 'Last sale'
|
||||
WHEN 'mrq' THEN 'Similar - ' + last_part
|
||||
WHEN 'mrs' THEN 'Similar - ' + last_part
|
||||
WHEN 'dsq' THEN last_part
|
||||
WHEN 'dss' THEN last_part
|
||||
ELSE ''
|
||||
END,
|
||||
CASE WHEN ISNULL(q.last_order, '0') = '0'
|
||||
THEN ' Qt# ' + ISNULL(q.last_quote, '')
|
||||
ELSE ' Ord# ' + ISNULL(q.last_order, '')
|
||||
END
|
||||
THEN ' | Qt# ' + ISNULL(q.last_quote, '')
|
||||
ELSE ' | Ord# ' + ISNULL(q.last_order, '')
|
||||
END,
|
||||
ISNULL(' | ' + CONVERT(varchar(10), q.last_date, 120), ''),
|
||||
' | Qty ' + format(q.last_qty,'#,###'),
|
||||
CASE WHEN last_isdiff <> '' THEN ' | Normalized To: ' + cast(last_price_norm AS varchar(10)) ELSE '' END,
|
||||
' | ' /*+ q.last_premium_method*/ + ' Last Target = ' + format(q.tprice_last,'0.0####') + ' | Current Target ' + format(q.tprice,'0.0####')
|
||||
)
|
||||
ELSE
|
||||
''
|
||||
END
|
||||
+ CASE WHEN last_isdiff <> '' THEN ' | normalized to: ' + cast(last_price_norm AS varchar(10)) ELSE '' END
|
||||
AS note
|
||||
FOR JSON PATH -- array with one object (no WITHOUT_ARRAY_WRAPPER)
|
||||
) AS details
|
||||
@ -488,10 +502,10 @@ BEGIN
|
||||
'List' AS label,
|
||||
(
|
||||
SELECT
|
||||
COALESCE('List:' + q.listcode,'No List') AS label,
|
||||
COALESCE('Code: ' + q.listcode,'No List') AS label,
|
||||
COALESCE(q.listprice,0) AS value,
|
||||
'currency' AS type,
|
||||
COALESCE(q.list_relevance,'') AS note
|
||||
COALESCE('List Min Qty: ' + format(q.list_from,'#,###'),'') + CASE WHEN q.list_relevance = '' THEN '' ELSE ' (' + q.list_relevance + ')' END AS note
|
||||
FOR JSON PATH
|
||||
)
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user