-- JSON-based helper function for last price selection CREATE OR ALTER FUNCTION pricing.pick_last_price_from_hist_json ( @part_stats NVARCHAR(MAX), @v1ds NVARCHAR(100) ) RETURNS @result TABLE ( price NUMERIC(20,5), source NVARCHAR(10), odate DATE, qty NUMERIC(20,5), dataseg NVARCHAR(100), ord NVARCHAR(20), quote NVARCHAR(20) ) AS BEGIN 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); SELECT @dsq = segflags.dsq, @dss = segflags.dss FROM OPENJSON(@part_stats, '$."' + @v1ds + '"') WITH (dss NVARCHAR(MAX) AS JSON, dsq NVARCHAR(MAX) AS JSON) segflags; SELECT @mrq = flags.mrq, @mrs = flags.mrs FROM OPENJSON(@part_stats) 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); 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 FROM OPENJSON(@dsq) 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 FROM OPENJSON(@dss) 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 FROM OPENJSON(@mrq) 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 FROM OPENJSON(@mrs) 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 (@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 (@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; 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); RETURN; END