Compare commits
1 Commits
Author | SHA1 | Date | |
---|---|---|---|
9452220c46 |
@ -1,167 +0,0 @@
|
||||
DROP FUNCTION pricequote.build_pricing_path_base;
|
||||
|
||||
CREATE OR REPLACE FUNCTION pricequote.build_pricing_path_base(
|
||||
_json JSONB
|
||||
)
|
||||
RETURNS TABLE (
|
||||
stlc TEXT
|
||||
,seq BIGINT
|
||||
,srtcode TEXT
|
||||
,ds TEXT
|
||||
,chan TEXT
|
||||
,tier TEXT
|
||||
,vol INT4RANGE
|
||||
,func TEXT
|
||||
,val NUMERIC
|
||||
,price NUMERIC
|
||||
,math TEXT[]
|
||||
,lastflag BOOLEAN
|
||||
)
|
||||
LANGUAGE plpgsql AS
|
||||
$$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
|
||||
WITH RECURSIVE
|
||||
-- 1️⃣ Parse JSONB into rows of (entity, attr, val)
|
||||
parsed AS (
|
||||
SELECT
|
||||
e.entity,
|
||||
COALESCE(e.attr, '') AS attr,
|
||||
e.val,
|
||||
e.func
|
||||
FROM jsonb_to_recordset(_json)
|
||||
AS e(entity TEXT, attr TEXT, val NUMERIC, func TEXT)
|
||||
),
|
||||
-- 2️⃣ Attach sequence & func from master option_sequence table
|
||||
sequenced AS (
|
||||
SELECT
|
||||
p.entity,
|
||||
p.attr,
|
||||
p.val,
|
||||
p.func,
|
||||
s.DOMAIN,
|
||||
DENSE_RANK() OVER (ORDER BY s.seq) AS seq,
|
||||
ROW_NUMBER() OVER (PARTITION BY p.entity ORDER BY COALESCE(p.val,0) ASC) srt
|
||||
FROM parsed p
|
||||
JOIN pricequote.option_sequence s
|
||||
ON p.entity = s.entity
|
||||
)
|
||||
--select * from sequenced ORDER BY seq, srt
|
||||
-- 3️⃣ Recursively accumulate pricing path
|
||||
,combos AS (
|
||||
-- 🚀 Base case: first in sequence
|
||||
SELECT
|
||||
s.entity,
|
||||
s.attr,
|
||||
s.seq,
|
||||
to_char(s.srt,'FM000') srtcode,
|
||||
'' ds,
|
||||
'' chan,
|
||||
'' tier,
|
||||
null::TEXT vol,
|
||||
s.func,
|
||||
s.val,
|
||||
s.val agg,
|
||||
CASE WHEN s.func = 'Price' THEN s.val ELSE NULL::NUMERIC END AS base,
|
||||
ARRAY[
|
||||
CASE
|
||||
WHEN s.func = 'Price' THEN
|
||||
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
|
||||
WHEN s.func = 'Factor' THEN
|
||||
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(COALESCE(NULLIF(CASE WHEN s.func = 'Price' THEN s.val END, NULL), 0) * (s.val - 1), 'FM9999999990.00000'), 10, ' ')
|
||||
ELSE
|
||||
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
|
||||
END
|
||||
] math
|
||||
FROM
|
||||
sequenced s
|
||||
WHERE
|
||||
s.seq = (SELECT MIN(x.seq) FROM sequenced x)
|
||||
UNION ALL
|
||||
-- 🔁 Recursive step: process next in sequence
|
||||
SELECT
|
||||
c.entity,
|
||||
c.attr,
|
||||
o.seq,
|
||||
c.srtcode || '.' || to_char(o.srt,'FM000'),
|
||||
c.ds || CASE WHEN o.DOMAIN = 'Product' THEN '.' || o.attr ELSE '' END,
|
||||
CASE WHEN o.DOMAIN = 'Channel' THEN o.attr ELSE c.chan END chan,
|
||||
CASE WHEN o.DOMAIN = 'Tier' THEN o.attr ELSE c.tier END tier,
|
||||
CASE WHEN o.DOMAIN = 'Volume' THEN o.attr ELSE c.vol END vol,
|
||||
o.func,
|
||||
o.val,
|
||||
CASE
|
||||
WHEN o.func = 'Price' THEN c.agg + o.val
|
||||
WHEN o.func = 'Factor' THEN c.agg + COALESCE(c.base, 0) * (o.val - 1)
|
||||
END agg,
|
||||
COALESCE(c.base, CASE WHEN o.func = 'Price' THEN o.val ELSE NULL::NUMERIC END) AS base,
|
||||
CASE WHEN (o.func = 'Price' AND o.val <> 0) OR (o.func = 'Factor' AND o.val <> 1) THEN
|
||||
c.math ||
|
||||
ARRAY[
|
||||
CASE
|
||||
WHEN o.func = 'Price' THEN
|
||||
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
|
||||
WHEN o.func = 'Factor' THEN
|
||||
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(COALESCE(c.base, 0) * (o.val - 1), 'FM9999999990.00000'), 10, ' ')
|
||||
ELSE
|
||||
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
|
||||
END
|
||||
]
|
||||
ELSE
|
||||
c.math
|
||||
END math
|
||||
FROM
|
||||
combos c
|
||||
JOIN sequenced o ON
|
||||
o.seq = c.seq + 1
|
||||
)
|
||||
SELECT
|
||||
-- c.entity
|
||||
c.attr
|
||||
,c.seq
|
||||
,c.srtcode
|
||||
,'v1:'||SUBSTRING(c.ds,2,100) ds
|
||||
,c.chan
|
||||
,c.tier
|
||||
-- ,c.vol
|
||||
,CASE
|
||||
WHEN c.vol ~ '^[0-9]+-[0-9]+$' THEN
|
||||
int4range(
|
||||
split_part(c.vol, '-', 1)::int,
|
||||
split_part(c.vol, '-', 2)::int,
|
||||
'[)'
|
||||
)
|
||||
WHEN c.vol ~ '^[0-9]+$' THEN
|
||||
int4range(
|
||||
c.vol::int,
|
||||
NULL,
|
||||
'[)'
|
||||
)
|
||||
ELSE NULL
|
||||
END AS vol
|
||||
,c.func
|
||||
,c.val
|
||||
,c.agg
|
||||
,c.math
|
||||
,c.seq = (SELECT max(x.seq) FROM sequenced x) lastflag
|
||||
FROM
|
||||
combos c /*WHERE seq = (SELECT max(seq) FROM sequenced)*/
|
||||
ORDER BY
|
||||
c.srtcode ASC;
|
||||
|
||||
END;
|
||||
$$;
|
||||
|
||||
/*
|
||||
Anchor:EU170S50 + 0.08
|
||||
Color Tier:P x 1.30
|
||||
Branding: + 0.00
|
||||
Packaging:SLV + 0.00
|
||||
Suffix:PCR x 1.00
|
||||
Accessories: + 0.00
|
||||
Channel:WHS + 0.00
|
||||
Volume:8 x 1.00
|
||||
-----------------------
|
||||
0.104
|
||||
*/
|
184
esc.json
184
esc.json
@ -1,184 +0,0 @@
|
||||
[
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Anchor",
|
||||
"attr": "BM.03000",
|
||||
"val": 0.15,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Color Tier",
|
||||
"attr": "B",
|
||||
"val": 1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Color Tier",
|
||||
"attr": "C",
|
||||
"val": 1.2,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Color Tier",
|
||||
"attr": "L",
|
||||
"val": 1.1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Color Tier",
|
||||
"attr": "M",
|
||||
"val": 1.2,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Color Tier",
|
||||
"attr": "P",
|
||||
"val": 1.2,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Color Tier",
|
||||
"attr": "T",
|
||||
"val": 1.1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Branding",
|
||||
"attr": null,
|
||||
"val": 0,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Branding",
|
||||
"attr": "L",
|
||||
"val": 0.04,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Branding",
|
||||
"attr": "P",
|
||||
"val": 0.1,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Packaging",
|
||||
"attr": "BDL",
|
||||
"val": 0.005,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Packaging",
|
||||
"attr": "CSE",
|
||||
"val": 0.01,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Packaging",
|
||||
"attr": "PLT",
|
||||
"val": 0,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Packaging",
|
||||
"attr": "SLV",
|
||||
"val": 0.005,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Suffix",
|
||||
"attr": null,
|
||||
"val": 1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Accessories",
|
||||
"attr": null,
|
||||
"val": 0,
|
||||
"func": "Price"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Channel",
|
||||
"attr": "DIR",
|
||||
"val": 1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Channel",
|
||||
"attr": "DRP",
|
||||
"val": 1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Channel",
|
||||
"attr": "WHS",
|
||||
"val": 1.1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Tier",
|
||||
"attr": 1,
|
||||
"val": 1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Tier",
|
||||
"attr": 2,
|
||||
"val": 1.05,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Tier",
|
||||
"attr": 3,
|
||||
"val": 1.1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Volume",
|
||||
"attr": "00-01",
|
||||
"val": 1.35,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Volume",
|
||||
"attr": "01-08",
|
||||
"val": 1.1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Volume",
|
||||
"attr": "24",
|
||||
"val": 1,
|
||||
"func": "Factor"
|
||||
},
|
||||
{
|
||||
"folder": "01 Gal Can",
|
||||
"entity": "Volume",
|
||||
"attr": "08-24",
|
||||
"val": 1.05,
|
||||
"func": "Factor"
|
||||
}
|
||||
]
|
@ -1,38 +1,15 @@
|
||||
|
||||
EXEC pricing.single_price_call
|
||||
@bill = 'GRIF0001',
|
||||
@ship = 'GRIF0001',
|
||||
@part = 'XNS0T1G3G18B096',
|
||||
@v1ds = 'v1:B..PLT..',
|
||||
@vol = 9600;
|
||||
|
||||
EXEC pricing.single_price_call
|
||||
@bill = 'FARM0001',
|
||||
@ship = 'KEYB0001',
|
||||
@part = 'HCA10000B661100',
|
||||
@v1ds = 'v1:T..CSE..D',
|
||||
@vol = 172000;
|
||||
|
||||
SELECT g.*
|
||||
FROM (SELECT
|
||||
TRY_CAST(.33275 AS NUMERIC(20,5)) AS tprice,
|
||||
TRY_CAST(.758 AS NUMERIC(20,5)) AS last_price_norm,
|
||||
TRY_CAST(null AS NUMERIC(20,5)) AS listprice_eff,
|
||||
TRY_CAST('2025-06-01' AS DATE) AS last_date
|
||||
) q
|
||||
CROSS APPLY pricing.guidance_logic(q.tprice, q.last_price_norm, q.listprice_eff, q.last_date, 0.05, 1.0, 1.0) g;
|
||||
|
||||
|
||||
SELECT * FROM pricing.lastpricedetail l WHERE customer = 'HYBELS' AND l.partgroup = 'HZP3E100'
|
||||
|
||||
SELECT * FROM pricing.pricelist_ranged pr WHERE pr.jcpart = 'XNS0T1G3G18B096' AND
|
||||
|
||||
SELECT * FROM CMSInterfaceIN.[CMS.CUSLG].
|
||||
@part = 'HZP3E100E21D050',
|
||||
@v1ds = 'v1:T..BDL..',
|
||||
@vol = 50000;
|
||||
|
||||
EXEC pricing.single_price_call
|
||||
@bill = 'GRIF0001',
|
||||
@ship = 'GRIF0001',
|
||||
@part = 'XNS0T1G3G18B096',
|
||||
@part = 'XNS0T1G3G18B96',
|
||||
@v1ds = 'v1:B..PLT..',
|
||||
@vol = 9600;
|
||||
|
||||
|
@ -1,80 +1,10 @@
|
||||
SELECT
|
||||
ui_json->'data'
|
||||
FROM pricequote.single_price_call(
|
||||
'FARM0001',
|
||||
'KEYB0001',
|
||||
'HCA10000B661100',
|
||||
'v1:T..CSE..D',
|
||||
50000
|
||||
) f;
|
||||
SELECT
|
||||
*
|
||||
FROM pricequote.single_price_call(
|
||||
'FARM0001',
|
||||
'KEYB0001',
|
||||
'HZP3E100E21D050',
|
||||
'v1:T..BDL..',
|
||||
50000
|
||||
) f
|
||||
|
||||
|
||||
SELECT
|
||||
*, ui_json->'data'
|
||||
FROM pricequote.single_price_call(
|
||||
'BFGS0001',
|
||||
'SPRI0019',
|
||||
'INT12040G18C100',
|
||||
'v1:B..CSE..',
|
||||
7037
|
||||
) f;
|
||||
|
||||
|
||||
SELECT
|
||||
*, ui_json->'data'
|
||||
FROM pricequote.single_price_call(
|
||||
'BELL0039',
|
||||
'BELL0039',
|
||||
'XNS0T1G3X19B096PZBND',
|
||||
'v1:L.P.PLT..',
|
||||
82420
|
||||
) f;
|
||||
|
||||
SELECT * FROM rlarp.cust WHERE code = 'PACK0009'
|
||||
|
||||
-- SELECT * FROM pricequote.lastpricedetail l WHERE customer = 'HYBELS' AND l.partgroup = 'HZP3E100';
|
||||
--
|
||||
|
||||
SELECT
|
||||
q.billto, q.shipto, q.part, q.v1ds, q.units_each, pc.tprice, pc.tmath
|
||||
FROM
|
||||
pricequote.live_quotes q
|
||||
LEFT JOIN LATERAL pricequote.single_price_call(
|
||||
billto, shipto, part, v1ds, units_each
|
||||
) pc ON TRUE
|
||||
WHERE
|
||||
qid = 113761
|
||||
-- AND qrn = 4;
|
||||
|
||||
create table pricequote.target_prices_base as (
|
||||
with
|
||||
expand AS (
|
||||
SELECT
|
||||
c.compset,
|
||||
c.stlc,
|
||||
c.floor,
|
||||
b.ds,
|
||||
b.chan,
|
||||
b.tier,
|
||||
b.vol,
|
||||
b.val,
|
||||
b.price,
|
||||
json_pretty(to_json(b.math)) math
|
||||
FROM
|
||||
pricequote.core_target c
|
||||
LEFT JOIN LATERAL pricequote.build_pricing_path_base (options||jsonb_build_object('entity','Anchor','attr',c.stlc,'val',c.floor,'func','Price')) b ON b.lastflag
|
||||
)
|
||||
-- select count(*) from expand
|
||||
select * from expand
|
||||
) with data;
|
||||
|
||||
-- SELECT
|
||||
-- stlc, ds, chan, tier, vol, price, math
|
||||
-- FROM
|
||||
-- pricequote.build_pricing_path_base(
|
||||
-- $$
|
||||
-- [{"folder":"01 Gal Can","entity":"Anchor","attr":"BM.03000","val":0.15,"func":"Price"},{"folder":"01 Gal Can","entity":"Color Tier","attr":"B","val":1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Color Tier","attr":"C","val":1.2,"func":"Factor"},{"folder":"01 Gal Can","entity":"Color Tier","attr":"L","val":1.1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Color Tier","attr":"M","val":1.2,"func":"Factor"},{"folder":"01 Gal Can","entity":"Color Tier","attr":"P","val":1.2,"func":"Factor"},{"folder":"01 Gal Can","entity":"Color Tier","attr":"T","val":1.1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Branding","attr":null,"val":0,"func":"Price"},{"folder":"01 Gal Can","entity":"Branding","attr":"L","val":0.04,"func":"Price"},{"folder":"01 Gal Can","entity":"Branding","attr":"P","val":0.1,"func":"Price"},{"folder":"01 Gal Can","entity":"Packaging","attr":"BDL","val":0.005,"func":"Price"},{"folder":"01 Gal Can","entity":"Packaging","attr":"CSE","val":0.01,"func":"Price"},{"folder":"01 Gal Can","entity":"Packaging","attr":"PLT","val":0,"func":"Price"},{"folder":"01 Gal Can","entity":"Packaging","attr":"SLV","val":0.005,"func":"Price"},{"folder":"01 Gal Can","entity":"Suffix","attr":null,"val":1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Accessories","attr":null,"val":0,"func":"Price"},{"folder":"01 Gal Can","entity":"Channel","attr":"DIR","val":1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Channel","attr":"DRP","val":1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Channel","attr":"WHS","val":1.1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Tier","attr":1,"val":1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Tier","attr":2,"val":1.05,"func":"Factor"},{"folder":"01 Gal Can","entity":"Tier","attr":3,"val":1.1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Volume","attr":"00-01","val":1.35,"func":"Factor"},{"folder":"01 Gal Can","entity":"Volume","attr":"01-08","val":1.1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Volume","attr":"24","val":1,"func":"Factor"},{"folder":"01 Gal Can","entity":"Volume","attr":"08-24","val":1.05,"func":"Factor"}]
|
||||
-- $$
|
||||
-- )
|
||||
-- WHERE
|
||||
-- lastflag
|
||||
|
@ -1,81 +0,0 @@
|
||||
-- CREATE OR ALTER FUNCTION pricing.approval_logic;
|
||||
|
||||
CREATE OR ALTER FUNCTION pricing.approval_logic(
|
||||
@target numeric(20,5),
|
||||
@last_norm numeric(20,5),
|
||||
@list_eff numeric(20,5),
|
||||
@last_date date,
|
||||
@floor_pct numeric(10,5) = 0.95,
|
||||
@cap_last_pct numeric(10,5) = 1.00,
|
||||
@cap_list_pct numeric(10,5) = 1.00
|
||||
)
|
||||
RETURNS @ret TABLE (
|
||||
approval_price numeric(20,5),
|
||||
approval_reason nvarchar(4000)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE
|
||||
@base_price numeric(20,5), -- starting point (target if available, else last_norm, else list_eff)
|
||||
@after_floor numeric(20,5), -- base but limited to x% lower than last price
|
||||
@after_cap_last numeric(20,5), -- previous step but limited to x% higher than last price
|
||||
@final_price numeric(20,5), -- previous step but limited to x% higher than list price
|
||||
@reason nvarchar(4000) = N''; -- logic source of price
|
||||
|
||||
-- Early exit if nothing to work with
|
||||
IF @target IS NULL AND @last_norm IS NULL AND @list_eff IS NULL
|
||||
BEGIN
|
||||
INSERT INTO @ret VALUES (NULL, N'No target, last, or list available');
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
-- Pick starting base price
|
||||
SET @base_price = COALESCE(@target, @last_norm, @list_eff);
|
||||
|
||||
-- Step 1: use base price unless it's more than x% below last price
|
||||
SET @after_floor = @base_price;
|
||||
IF @last_norm IS NOT NULL
|
||||
SET @after_floor = ROUND(
|
||||
CASE WHEN @base_price >= @last_norm*@floor_pct
|
||||
THEN @base_price
|
||||
ELSE @last_norm*@floor_pct
|
||||
END, 5);
|
||||
|
||||
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||
SET @after_cap_last = @after_floor;
|
||||
IF @last_norm IS NOT NULL
|
||||
SET @after_cap_last = ROUND(
|
||||
CASE WHEN @after_floor <= @last_norm*@cap_last_pct
|
||||
THEN @after_floor
|
||||
ELSE @last_norm*@cap_last_pct
|
||||
END, 5);
|
||||
|
||||
-- Step 3: use price from last step, but don't allow it to be more than x% above list price
|
||||
SET @final_price = @after_cap_last;
|
||||
IF @list_eff IS NOT NULL
|
||||
SET @final_price = ROUND(
|
||||
CASE WHEN @after_cap_last <= @list_eff*@cap_list_pct
|
||||
THEN @after_cap_last
|
||||
ELSE @list_eff*@cap_list_pct
|
||||
END, 5);
|
||||
|
||||
-- Reason text
|
||||
SET @reason =
|
||||
CASE
|
||||
WHEN @target IS NOT NULL THEN N'Using target price'
|
||||
WHEN @last_norm IS NOT NULL THEN N'Using last price as base'
|
||||
WHEN @list_eff IS NOT NULL THEN N'Using list price as base'
|
||||
END;
|
||||
|
||||
IF @last_norm IS NOT NULL AND @after_floor > @base_price
|
||||
SET @reason = N'Last price drop limit';
|
||||
|
||||
IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor
|
||||
SET @reason = N'Last price increase limit';
|
||||
|
||||
IF @list_eff IS NOT NULL AND @final_price < @after_cap_last
|
||||
SET @reason = N'List price ceiling';
|
||||
|
||||
INSERT INTO @ret VALUES (@final_price, @reason);
|
||||
RETURN;
|
||||
END;
|
@ -1,72 +0,0 @@
|
||||
CREATE OR REPLACE FUNCTION pricequote.approval_logic(
|
||||
_target numeric(20,5),
|
||||
_last_norm numeric(20,5),
|
||||
_list_eff numeric(20,5),
|
||||
_last_date date,
|
||||
_floor_pct numeric(10,5) DEFAULT 0.95,
|
||||
_cap_last_pct numeric(10,5) DEFAULT 1.00,
|
||||
_cap_list_pct numeric(10,5) DEFAULT 1.00
|
||||
)
|
||||
RETURNS TABLE (
|
||||
approval_price numeric(20,5),
|
||||
approval_reason text
|
||||
)
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
base_price numeric(20,5);
|
||||
after_floor numeric(20,5);
|
||||
after_cap_last numeric(20,5);
|
||||
final_price numeric(20,5);
|
||||
reason text := '';
|
||||
BEGIN
|
||||
|
||||
-- Early exit if nothing to work with
|
||||
IF _target IS NULL AND _last_norm IS NULL AND _list_eff IS NULL THEN
|
||||
RETURN QUERY SELECT NULL::numeric, 'No target, last, or list available';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
|
||||
-- Pick starting base price
|
||||
base_price := COALESCE(_target, _last_norm, _list_eff);
|
||||
|
||||
-- Step 1: use base price unless it's more than x% below last price
|
||||
after_floor := base_price;
|
||||
IF _last_norm IS NOT NULL THEN
|
||||
after_floor := GREATEST(base_price, ROUND(_last_norm*_floor_pct,5));
|
||||
END IF;
|
||||
|
||||
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||
after_cap_last := after_floor;
|
||||
IF _last_norm IS NOT NULL THEN
|
||||
after_cap_last := LEAST(after_floor, ROUND(_last_norm*_cap_last_pct,5));
|
||||
END IF;
|
||||
|
||||
-- cap to list (binds if it lowers price)
|
||||
final_price := after_cap_last;
|
||||
IF _list_eff IS NOT NULL THEN
|
||||
final_price := LEAST(after_cap_last, ROUND(_list_eff*_cap_list_pct,5));
|
||||
END IF;
|
||||
|
||||
-- Reason text
|
||||
reason :=
|
||||
CASE
|
||||
WHEN _target IS NOT NULL THEN 'Using target price'
|
||||
WHEN _last_norm IS NOT NULL THEN 'Using last price as base'
|
||||
WHEN _list_eff IS NOT NULL THEN 'Using list price as base'
|
||||
END;
|
||||
|
||||
IF _last_norm IS NOT NULL AND after_floor > base_price THEN
|
||||
reason := 'Last price drop limit';
|
||||
END IF;
|
||||
|
||||
IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN
|
||||
reason := 'Last price increase limit';
|
||||
END IF;
|
||||
|
||||
IF _list_eff IS NOT NULL AND final_price < after_cap_last THEN
|
||||
reason := 'List price ceiling';
|
||||
END IF;
|
||||
|
||||
RETURN QUERY SELECT final_price, reason;
|
||||
END $$;
|
@ -1,61 +1,119 @@
|
||||
-- CREATE OR ALTER FUNCTION pricing.guidance_logic;
|
||||
|
||||
CREATE OR ALTER FUNCTION pricing.guidance_logic(
|
||||
@target numeric(20,5),
|
||||
@last_norm numeric(20,5),
|
||||
@list_eff numeric(20,5),
|
||||
@last_date date,
|
||||
@floor_pct numeric(10,5) = 0.95,
|
||||
@cap_last_pct numeric(10,5) = 1.00,
|
||||
@cap_list_pct numeric(10,5) = 1.00
|
||||
-- This function returns the least of two NUMERIC(20,5) values.
|
||||
CREATE OR ALTER FUNCTION dbo.LEAST_NUMERIC205(
|
||||
@a NUMERIC(20,5),
|
||||
@b NUMERIC(20,5)
|
||||
)
|
||||
RETURNS @ret TABLE (
|
||||
guidance_price numeric(20,5),
|
||||
guidance_reason nvarchar(4000)
|
||||
RETURNS NUMERIC(20,5)
|
||||
AS
|
||||
BEGIN
|
||||
RETURN CASE
|
||||
WHEN @a IS NULL THEN @b
|
||||
WHEN @b IS NULL THEN @a
|
||||
WHEN @a < @b THEN @a ELSE @b
|
||||
END
|
||||
END
|
||||
GO
|
||||
|
||||
-- This function returns the greatest of two NUMERIC(20,5) values.
|
||||
CREATE OR ALTER FUNCTION dbo.GREATEST_NUMERIC205(
|
||||
@a NUMERIC(20,5),
|
||||
@b NUMERIC(20,5)
|
||||
)
|
||||
RETURNS NUMERIC(20,5)
|
||||
AS
|
||||
BEGIN
|
||||
RETURN CASE
|
||||
WHEN @a IS NULL THEN @b
|
||||
WHEN @b IS NULL THEN @a
|
||||
WHEN @a > @b THEN @a ELSE @b
|
||||
END
|
||||
END
|
||||
GO
|
||||
|
||||
-- This function implements the guidance logic for pricing based on target, last, and list prices.
|
||||
CREATE OR ALTER FUNCTION pricing.guidance_logic (
|
||||
@target_price NUMERIC(20,5),
|
||||
@last_price NUMERIC(20,5),
|
||||
@list_price NUMERIC(20,5),
|
||||
@last_date DATE
|
||||
)
|
||||
RETURNS @result TABLE (
|
||||
guidance_price NUMERIC(20,5),
|
||||
guidance_reason NVARCHAR(MAX)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE
|
||||
@base_price numeric(20,5), -- starting point (target if available, else last_norm, else list_eff)
|
||||
@after_floor numeric(20,5), -- base but limited to x% lower than last price
|
||||
@after_cap_last numeric(20,5), -- previous step but limited to x% higher than last price
|
||||
@final_price numeric(20,5), -- previous step but limited to x% higher than list price
|
||||
@reason nvarchar(4000) = N''; -- logic source of price
|
||||
DECLARE @price NUMERIC(20,5);
|
||||
DECLARE @reason NVARCHAR(MAX) = '';
|
||||
DECLARE @floored NUMERIC(20,5);
|
||||
DECLARE @capped NUMERIC(20,5);
|
||||
DECLARE @use_last_price BIT = 0;
|
||||
|
||||
-- Early exit if nothing to work with
|
||||
IF @target IS NULL AND @last_norm IS NULL AND @list_eff IS NULL
|
||||
-- Determine if last price is recent (within last 2 years)
|
||||
IF @last_price IS NOT NULL AND @last_date IS NOT NULL AND @last_date > DATEADD(YEAR, -2, CAST(GETDATE() AS DATE))
|
||||
SET @use_last_price = 1;
|
||||
|
||||
IF @target_price IS NOT NULL AND @use_last_price = 1
|
||||
BEGIN
|
||||
INSERT INTO @ret VALUES (NULL, N'No target, last, or list available');
|
||||
RETURN;
|
||||
END;
|
||||
SET @floored = dbo.GREATEST_NUMERIC205(@target_price, @last_price * 0.95);
|
||||
SET @capped = dbo.LEAST_NUMERIC205(@floored, @last_price);
|
||||
SET @price = dbo.LEAST_NUMERIC205(ISNULL(@list_price, 1e9), @capped);
|
||||
|
||||
-- Pick starting base price
|
||||
SET @base_price = COALESCE(@target, @last_norm, @list_eff);
|
||||
-- Reason text
|
||||
SET @reason =
|
||||
CASE
|
||||
WHEN @target IS NOT NULL THEN N'Using target price'
|
||||
WHEN @last_norm IS NOT NULL THEN N'Using last price as base'
|
||||
WHEN @list_eff IS NOT NULL THEN N'Using list price as base'
|
||||
END;
|
||||
|
||||
-- Step 1: use base price less than last price, use last price
|
||||
IF @base_price < @last_norm
|
||||
BEGIN
|
||||
SET @base_price = @last_norm;
|
||||
SET @reason = N'Last price';
|
||||
IF @price = @last_price
|
||||
BEGIN
|
||||
SET @reason = 'Cap at last price';
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @reason = 'Using target price';
|
||||
IF @target_price < @last_price * 0.95
|
||||
SET @reason += ', floored to 5% below last price';
|
||||
IF @target_price > @last_price
|
||||
SET @reason += ', capped to not exceed last price';
|
||||
IF @list_price IS NOT NULL AND @price = @list_price AND @target_price > @list_price
|
||||
SET @reason += ', capped to not exceed list price';
|
||||
END
|
||||
END
|
||||
|
||||
|
||||
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||
IF @base_price > @list_eff
|
||||
ELSE IF @use_last_price = 1
|
||||
BEGIN
|
||||
SET @base_price = @list_eff;
|
||||
SET @reason = N'List price ceiling';
|
||||
SET @price = @last_price;
|
||||
SET @reason = 'Last price - no target';
|
||||
END
|
||||
|
||||
SET @final_price = @base_price;
|
||||
|
||||
INSERT INTO @ret VALUES (@final_price, @reason);
|
||||
ELSE IF @target_price IS NOT NULL
|
||||
BEGIN
|
||||
SET @price = @target_price;
|
||||
IF @last_price IS NOT NULL AND @last_date IS NOT NULL
|
||||
BEGIN
|
||||
SET @reason = CONCAT(
|
||||
'Last price ignored (too old: ',
|
||||
CONVERT(NVARCHAR(10), @last_date, 120),
|
||||
'), using target price'
|
||||
);
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @reason = 'Target price - no prior sale';
|
||||
END
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @price = NULL;
|
||||
IF @last_price IS NOT NULL AND @last_date IS NOT NULL
|
||||
BEGIN
|
||||
SET @reason = CONCAT(
|
||||
'Last price ignored (too old: ',
|
||||
CONVERT(NVARCHAR(10), @last_date, 120),
|
||||
'), no pricing available'
|
||||
);
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @reason = 'No pricing available';
|
||||
END
|
||||
END
|
||||
|
||||
INSERT INTO @result VALUES (@price, @reason);
|
||||
RETURN;
|
||||
END;
|
||||
END
|
||||
GO
|
@ -1,56 +1,74 @@
|
||||
CREATE OR REPLACE FUNCTION pricequote.guidance_logic(
|
||||
_target numeric(20,5),
|
||||
_last_norm numeric(20,5),
|
||||
_list_eff numeric(20,5),
|
||||
_last_date date,
|
||||
_floor_pct numeric(10,5) DEFAULT 0.95,
|
||||
_cap_last_pct numeric(10,5) DEFAULT 1.00,
|
||||
_cap_list_pct numeric(10,5) DEFAULT 1.00
|
||||
_target_price NUMERIC(20,5),
|
||||
_last_price NUMERIC(20,5),
|
||||
_list_price NUMERIC(20,5),
|
||||
_last_date DATE
|
||||
)
|
||||
RETURNS TABLE (
|
||||
guidance_price numeric(20,5),
|
||||
guidance_reason text
|
||||
)
|
||||
LANGUAGE plpgsql AS $$
|
||||
guidance_price NUMERIC(20,5),
|
||||
guidance_reason TEXT
|
||||
) AS $$
|
||||
DECLARE
|
||||
base_price numeric(20,5);
|
||||
after_floor numeric(20,5);
|
||||
after_cap_last numeric(20,5);
|
||||
final_price numeric(20,5);
|
||||
reason text := '';
|
||||
|
||||
_price NUMERIC(20,5);
|
||||
_reason TEXT := '';
|
||||
_floored NUMERIC(20,5);
|
||||
_capped NUMERIC(20,5);
|
||||
_use_last_price BOOLEAN := FALSE;
|
||||
BEGIN
|
||||
|
||||
-- Early exit if nothing to work with
|
||||
IF _target IS NULL AND _last_norm IS NULL AND _list_eff IS NULL THEN
|
||||
RETURN QUERY SELECT NULL::numeric, 'No target, last, or list available';
|
||||
RETURN;
|
||||
-- Evaluate whether last price is recent enough
|
||||
IF _last_price IS NOT NULL AND _last_date IS NOT NULL AND _last_date > CURRENT_DATE - INTERVAL '2 years' THEN
|
||||
_use_last_price := TRUE;
|
||||
END IF;
|
||||
|
||||
|
||||
-- Pick starting base price
|
||||
base_price := COALESCE(_target, _last_norm, _list_eff);
|
||||
-- Reason text
|
||||
reason :=
|
||||
CASE
|
||||
WHEN _target IS NOT NULL THEN 'Using target price'
|
||||
WHEN _last_norm IS NOT NULL THEN 'Using last price as base'
|
||||
WHEN _list_eff IS NOT NULL THEN 'Using list price as base'
|
||||
END;
|
||||
IF _target_price IS NOT NULL AND _use_last_price THEN
|
||||
_floored := GREATEST(_target_price, _last_price * 0.95);
|
||||
_capped := LEAST(_floored, _last_price);
|
||||
_price := LEAST(COALESCE(_list_price, 1e9), _capped);
|
||||
|
||||
-- Step 1: use base price less than last price, use last price
|
||||
IF base_price < _last_norm THEN
|
||||
base_price := _last_norm;
|
||||
reason := 'Last price';
|
||||
IF _price = _last_price THEN
|
||||
_reason := 'Cap at last price';
|
||||
ELSE
|
||||
_reason := 'Using target price';
|
||||
IF _target_price < _last_price * 0.95 THEN
|
||||
_reason := _reason || ', floored to 5% below last price';
|
||||
END IF;
|
||||
IF _target_price > _last_price THEN
|
||||
_reason := _reason || ', capped to not exceed last price';
|
||||
END IF;
|
||||
IF _list_price IS NOT NULL AND _price = _list_price AND _target_price > _list_price THEN
|
||||
_reason := _reason || ', capped to not exceed list price';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
ELSIF _use_last_price THEN
|
||||
_price := _last_price;
|
||||
_reason := 'Last price - no target';
|
||||
|
||||
ELSIF _target_price IS NOT NULL THEN
|
||||
_price := _target_price;
|
||||
|
||||
IF _last_price IS NOT NULL AND _last_date IS NOT NULL THEN
|
||||
_reason := format(
|
||||
'Last price ignored (too old: %s), using target price',
|
||||
to_char(_last_date, 'YYYY-MM-DD')
|
||||
);
|
||||
ELSE
|
||||
_reason := 'Target price - no prior sale';
|
||||
END IF;
|
||||
|
||||
ELSE
|
||||
_price := NULL;
|
||||
|
||||
IF _last_price IS NOT NULL AND _last_date IS NOT NULL THEN
|
||||
_reason := format(
|
||||
'Last price ignored (too old: %s), no pricing available',
|
||||
to_char(_last_date, 'YYYY-MM-DD')
|
||||
);
|
||||
ELSE
|
||||
_reason := 'No pricing available';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||
IF base_price > _list_eff THEN
|
||||
base_price := _list_eff;
|
||||
reason := 'List price ceiling';
|
||||
END IF;
|
||||
|
||||
final_price := base_price;
|
||||
|
||||
RETURN QUERY SELECT final_price, reason;
|
||||
END $$;
|
||||
RETURN QUERY SELECT _price, _reason;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
@ -1,3 +1,4 @@
|
||||
|
||||
-- JSON-based helper function for last price selection
|
||||
CREATE OR ALTER FUNCTION pricing.pick_last_price_from_hist_json (
|
||||
@part_stats NVARCHAR(MAX),
|
||||
@ -10,12 +11,11 @@ RETURNS @result TABLE (
|
||||
qty NUMERIC(20,5),
|
||||
dataseg NVARCHAR(100),
|
||||
ord NVARCHAR(20),
|
||||
quote NVARCHAR(20),
|
||||
part NVARCHAR(100)
|
||||
quote NVARCHAR(20)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @age_threshold DATE = DATEADD(month, -18, GETDATE());
|
||||
DECLARE @age_threshold DATE = DATEADD(year, -1, GETDATE());
|
||||
|
||||
-- Extract all relevant objects from JSON
|
||||
DECLARE @dsq NVARCHAR(MAX), @dss NVARCHAR(MAX), @mrq NVARCHAR(MAX), @mrs NVARCHAR(MAX);
|
||||
@ -27,81 +27,63 @@ 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), @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);
|
||||
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);
|
||||
|
||||
IF @dsq IS NOT NULL
|
||||
SELECT @dsq_price = price, @dsq_date = odate, @dsq_qty = qty, @dsq_dataseg = datasegment, @dsq_ord = ordnum, @dsq_quote = quoten, @dsq_part = part
|
||||
SELECT @dsq_price = price, @dsq_date = odate, @dsq_qty = qty, @dsq_dataseg = datasegment, @dsq_ord = ordnum, @dsq_quote = quoten
|
||||
FROM OPENJSON(@dsq)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
IF @dss IS NOT NULL
|
||||
SELECT @dss_price = price, @dss_date = odate, @dss_qty = qty, @dss_dataseg = datasegment, @dss_ord = ordnum, @dss_quote = quoten, @dss_part = part
|
||||
SELECT @dss_price = price, @dss_date = odate, @dss_qty = qty, @dss_dataseg = datasegment, @dss_ord = ordnum, @dss_quote = quoten
|
||||
FROM OPENJSON(@dss)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
IF @mrq IS NOT NULL
|
||||
SELECT @mrq_price = price, @mrq_date = odate, @mrq_qty = qty, @mrq_dataseg = datasegment, @mrq_ord = ordnum, @mrq_quote = quoten, @mrq_part = part
|
||||
SELECT @mrq_price = price, @mrq_date = odate, @mrq_qty = qty, @mrq_dataseg = datasegment, @mrq_ord = ordnum, @mrq_quote = quoten
|
||||
FROM OPENJSON(@mrq)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
IF @mrs IS NOT NULL
|
||||
SELECT @mrs_price = price, @mrs_date = odate, @mrs_qty = qty, @mrs_dataseg = datasegment, @mrs_ord = ordnum, @mrs_quote = quoten, @mrs_part = part
|
||||
SELECT @mrs_price = price, @mrs_date = odate, @mrs_qty = qty, @mrs_dataseg = datasegment, @mrs_ord = ordnum, @mrs_quote = quoten
|
||||
FROM OPENJSON(@mrs)
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20), part NVARCHAR(100));
|
||||
WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20));
|
||||
|
||||
-- Use the same selection logic as before
|
||||
-- 1. Prefer the most recent of dss/dsq if either is within the age threshold
|
||||
IF (@dss_date IS NOT NULL AND @dss_date > @age_threshold)
|
||||
BEGIN
|
||||
INSERT INTO @result VALUES (@dss_price, 'dss', @dss_date, @dss_qty, @dss_dataseg, @dss_ord, @dss_quote, @dss_part);
|
||||
RETURN;
|
||||
END
|
||||
-- IF (@dsq_date IS NOT NULL AND @dsq_date > @age_threshold)
|
||||
-- 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, @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, @dss_part);
|
||||
-- RETURN;
|
||||
-- END
|
||||
IF (@dsq_date IS NOT NULL AND @dsq_date > @age_threshold)
|
||||
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);
|
||||
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);
|
||||
RETURN;
|
||||
END
|
||||
|
||||
-- 2. If both dss/dsq are older than the threshold, use the most recent of mrs/mrq if either exists
|
||||
IF @mrs_date IS NOT NULL AND @mrs_date > @age_threshold
|
||||
BEGIN
|
||||
INSERT INTO @result VALUES (@mrs_price, 'mrs', @mrs_date, @mrs_qty, @mrs_dataseg, @mrs_ord, @mrs_quote, @mrs_part);
|
||||
RETURN;
|
||||
END
|
||||
-- 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, @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, @mrs_part);
|
||||
-- RETURN;
|
||||
-- END
|
||||
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);
|
||||
ELSE IF @mrs_date IS NOT NULL
|
||||
INSERT INTO @result VALUES (@mrs_price, 'mrs', @mrs_date, @mrs_qty, @mrs_dataseg, @mrs_ord, @mrs_quote);
|
||||
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
|
||||
-- ,@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, @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, @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, @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, @best_part = @mrs_part;
|
||||
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;
|
||||
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;
|
||||
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;
|
||||
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;
|
||||
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;
|
||||
|
||||
-- IF @best_price IS NOT NULL
|
||||
-- INSERT INTO @result VALUES (@best_price, @best_source, @best_date, @best_qty, @best_dataseg, @best_ord, @best_quote, @best_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);
|
||||
|
||||
RETURN;
|
||||
END
|
||||
|
@ -12,7 +12,7 @@ DECLARE
|
||||
BEGIN
|
||||
-- Central control for age threshold
|
||||
DECLARE
|
||||
age_threshold INTERVAL := INTERVAL '18 months';
|
||||
age_threshold INTERVAL := INTERVAL '1 year';
|
||||
dsq_date DATE := NULL;
|
||||
dss_date DATE := NULL;
|
||||
mrq_date DATE := NULL;
|
||||
@ -20,7 +20,6 @@ BEGIN
|
||||
best JSONB := NULL;
|
||||
best_date DATE := NULL;
|
||||
BEGIN
|
||||
-- set dates
|
||||
IF dsq IS NOT NULL AND (dsq->>'price') IS NOT NULL THEN
|
||||
dsq_date := (dsq->>'odate')::date;
|
||||
END IF;
|
||||
@ -35,31 +34,40 @@ BEGIN
|
||||
END IF;
|
||||
|
||||
-- 1. Prefer the most recent of dss/dsq if either is within the age threshold
|
||||
IF dss_date IS NOT NULL AND dss_date > (CURRENT_DATE - age_threshold) THEN
|
||||
result := dss || jsonb_build_object('source', 'dss');
|
||||
IF (dsq_date IS NOT NULL AND dsq_date > (CURRENT_DATE - age_threshold))
|
||||
OR (dss_date IS NOT NULL AND dss_date > (CURRENT_DATE - age_threshold)) THEN
|
||||
IF dsq_date IS NOT NULL AND (dss_date IS NULL OR dsq_date >= dss_date) AND dsq_date > (CURRENT_DATE - age_threshold) THEN
|
||||
result := dsq || jsonb_build_object('source', 'dsq');
|
||||
ELSIF dss_date IS NOT NULL AND dss_date > (CURRENT_DATE - age_threshold) THEN
|
||||
result := dss || jsonb_build_object('source', 'dss');
|
||||
END IF;
|
||||
-- 2. If both dss/dsq are older than the threshold, use the most recent of mrs/mrq if either exists
|
||||
ELSIF mrs_date IS NOT NULL AND mrs_date > (CURRENT_DATE - age_threshold) THEN
|
||||
result := mrs || jsonb_build_object('source', 'mrs');
|
||||
ELSIF (mrq_date IS NOT NULL OR mrs_date IS NOT NULL) THEN
|
||||
IF mrq_date IS NOT NULL AND (mrs_date IS NULL OR mrq_date >= mrs_date) THEN
|
||||
result := mrq || jsonb_build_object('source', 'mrq');
|
||||
ELSIF mrs_date IS NOT NULL THEN
|
||||
result := mrs || jsonb_build_object('source', 'mrs');
|
||||
END IF;
|
||||
-- 3. If all are at least as old as the threshold, pick the least oldest price available
|
||||
ELSE
|
||||
best := NULL;
|
||||
best_date := NULL;
|
||||
-- IF dsq_date IS NOT NULL THEN
|
||||
-- best := dsq || jsonb_build_object('source', 'dsq');
|
||||
-- best_date := dsq_date;
|
||||
-- END IF;
|
||||
-- IF dss_date IS NOT NULL AND (best_date IS NULL OR dss_date > best_date) THEN
|
||||
-- best := dss || jsonb_build_object('source', 'dss');
|
||||
-- best_date := dss_date;
|
||||
-- END IF;
|
||||
-- IF mrq_date IS NOT NULL AND (best_date IS NULL OR mrq_date > best_date) THEN
|
||||
-- best := mrq || jsonb_build_object('source', 'mrq');
|
||||
-- best_date := mrq_date;
|
||||
-- END IF;
|
||||
-- IF mrs_date IS NOT NULL AND (best_date IS NULL OR mrs_date > best_date) THEN
|
||||
-- best := mrs || jsonb_build_object('source', 'mrs');
|
||||
-- best_date := mrs_date;
|
||||
-- END IF;
|
||||
IF dsq_date IS NOT NULL THEN
|
||||
best := dsq || jsonb_build_object('source', 'dsq');
|
||||
best_date := dsq_date;
|
||||
END IF;
|
||||
IF dss_date IS NOT NULL AND (best_date IS NULL OR dss_date > best_date) THEN
|
||||
best := dss || jsonb_build_object('source', 'dss');
|
||||
best_date := dss_date;
|
||||
END IF;
|
||||
IF mrq_date IS NOT NULL AND (best_date IS NULL OR mrq_date > best_date) THEN
|
||||
best := mrq || jsonb_build_object('source', 'mrq');
|
||||
best_date := mrq_date;
|
||||
END IF;
|
||||
IF mrs_date IS NOT NULL AND (best_date IS NULL OR mrs_date > best_date) THEN
|
||||
best := mrs || jsonb_build_object('source', 'mrs');
|
||||
best_date := mrs_date;
|
||||
END IF;
|
||||
result := best;
|
||||
END IF;
|
||||
RETURN result;
|
||||
|
@ -1,265 +1,247 @@
|
||||
-- Recreate queue with columns matching single_price_call outputs
|
||||
DROP TABLE IF EXISTS pricequote.queue;
|
||||
|
||||
CREATE TABLE pricequote.queue (
|
||||
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,
|
||||
hist JSONB,
|
||||
tprice NUMERIC,
|
||||
tmath JSONB,
|
||||
volume_range TEXT,
|
||||
listprice NUMERIC,
|
||||
listcode TEXT,
|
||||
listprice_eff NUMERIC,
|
||||
list_relevance TEXT,
|
||||
guidance_price NUMERIC,
|
||||
guidance_reason TEXT,
|
||||
approval_price NUMERIC,
|
||||
approval_reason TEXT,
|
||||
expl JSONB,
|
||||
ui_json JSONB
|
||||
bill TEXT,
|
||||
ship TEXT,
|
||||
part TEXT,
|
||||
stlc TEXT,
|
||||
v1ds TEXT,
|
||||
vol NUMERIC,
|
||||
chan TEXT,
|
||||
cust TEXT,
|
||||
tier TEXT,
|
||||
pltq NUMERIC,
|
||||
plevel TEXT,
|
||||
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,
|
||||
list_price NUMERIC,
|
||||
list_code TEXT,
|
||||
guidance_price NUMERIC,
|
||||
guidance_reason TEXT,
|
||||
expl JSONB,
|
||||
ui_json JSONB,
|
||||
partgroup TEXT
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_osm_stack_merge
|
||||
ON rlarp.osm_stack (bill_cust, ship_cust, part, stlc, dataseg, qtyord);
|
||||
/*
|
||||
====================================================================================
|
||||
Script: matrix_guidance.pg.sql
|
||||
Purpose: Batch pricing logic for sales matrix (PostgreSQL)
|
||||
-----------------------------------------------------------------------------------
|
||||
Description:
|
||||
- Seeds a queue table with distinct pricing scenarios from rlarp.osm_stack
|
||||
- Enriches each scenario with customer, channel, tier, pack quantity, and price level
|
||||
- Looks up and applies target price, price history, list price, and guidance logic
|
||||
- Builds a JSON explanation for each scenario
|
||||
- Merges results back into the main sales matrix table
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_queue_merge
|
||||
ON pricequote.queue (bill, ship, part, stlc, v1ds, vol);
|
||||
Inputs:
|
||||
- Source table: rlarp.osm_stack
|
||||
- Pricing reference tables: pricequote.target_prices, pricequote.lastpricedetail, pricequote.pricelist_ranged
|
||||
- Customer/item reference: rlarp.cust, CMS.CUSLG.itemm, CMS.CUSLG.IPRCBHC
|
||||
|
||||
-- Batch procedure mirroring single_price_call logic (4-space indentation)
|
||||
Outputs:
|
||||
- Updates rlarp.osm_stack.pricing with a JSON explanation for each scenario
|
||||
- All intermediate results are stored in pricequote.queue
|
||||
|
||||
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 batch/matrix pricing updates
|
||||
- Assumes all referenced tables and functions exist
|
||||
- See also: single_price_call.pg.sql for single-row logic
|
||||
====================================================================================
|
||||
*/
|
||||
|
||||
CREATE INDEX idx_osm_stack_merge
|
||||
ON rlarp.osm_stack (
|
||||
bill_cust,
|
||||
ship_cust,
|
||||
part,
|
||||
stlc,
|
||||
dataseg,
|
||||
qtyord
|
||||
);
|
||||
|
||||
CREATE INDEX idx_queue_merge
|
||||
ON pricequote.queue (
|
||||
bill,
|
||||
ship,
|
||||
part,
|
||||
stlc,
|
||||
v1ds,
|
||||
vol
|
||||
);
|
||||
|
||||
|
||||
--DROP PROCEDURE IF EXISTS pricequote.process_queue;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE pricequote.process_queue()
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
--------------------------------------------------------------------
|
||||
-- 1) Seed queue from matrix
|
||||
--------------------------------------------------------------------
|
||||
DELETE FROM pricequote.queue;
|
||||
-- 1:30
|
||||
|
||||
INSERT INTO pricequote.queue (bill, ship, part, stlc, v1ds, vol, expl, ui_json)
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 1: Seed the queue table with distinct pricing scenarios
|
||||
-----------------------------------------------------------------------
|
||||
DELETE FROM pricequote.queue;
|
||||
|
||||
INSERT INTO pricequote.queue (bill, ship, part, stlc, v1ds, vol, expl)
|
||||
SELECT DISTINCT
|
||||
o.bill_cust,
|
||||
o.ship_cust,
|
||||
o.bill_cust AS bill,
|
||||
o.ship_cust AS ship,
|
||||
o.part,
|
||||
o.stlc,
|
||||
o.dataseg,
|
||||
o.qtyord,
|
||||
'{}'::jsonb,
|
||||
'{}'::jsonb
|
||||
o.dataseg AS v1ds,
|
||||
o.qtyord AS vol,
|
||||
'{}'::jsonb AS expl
|
||||
FROM rlarp.osm_stack o
|
||||
WHERE
|
||||
WHERE
|
||||
o.fs_line = '41010'
|
||||
AND o.calc_status <> 'CANCELLED'
|
||||
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
||||
AND o.part IS NOT NULL
|
||||
AND SUBSTRING(o.glec, 1, 1) <= '2';
|
||||
-- 2:12 0:38
|
||||
AND substring(o.glec, 1, 1) <= '2';
|
||||
-- 44 seconds
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 2) Enrich: chan, tier, cust, pltq, plevel, partgroup (+stlc fix)
|
||||
--------------------------------------------------------------------
|
||||
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 2: Enrich customer, tier, channel, pack quantity, and level
|
||||
-----------------------------------------------------------------------
|
||||
MERGE INTO pricequote.queue q
|
||||
USING (
|
||||
SELECT
|
||||
SELECT
|
||||
q.ctid,
|
||||
-- Determine sales channel
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) WHEN 'DIS' THEN 'WHS' ELSE 'DRP' END
|
||||
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN 'WHS'
|
||||
ELSE 'DRP'
|
||||
END
|
||||
ELSE 'DIR'
|
||||
END AS chan,
|
||||
|
||||
-- Determine pricing tier
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE COALESCE(sc.tier, bc.tier)
|
||||
END AS tier,
|
||||
|
||||
-- Resolve customer DBA name
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) WHEN 'DIS' THEN bc.dba ELSE sc.dba END
|
||||
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN bc.dba
|
||||
ELSE sc.dba
|
||||
END
|
||||
ELSE bc.dba
|
||||
END AS cust,
|
||||
|
||||
-- Pack quantity
|
||||
i.mpck AS pltq,
|
||||
|
||||
-- Price level
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) WHEN 'DIS' THEN sc.plevel ELSE bc.plevel END
|
||||
WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN sc.plevel
|
||||
ELSE bc.plevel
|
||||
END
|
||||
ELSE bc.plevel
|
||||
END AS plevel,
|
||||
i.partgroup AS partgroup,
|
||||
SUBSTRING(q.part, 1, 8) AS stlc_fix
|
||||
i.partgroup
|
||||
FROM pricequote.queue q
|
||||
JOIN rlarp.cust bc ON bc.code = q.bill
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
|
||||
LEFT JOIN "CMS.CUSLG".itemm i ON i.item = q.part
|
||||
) s
|
||||
ON (q.ctid = s.ctid)
|
||||
WHEN MATCHED THEN UPDATE SET
|
||||
chan = s.chan,
|
||||
tier = s.tier,
|
||||
cust = s.cust,
|
||||
pltq = s.pltq,
|
||||
plevel = s.plevel,
|
||||
partgroup = s.partgroup,
|
||||
stlc = COALESCE(q.stlc, s.stlc_fix);
|
||||
-- 4:51 0:17
|
||||
) src
|
||||
ON (q.ctid = src.ctid)
|
||||
WHEN MATCHED THEN
|
||||
UPDATE SET
|
||||
chan = src.chan,
|
||||
tier = src.tier,
|
||||
cust = src.cust,
|
||||
pltq = src.pltq,
|
||||
plevel = src.plevel,
|
||||
partgroup = src.partgroup;
|
||||
-- 17 seconds
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 3) Scenario fields from item master: part_v1ds, v0ds, orig costs
|
||||
-- + customized flag
|
||||
--------------------------------------------------------------------
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 3: Apply target prices and embed target metadata
|
||||
-----------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
part_v1ds = i0.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 = i0.curstdus,
|
||||
futstd_orig = i0.futstdus,
|
||||
customized = CASE
|
||||
WHEN i0.v1ds IS NOT NULL AND q.v1ds IS NOT NULL AND i0.v1ds <> q.v1ds
|
||||
THEN 'Customized'
|
||||
ELSE ''
|
||||
END
|
||||
FROM "CMS.CUSLG".itemm i0
|
||||
WHERE i0.item = q.part;
|
||||
-- 3:21 0:20
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 4) History: store hist, extract last_* with precedence helper
|
||||
--------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
hist = x.part_stats, -- from the correlated subquery
|
||||
last_price = (j->>'price')::NUMERIC,
|
||||
last_qty = (j->>'qty')::NUMERIC,
|
||||
last_dataseg = j->>'datasegment',
|
||||
last_date = (j->>'odate')::DATE,
|
||||
last_order = j->>'ordnum',
|
||||
last_quote = j->>'quoten',
|
||||
last_source = j->>'source',
|
||||
last_isdiff = CASE
|
||||
WHEN (j->>'datasegment') IS NOT NULL
|
||||
AND q.v1ds IS NOT NULL
|
||||
AND (j->>'datasegment') <> q.v1ds
|
||||
THEN 'Last Sale Diff Part'
|
||||
END,
|
||||
last_v0ds = (CASE SUBSTRING(j->>'datasegment', 4, 1)
|
||||
WHEN 'B' THEN 'B' ELSE 'C' END)
|
||||
|| (CASE SUBSTRING(j->>'datasegment', 6, 1)
|
||||
WHEN 'L' THEN 'L'
|
||||
WHEN 'P' THEN 'P'
|
||||
ELSE '' END)
|
||||
FROM (
|
||||
SELECT
|
||||
q2.ctid,
|
||||
lp2.part_stats,
|
||||
pricequote.pick_last_price_from_hist(lp2.part_stats, q2.v1ds) AS j
|
||||
FROM pricequote.queue q2
|
||||
JOIN pricequote.lastpricedetail lp2
|
||||
ON lp2.customer = q2.cust
|
||||
AND lp2.partgroup = q2.partgroup
|
||||
) AS x
|
||||
WHERE q.ctid = x.ctid;
|
||||
-- 7:32 1:31
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 5) Target (requested v1ds): tprice, tmath, volume_range
|
||||
--------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
SET
|
||||
tprice = tp.price,
|
||||
tmath = to_json(tp.math),
|
||||
volume_range = tp.vol::TEXT
|
||||
FROM pricequote.target_prices_base tp
|
||||
WHERE
|
||||
expl = q.expl || jsonb_build_object(
|
||||
'target_price', tp.price,
|
||||
'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0)),
|
||||
'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0), 5),
|
||||
'volume range', tp.vol::TEXT,
|
||||
'customer', q.cust,
|
||||
'channel', q.chan,
|
||||
'tier', TRIM(q.tier),
|
||||
'target math', tp.math
|
||||
)
|
||||
FROM pricequote.target_prices tp
|
||||
WHERE
|
||||
tp.stlc = q.stlc
|
||||
AND tp.ds = q.v1ds
|
||||
AND tp.chan = q.chan
|
||||
AND tp.tier = q.tier
|
||||
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp.vol;
|
||||
-- 2:51 0:15
|
||||
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::int <@ tp.vol;
|
||||
-- 20 seconds
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 6) Target for last_dataseg (tprice_last)
|
||||
--------------------------------------------------------------------
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 4: Lookup price history and embed all relevant keys and precedence
|
||||
-----------------------------------------------------------------------
|
||||
-- Use the helper function to extract last price precedence and build JSON explanation as in single_price_call
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
tprice_last = tp2.price
|
||||
FROM pricequote.target_prices_base tp2
|
||||
WHERE
|
||||
q.last_dataseg IS NOT NULL
|
||||
AND tp2.stlc = q.stlc
|
||||
AND tp2.ds = q.last_dataseg
|
||||
AND tp2.chan = q.chan
|
||||
AND tp2.tier = q.tier
|
||||
AND FLOOR(q.last_qty / NULLIF(q.pltq, 0))::INT <@ tp2.vol;
|
||||
-- 1:26 0:08
|
||||
SET
|
||||
last_price = (last_json->>'price')::numeric,
|
||||
last_qty = (last_json->>'qty')::numeric,
|
||||
last_dataseg = last_json->>'datasegment',
|
||||
last_date = (last_json->>'odate')::date,
|
||||
last_order = last_json->>'ordnum',
|
||||
last_quote = last_json->>'quoten',
|
||||
last_source = last_json->>'source',
|
||||
expl = q.expl || jsonb_build_object(
|
||||
'last_price', (last_json->>'price')::numeric,
|
||||
'last_qty', (last_json->>'qty')::numeric,
|
||||
'last_dataseg', last_json->>'datasegment',
|
||||
'last_source', last_json->>'source',
|
||||
'last_date', (last_json->>'odate')::date,
|
||||
'last_order', last_json->>'ordnum',
|
||||
'last_quote', last_json->>'quoten'
|
||||
)
|
||||
FROM (
|
||||
SELECT q.ctid, pricequote.pick_last_price_from_hist(lp.part_stats, q.v1ds) AS last_json
|
||||
FROM pricequote.queue q
|
||||
JOIN pricequote.lastpricedetail lp
|
||||
ON lp.customer = q.cust AND lp.partgroup = q.partgroup
|
||||
) sub
|
||||
WHERE q.ctid = sub.ctid;
|
||||
-- 2 minutes 36 seconds
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 7) Cost data for requested v1ds and last_dataseg
|
||||
--------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
curstd = CASE WHEN COALESCE(q.customized,'') = '' THEN q.curstd_orig ELSE COALESCE(s.v1_cur, s.v0_cur) END,
|
||||
futstd = CASE WHEN COALESCE(q.customized,'') = '' THEN q.futstd_orig ELSE COALESCE(s.v1_fut, s.v0_fut) END,
|
||||
curstd_last = CASE WHEN COALESCE(q.last_isdiff,'') = '' THEN q.curstd_orig ELSE COALESCE(s.v1l_cur, s.v0l_cur) END,
|
||||
futstd_last = CASE WHEN COALESCE(q.last_isdiff,'') = '' THEN q.futstd_orig ELSE COALESCE(s.v1l_fut, s.v0l_fut) END
|
||||
FROM (
|
||||
SELECT
|
||||
q2.ctid,
|
||||
v1.curstdus AS v1_cur,
|
||||
v1.futstdus AS v1_fut,
|
||||
v0.curstdus AS v0_cur,
|
||||
v0.futstdus AS v0_fut,
|
||||
v1l.curstdus AS v1l_cur,
|
||||
v1l.futstdus AS v1l_fut,
|
||||
v0l.curstdus AS v0l_cur,
|
||||
v0l.futstdus AS v0l_fut
|
||||
FROM pricequote.queue q2
|
||||
LEFT JOIN rlarp.cost_v1ds v1
|
||||
ON v1.stlc = q2.stlc AND v1.v1ds = q2.v1ds
|
||||
LEFT JOIN rlarp.cost_v0ds v0
|
||||
ON v0.stlc = q2.stlc AND v0.v0ds = q2.v0ds
|
||||
LEFT JOIN rlarp.cost_v1ds v1l
|
||||
ON v1l.stlc = q2.stlc AND v1l.v1ds = q2.last_dataseg
|
||||
LEFT JOIN rlarp.cost_v0ds v0l
|
||||
ON v0l.stlc = q2.stlc AND v0l.v0ds = q2.last_v0ds
|
||||
) AS s
|
||||
WHERE q.ctid = s.ctid;
|
||||
-- 4:15 0:25
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 8) List price (lowest valid); allow open-ended ranges (vb_to IS NULL)
|
||||
--------------------------------------------------------------------
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 5: Resolve best list price and insert it with list code
|
||||
-----------------------------------------------------------------------
|
||||
WITH ranked_prices AS (
|
||||
SELECT
|
||||
SELECT
|
||||
q.ctid,
|
||||
pr.price,
|
||||
pr.jcplcd,
|
||||
@ -272,262 +254,58 @@ BEGIN
|
||||
ON pr.jcplcd = TRIM(i.jbplcd)
|
||||
AND pr.jcpart = q.part
|
||||
AND q.vol >= pr.vb_from
|
||||
AND (q.vol < pr.vb_to OR pr.vb_to IS NULL)
|
||||
AND q.vol < pr.vb_to
|
||||
),
|
||||
best_price AS (
|
||||
SELECT * FROM ranked_prices WHERE rn = 1
|
||||
)
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
listprice = p.price,
|
||||
listcode = p.jcplcd
|
||||
SET
|
||||
list_price = p.price,
|
||||
list_code = p.jcplcd,
|
||||
expl = q.expl || jsonb_build_object(
|
||||
'list_price', p.price,
|
||||
'list_code', p.jcplcd
|
||||
)
|
||||
FROM best_price p
|
||||
WHERE q.ctid = p.ctid;
|
||||
-- 2:48 0:18
|
||||
-- 15 seconds
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 9) Normalize last (when last_dataseg != v1ds) + effective list flags
|
||||
--------------------------------------------------------------------
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 6: Compute guidance price using logic function
|
||||
-----------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
last_premium = CASE
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
AND q.tprice_last IS NOT NULL
|
||||
AND q.tprice IS NOT NULL
|
||||
AND q.tprice_last <> 0
|
||||
THEN ROUND(q.tprice / q.tprice_last, 5)
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
AND q.curstd_last IS NOT NULL
|
||||
AND q.curstd IS NOT NULL
|
||||
AND q.curstd_last <> 0
|
||||
THEN ROUND(q.curstd / q.curstd_last,5)
|
||||
END,
|
||||
last_premium_method = CASE
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
AND q.tprice_last IS NOT NULL
|
||||
AND q.tprice IS NOT NULL
|
||||
AND q.tprice_last <> 0
|
||||
THEN 'Target Price Ratio'
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
AND q.curstd_last IS NOT NULL
|
||||
AND q.curstd IS NOT NULL
|
||||
AND q.curstd_last <> 0
|
||||
THEN 'Cost Ratio'
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
THEN 'Unknown'
|
||||
END,
|
||||
last_price_norm = CASE
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
AND q.tprice_last IS NOT NULL
|
||||
AND q.tprice IS NOT NULL
|
||||
AND q.tprice_last <> 0
|
||||
THEN ROUND(q.last_price * (q.tprice / q.tprice_last), 5)
|
||||
WHEN q.last_isdiff IS NOT NULL
|
||||
AND q.curstd_last IS NOT NULL
|
||||
AND q.curstd IS NOT NULL
|
||||
AND q.curstd_last <> 0
|
||||
THEN ROUND(q.last_price * (q.curstd / q.curstd_last), 5)
|
||||
ELSE q.last_price
|
||||
END,
|
||||
listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END,
|
||||
list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END;
|
||||
-- 2:22 0:23
|
||||
SET
|
||||
guidance_price = g.guidance_price,
|
||||
guidance_reason = g.guidance_reason,
|
||||
expl = q.expl || jsonb_build_object(
|
||||
'guidance_price', g.guidance_price,
|
||||
'guidance_reason', g.guidance_reason
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
q.ctid,
|
||||
g.guidance_price,
|
||||
g.guidance_reason
|
||||
FROM pricequote.queue q
|
||||
JOIN LATERAL pricequote.guidance_logic(
|
||||
q.tprice,
|
||||
q.last_price,
|
||||
q.list_price,
|
||||
q.last_date
|
||||
) g ON TRUE
|
||||
) g
|
||||
WHERE q.ctid = g.ctid;
|
||||
-- 27 seconds
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 10) Guidance using normalized last + effective list
|
||||
--------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
guidance_price = s.guidance_price,
|
||||
guidance_reason = s.guidance_reason,
|
||||
approval_price = s.approval_price,
|
||||
approval_reason = s.approval_reason
|
||||
FROM (
|
||||
SELECT
|
||||
q2.ctid,
|
||||
g.guidance_price,
|
||||
g.guidance_reason,
|
||||
a.approval_price,
|
||||
a.approval_reason
|
||||
FROM
|
||||
pricequote.queue q2
|
||||
JOIN LATERAL pricequote.guidance_logic(
|
||||
q2.tprice,
|
||||
q2.last_price_norm,
|
||||
q2.listprice_eff,
|
||||
q2.last_date,
|
||||
1.0, 1.0, 1.0
|
||||
) g ON TRUE
|
||||
JOIN LATERAL pricequote.approval_logic(
|
||||
q2.tprice,
|
||||
q2.last_price_norm,
|
||||
q2.listprice_eff,
|
||||
q2.last_date,
|
||||
1.0, 1.0, 1.0
|
||||
) a ON TRUE
|
||||
) s
|
||||
WHERE q.ctid = s.ctid;
|
||||
-- 4:33 0:39
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 11) Build expl and ui_json identical to single_price_call
|
||||
--------------------------------------------------------------------
|
||||
UPDATE pricequote.queue q
|
||||
SET
|
||||
expl = jsonb_build_object(
|
||||
'last', jsonb_build_object(
|
||||
'last_part', (pricequote.pick_last_price_from_hist(q.hist, q.v1ds)->>'part'),
|
||||
'last_price', q.last_price,
|
||||
'last_qty', q.last_qty,
|
||||
'last_dataseg', q.last_dataseg,
|
||||
'last_v0ds', q.last_v0ds,
|
||||
'last_source', q.last_source,
|
||||
'last_date', q.last_date,
|
||||
'last_order', q.last_order,
|
||||
'last_quote', q.last_quote,
|
||||
'last_isdiff', q.last_isdiff,
|
||||
'last_premium', q.last_premium,
|
||||
'last_premium_method', q.last_premium_method,
|
||||
'last_price_norm', q.last_price_norm,
|
||||
'tprice_last', q.tprice_last
|
||||
),
|
||||
'scenario', jsonb_build_object(
|
||||
'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0)),
|
||||
'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0), 5),
|
||||
'customer', q.cust,
|
||||
'channel', q.chan,
|
||||
'tier', TRIM(q.tier),
|
||||
'v1ds', q.v1ds,
|
||||
'v0ds', q.v0ds,
|
||||
'part_v1ds', q.part_v1ds,
|
||||
'customized', q.customized
|
||||
),
|
||||
'cost', jsonb_build_object(
|
||||
'curstd_orig', q.curstd_orig,
|
||||
'futstd_orig', q.futstd_orig,
|
||||
'curstd_last', q.curstd_last,
|
||||
'futstd_last', q.futstd_last,
|
||||
'curstd', q.curstd,
|
||||
'futstd', q.futstd
|
||||
),
|
||||
'targets', jsonb_build_object(
|
||||
'target_price', q.tprice,
|
||||
'target_math', q.tmath,
|
||||
'volume_range', q.volume_range
|
||||
),
|
||||
'list', jsonb_build_object(
|
||||
'listcode', q.listcode,
|
||||
'listprice', q.listprice,
|
||||
'listprice_eff', q.listprice_eff,
|
||||
'list_relevance', q.list_relevance
|
||||
),
|
||||
'guidance_price', q.guidance_price,
|
||||
'guidance_reason', q.guidance_reason,
|
||||
'approval_price', q.approval_price,
|
||||
'approval_reason', q.approval_reason
|
||||
),
|
||||
ui_json = jsonb_build_object(
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'History',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', CASE WHEN q.last_price IS NOT NULL THEN 'Last Sale: ' || q.last_date ELSE 'No Recent' END,
|
||||
'value', COALESCE(q.last_price, 0),
|
||||
'type', 'currency',
|
||||
'note', CASE WHEN q.last_price IS NOT NULL THEN
|
||||
CASE q.last_source
|
||||
WHEN 'mrq' THEN 'Recent similar ' || (pricequote.pick_last_price_from_hist(q.hist, q.v1ds)->>'part') || ' qty: ' || q.last_qty
|
||||
WHEN 'mrs' THEN 'Recent similar ' || (pricequote.pick_last_price_from_hist(q.hist, q.v1ds)->>'part') || ' qty: ' || q.last_qty
|
||||
WHEN 'dsq' THEN 'Last quote qty: ' || q.last_qty
|
||||
WHEN 'dss' THEN 'Last sale qty: ' || q.last_qty
|
||||
ELSE ''
|
||||
END
|
||||
|| CASE WHEN COALESCE(q.last_order, '0') = '0'
|
||||
THEN ' Qt# ' || COALESCE(q.last_quote, '')
|
||||
ELSE ' Ord# ' || COALESCE(q.last_order, '')
|
||||
END
|
||||
END
|
||||
)
|
||||
)
|
||||
|| CASE WHEN COALESCE(q.last_premium, 1) <> 1 THEN
|
||||
jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'Price Difference',
|
||||
'value', q.last_premium,
|
||||
'type', 'percent',
|
||||
'note', q.last_premium_method
|
||||
)
|
||||
)
|
||||
ELSE '[]'::jsonb END
|
||||
|| CASE WHEN COALESCE(q.last_premium, 1) <> 1 THEN
|
||||
jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'Adjusted Price',
|
||||
'value', q.last_price_norm,
|
||||
'type', 'currency',
|
||||
'note', 'normalized to ' || q.v1ds
|
||||
)
|
||||
)
|
||||
ELSE '[]'::jsonb END
|
||||
),
|
||||
jsonb_build_object(
|
||||
'label', 'List',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'List:' || COALESCE(q.listcode, ''),
|
||||
'value', q.listprice,
|
||||
'type', 'currency',
|
||||
'note', q.list_relevance
|
||||
)
|
||||
)
|
||||
),
|
||||
jsonb_build_object(
|
||||
'label', 'Target Calculation',
|
||||
'details',
|
||||
(
|
||||
SELECT jsonb_agg(
|
||||
jsonb_build_object(
|
||||
'label', CASE WHEN v <> '' THEN RTRIM(SUBSTRING(v, 1, 18)) ELSE 'No Target' END,
|
||||
'value', CASE WHEN v <> '' THEN SUBSTRING(v, 23, 7)::NUMERIC(20,5)
|
||||
+ CASE SUBSTRING(v, 19, 1) WHEN '+' THEN 0 ELSE -1 END
|
||||
ELSE 0 END,
|
||||
'type', CASE WHEN v <> '' THEN CASE SUBSTRING(v, 19, 1) WHEN '+' THEN 'currency' ELSE 'Percent' END ELSE '' END,
|
||||
'note', CASE WHEN v <> '' THEN CASE SUBSTRING(v, 19, 1) WHEN '+' THEN 'Price' ELSE 'Premium' END ELSE '' END
|
||||
)
|
||||
)
|
||||
FROM jsonb_array_elements_text(COALESCE(q.tmath, '[""]'::jsonb)) AS t(v)
|
||||
)
|
||||
|| CASE WHEN q.tprice IS NULL THEN '[]'::jsonb
|
||||
ELSE jsonb_build_object('label', 'Price', 'value', COALESCE(q.tprice, 0), 'type', 'currency', 'note', 'Total') END
|
||||
),
|
||||
jsonb_build_object(
|
||||
'label', 'Guidance',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'Price',
|
||||
'value', COALESCE(q.guidance_price, 0),
|
||||
'type', 'currency',
|
||||
'note', COALESCE(q.guidance_reason, '')
|
||||
)
|
||||
)
|
||||
)
|
||||
),
|
||||
'data', q.expl
|
||||
);
|
||||
-- 7:59 2:17
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 12) Merge back into matrix (store both expl and ui)
|
||||
--------------------------------------------------------------------
|
||||
-----------------------------------------------------------------------
|
||||
-- Step 7: merge the results back into sales matrix
|
||||
-----------------------------------------------------------------------
|
||||
UPDATE rlarp.osm_stack o
|
||||
SET pricing = pricing
|
||||
|| jsonb_build_object(
|
||||
'expl', q.expl,
|
||||
'ui', q.ui_json
|
||||
)
|
||||
SET pricing = pricing || q.expl
|
||||
FROM pricequote.queue q
|
||||
WHERE
|
||||
WHERE
|
||||
o.bill_cust = q.bill
|
||||
AND o.ship_cust IS NOT DISTINCT FROM q.ship
|
||||
AND o.part = q.part
|
||||
@ -538,9 +316,12 @@ BEGIN
|
||||
AND o.calc_status <> 'CANCELLED'
|
||||
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
||||
AND o.part IS NOT NULL
|
||||
AND SUBSTRING(o.glec, 1, 1) <= '2';
|
||||
-- 14:13 10:09
|
||||
AND substring(o.glec, 1, 1) <= '2';
|
||||
-- 6 minutes 31 seconds
|
||||
|
||||
-----------------------------------------------------------------------
|
||||
-- Done
|
||||
-----------------------------------------------------------------------
|
||||
RAISE NOTICE 'Queue processing complete.';
|
||||
END;
|
||||
$$;
|
||||
|
@ -113,7 +113,6 @@ BEGIN
|
||||
last_order NVARCHAR(10),
|
||||
last_quote NVARCHAR(10),
|
||||
last_isdiff NVARCHAR(100),
|
||||
last_part NVARCHAR(100),
|
||||
------------step 3 lookup target---------------
|
||||
tprice NUMERIC(20,5),
|
||||
tprice_last NUMERIC(20,5),
|
||||
@ -132,12 +131,9 @@ 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),
|
||||
approval_price NUMERIC(20,5),
|
||||
approval_reason NVARCHAR(MAX),
|
||||
------------step 7 build json------------------
|
||||
expl NVARCHAR(MAX),
|
||||
ui_json NVARCHAR(MAX)
|
||||
@ -175,7 +171,7 @@ BEGIN
|
||||
WHEN 'DIS' THEN bc.dba
|
||||
ELSE sc.dba
|
||||
END
|
||||
ELSE bc.dba
|
||||
ELSE q.bill
|
||||
END,
|
||||
pltq = i.mpck,
|
||||
plevel =
|
||||
@ -229,11 +225,10 @@ BEGIN
|
||||
last_order = b.ord,
|
||||
last_quote = b.quote,
|
||||
last_isdiff = CASE WHEN b.dataseg IS NOT NULL AND q.v1ds IS NOT NULL AND b.dataseg <> q.v1ds
|
||||
THEN 'Last Sale Diff Part' ELSE '' END,
|
||||
last_part = b.part
|
||||
THEN 'Last Sale Diff Part' ELSE '' END
|
||||
FROM @queue q
|
||||
CROSS APPLY (
|
||||
SELECT TOP 1 price, source, odate, qty, dataseg, ord, quote, part
|
||||
SELECT TOP 1 price, source, odate, qty, dataseg, ord, quote
|
||||
FROM pricing.pick_last_price_from_hist_json(q.hist, q.v1ds)
|
||||
) b;
|
||||
|
||||
@ -262,9 +257,9 @@ BEGIN
|
||||
AND q.last_dataseg = tpl.ds
|
||||
AND q.chan = tpl.chan
|
||||
AND q.tier = tpl.tier
|
||||
AND (q.last_qty/q.pltq) >= tpl.lower_bound
|
||||
AND q.calculated_pallets >= tpl.lower_bound
|
||||
AND (
|
||||
tpl.upper_bound IS NULL OR (q.last_qty/q.pltq) < tpl.upper_bound
|
||||
tpl.upper_bound IS NULL OR q.calculated_pallets < tpl.upper_bound
|
||||
);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
@ -341,9 +336,7 @@ 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,
|
||||
p.vb_from,
|
||||
p.vb_to
|
||||
) AS rn
|
||||
FROM @queue q
|
||||
INNER JOIN CMSInterfaceIn."CMS.CUSLG".IPRCBHC i
|
||||
ON TRIM(i.jbplvl) = TRIM(q.plevel)
|
||||
@ -358,9 +351,8 @@ BEGIN
|
||||
SET
|
||||
listcode = rp.jcplcd
|
||||
,listprice = rp.price
|
||||
,listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE rp.price END
|
||||
,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
|
||||
@ -379,33 +371,13 @@ BEGIN
|
||||
SET
|
||||
guidance_price = g.guidance_price
|
||||
,guidance_reason = g.guidance_reason
|
||||
,approval_price = a.approval_price
|
||||
,approval_reason = a.approval_reason
|
||||
FROM @queue q
|
||||
CROSS APPLY pricing.guidance_logic(
|
||||
TRY_CAST(q.tprice AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.last_price_norm AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.listprice_eff AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.last_date AS DATE),
|
||||
--allowable price drop percent
|
||||
1.0,
|
||||
--cap on last price
|
||||
1.0,
|
||||
--cap on list percent
|
||||
1.0
|
||||
) g
|
||||
CROSS APPLY pricing.approval_logic(
|
||||
TRY_CAST(q.tprice AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.last_price_norm AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.listprice_eff AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.last_date AS DATE),
|
||||
--allowable price drop percent
|
||||
1.0,
|
||||
--cap on last price
|
||||
1.0,
|
||||
--cap on list percent
|
||||
1.0
|
||||
) a;
|
||||
TRY_CAST(q.last_date AS DATE)
|
||||
) g;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 8: Assemble structured 'expl' JSON from populated columns.
|
||||
@ -420,7 +392,6 @@ BEGIN
|
||||
,q.last_source AS last_source
|
||||
,FORMAT(q.last_date, 'yyyy-MM-dd') AS last_date
|
||||
,q.last_isdiff AS last_isdiff
|
||||
,q.last_part AS last_part
|
||||
,q.tprice_last AS tprice_last
|
||||
,q.tprice AS target_price
|
||||
,JSON_QUERY(q.tmath) AS target_math
|
||||
@ -452,8 +423,6 @@ BEGIN
|
||||
,q.list_relevance AS list_relevance
|
||||
,q.guidance_price AS guidance_price
|
||||
,q.guidance_reason AS guidance_reason
|
||||
,q.approval_price AS approval_price
|
||||
,q.approval_reason AS approval_reason
|
||||
-- JSON_QUERY(hist) AS [history]
|
||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||
)
|
||||
@ -468,128 +437,55 @@ BEGIN
|
||||
(
|
||||
SELECT
|
||||
panel.label,
|
||||
panel.detailLevel,
|
||||
JSON_QUERY(panel.details) AS details
|
||||
FROM (
|
||||
-- History Panel
|
||||
SELECT
|
||||
'History' AS label,
|
||||
1 as detailLevel,
|
||||
(
|
||||
SELECT
|
||||
----------------------label------------------------------------------------
|
||||
CASE
|
||||
WHEN q.last_price IS NOT NULL
|
||||
THEN
|
||||
CASE ISNULL(q.last_source, '')
|
||||
WHEN 'mrq' THEN 'Similar Quote'
|
||||
WHEN 'mrs' THEN 'Similar Sale'
|
||||
WHEN 'dsq' THEN 'Last Quote'
|
||||
WHEN 'dss' THEN 'Last Sale'
|
||||
ELSE ''
|
||||
END
|
||||
ELSE 'No Recent'
|
||||
END AS label,
|
||||
----------------------detail-----------------------------------------------
|
||||
1 AS detailLevel,
|
||||
----------------------value------------------------------------------------
|
||||
ISNULL(q.last_price, 0) AS value,
|
||||
----------------------type-------------------------------------------------
|
||||
'currency' AS type,
|
||||
----------------------note-------------------------------------------------
|
||||
CASE
|
||||
WHEN q.last_price IS NOT NULL THEN
|
||||
CONCAT(
|
||||
CASE ISNULL(q.last_source, '')
|
||||
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,
|
||||
ISNULL(' | ' + CONVERT(varchar(10), q.last_date, 120), ''),
|
||||
' | Qty ' + format(q.last_qty,'#,###'),
|
||||
CASE WHEN COALESCE(last_isdiff,'') <> ''
|
||||
THEN
|
||||
' | Normalized To: ' + cast(last_price_norm AS varchar(10))
|
||||
+ ' | ' /*+ q.last_premium_method*/ + ' Last Target = ' + format(q.tprice_last,'0.0####') + ' | Current Target = ' + format(q.tprice,'0.0####')
|
||||
ELSE ''
|
||||
END
|
||||
)
|
||||
ELSE
|
||||
''
|
||||
END
|
||||
AS note
|
||||
FOR JSON PATH -- array with one object (no WITHOUT_ARRAY_WRAPPER)
|
||||
) AS details
|
||||
SELECT
|
||||
'History' AS label,
|
||||
(
|
||||
SELECT
|
||||
'Last Price' AS label,
|
||||
q.last_price AS value,
|
||||
'currency' AS type,
|
||||
CONCAT(
|
||||
'Source: ', ISNULL(q.last_source, 'N/A'),
|
||||
' | Date: ', ISNULL(CONVERT(varchar(10), q.last_date, 120), 'N/A'),
|
||||
' | Order: ', ISNULL(q.last_order, 'N/A'),
|
||||
' | Quote: ', ISNULL(q.last_quote, 'N/A'),
|
||||
' | Dataseg: ', ISNULL(q.last_dataseg, 'N/A'),
|
||||
' | Qty: ', ISNULL(CAST(q.last_qty AS varchar(32)), 'N/A')
|
||||
) AS note
|
||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||
) AS details
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- List Panel
|
||||
SELECT
|
||||
'List' AS label,
|
||||
1 AS detailLevel,
|
||||
(
|
||||
SELECT
|
||||
COALESCE('Code: ' + q.listcode,'No List') AS label,
|
||||
1 AS detailLevel,
|
||||
COALESCE(q.listprice,0) AS value,
|
||||
'List:' + q.listcode AS label,
|
||||
q.listprice AS value,
|
||||
'currency' AS type,
|
||||
COALESCE('List Min Qty: ' + format(q.list_from,'#,###'),'') + CASE WHEN q.list_relevance = '' THEN '' ELSE ' (' + q.list_relevance + ')' END AS note
|
||||
q.list_relevance AS note
|
||||
FOR JSON PATH
|
||||
) AS details
|
||||
)
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Target Support Panel
|
||||
SELECT
|
||||
'Target Calculation' AS label,
|
||||
5 AS detailLevel,
|
||||
'Target Support' AS label,
|
||||
(
|
||||
SELECT * FROM (
|
||||
SELECT
|
||||
----------------------label------------------------------------------------
|
||||
CASE WHEN value <> '' THEN replace(RTRIM(SUBSTRING(value,1,18)),'Anchor:', '') ELSE 'No Target' END AS label,
|
||||
----------------------detailLevel------------------------------------------
|
||||
10 AS detailLevel,
|
||||
----------------------value------------------------------------------------
|
||||
CASE WHEN value <> '' THEN
|
||||
TRY_CAST(SUBSTRING(value,23,7) AS NUMERIC(20,5))
|
||||
+ CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END
|
||||
ELSE 0 END AS value,
|
||||
----------------------type-------------------------------------------------
|
||||
CASE WHEN value <> '' THEN
|
||||
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'Percent' END
|
||||
ELSE '' END AS type,
|
||||
----------------------note-------------------------------------------------
|
||||
CASE WHEN value <> '' THEN
|
||||
CASE WHEN CHARINDEX('Anchor',value) <> 0 THEN
|
||||
'Base Floor'
|
||||
ELSE
|
||||
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'Price' ELSE 'Premium' END
|
||||
END
|
||||
ELSE '' END AS note
|
||||
FROM @queue q
|
||||
OUTER APPLY OPENJSON(q.expl, '$.target_math')
|
||||
WITH (value NVARCHAR(MAX) '$')
|
||||
UNION ALL
|
||||
SELECT
|
||||
----------------------label------------------------------------------------
|
||||
'Target' AS label,
|
||||
----------------------detailLevel------------------------------------------
|
||||
5 AS detailLevel,
|
||||
----------------------value------------------------------------------------
|
||||
tprice AS value,
|
||||
----------------------type-------------------------------------------------
|
||||
'currency' AS type,
|
||||
----------------------note-------------------------------------------------
|
||||
'Total' AS note
|
||||
FROM @queue q
|
||||
) x
|
||||
SELECT
|
||||
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 '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) '$')
|
||||
FOR JSON PATH
|
||||
) AS details
|
||||
|
||||
@ -598,12 +494,10 @@ BEGIN
|
||||
-- Guidance Panel
|
||||
SELECT
|
||||
'Guidance' AS label,
|
||||
1 AS detailLevel,
|
||||
(
|
||||
SELECT
|
||||
'Price' AS label,
|
||||
1 AS detailLevel,
|
||||
COALESCE(q.guidance_price,0) AS value,
|
||||
q.guidance_price AS value,
|
||||
'currency' AS type,
|
||||
q.guidance_reason AS note
|
||||
FOR JSON PATH
|
||||
@ -619,5 +513,5 @@ BEGIN
|
||||
--------------------------------------------------------------------------------
|
||||
-- Final: Return all calculated fields and JSON payloads.
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT guidance_price, ui_json FROM @queue;
|
||||
SELECT guidance_price, ui_json FROM @queue;
|
||||
END;
|
||||
|
@ -35,7 +35,7 @@
|
||||
====================================================================================
|
||||
*/
|
||||
|
||||
-- DROP FUNCTION pricequote.single_price_call(text,text,text,text,numeric) CASCADE;
|
||||
DROP FUNCTION pricequote.single_price_call(text,text,text,text,numeric);
|
||||
|
||||
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
|
||||
_bill TEXT,
|
||||
@ -79,7 +79,6 @@ RETURNS TABLE (
|
||||
last_order TEXT,
|
||||
last_quote TEXT,
|
||||
last_source TEXT,
|
||||
hist JSONB,
|
||||
tprice NUMERIC,
|
||||
tmath JSONB,
|
||||
volume_range TEXT,
|
||||
@ -89,8 +88,6 @@ RETURNS TABLE (
|
||||
list_relevance TEXT,
|
||||
guidance_price NUMERIC,
|
||||
guidance_reason TEXT,
|
||||
approval_price NUMERIC,
|
||||
approval_reason TEXT,
|
||||
expl JSONB,
|
||||
ui_json JSONB
|
||||
) AS $$
|
||||
@ -130,10 +127,10 @@ DECLARE
|
||||
_last_isdiff TEXT;
|
||||
_last_part TEXT;
|
||||
------------step 3 lookup target---------------
|
||||
_tprice NUMERIC(20,5);
|
||||
_tprice NUMERIC;
|
||||
_tmath JSONB;
|
||||
_volume_range TEXT;
|
||||
_tprice_last NUMERIC(20,5);
|
||||
_tprice_last NUMERIC;
|
||||
------------step 4 normalize last price--------
|
||||
_curstd NUMERIC;
|
||||
_futstd NUMERIC;
|
||||
@ -150,8 +147,6 @@ DECLARE
|
||||
------------step 6 compute guidance------------
|
||||
_guidance_price NUMERIC;
|
||||
_guidance_reason TEXT;
|
||||
_approval_price NUMERIC;
|
||||
_approval_reason TEXT;
|
||||
------------step 7 build json------------------
|
||||
_expl JSONB := '{}'::jsonb;
|
||||
_ui_json JSONB := '{}'::jsonb;
|
||||
@ -269,7 +264,7 @@ BEGIN
|
||||
,_tmath
|
||||
,_volume_range
|
||||
FROM
|
||||
pricequote.target_prices_base tp
|
||||
pricequote.target_prices tp
|
||||
WHERE
|
||||
tp.stlc = _stlc
|
||||
AND tp.ds = _v1ds
|
||||
@ -287,36 +282,38 @@ BEGIN
|
||||
INTO
|
||||
_tprice_last
|
||||
FROM
|
||||
pricequote.target_prices_base tp
|
||||
pricequote.target_prices tp
|
||||
WHERE
|
||||
tp.stlc = _stlc
|
||||
AND tp.ds = _last_dataseg
|
||||
AND tp.chan = _chan
|
||||
AND tp.tier = _tier
|
||||
AND FLOOR(_last_qty / NULLIF(_pltq, 0))::int <@ tp.vol;
|
||||
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;
|
||||
|
||||
SELECT
|
||||
ROUND(CASE WHEN COALESCE(_customized,'') = '' THEN _curstd_orig ELSE COALESCE(v1.curstdus, v0.curstdus) END,5) AS curstd,
|
||||
ROUND(CASE WHEN COALESCE(_customized,'') = '' THEN _futstd_orig ELSE COALESCE(v1.futstdus, v0.futstdus) END,5) AS futstd,
|
||||
ROUND(CASE WHEN COALESCE(_last_isdiff,'') = '' THEN _curstd_orig ELSE COALESCE(v1l.curstdus, v0l.curstdus) END,5) AS curstd_last,
|
||||
ROUND(CASE WHEN COALESCE(_last_isdiff,'') = '' THEN _futstd_orig ELSE COALESCE(v1l.futstdus, v0l.futstdus) END,5) AS futstd_last
|
||||
INTO
|
||||
_curstd, _futstd, _curstd_last, _futstd_last
|
||||
FROM (VALUES (1)) AS x(dummy)
|
||||
LEFT JOIN rlarp.cost_v1ds v1
|
||||
ON v1.stlc = _stlc AND v1.v1ds = _v1ds
|
||||
LEFT JOIN rlarp.cost_v0ds v0
|
||||
ON v0.stlc = _stlc AND v0.v0ds = _v0ds
|
||||
LEFT JOIN rlarp.cost_v1ds v1l
|
||||
ON v1l.stlc = _stlc AND v1l.v1ds = _last_dataseg
|
||||
LEFT JOIN rlarp.cost_v0ds v0l
|
||||
ON v0l.stlc = _stlc AND v0l.v0ds = _last_v0ds
|
||||
LIMIT 1;
|
||||
|
||||
-- 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
|
||||
@ -327,7 +324,7 @@ BEGIN
|
||||
_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 := ROUND(_curstd / _curstd_last, 5);
|
||||
_last_premium := _curstd / _curstd_last;
|
||||
_last_price_norm := ROUND(_last_price * (_curstd / _curstd_last), 5);
|
||||
_last_premium_method := 'Cost Ratio';
|
||||
ELSE
|
||||
@ -376,16 +373,10 @@ BEGIN
|
||||
SELECT
|
||||
gl.guidance_price
|
||||
,gl.guidance_reason
|
||||
,al.approval_price
|
||||
,al.approval_reason
|
||||
INTO
|
||||
_guidance_price
|
||||
,_guidance_reason
|
||||
,_approval_price
|
||||
,_approval_reason
|
||||
FROM
|
||||
pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date, 1.0, 1.0, 1.0) gl
|
||||
CROSS JOIN pricequote.approval_logic(_tprice, _last_price_norm, _listprice_eff, _last_date, 1.0, 1.0, 1.0) al;
|
||||
FROM pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date) gl;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 8: Build explanation JSON
|
||||
@ -433,8 +424,7 @@ BEGIN
|
||||
'targets',
|
||||
jsonb_build_object(
|
||||
'target_price', _tprice,
|
||||
'target_math', _tmath,
|
||||
'volume_range', _volume_range
|
||||
'target_math', _tmath
|
||||
),
|
||||
'list',
|
||||
jsonb_build_object(
|
||||
@ -444,9 +434,7 @@ BEGIN
|
||||
'list_relevance', _list_relevance
|
||||
),
|
||||
'guidance_price', _guidance_price,
|
||||
'guidance_reason', _guidance_reason,
|
||||
'approval_price', _approval_price,
|
||||
'approval_reason', _approval_reason
|
||||
'guidance_reason', _guidance_reason
|
||||
);
|
||||
|
||||
------------------------------------------------------------------
|
||||
@ -454,126 +442,42 @@ BEGIN
|
||||
------------------------------------------------------------------
|
||||
_ui_json := jsonb_build_object(
|
||||
'details', jsonb_build_array(
|
||||
------------------------------------------
|
||||
-- history
|
||||
------------------------------------------
|
||||
jsonb_build_object(
|
||||
'label', 'History',
|
||||
10, 'detailLevel',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', CASE WHEN _last_price IS NOT NULL THEN 'Last Sale: ' || _last_date ELSE 'No Recent' END,
|
||||
'detailLevel', 10,
|
||||
'value', COALESCE(_last_price,0),
|
||||
'type', 'currency',
|
||||
'note', CASE WHEN _last_price IS NOT NULL THEN
|
||||
CASE _last_source
|
||||
WHEN 'mrq' THEN 'Recent similar ' || _last_part || ' ' || 'qty: ' || _last_qty
|
||||
WHEN 'mrs' THEN 'Recent similar ' || _last_part || ' ' || 'qty: ' || _last_qty
|
||||
WHEN 'dsq' THEN 'Last quote ' || 'qty: ' || _last_qty
|
||||
WHEN 'dss' THEN 'Last sale ' || 'qty: ' || _last_qty
|
||||
ELSE ''
|
||||
END ||
|
||||
'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
|
||||
)
|
||||
)
|
||||
||CASE WHEN COALESCE(_last_premium,1) <> 1 THEN
|
||||
COALESCE(jsonb_build_array(jsonb_build_object(
|
||||
'label','Price Difference',
|
||||
'detailLevel',10,
|
||||
'value', _last_premium,
|
||||
'type','percent',
|
||||
'note', _last_premium_method
|
||||
)),'[]'::jsonb)
|
||||
ELSE
|
||||
'[]'::jsonb
|
||||
END
|
||||
||CASE WHEN COALESCE(_last_premium,1) <> 1 THEN
|
||||
COALESCE(jsonb_build_array(jsonb_build_object(
|
||||
'label','Adjusted Price',
|
||||
'detailLevel',10,
|
||||
'value', _last_price_norm,
|
||||
'type','currency',
|
||||
'note','normalized to ' || _v1ds
|
||||
)),'[]'::jsonb)
|
||||
ELSE
|
||||
'[]'::jsonb
|
||||
END
|
||||
),
|
||||
------------------------------------------
|
||||
-- price list
|
||||
------------------------------------------
|
||||
jsonb_build_object(
|
||||
'label', 'List',
|
||||
'detailLevel',10,
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'List:' || COALESCE(_list_code, ''),
|
||||
'detailLevel',10,
|
||||
'value', _list_price,
|
||||
'type', 'currency',
|
||||
'note', _list_relevance
|
||||
)
|
||||
)
|
||||
),
|
||||
------------------------------------------
|
||||
-- history
|
||||
------------------------------------------
|
||||
jsonb_build_object(
|
||||
'label', 'Target Calculation',
|
||||
'detailLevel',10,
|
||||
'details',
|
||||
-- jsonb_build_array(
|
||||
(
|
||||
SELECT
|
||||
jsonb_agg(
|
||||
jsonb_build_object(
|
||||
----------------------label------------------------------------------------
|
||||
'label',CASE WHEN value <> '' THEN RTRIM(SUBSTRING(value,1,18)) ELSE 'No Target' END,
|
||||
----------------------detailLevel------------------------------------------
|
||||
'detailLevel',10,
|
||||
----------------------value------------------------------------------------
|
||||
'value',CASE WHEN value <> '' THEN
|
||||
SUBSTRING(value,23,7)::NUMERIC(20,5) +
|
||||
CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END
|
||||
ELSE
|
||||
0
|
||||
END,
|
||||
----------------------type-------------------------------------------------
|
||||
'type', CASE WHEN value <> '' THEN
|
||||
CASE SUBSTRING(value,19,1)
|
||||
WHEN '+' THEN 'currency'
|
||||
ELSE 'Percent'
|
||||
END
|
||||
ELSE '' END,
|
||||
----------------------note-------------------------------------------------
|
||||
'note',CASE WHEN value <> '' THEN
|
||||
CASE SUBSTRING(value,19,1)
|
||||
WHEN '+' THEN 'Price'
|
||||
ELSE 'Premium'
|
||||
END
|
||||
ELSE '' END
|
||||
)
|
||||
)
|
||||
FROM jsonb_array_elements_text(COALESCE(_tmath,'[""]'::jsonb)) ae
|
||||
)
|
||||
||CASE WHEN _tprice IS NULL THEN '[]'::jsonb ELSE jsonb_build_object('label','Price','value',COALESCE(_tprice,0),'type','currency','note','Total') END
|
||||
-- )
|
||||
'label', 'Target Support',
|
||||
'details', _tmath
|
||||
),
|
||||
------------------------------------------
|
||||
-- history
|
||||
------------------------------------------
|
||||
jsonb_build_object(
|
||||
'label', 'Guidance',
|
||||
'detailLevel',10,
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'Price',
|
||||
'detailLevel',10,
|
||||
'value', COALESCE(_guidance_price,0),
|
||||
'value', _guidance_price,
|
||||
'type', 'currency',
|
||||
'note', COALESCE(_guidance_reason,'')
|
||||
'note', _guidance_reason
|
||||
)
|
||||
)
|
||||
)
|
||||
@ -590,11 +494,10 @@ BEGIN
|
||||
_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, _hist,
|
||||
_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,
|
||||
_approval_price, _approval_reason,
|
||||
_expl, _ui_json;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
@ -1,7 +1,7 @@
|
||||
-- set work_mem TO '4GB';
|
||||
--
|
||||
DROP VIEW IF EXISTS rlarp.quote_review;
|
||||
CREATE OR REPLACE VIEW rlarp.quote_review AS
|
||||
CREATE VIEW rlarp.quote_review AS
|
||||
WITH
|
||||
---------------------get quote lines from SQL Server---------------------
|
||||
lq AS MATERIALIZED (
|
||||
@ -105,10 +105,7 @@ lq AS MATERIALIZED (
|
||||
-- ,jsonb_pretty(pricing) pricing
|
||||
,p.guidance_price
|
||||
,p.guidance_reason
|
||||
,p.approval_price
|
||||
,p.approval_reason
|
||||
,p.tprice guidance_target
|
||||
,jsonb_pretty(p.ui_json->'data') expl
|
||||
,jsonb_pretty(p.expl) expl
|
||||
FROM
|
||||
lq
|
||||
LEFT OUTER JOIN "CMS.CUSLG".itemm i ON
|
||||
@ -134,6 +131,7 @@ lq AS MATERIALIZED (
|
||||
lq.billto
|
||||
,lq.shipto
|
||||
,lq.part
|
||||
,substring(lq.part,1,8)
|
||||
,lq.v1ds
|
||||
,lq.units_each
|
||||
) p ON TRUE
|
||||
@ -178,4 +176,4 @@ lq AS MATERIALIZED (
|
||||
WHERE
|
||||
COALESCE(g.bestprice,1) = 1
|
||||
)
|
||||
SELECT * FROM hist --LIMIT 1000--WHERE qid = 108655
|
||||
SELECT * FROM hist --WHERE qid = 108655
|
||||
|
@ -1,16 +0,0 @@
|
||||
|
||||
DROP TABLE IF EXISTS pricequote.core_target;
|
||||
|
||||
CREATE TABLE pricequote.core_target (
|
||||
compset TEXT NOT NULL,
|
||||
stlc TEXT NOT NULL,
|
||||
floor NUMERIC NOT NULL,
|
||||
options JSONB NOT NULL,
|
||||
PRIMARY KEY (stlc)
|
||||
);
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON pricequote.target_prices TO PUBLIC;
|
||||
|
||||
DROP TABLE IF EXISTS import.core_target;
|
||||
|
||||
CREATE TABLE import.core_target AS (SELECT * FROM pricequote.core_target);
|
@ -51,50 +51,42 @@ WITH base AS (
|
||||
ranked AS (
|
||||
SELECT
|
||||
b.*
|
||||
-- Most recent sale (Actuals only)
|
||||
,CASE WHEN b.version = 'Actual' THEN
|
||||
ROW_NUMBER() OVER (
|
||||
-- Most recent sale
|
||||
,ROW_NUMBER() OVER (
|
||||
PARTITION BY b.customer, b.partgroup
|
||||
ORDER BY b.odate DESC
|
||||
)
|
||||
END AS rn_mrs
|
||||
-- Most recent quote (Quotes only)
|
||||
,CASE WHEN b.version = 'Quotes' THEN
|
||||
ROW_NUMBER() OVER (
|
||||
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
|
||||
) AS rn_mrs
|
||||
-- Most recent quote
|
||||
,ROW_NUMBER() OVER (
|
||||
PARTITION BY b.customer, b.partgroup
|
||||
ORDER BY b.odate DESC
|
||||
)
|
||||
END AS rn_mrq
|
||||
-- Largest volume sale (Actuals only; last 12 months prioritized)
|
||||
,CASE WHEN b.version = 'Actual' THEN
|
||||
ROW_NUMBER() OVER (
|
||||
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
|
||||
) AS rn_mrq
|
||||
-- Largest volume sale (last 12 months)
|
||||
,ROW_NUMBER() OVER (
|
||||
PARTITION BY b.customer, b.partgroup
|
||||
ORDER BY
|
||||
CASE WHEN b.version = 'Actual' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC,
|
||||
b.qty DESC
|
||||
)
|
||||
END AS rn_lvs
|
||||
-- Largest volume quote (Quotes only; last 12 months prioritized)
|
||||
,CASE WHEN b.version = 'Quotes' THEN
|
||||
ROW_NUMBER() OVER (
|
||||
ORDER BY CASE
|
||||
WHEN b.version = 'Actual' AND b.odate >= DATEADD(YEAR, -1, GETDATE())
|
||||
THEN b.qty ELSE NULL
|
||||
END DESC
|
||||
) AS rn_lvs
|
||||
-- Largest volume quote (last 12 months)
|
||||
,ROW_NUMBER() OVER (
|
||||
PARTITION BY b.customer, b.partgroup
|
||||
ORDER BY
|
||||
CASE WHEN b.version = 'Quotes' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC,
|
||||
b.qty DESC
|
||||
)
|
||||
END AS rn_lvq
|
||||
,CASE WHEN b.version = 'Actual' THEN
|
||||
ROW_NUMBER() OVER (
|
||||
ORDER BY CASE
|
||||
WHEN b.version = 'Quotes' AND b.odate >= DATEADD(YEAR, -1, GETDATE())
|
||||
THEN b.qty ELSE NULL
|
||||
END DESC
|
||||
) AS rn_lvq
|
||||
-- Most recent sale per data segment
|
||||
,ROW_NUMBER() OVER (
|
||||
PARTITION BY b.customer, b.partgroup, b.dataseg, b.version
|
||||
ORDER BY b.odate DESC
|
||||
)
|
||||
END AS rn_dss
|
||||
,CASE WHEN b.version = 'Quotes' THEN
|
||||
ROW_NUMBER() OVER (
|
||||
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
|
||||
) AS rn_dss
|
||||
-- Most recent quote per data segment
|
||||
,ROW_NUMBER() OVER (
|
||||
PARTITION BY b.customer, b.partgroup, b.dataseg, b.version
|
||||
ORDER BY b.odate DESC
|
||||
)
|
||||
END AS rn_dsq
|
||||
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
|
||||
) AS rn_dsq
|
||||
FROM base b
|
||||
)
|
||||
--------------------------------------------------------------------------------
|
||||
@ -129,7 +121,7 @@ ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordn
|
||||
-- Step 3.1: Explode all flags from the #flagged table
|
||||
WITH exploded_flags AS (
|
||||
SELECT
|
||||
customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten,
|
||||
customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten,
|
||||
flag
|
||||
FROM #flagged
|
||||
CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag)
|
||||
|
@ -1,13 +1,10 @@
|
||||
-- REFRESH MATERIALIZED VIEW pricequote.lastpricedetail;
|
||||
|
||||
DROP MATERIALIZED VIEW pricequote.lastpricedetail;
|
||||
REFRESH MATERIALIZED VIEW pricequote.lastpricedetail;
|
||||
|
||||
CREATE MATERIALIZED VIEW pricequote.lastpricedetail AS
|
||||
WITH base AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
part,
|
||||
dataseg,
|
||||
version,
|
||||
qtyord AS qty,
|
||||
@ -26,41 +23,32 @@ WITH base AS (
|
||||
AND version IN ('Actual', 'Quotes')
|
||||
),
|
||||
ranked AS (
|
||||
SELECT b.*,
|
||||
-- Most recent sale (Actuals first, newest date first)
|
||||
CASE WHEN version = 'Actual' THEN ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY (version = 'Actual') DESC,
|
||||
odate DESC NULLS LAST
|
||||
) END AS rn_mrs,
|
||||
-- Most recent quote (Quotes first, newest date first)
|
||||
CASE WHEN version = 'Quotes' THEN ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY (version = 'Quotes') DESC,
|
||||
odate DESC NULLS LAST
|
||||
) END AS rn_mrq,
|
||||
-- Largest volume sale in last year (those inside window first)
|
||||
CASE WHEN version = 'Actual' THEN ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY (version = 'Actual' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC,
|
||||
qty DESC NULLS LAST
|
||||
) END AS rn_lvs,
|
||||
-- Largest volume quote in last year (those inside window first)
|
||||
CASE WHEN version = 'Quotes' THEN ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY (version = 'Quotes' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC,
|
||||
qty DESC NULLS LAST
|
||||
) END AS rn_lvq,
|
||||
-- Per dataseg/version: most recent (version fixed in partition, so just date)
|
||||
CASE WHEN version = 'Actual' THEN ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup, dataseg, version
|
||||
ORDER BY odate DESC NULLS LAST
|
||||
) END AS rn_dss,
|
||||
CASE WHEN version = 'Quotes' THEN ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup, dataseg, version
|
||||
ORDER BY odate DESC NULLS LAST
|
||||
) END AS rn_dsq
|
||||
FROM base b
|
||||
SELECT *,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC
|
||||
) AS rn_mrs,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC
|
||||
) AS rn_mrq,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Actual' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC
|
||||
) AS rn_lvs,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Quotes' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC
|
||||
) AS rn_lvq,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup, dataseg, version
|
||||
ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC
|
||||
) AS rn_dss,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup, dataseg, version
|
||||
ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC
|
||||
) AS rn_dsq
|
||||
FROM base
|
||||
),
|
||||
flagged AS (
|
||||
SELECT *,
|
||||
@ -68,16 +56,15 @@ flagged AS (
|
||||
CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2,
|
||||
CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3,
|
||||
CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4,
|
||||
CASE WHEN rn_dss = 1 AND VERSION = 'Actual' THEN 'dss' END AS f5,
|
||||
CASE WHEN rn_dsq = 1 AND VERSION = 'Quotes' THEN 'dsq' END AS f6
|
||||
CASE WHEN rn_dss = 1 THEN 'dss' END AS f5,
|
||||
CASE WHEN rn_dsq = 1 THEN 'dsq' END AS f6
|
||||
FROM ranked
|
||||
WHERE
|
||||
rn_mrs = 1 OR rn_mrq = 1 OR rn_lvs = 1 OR rn_lvq = 1 OR rn_dss = 1 OR rn_dsq = 1
|
||||
)
|
||||
--SELECT * FROM flagged WHERE customer = 'HYBELS' AND partgroup = 'HZP3E100'
|
||||
,exploded_flags AS (
|
||||
),
|
||||
exploded_flags AS (
|
||||
SELECT
|
||||
customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten,
|
||||
customer, partgroup, dataseg, version, qty, price, odate, ordnum, quoten,
|
||||
unnest(ARRAY[f1, f2, f3, f4, f5, f6]) AS flag
|
||||
FROM flagged
|
||||
),
|
||||
@ -90,7 +77,6 @@ serialized_flags AS (
|
||||
jsonb_build_object(
|
||||
'version', version,
|
||||
'datasegment', dataseg,
|
||||
'part', part,
|
||||
'qty', qty,
|
||||
'price', price,
|
||||
'odate', odate,
|
||||
@ -139,4 +125,4 @@ WITH DATA;
|
||||
|
||||
--SELECT * FROM pricequote.lastpricedetail;
|
||||
|
||||
CREATE INDEX lastpricedetail_idx ON pricequote.lastpricedetail(customer, partgroup);
|
||||
CREATE INDEX lastpricedetail_idx ON pricequote.lastpricedetail(customer, partgroup);
|
@ -1,28 +0,0 @@
|
||||
CREATE OR REPLACE PROCEDURE pricequote.refresh_target_prices_base()
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
DELETE FROM pricequote.target_prices_base;
|
||||
|
||||
WITH expand AS (
|
||||
SELECT
|
||||
c.compset,
|
||||
c.stlc,
|
||||
c.floor,
|
||||
b.ds,
|
||||
b.chan,
|
||||
b.tier,
|
||||
b.vol,
|
||||
b.val,
|
||||
b.price,
|
||||
b.math AS math
|
||||
FROM pricequote.core_target c
|
||||
LEFT JOIN LATERAL pricequote.build_pricing_path_base(
|
||||
c.options || jsonb_build_object('entity','Anchor','attr',c.stlc,'val',c.floor,'func','Price')
|
||||
) AS b
|
||||
ON b.lastflag
|
||||
)
|
||||
INSERT INTO pricequote.target_prices_base
|
||||
SELECT * FROM expand;
|
||||
END;
|
||||
$$;
|
@ -1,17 +0,0 @@
|
||||
DROP TABLE pricequote.target_prices_base CASCADE;
|
||||
|
||||
CREATE TABLE pricequote.target_prices_base (
|
||||
compset TEXT NOT NULL,
|
||||
stlc TEXT NOT NULL,
|
||||
floor NUMERIC NOT NULL,
|
||||
ds TEXT NOT NULL,
|
||||
chan TEXT NOT NULL,
|
||||
tier TEXT NOT NULL,
|
||||
vol INT4RANGE NOT NULL,
|
||||
val NUMERIC NOT NULL,
|
||||
price NUMERIC,
|
||||
math TEXT[],
|
||||
PRIMARY KEY (stlc, ds, chan, tier, vol)
|
||||
);
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON pricequote.target_prices_base TO PUBLIC;
|
@ -8,4 +8,4 @@ SELECT
|
||||
,price
|
||||
,to_jsonb(math)::text AS math
|
||||
FROM
|
||||
pricequote.target_prices_base;
|
||||
pricequote.target_prices;
|
132
ui_schema.json
132
ui_schema.json
@ -1,77 +1,75 @@
|
||||
{
|
||||
"details": [
|
||||
{
|
||||
"label": "History",
|
||||
"detailLevel": 10,
|
||||
"details": [
|
||||
"details": [
|
||||
{
|
||||
"label": "Last Quote",
|
||||
"detailLevel": 10,
|
||||
"value": 0.1012,
|
||||
"type": "currency",
|
||||
"note": "XNS0T1G3G18B096 | Ord# 1008338 | 2025-06-12 | Qty 19,200"
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"label": "List",
|
||||
"detailLevel": 10,
|
||||
"details": [
|
||||
{
|
||||
"label": "Code: GUAU",
|
||||
"detailLevel": 10,
|
||||
"value": 0.11,
|
||||
"type": "currency",
|
||||
"note": "List Min Qty: 9,600"
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"label": "Target Calculation",
|
||||
"detailLevel": 10,
|
||||
"details": [
|
||||
{
|
||||
"label": "XNS0T1G3",
|
||||
"detailLevel": 10,
|
||||
"value": 0.08,
|
||||
"type": "currency",
|
||||
"note": "Base Floor"
|
||||
"label": "Model Inputs",
|
||||
"details": [
|
||||
{
|
||||
"label": "Base Cost",
|
||||
"value": 1.22446,
|
||||
"type": "currency"
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"label": "Channel:WHS",
|
||||
"detailLevel": 10,
|
||||
"value": 0.2,
|
||||
"type": "Percent",
|
||||
"note": "Premium"
|
||||
"label": "Peer Target",
|
||||
"details": [
|
||||
{
|
||||
"label": "Peer Median Margin",
|
||||
"value": 36.873,
|
||||
"type": "percent",
|
||||
"note": "DIR|102 - HANGING POTS|110 - INJECTION|Tier 2"
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"label": "Volume:1-8",
|
||||
"detailLevel": 10,
|
||||
"value": 0.1,
|
||||
"type": "Percent",
|
||||
"note": "Premium"
|
||||
"label": "Target Support",
|
||||
"details": [
|
||||
{
|
||||
"label": "Tier 1 Truckload",
|
||||
"value": 80,
|
||||
"type": "currency",
|
||||
"note": "reviewed floor price"
|
||||
},
|
||||
{
|
||||
"label": "Warehouse",
|
||||
"value": 1.2,
|
||||
"type": "percent"
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"label": "Target",
|
||||
"detailLevel": 10,
|
||||
"value": 0.1056,
|
||||
"type": "currency",
|
||||
"note": "Total"
|
||||
"label": "Factor Adjustment",
|
||||
"details": [
|
||||
{
|
||||
"label": "Package UOM",
|
||||
"value": -0.01,
|
||||
"type": "percent"
|
||||
},
|
||||
{
|
||||
"label": "# of Pallets",
|
||||
"value": 0.02,
|
||||
"type": "percent",
|
||||
"note": "0.03"
|
||||
},
|
||||
{
|
||||
"label": "Urgency",
|
||||
"value": 0.03,
|
||||
"type": "percent",
|
||||
"note": "Top Priority"
|
||||
},
|
||||
{
|
||||
"label": "State Adder/Subtractor",
|
||||
"value": -0.02,
|
||||
"type": "percent",
|
||||
"note": "OH"
|
||||
},
|
||||
{
|
||||
"label": "Branding",
|
||||
"value": 0,
|
||||
"type": "currency"
|
||||
}
|
||||
]
|
||||
}
|
||||
]
|
||||
},
|
||||
{
|
||||
"label": "Guidance",
|
||||
"detailLevel": 10,
|
||||
"details": [
|
||||
{
|
||||
"label": "Price",
|
||||
"detailLevel": 10,
|
||||
"value": 0.1012,
|
||||
"type": "currency",
|
||||
"note": "Using target price, capped to not exceed last price"
|
||||
}
|
||||
]
|
||||
}
|
||||
]
|
||||
]
|
||||
}
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user