diff --git a/procs/guidance_logic.ms.sql b/procs/guidance_logic.ms.sql index 8f6f0a9..2071384 100644 --- a/procs/guidance_logic.ms.sql +++ b/procs/guidance_logic.ms.sql @@ -1,119 +1,59 @@ - --- 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) +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.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 -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) +RETURN +WITH base AS ( + SELECT + CAST(CASE WHEN @target IS NULL THEN NULL ELSE @target END AS numeric(20,5)) AS price +), floored AS ( + SELECT + CASE WHEN price IS NULL OR @last_norm IS NULL OR @floor_pct<=0 + THEN price + ELSE CAST(ROUND(IIF(price>@last_norm*(1-@floor_pct),price,@last_norm*(1-@floor_pct)),5) AS numeric(20,5)) + END AS price + FROM base +), cap_last AS ( + 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) -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 @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 +SELECT + 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 recent sale or list; using target price' 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 -GO \ No newline at end of file + CONCAT( + 'Using target price', + CASE WHEN @last_norm IS NOT NULL AND @floor_pct>0 + THEN CONCAT(', floored to ', FORMAT(@floor_pct*100,'0.##'), '% below last price') ELSE '' END, + CASE WHEN @last_norm IS NOT NULL AND @cap_last_pct<1 + THEN CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price') + WHEN @last_norm IS NOT NULL AND @cap_last_pct=1 + THEN ', capped to not exceed last price' + ELSE '' END, + CASE WHEN @list_eff IS NOT NULL AND @cap_list_pct<1 + THEN CONCAT(', capped to ', FORMAT(@cap_list_pct*100,'0.##'), '% of list price') + WHEN @list_eff IS NOT NULL AND @cap_list_pct=1 + THEN ', capped to not exceed list price' + ELSE '' END + ) + END AS guidance_reason; diff --git a/procs/guidance_logic.pg.sql b/procs/guidance_logic.pg.sql index bebd158..f171cbd 100644 --- a/procs/guidance_logic.pg.sql +++ b/procs/guidance_logic.pg.sql @@ -1,76 +1,69 @@ CREATE OR REPLACE FUNCTION pricequote.guidance_logic( - _target_price NUMERIC(20,5), - _last_price NUMERIC(20,5), - _list_price NUMERIC(20,5), - _last_date DATE + _target numeric(20,5), + _last_norm numeric(20,5), + _list_eff numeric(20,5), + _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 ( - guidance_price NUMERIC(20,5), - guidance_reason TEXT -) AS $$ +RETURNS TABLE (guidance_price numeric(20,5), guidance_reason text) +LANGUAGE plpgsql AS $$ DECLARE - _price NUMERIC(20,5); - _reason TEXT := ''; - _floored NUMERIC(20,5); - _capped NUMERIC(20,5); - _use_last_price BOOLEAN := FALSE; + base_price numeric(20,5); + after_floor numeric(20,5); + after_cap_last numeric(20,5); + final_price numeric(20,5); + reason text := ''; BEGIN - -- 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; + IF _target IS NULL THEN + RETURN QUERY SELECT NULL::numeric, 'No target price available'; + RETURN; END IF; - 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); + base_price := _target; - 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; + -- 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; - ELSIF _use_last_price THEN - _price := _last_price; - _reason := 'Last price - no target'; + -- 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; - 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', - 'Last price ignored, using target price', - to_char(_last_date, 'YYYY-MM-DD') - ); - ELSE - _reason := 'Target price - no prior sale'; - 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; + -- build reason + IF _last_norm IS NULL AND _list_eff IS NULL THEN + reason := 'No prior sale or list; using target price'; 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', - 'Last price too old, no pricing available', - to_char(_last_date, 'YYYY-MM-DD') - ); - ELSE - _reason := 'No pricing available'; + 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 _price, _reason; -END; -$$ LANGUAGE plpgsql; + RETURN QUERY SELECT final_price, reason; +END $$; diff --git a/procs/matrix_guidance.pg.sql b/procs/matrix_guidance.pg.sql index 09c0175..9c8f3e9 100644 --- a/procs/matrix_guidance.pg.sql +++ b/procs/matrix_guidance.pg.sql @@ -216,7 +216,7 @@ BEGIN AND tp2.ds = q.last_dataseg AND tp2.chan = q.chan 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 -------------------------------------------------------------------- @@ -297,7 +297,7 @@ BEGIN AND q.curstd_last IS NOT NULL AND q.curstd IS NOT NULL AND q.curstd_last <> 0 - THEN q.curstd / q.curstd_last + THEN ROUND(q.curstd / q.curstd_last,5) END, last_premium_method = CASE WHEN q.last_isdiff IS NOT NULL @@ -347,7 +347,8 @@ BEGIN q2.tprice, q2.last_price_norm, q2.listprice_eff, - q2.last_date + q2.last_date, + .05, 1.0, 1.0 ) g ON TRUE ) s WHERE q.ctid = s.ctid; diff --git a/procs/single_price_call.ms.sql b/procs/single_price_call.ms.sql index 3240130..3a2b6be 100644 --- a/procs/single_price_call.ms.sql +++ b/procs/single_price_call.ms.sql @@ -382,7 +382,8 @@ BEGIN 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) + TRY_CAST(q.last_date AS DATE), + .05, 1.0, 1.0 ) g; -------------------------------------------------------------------------------- @@ -485,8 +486,12 @@ BEGIN END, ISNULL(' | ' + CONVERT(varchar(10), q.last_date, 120), ''), ' | Qty ' + format(q.last_qty,'#,###'), - CASE WHEN last_isdiff <> '' THEN ' | Normalized To: ' + cast(last_price_norm AS varchar(10)) ELSE '' END, - ' | ' /*+ q.last_premium_method*/ + ' Last Target = ' + format(q.tprice_last,'0.0####') + ' | Current Target ' + format(q.tprice,'0.0####') + 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 '' diff --git a/procs/single_price_call.pg.sql b/procs/single_price_call.pg.sql index c4c0307..3ec1fef 100644 --- a/procs/single_price_call.pg.sql +++ b/procs/single_price_call.pg.sql @@ -375,7 +375,7 @@ BEGIN INTO _guidance_price ,_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