77 lines
3.2 KiB
PL/PgSQL
77 lines
3.2 KiB
PL/PgSQL
CREATE OR REPLACE FUNCTION pricequote.pick_last_price_from_hist(
|
|
hist JSONB,
|
|
v1ds TEXT
|
|
)
|
|
RETURNS JSONB AS $$
|
|
DECLARE
|
|
dsq JSONB := (hist -> v1ds) -> 'dsq';
|
|
dss JSONB := (hist -> v1ds) -> 'dss';
|
|
mrq JSONB := hist -> 'mrq';
|
|
mrs JSONB := hist -> 'mrs';
|
|
result JSONB;
|
|
BEGIN
|
|
-- Central control for age threshold
|
|
DECLARE
|
|
age_threshold INTERVAL := INTERVAL '1 year';
|
|
dsq_date DATE := NULL;
|
|
dss_date DATE := NULL;
|
|
mrq_date DATE := NULL;
|
|
mrs_date DATE := NULL;
|
|
best JSONB := NULL;
|
|
best_date DATE := NULL;
|
|
BEGIN
|
|
IF dsq IS NOT NULL AND (dsq->>'price') IS NOT NULL THEN
|
|
dsq_date := (dsq->>'odate')::date;
|
|
END IF;
|
|
IF dss IS NOT NULL AND (dss->>'price') IS NOT NULL THEN
|
|
dss_date := (dss->>'odate')::date;
|
|
END IF;
|
|
IF mrq IS NOT NULL AND (mrq->>'price') IS NOT NULL THEN
|
|
mrq_date := (mrq->>'odate')::date;
|
|
END IF;
|
|
IF mrs IS NOT NULL AND (mrs->>'price') IS NOT NULL THEN
|
|
mrs_date := (mrs->>'odate')::date;
|
|
END IF;
|
|
|
|
-- 1. Prefer the most recent of dss/dsq if either is within the age threshold
|
|
IF (dsq_date IS NOT NULL AND dsq_date > (CURRENT_DATE - age_threshold))
|
|
OR (dss_date IS NOT NULL AND dss_date > (CURRENT_DATE - age_threshold)) THEN
|
|
IF dsq_date IS NOT NULL AND (dss_date IS NULL OR dsq_date >= dss_date) AND dsq_date > (CURRENT_DATE - age_threshold) THEN
|
|
result := dsq || jsonb_build_object('source', 'dsq');
|
|
ELSIF dss_date IS NOT NULL AND dss_date > (CURRENT_DATE - age_threshold) THEN
|
|
result := dss || jsonb_build_object('source', 'dss');
|
|
END IF;
|
|
-- 2. If both dss/dsq are older than the threshold, use the most recent of mrs/mrq if either exists
|
|
ELSIF (mrq_date IS NOT NULL OR mrs_date IS NOT NULL) THEN
|
|
IF mrq_date IS NOT NULL AND (mrs_date IS NULL OR mrq_date >= mrs_date) THEN
|
|
result := mrq || jsonb_build_object('source', 'mrq');
|
|
ELSIF mrs_date IS NOT NULL THEN
|
|
result := mrs || jsonb_build_object('source', 'mrs');
|
|
END IF;
|
|
-- 3. If all are at least as old as the threshold, pick the least oldest price available
|
|
ELSE
|
|
best := NULL;
|
|
best_date := NULL;
|
|
IF dsq_date IS NOT NULL THEN
|
|
best := dsq || jsonb_build_object('source', 'dsq');
|
|
best_date := dsq_date;
|
|
END IF;
|
|
IF dss_date IS NOT NULL AND (best_date IS NULL OR dss_date > best_date) THEN
|
|
best := dss || jsonb_build_object('source', 'dss');
|
|
best_date := dss_date;
|
|
END IF;
|
|
IF mrq_date IS NOT NULL AND (best_date IS NULL OR mrq_date > best_date) THEN
|
|
best := mrq || jsonb_build_object('source', 'mrq');
|
|
best_date := mrq_date;
|
|
END IF;
|
|
IF mrs_date IS NOT NULL AND (best_date IS NULL OR mrs_date > best_date) THEN
|
|
best := mrs || jsonb_build_object('source', 'mrs');
|
|
best_date := mrs_date;
|
|
END IF;
|
|
result := best;
|
|
END IF;
|
|
RETURN result;
|
|
END;
|
|
END;
|
|
$$ LANGUAGE plpgsql IMMUTABLE;
|