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, @cap_last_pct numeric(10,5) = 1.00, @cap_list_pct numeric(10,5) = 1.00 ) RETURNS @ret TABLE ( guidance_price numeric(20,5), guidance_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), -- after applying floor: raised if below (1 - floor_pct) * last_norm @after_cap_last numeric(20,5), -- after applying last cap: lowered if above cap_last_pct * last_norm @final_price numeric(20,5), -- after applying list cap: lowered if above cap_list_pct * list_eff @reason nvarchar(4000) = N''; -- explanation text for what rules applied -- 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*(1-@floor_pct) THEN @base_price ELSE @last_norm*(1-@floor_pct) END, 5); -- Step 2: cap vs last_norm 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: cap vs list_eff 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 '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 @floor_pct > 0 AND @after_floor > @base_price SET @reason += N', floored to ' + FORMAT(@floor_pct*100,'0.##') + N'% below last price'; IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor SET @reason += CASE WHEN @cap_last_pct = 1 THEN N', capped to not exceed last price' ELSE N', capped to ' + FORMAT(@cap_last_pct*100,'0.##') + N'% of last price' END; IF @list_eff IS NOT NULL AND @final_price < @after_cap_last SET @reason += CASE WHEN @cap_list_pct = 1 THEN N', capped to not exceed list price' ELSE N', capped to ' + FORMAT(@cap_list_pct*100,'0.##') + N'% of list price' END; INSERT INTO @ret VALUES (@final_price, @reason); RETURN; END;