diff --git a/sql/spread.pg.sql b/sql/spread.pg.sql index 5a470f0..0c6105e 100644 --- a/sql/spread.pg.sql +++ b/sql/spread.pg.sql @@ -1,18 +1,68 @@ +DROP FUNCTION IF EXISTS rlarp.get_premium; +CREATE OR REPLACE FUNCTION rlarp.get_premium(_mold text, _season int, _chan text, _relevant text, _quoted text) +RETURNS jsonb +LANGUAGE plpgsql AS +--DO +$func$ +BEGIN + +DECLARE + _factor jsonb; + WITH --targte spreads-- -ts AS ( +bridge AS ( SELECT + -- 'FHR14000' mold + --,2024 season + --,'DIRECT' chan + --,'v1:B..SLV..' relevant + --,'v1:S..SLV..' quoted + _mold mold + ,_season season + ,_chan chan + ,_relevant relevant + ,_quoted quoted +) +,ts AS ( + SELECT t.* --, round(target_price/min(target_price) over (partition by mold, chan, season),5) spread - , target_price/min(target_price) over (partition by mold, chan, season) spread + ,t.target_price/min(t.target_price) over (partition by t.mold, t.chan, t.season) spread + ,b.quoted + ,b.relevant + ,CASE t.data_segment WHEN b.quoted THEN 'get to here' WHEN b.relevant THEN 'from here' END flag FROM pricequote.market_setavgprice t - WHERE - mold = 'FHR14000' - and season = 2024 - and chan = 'DIRECT' - and data_segment like 'v1%' + INNER JOIN bridge b ON + t.mold = b.mold + and t.season = b.season + and t.chan = b.chan + and t.data_segment like 'v1%' + and t.geo = 'ALL' + and t.country = 'ALL' + and t.geo = 'ALL' ORDER BY target_price ASC ) -SELECT mold, chan, season, data_segment, spread, max(spread) over (), min(spread) OVER () spread FROM ts WHERE data_segment IN ('v1:B..SLV..','v1:S..SLV..') +--SELECT * FROM ts +SELECT + --mold + --,chan + --,season + --,ROUND(max(spread) FILTER (WHERE flag = 'get to here'),5) quote + --,ROUND(max(spread) FILTER (WHERE flag = 'from here') ,5) relevant + jsonb_build_object('bridgePremium',ROUND(max(spread) FILTER (WHERE flag = 'get to here') + /max(spread) FILTER (WHERE flag = 'from here') ,5)) +INTO + _factor +FROM + ts +GROUP BY + mold + ,chan + ,season; + +RETURN _factor; +END +$func$