work on guidance logic output text and parameterize caps and floors

This commit is contained in:
Paul Trowbridge 2025-08-14 02:32:01 -04:00
parent c46d4c25d7
commit ccf50036ca
5 changed files with 123 additions and 184 deletions

View File

@ -1,119 +1,59 @@
CREATE OR ALTER FUNCTION pricing.guidance_logic(
-- This function returns the least of two NUMERIC(20,5) values. @target numeric(20,5),
CREATE OR ALTER FUNCTION dbo.LEAST_NUMERIC205( @last_norm numeric(20,5),
@a NUMERIC(20,5), @list_eff numeric(20,5),
@b NUMERIC(20,5) @last_date date,
@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 NUMERIC(20,5) RETURNS TABLE
AS AS
BEGIN RETURN
RETURN CASE WITH base AS (
WHEN @a IS NULL THEN @b SELECT
WHEN @b IS NULL THEN @a CAST(CASE WHEN @target IS NULL THEN NULL ELSE @target END AS numeric(20,5)) AS price
WHEN @a < @b THEN @a ELSE @b ), floored AS (
END SELECT
END CASE WHEN price IS NULL OR @last_norm IS NULL OR @floor_pct<=0
GO THEN price
ELSE CAST(ROUND(IIF(price>@last_norm*(1-@floor_pct),price,@last_norm*(1-@floor_pct)),5) AS numeric(20,5))
-- This function returns the greatest of two NUMERIC(20,5) values. END AS price
CREATE OR ALTER FUNCTION dbo.GREATEST_NUMERIC205( FROM base
@a NUMERIC(20,5), ), cap_last AS (
@b NUMERIC(20,5) SELECT
CASE WHEN price IS NULL OR @last_norm IS NULL
THEN price
ELSE CAST(ROUND(IIF(price<@last_norm*@cap_last_pct,price,@last_norm*@cap_last_pct),5) AS numeric(20,5))
END AS price
FROM floored
), cap_list AS (
SELECT
CASE WHEN price IS NULL OR @list_eff IS NULL
THEN price
ELSE CAST(ROUND(IIF(price<@list_eff*@cap_list_pct,price,@list_eff*@cap_list_pct),5) AS numeric(20,5))
END AS price
FROM cap_last
) )
RETURNS NUMERIC(20,5) SELECT
AS price AS guidance_price,
BEGIN CASE
RETURN CASE WHEN @target IS NULL THEN 'No target price available'
WHEN @a IS NULL THEN @b WHEN @last_norm IS NULL AND @list_eff IS NULL THEN 'No recent sale or list; using target price'
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 @price NUMERIC(20,5);
DECLARE @reason NVARCHAR(MAX) = '';
DECLARE @floored NUMERIC(20,5);
DECLARE @capped NUMERIC(20,5);
DECLARE @use_last_price BIT = 0;
-- 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
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);
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
ELSE IF @use_last_price = 1
BEGIN
SET @price = @last_price;
SET @reason = 'Last price - no target';
END
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 ELSE
BEGIN CONCAT(
SET @price = NULL; 'Using target price',
IF @last_price IS NOT NULL AND @last_date IS NOT NULL CASE WHEN @last_norm IS NOT NULL AND @floor_pct>0
BEGIN THEN CONCAT(', floored to ', FORMAT(@floor_pct*100,'0.##'), '% below last price') ELSE '' END,
SET @reason = CONCAT( CASE WHEN @last_norm IS NOT NULL AND @cap_last_pct<1
'Last price ignored (too old: ', THEN CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price')
CONVERT(NVARCHAR(10), @last_date, 120), WHEN @last_norm IS NOT NULL AND @cap_last_pct=1
'), no pricing available' THEN ', capped to not exceed last price'
); ELSE '' END,
END CASE WHEN @list_eff IS NOT NULL AND @cap_list_pct<1
ELSE THEN CONCAT(', capped to ', FORMAT(@cap_list_pct*100,'0.##'), '% of list price')
BEGIN WHEN @list_eff IS NOT NULL AND @cap_list_pct=1
SET @reason = 'No pricing available'; THEN ', capped to not exceed list price'
END ELSE '' END
END )
END AS guidance_reason;
INSERT INTO @result VALUES (@price, @reason);
RETURN;
END
GO

View File

@ -1,76 +1,69 @@
CREATE OR REPLACE FUNCTION pricequote.guidance_logic( CREATE OR REPLACE FUNCTION pricequote.guidance_logic(
_target_price NUMERIC(20,5), _target numeric(20,5),
_last_price NUMERIC(20,5), _last_norm numeric(20,5),
_list_price NUMERIC(20,5), _list_eff numeric(20,5),
_last_date DATE _last_date date,
_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 ( RETURNS TABLE (guidance_price numeric(20,5), guidance_reason text)
guidance_price NUMERIC(20,5), LANGUAGE plpgsql AS $$
guidance_reason TEXT
) AS $$
DECLARE DECLARE
_price NUMERIC(20,5); base_price numeric(20,5);
_reason TEXT := ''; after_floor numeric(20,5);
_floored NUMERIC(20,5); after_cap_last numeric(20,5);
_capped NUMERIC(20,5); final_price numeric(20,5);
_use_last_price BOOLEAN := FALSE; reason text := '';
BEGIN BEGIN
-- Evaluate whether last price is recent enough IF _target IS NULL THEN
IF _last_price IS NOT NULL AND _last_date IS NOT NULL AND _last_date > CURRENT_DATE - INTERVAL '2 years' THEN RETURN QUERY SELECT NULL::numeric, 'No target price available';
_use_last_price := TRUE; RETURN;
END IF; END IF;
IF _target_price IS NOT NULL AND _use_last_price THEN base_price := _target;
_floored := GREATEST(_target_price, _last_price * 0.95);
_capped := LEAST(_floored, _last_price);
_price := LEAST(COALESCE(_list_price, 1e9), _capped);
IF _price = _last_price THEN -- floor (binds if it raises price)
_reason := 'Cap at last price'; after_floor := base_price;
ELSE IF _last_norm IS NOT NULL AND _floor_pct > 0 THEN
_reason := 'Using target price'; after_floor := GREATEST(base_price, ROUND(_last_norm*(1-_floor_pct),5));
IF _target_price < _last_price * 0.95 THEN END IF;
_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 -- cap to last (binds if it lowers price)
_price := _last_price; after_cap_last := after_floor;
_reason := 'Last price - no target'; IF _last_norm IS NOT NULL THEN
after_cap_last := LEAST(after_floor, ROUND(_last_norm*_cap_last_pct,5));
END IF;
ELSIF _target_price IS NOT NULL THEN -- cap to list (binds if it lowers price)
_price := _target_price; final_price := after_cap_last;
IF _list_eff IS NOT NULL THEN
IF _last_price IS NOT NULL AND _last_date IS NOT NULL THEN final_price := LEAST(after_cap_last, ROUND(_list_eff*_cap_list_pct,5));
_reason := format( END IF;
-- 'Last price ignored (too old: %s), using target price',
'Last price ignored, using target price',
to_char(_last_date, 'YYYY-MM-DD')
);
ELSE
_reason := 'Target price - no prior sale';
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 ELSE
_price := NULL; reason := 'Using target price';
IF _last_norm IS NOT NULL AND _floor_pct > 0 AND after_floor > base_price THEN
IF _last_price IS NOT NULL AND _last_date IS NOT NULL THEN reason := reason || format(', floored to %s%% below last price', to_char((_floor_pct*100)::numeric,'FM999990.##'));
_reason := format( END IF;
-- 'Last price ignored (too old: %s), no pricing available', IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN
'Last price too old, no pricing available', IF _cap_last_pct = 1 THEN
to_char(_last_date, 'YYYY-MM-DD') reason := reason || ', capped to not exceed last price';
); ELSE
ELSE reason := reason || format(', capped to %s%% of last price', to_char((_cap_last_pct*100)::numeric,'FM999990.##'));
_reason := 'No pricing available'; 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;
END IF; END IF;
RETURN QUERY SELECT _price, _reason; RETURN QUERY SELECT final_price, reason;
END; END $$;
$$ LANGUAGE plpgsql;

View File

@ -216,7 +216,7 @@ BEGIN
AND tp2.ds = q.last_dataseg AND tp2.ds = q.last_dataseg
AND tp2.chan = q.chan AND tp2.chan = q.chan
AND tp2.tier = q.tier AND tp2.tier = q.tier
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp2.vol; AND FLOOR(q.last_qty / NULLIF(q.pltq, 0))::INT <@ tp2.vol;
-- 17 sec -- 17 sec
-------------------------------------------------------------------- --------------------------------------------------------------------
@ -297,7 +297,7 @@ BEGIN
AND q.curstd_last IS NOT NULL AND q.curstd_last IS NOT NULL
AND q.curstd IS NOT NULL AND q.curstd IS NOT NULL
AND q.curstd_last <> 0 AND q.curstd_last <> 0
THEN q.curstd / q.curstd_last THEN ROUND(q.curstd / q.curstd_last,5)
END, END,
last_premium_method = CASE last_premium_method = CASE
WHEN q.last_isdiff IS NOT NULL WHEN q.last_isdiff IS NOT NULL
@ -347,7 +347,8 @@ BEGIN
q2.tprice, q2.tprice,
q2.last_price_norm, q2.last_price_norm,
q2.listprice_eff, q2.listprice_eff,
q2.last_date q2.last_date,
.05, 1.0, 1.0
) g ON TRUE ) g ON TRUE
) s ) s
WHERE q.ctid = s.ctid; WHERE q.ctid = s.ctid;

