include all history
This commit is contained in:
parent
87d2bd39cd
commit
32217d52c4
@ -14,6 +14,15 @@ export function apply_guidance(doc: any) {
|
||||
return match ? match.adj : null;
|
||||
}
|
||||
|
||||
//let custPrice null;
|
||||
//let custReason null;
|
||||
//let cvolPrice null;
|
||||
//let cvolReason null;
|
||||
//let markPrice null;
|
||||
//let markReason null;
|
||||
//let targPrice null;
|
||||
//let targReason null;
|
||||
|
||||
const targetPrice = doc.pricing?.v1tp ?? doc.pricing?.v0tp;
|
||||
const priceBand = doc.pricing?.v1stdv ?? doc.pricing?.v0stdv;
|
||||
const earlyPrice = doc.hist?.cust?.early_price;
|
||||
|
@ -16,6 +16,7 @@ sort AS (
|
||||
,gset.*
|
||||
,row_number() OVER (PARTITION BY p.agglevel ORDER BY avgunits DESC) rn
|
||||
,stats.*
|
||||
,season
|
||||
FROM
|
||||
rlarp.price_pool_dev p
|
||||
JOIN LATERAL jsonb_to_record(gset) AS gset(
|
||||
@ -37,6 +38,8 @@ sort AS (
|
||||
,early_price numeric
|
||||
,recent_season int
|
||||
,recent_price numeric
|
||||
,last_season int
|
||||
,last_price numeric
|
||||
) ON TRUE
|
||||
WHERE
|
||||
gset @> jsonb_build_object(
|
||||
@ -95,6 +98,9 @@ SELECT
|
||||
,early_price
|
||||
,recent_season
|
||||
,recent_price
|
||||
,last_season
|
||||
,last_price
|
||||
,season
|
||||
FROM
|
||||
sort
|
||||
)
|
||||
@ -130,13 +136,16 @@ FROM
|
||||
,'early_price' ,early_price
|
||||
,'recent_season' ,recent_season
|
||||
,'recent_price' ,recent_price
|
||||
,'last_season' ,last_season
|
||||
,'last_price' ,last_price
|
||||
,'ds' ,COALESCE(v1ds,v0ds)
|
||||
,'rank'
|
||||
,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC)
|
||||
,'rank' ,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC)
|
||||
,'pricinghistory' ,season
|
||||
)
|
||||
)
|
||||
) doc
|
||||
,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC) rnk
|
||||
,season
|
||||
FROM
|
||||
flag
|
||||
LEFT OUTER JOIN rel ON
|
||||
|
153
sql/get_hist_debug.pg.sql
Normal file
153
sql/get_hist_debug.pg.sql
Normal file
@ -0,0 +1,153 @@
|
||||
WITH
|
||||
sel AS (select 'v1:P.P.PLT..' _v1ds, 'ALTMAN PLANTS' _cust, 'XNS0T1G3' _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.*
|
||||
,season
|
||||
FROM
|
||||
rlarp.price_pool_dev p
|
||||
CROSS JOIN sel
|
||||
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
|
||||
,last_season int
|
||||
,last_price numeric
|
||||
) 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
|
||||
,last_season
|
||||
,last_price
|
||||
,season
|
||||
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)
|
||||
,('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(
|
||||
flag.source
|
||||
,jsonb_build_object(
|
||||
'relevance' ,relevance
|
||||
,'avgunits' ,avgunits
|
||||
,'avgordcount' ,avgordcount
|
||||
,'avgcustcount' ,avgcustcount
|
||||
,'avgtargetprice' ,avgtargetprice
|
||||
,'early_season' ,early_season
|
||||
,'early_price' ,early_price
|
||||
,'recent_season' ,recent_season
|
||||
,'recent_price' ,recent_price
|
||||
,'last_season' ,last_season
|
||||
,'last_price' ,last_price
|
||||
,'ds' ,COALESCE(v1ds,v0ds)
|
||||
,'rank' ,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC)
|
||||
,'pricinghistory' ,season
|
||||
)
|
||||
)
|
||||
) doc
|
||||
,row_number() OVER (PARTITION BY flag.source ORDER BY rel.prefer ASC) rnk
|
||||
,season
|
||||
FROM
|
||||
flag
|
||||
LEFT OUTER JOIN rel ON
|
||||
rel.flag = flag.relevance
|
||||
WHERE
|
||||
relevance ~ 'vol|exact'
|
||||
)
|
||||
--SELECT rnk, jsonb_pretty(doc) doc, jsonb_pretty(season) season FROM rel_sort
|
||||
--SELECT jsonb_pretty(jsonb_agg(doc)) FROM rel_sort
|
||||
--SELECT jsonb_pretty(jsonb_obj_aggc(doc)) FROM rel_sort--INTO _result FROM rel_sort WHERE rnk = 1;
|
||||
SELECT * FROM rel_sort;
|
@ -1,7 +1,7 @@
|
||||
--CREATE OR REPLACE PROCEDURE rlarp.price_pool()
|
||||
--LANGUAGE plpgsql AS
|
||||
--$func$
|
||||
--BEGIN
|
||||
BEGIN;
|
||||
DROP TABLE IF EXISTS rlarp.price_pool_dev;
|
||||
CREATE TABLE IF NOT EXISTS rlarp.price_pool_dev AS (
|
||||
WITH
|
||||
@ -124,8 +124,9 @@ CREATE TABLE IF NOT EXISTS rlarp.price_pool_dev AS (
|
||||
,round(avg(ordcount) ,1) avgordcount
|
||||
,round(avg(units) ,0) avgunits
|
||||
,round(avg(target_price),5) avgtargetprice
|
||||
,min(oseas) FILTER (WHERE oseas BETWEEN 2020 AND 2022)::text early_season
|
||||
,min(oseas) FILTER (WHERE oseas BETWEEN 2020 AND 2023)::text early_season
|
||||
,min(oseas) FILTER (WHERE oseas >= 2024)::text recent_season
|
||||
,max(oseas) FILTER (WHERE oseas >= 2020)::text last_season
|
||||
--,oseas
|
||||
--,units
|
||||
--,sales_usd
|
||||
@ -159,6 +160,10 @@ CREATE TABLE IF NOT EXISTS rlarp.price_pool_dev AS (
|
||||
,recent_season::int
|
||||
,'recent_price'
|
||||
,(season->recent_season->>'price_usd')::numeric
|
||||
,'last_season'
|
||||
,last_season::int
|
||||
,'last_price'
|
||||
,(season->last_season->>'price_usd')::numeric
|
||||
) stats
|
||||
FROM
|
||||
find_stats
|
||||
@ -166,3 +171,4 @@ CREATE TABLE IF NOT EXISTS rlarp.price_pool_dev AS (
|
||||
) WITH DATA;
|
||||
|
||||
create index ppd_gset on rlarp.price_pool_dev using gin (gset);
|
||||
END;
|
||||
|
Loading…
Reference in New Issue
Block a user