price_api/sql/get_hist.pg.sql

163 lines
4.8 KiB
MySQL
Raw Normal View History

2023-11-10 01:44:37 -05:00
CREATE OR REPLACE FUNCTION rlarp.get_hist(_mold text, _v1ds text, _cust text, _chan text)
RETURNS jsonb
LANGUAGE plpgsql
AS $func$
DECLARE
_result jsonb;
BEGIN
WITH
--sel AS (select 'v1:P.P.PLT..' _v1ds, 'ALTMAN PLANTS' _cust, 'XNT0TQT3' _mold, 'D' _chan)
sort AS (
SELECT
p.agglevel
,CASE WHEN p.agglevel ? 'cust' THEN 'cust' ELSE 'market' END source
,COALESCE(gset.v1ds = _v1ds,false) v1ds_match
,gset.chan = _chan chan_match
,gset.*
,row_number() OVER (PARTITION BY p.agglevel ORDER BY avgunits DESC) rn
,stats.*
2023-11-15 15:26:21 -05:00
,season
2023-11-10 01:44:37 -05:00
FROM
rlarp.price_pool_dev p
JOIN LATERAL jsonb_to_record(gset) AS gset(
chan text
,mold text
,v1ds text
,v0ds text
,cust text
,vers text
--,nurs text
--,ghse text
) ON TRUE
JOIN LATERAL jsonb_to_record(stats) AS stats(
avgunits numeric
,avgtargetprice numeric
,avgordcount numeric
,avgcustcount numeric
,early_season int
,early_price numeric
,recent_season int
,recent_price numeric
2023-11-15 15:26:21 -05:00
,last_season int
,last_price numeric
2023-11-10 01:44:37 -05:00
) ON TRUE
WHERE
gset @> jsonb_build_object(
'mold', _mold
,'vers', 'A'
)
AND (
gset @> jsonb_build_object(
'cust', _cust
)
OR NOT gset ? 'cust'
)
AND COALESCE(stats.early_season,stats.recent_season) IS NOT NULL
AND NOT p.agglevel ? 'nurs'
AND NOT p.agglevel ? 'ghse'
ORDER BY
source ASC
,rn ASC
)
,flag AS (
SELECT
--agglevel
CASE source
WHEN 'cust' THEN
CASE WHEN v1ds IS NOT NULL THEN
CASE WHEN v1ds_match THEN 'customer exact' ELSE
CASE WHEN rn = 1 THEN 'customer v1ds vol' ELSE 'customer v1ds other' END
END
ELSE
CASE WHEN rn = 1 THEN 'customer v0ds vol' ELSE 'customer v0ds other' END
END
ELSE
CASE WHEN v1ds IS NOT NULL THEN
CASE WHEN v1ds_match THEN 'market exact' ELSE
CASE WHEN rn = 1 THEN 'market v1ds vol' ELSE 'market v1ds other' END
END
ELSE
CASE WHEN rn = 1 THEN 'market v0ds vol' ELSE 'market v0ds other' END
END
END relevance
,source
,v1ds_match
,chan_match
,chan
,mold
,v1ds
,v0ds
,cust
,vers
,rn
,avgunits
,avgordcount
,avgcustcount
,avgtargetprice
,early_season
,early_price
,recent_season
,recent_price
2023-11-15 15:26:21 -05:00
,last_season
,last_price
,season
2023-11-10 01:44:37 -05:00
FROM
sort
)
,rel AS (
SELECT * FROM (values
('customer exact' ,1)
,('customer v0ds other',7)
,('customer v0ds vol' ,3)
,('customer v1ds other',6)
,('customer v1ds vol' ,2) --this will always sort to the top, v0ds will never sort to the top. you will always be getting the highest volume base price
2023-11-10 01:44:37 -05:00
,('market exact' ,4)
,('market v0ds other' ,9)
,('market v0ds vol' ,5)
,('market v1ds other' ,8)
) x (flag,prefer)
)
,rel_sort AS (
SELECT
-- flag.relevance
--,flag.source
--,rel.prefer
--,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC) best
jsonb_strip_nulls(
jsonb_build_object(
2023-11-10 02:04:16 -05:00
flag.source
2023-11-10 01:44:37 -05:00
,jsonb_build_object(
2023-11-10 02:04:16 -05:00
'relevance' ,relevance
,'avgunits' ,avgunits
2023-11-10 01:44:37 -05:00
,'avgordcount' ,avgordcount
,'avgcustcount' ,avgcustcount
,'avgtargetprice' ,avgtargetprice
,'early_season' ,early_season
,'early_price' ,early_price
,'recent_season' ,recent_season
,'recent_price' ,recent_price
2023-11-15 15:26:21 -05:00
,'last_season' ,last_season
,'last_price' ,last_price
2023-11-10 01:44:37 -05:00
,'ds' ,COALESCE(v1ds,v0ds)
2023-11-15 15:26:21 -05:00
,'rank' ,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC)
,'pricinghistory' ,season
2023-11-10 01:44:37 -05:00
)
)
) doc
2023-11-10 02:04:16 -05:00
,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC) rnk
2023-11-15 15:26:21 -05:00
,season
2023-11-10 01:44:37 -05:00
FROM
flag
LEFT OUTER JOIN rel ON
rel.flag = flag.relevance
WHERE
relevance ~ 'vol|exact'
)
--SELECT jsonb_pretty(jsonb_agg(doc)) FROM rel_sort
2023-11-10 02:04:16 -05:00
SELECT jsonb_obj_aggc(doc) INTO _result FROM rel_sort WHERE rnk = 1;
2023-11-10 01:44:37 -05:00
RETURN _result;
END
$func$;