View File

@ -382,7 +382,8 @@ BEGIN
TRY_CAST(q.tprice AS NUMERIC(20,5)), TRY_CAST(q.tprice AS NUMERIC(20,5)),
TRY_CAST(q.last_price_norm 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.listprice_eff AS NUMERIC(20,5)),
TRY_CAST(q.last_date AS DATE) TRY_CAST(q.last_date AS DATE),
.05, 1.0, 1.0
) g; ) g;
-------------------------------------------------------------------------------- --------------------------------------------------------------------------------
@ -485,8 +486,12 @@ BEGIN
END, END,
ISNULL(' | ' + CONVERT(varchar(10), q.last_date, 120), ''), ISNULL(' | ' + CONVERT(varchar(10), q.last_date, 120), ''),
' | Qty ' + format(q.last_qty,'#,###'), ' | Qty ' + format(q.last_qty,'#,###'),
CASE WHEN last_isdiff <> '' THEN ' | Normalized To: ' + cast(last_price_norm AS varchar(10)) ELSE '' END, CASE WHEN COALESCE(last_isdiff,'') <> ''
' | ' /*+ q.last_premium_method*/ + ' Last Target = ' + format(q.tprice_last,'0.0####') + ' | Current Target ' + format(q.tprice,'0.0####') 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 ELSE
'' ''

View File

@ -375,7 +375,7 @@ BEGIN
INTO INTO
_guidance_price _guidance_price
,_guidance_reason ,_guidance_reason
FROM pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date) gl; FROM pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date, .05, 1.0, 1.0) gl;
------------------------------------------------------------------ ------------------------------------------------------------------
-- Step 8: Build explanation JSON -- Step 8: Build explanation JSON