Compare commits
No commits in common. "master" and "new_targets" have entirely different histories.
master
...
new_target
@ -1,5 +1,5 @@
|
||||
SELECT
|
||||
ui_json->'data'
|
||||
ui_json->'details'
|
||||
FROM pricequote.single_price_call(
|
||||
'FARM0001',
|
||||
'KEYB0001',
|
||||
@ -7,44 +7,39 @@
|
||||
'v1:T..CSE..D',
|
||||
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
|
||||
-- ui_json->'details'
|
||||
-- FROM pricequote.single_price_call(
|
||||
-- 'FARM0001',
|
||||
-- 'KEYB0001',
|
||||
-- 'HZP3E103E21D050',
|
||||
-- 'v1:C..BDL..',
|
||||
-- 50000
|
||||
-- ) f;
|
||||
--
|
||||
-- SELECT
|
||||
-- ui_json
|
||||
-- FROM pricequote.single_price_call(
|
||||
-- 'BFGS0001',
|
||||
-- 'BOBS0002',
|
||||
-- 'HTI10754B12B024LXB04',
|
||||
-- 'v1:L.L.PLT..',
|
||||
-- 172000
|
||||
-- ) f;
|
||||
--
|
||||
-- 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
|
||||
pc.expl, pc.hist
|
||||
FROM
|
||||
pricequote.live_quotes q
|
||||
pricequote.live_quotes
|
||||
LEFT JOIN LATERAL pricequote.single_price_call(
|
||||
billto, shipto, part, v1ds, units_each
|
||||
) pc ON TRUE
|
||||
WHERE
|
||||
qid = 113761
|
||||
-- AND qrn = 4;
|
||||
qid = 113800
|
||||
AND qrn = 4;
|
||||
|
||||
create table pricequote.target_prices_base as (
|
||||
with
|
||||
|
@ -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,83 @@
|
||||
-- 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,
|
||||
@floor_pct numeric(10,5) = 0.05, -- e.g., 5%
|
||||
@cap_last_pct numeric(10,5) = 1.00, -- e.g., 100%
|
||||
@cap_list_pct numeric(10,5) = 1.00
|
||||
)
|
||||
RETURNS @ret TABLE (
|
||||
guidance_price numeric(20,5),
|
||||
guidance_reason nvarchar(4000)
|
||||
)
|
||||
RETURNS TABLE
|
||||
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);
|
||||
-- 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';
|
||||
END
|
||||
|
||||
|
||||
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||
IF @base_price > @list_eff
|
||||
BEGIN
|
||||
SET @base_price = @list_eff;
|
||||
SET @reason = N'List price ceiling';
|
||||
END
|
||||
|
||||
SET @final_price = @base_price;
|
||||
|
||||
INSERT INTO @ret VALUES (@final_price, @reason);
|
||||
RETURN;
|
||||
END;
|
||||
RETURN
|
||||
WITH params AS (
|
||||
SELECT
|
||||
@target AS base_price,
|
||||
@last_norm AS last_norm,
|
||||
@list_eff AS list_eff,
|
||||
@floor_pct AS floor_pct,
|
||||
@cap_last_pct AS cap_last_pct,
|
||||
-- HARD CEILING at list: clamp to <= 1.00 regardless of input
|
||||
CASE WHEN @cap_list_pct IS NULL OR @cap_list_pct > 1 THEN 1.00 ELSE @cap_list_pct END AS eff_list_cap
|
||||
),
|
||||
step_floor AS (
|
||||
SELECT
|
||||
base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap,
|
||||
CAST(
|
||||
CASE
|
||||
WHEN base_price IS NULL OR last_norm IS NULL OR floor_pct <= 0
|
||||
THEN base_price
|
||||
ELSE ROUND(IIF(base_price >= last_norm*(1-floor_pct), base_price, last_norm*(1-floor_pct)), 5)
|
||||
END
|
||||
AS numeric(20,5)) AS after_floor
|
||||
FROM params
|
||||
),
|
||||
step_cap_last AS (
|
||||
SELECT
|
||||
base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, after_floor,
|
||||
CAST(
|
||||
CASE
|
||||
WHEN after_floor IS NULL OR last_norm IS NULL
|
||||
THEN after_floor
|
||||
ELSE ROUND(IIF(after_floor <= last_norm*cap_last_pct, after_floor, last_norm*cap_last_pct), 5)
|
||||
END
|
||||
AS numeric(20,5)) AS after_cap_last
|
||||
FROM step_floor
|
||||
),
|
||||
step_cap_list AS (
|
||||
SELECT
|
||||
base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, after_floor, after_cap_last,
|
||||
CAST(
|
||||
CASE
|
||||
WHEN after_cap_last IS NULL OR list_eff IS NULL
|
||||
THEN after_cap_last
|
||||
ELSE ROUND(IIF(after_cap_last <= list_eff*eff_list_cap, after_cap_last, list_eff*eff_list_cap), 5)
|
||||
END
|
||||
AS numeric(20,5)) AS final_price
|
||||
FROM step_cap_last
|
||||
)
|
||||
SELECT
|
||||
final_price AS guidance_price,
|
||||
CASE
|
||||
WHEN @target IS NULL THEN 'No target price available'
|
||||
WHEN @last_norm IS NULL AND @list_eff IS NULL THEN 'No prior sale or list; using target price'
|
||||
ELSE
|
||||
CONCAT(
|
||||
'Using target price',
|
||||
-- show floor only if it raised price
|
||||
CASE WHEN last_norm IS NOT NULL AND @floor_pct > 0 AND after_floor > base_price
|
||||
THEN CONCAT(', floored to ', FORMAT(@floor_pct*100,'0.##'), '% below last price') ELSE '' END,
|
||||
-- show last cap only if it lowered price
|
||||
CASE WHEN last_norm IS NOT NULL AND after_cap_last < after_floor
|
||||
THEN CASE WHEN @cap_last_pct = 1
|
||||
THEN ', capped to not exceed last price'
|
||||
ELSE CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price')
|
||||
END
|
||||
ELSE '' END,
|
||||
-- show list cap only if it lowered price (always “not exceed” because eff_list_cap<=1)
|
||||
CASE WHEN list_eff IS NOT NULL AND final_price < after_cap_last
|
||||
THEN ', capped to not exceed list price'
|
||||
ELSE '' END
|
||||
)
|
||||
END AS guidance_reason
|
||||
FROM step_cap_list;
|
@ -3,14 +3,11 @@ CREATE OR REPLACE FUNCTION pricequote.guidance_logic(
|
||||
_last_norm numeric(20,5),
|
||||
_list_eff numeric(20,5),
|
||||
_last_date date,
|
||||
_floor_pct numeric(10,5) DEFAULT 0.95,
|
||||
_floor_pct numeric(10,5) DEFAULT 0.05,
|
||||
_cap_last_pct numeric(10,5) DEFAULT 1.00,
|
||||
_cap_list_pct numeric(10,5) DEFAULT 1.00
|
||||
)
|
||||
RETURNS TABLE (
|
||||
guidance_price numeric(20,5),
|
||||
guidance_reason text
|
||||
)
|
||||
RETURNS TABLE (guidance_price numeric(20,5), guidance_reason text)
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
base_price numeric(20,5);
|
||||
@ -18,39 +15,55 @@ DECLARE
|
||||
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';
|
||||
IF _target IS NULL THEN
|
||||
RETURN QUERY SELECT NULL::numeric, 'No target price available';
|
||||
RETURN;
|
||||
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;
|
||||
base_price := _target;
|
||||
|
||||
-- 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';
|
||||
-- floor (binds if it raises price)
|
||||
after_floor := base_price;
|
||||
IF _last_norm IS NOT NULL AND _floor_pct > 0 THEN
|
||||
after_floor := GREATEST(base_price, ROUND(_last_norm*(1-_floor_pct),5));
|
||||
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';
|
||||
-- cap to last (binds if it lowers 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;
|
||||
|
||||
final_price := base_price;
|
||||
-- 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;
|
||||
|
||||
-- build reason
|
||||
IF _last_norm IS NULL AND _list_eff IS NULL THEN
|
||||
reason := 'No prior sale or list; using target price';
|
||||
ELSE
|
||||
reason := 'Using target price';
|
||||
IF _last_norm IS NOT NULL AND _floor_pct > 0 AND after_floor > base_price THEN
|
||||
reason := reason || format(', floored to %s%% below last price', to_char((_floor_pct*100)::numeric,'FM999990.##'));
|
||||
END IF;
|
||||
IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN
|
||||
IF _cap_last_pct = 1 THEN
|
||||
reason := reason || ', capped to not exceed last price';
|
||||
ELSE
|
||||
reason := reason || format(', capped to %s%% of last price', to_char((_cap_last_pct*100)::numeric,'FM999990.##'));
|
||||
END IF;
|
||||
END IF;
|
||||
IF _list_eff IS NOT NULL AND final_price < after_cap_last THEN
|
||||
IF _cap_list_pct = 1 THEN
|
||||
reason := reason || ', capped to not exceed list price';
|
||||
ELSE
|
||||
reason := reason || format(', capped to %s%% of list price', to_char((_cap_list_pct*100)::numeric,'FM999990.##'));
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN QUERY SELECT final_price, reason;
|
||||
END $$;
|
||||
END $$;
|
@ -46,8 +46,6 @@ CREATE TABLE pricequote.queue (
|
||||
list_relevance TEXT,
|
||||
guidance_price NUMERIC,
|
||||
guidance_reason TEXT,
|
||||
approval_price NUMERIC,
|
||||
approval_reason TEXT,
|
||||
expl JSONB,
|
||||
ui_json JSONB
|
||||
);
|
||||
@ -87,7 +85,7 @@ BEGIN
|
||||
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
||||
AND o.part IS NOT NULL
|
||||
AND SUBSTRING(o.glec, 1, 1) <= '2';
|
||||
-- 2:12 0:38
|
||||
-- 2:12
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 2) Enrich: chan, tier, cust, pltq, plevel, partgroup (+stlc fix)
|
||||
@ -129,7 +127,7 @@ BEGIN
|
||||
plevel = s.plevel,
|
||||
partgroup = s.partgroup,
|
||||
stlc = COALESCE(q.stlc, s.stlc_fix);
|
||||
-- 4:51 0:17
|
||||
-- 4:51
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 3) Scenario fields from item master: part_v1ds, v0ds, orig costs
|
||||
@ -149,7 +147,7 @@ BEGIN
|
||||
END
|
||||
FROM "CMS.CUSLG".itemm i0
|
||||
WHERE i0.item = q.part;
|
||||
-- 3:21 0:20
|
||||
-- 3:21
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 4) History: store hist, extract last_* with precedence helper
|
||||
@ -187,7 +185,7 @@ BEGIN
|
||||
AND lp2.partgroup = q2.partgroup
|
||||
) AS x
|
||||
WHERE q.ctid = x.ctid;
|
||||
-- 7:32 1:31
|
||||
-- 7:32
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 5) Target (requested v1ds): tprice, tmath, volume_range
|
||||
@ -204,7 +202,7 @@ BEGIN
|
||||
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
|
||||
-- 2:51
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 6) Target for last_dataseg (tprice_last)
|
||||
@ -220,7 +218,7 @@ BEGIN
|
||||
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
|
||||
-- 1:26
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 7) Cost data for requested v1ds and last_dataseg
|
||||
@ -253,7 +251,7 @@ BEGIN
|
||||
ON v0l.stlc = q2.stlc AND v0l.v0ds = q2.last_v0ds
|
||||
) AS s
|
||||
WHERE q.ctid = s.ctid;
|
||||
-- 4:15 0:25
|
||||
-- 4:15
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 8) List price (lowest valid); allow open-ended ranges (vb_to IS NULL)
|
||||
@ -283,7 +281,7 @@ BEGIN
|
||||
listcode = p.jcplcd
|
||||
FROM best_price p
|
||||
WHERE q.ctid = p.ctid;
|
||||
-- 2:48 0:18
|
||||
-- 2:48
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 9) Normalize last (when last_dataseg != v1ds) + effective list flags
|
||||
@ -331,7 +329,7 @@ BEGIN
|
||||
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
|
||||
-- 2:22
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 10) Guidance using normalized last + effective list
|
||||
@ -339,35 +337,23 @@ BEGIN
|
||||
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
|
||||
guidance_reason = s.guidance_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
|
||||
g.guidance_reason
|
||||
FROM pricequote.queue q2
|
||||
JOIN LATERAL pricequote.guidance_logic(
|
||||
q2.tprice,
|
||||
q2.last_price_norm,
|
||||
q2.listprice_eff,
|
||||
q2.last_date,
|
||||
.05, 1.0, 1.0
|
||||
) g ON TRUE
|
||||
) s
|
||||
WHERE q.ctid = s.ctid;
|
||||
-- 4:33 0:39
|
||||
-- 4:33
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 11) Build expl and ui_json identical to single_price_call
|
||||
@ -422,9 +408,7 @@ BEGIN
|
||||
'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
|
||||
'guidance_reason', q.guidance_reason
|
||||
),
|
||||
ui_json = jsonb_build_object(
|
||||
'details', jsonb_build_array(
|
||||
@ -515,7 +499,7 @@ BEGIN
|
||||
),
|
||||
'data', q.expl
|
||||
);
|
||||
-- 7:59 2:17
|
||||
-- 7:59
|
||||
|
||||
--------------------------------------------------------------------
|
||||
-- 12) Merge back into matrix (store both expl and ui)
|
||||
@ -539,7 +523,7 @@ BEGIN
|
||||
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
||||
AND o.part IS NOT NULL
|
||||
AND SUBSTRING(o.glec, 1, 1) <= '2';
|
||||
-- 14:13 10:09
|
||||
-- 14:13
|
||||
|
||||
RAISE NOTICE 'Queue processing complete.';
|
||||
END;
|
||||
|
@ -136,8 +136,6 @@ BEGIN
|
||||
------------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)
|
||||
@ -379,8 +377,6 @@ 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)),
|
||||
@ -388,24 +384,12 @@ BEGIN
|
||||
TRY_CAST(q.listprice_eff AS NUMERIC(20,5)),
|
||||
TRY_CAST(q.last_date AS DATE),
|
||||
--allowable price drop percent
|
||||
1.0,
|
||||
.05,
|
||||
--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;
|
||||
) g;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 8: Assemble structured 'expl' JSON from populated columns.
|
||||
@ -452,8 +436,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
|
||||
)
|
||||
@ -474,7 +456,7 @@ BEGIN
|
||||
-- History Panel
|
||||
SELECT
|
||||
'History' AS label,
|
||||
1 as detailLevel,
|
||||
10 as detailLevel,
|
||||
(
|
||||
SELECT
|
||||
----------------------label------------------------------------------------
|
||||
@ -491,7 +473,7 @@ BEGIN
|
||||
ELSE 'No Recent'
|
||||
END AS label,
|
||||
----------------------detail-----------------------------------------------
|
||||
1 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
----------------------value------------------------------------------------
|
||||
ISNULL(q.last_price, 0) AS value,
|
||||
----------------------type-------------------------------------------------
|
||||
@ -532,11 +514,11 @@ BEGIN
|
||||
-- List Panel
|
||||
SELECT
|
||||
'List' AS label,
|
||||
1 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
(
|
||||
SELECT
|
||||
COALESCE('Code: ' + q.listcode,'No List') AS label,
|
||||
1 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
COALESCE(q.listprice,0) 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
|
||||
@ -548,7 +530,7 @@ BEGIN
|
||||
-- Target Support Panel
|
||||
SELECT
|
||||
'Target Calculation' AS label,
|
||||
5 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
(
|
||||
SELECT * FROM (
|
||||
SELECT
|
||||
@ -581,7 +563,7 @@ BEGIN
|
||||
----------------------label------------------------------------------------
|
||||
'Target' AS label,
|
||||
----------------------detailLevel------------------------------------------
|
||||
5 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
----------------------value------------------------------------------------
|
||||
tprice AS value,
|
||||
----------------------type-------------------------------------------------
|
||||
@ -598,11 +580,11 @@ BEGIN
|
||||
-- Guidance Panel
|
||||
SELECT
|
||||
'Guidance' AS label,
|
||||
1 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
(
|
||||
SELECT
|
||||
'Price' AS label,
|
||||
1 AS detailLevel,
|
||||
10 AS detailLevel,
|
||||
COALESCE(q.guidance_price,0) AS value,
|
||||
'currency' AS type,
|
||||
q.guidance_reason AS note
|
||||
|
@ -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) CASCADE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
|
||||
_bill TEXT,
|
||||
@ -89,8 +89,6 @@ RETURNS TABLE (
|
||||
list_relevance TEXT,
|
||||
guidance_price NUMERIC,
|
||||
guidance_reason TEXT,
|
||||
approval_price NUMERIC,
|
||||
approval_reason TEXT,
|
||||
expl JSONB,
|
||||
ui_json JSONB
|
||||
) AS $$
|
||||
@ -150,8 +148,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;
|
||||
@ -376,16 +372,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, .05, 1.0, 1.0) gl;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 8: Build explanation JSON
|
||||
@ -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
|
||||
);
|
||||
|
||||
------------------------------------------------------------------
|
||||
@ -594,7 +582,6 @@ BEGIN
|
||||
_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;
|
||||
|
@ -105,9 +105,6 @@ 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
|
||||
FROM
|
||||
lq
|
||||
@ -178,4 +175,4 @@ lq AS MATERIALIZED (
|
||||
WHERE
|
||||
COALESCE(g.bestprice,1) = 1
|
||||
)
|
||||
SELECT * FROM hist --LIMIT 1000--WHERE qid = 108655
|
||||
SELECT * FROM hist --WHERE qid = 108655
|
||||
|
@ -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, part, dataseg, version, part, qty, price, odate, ordnum, quoten,
|
||||
flag
|
||||
FROM #flagged
|
||||
CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag)
|
||||
|
@ -1,28 +1,27 @@
|
||||
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;
|
||||
$$;
|
||||
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 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
|
||||
INSERT INTO
|
||||
pricequote.target_prices_base
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
expand;
|
||||
|
Loading…
Reference in New Issue
Block a user