cur standard column name

This commit is contained in:
Paul Trowbridge 2024-04-05 09:24:18 -04:00
parent 6d987ee0aa
commit 51ba3fe3ca
4 changed files with 83 additions and 2 deletions

70
live_quote_mv.pg.sql Normal file
View File

@ -0,0 +1,70 @@
set work_mem TO '4GB';
DROP TABLE IF EXISTS rlarp.live_quotes_review_mv;
CREATE TABLE rlarp.live_quotes_review_mv AS
WITH
lq AS MATERIALIZED (
SELECT
lq.*
,substring(lq.part,1,8) mold
FROM
pricequote.live_quotes lq
)
,lqg AS (
SELECT
lq.*
,pricing->'product'->>'mold' part_group
,substring(pricing->'customer'->>'chan',1,1) qchan
,pricing->'customer'->>'cust' qcust
,pricing->'product'->>'itemrel' item_fit
,(pricing->'product'->>'pltq')::numeric pltq
,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance
,pricing->'guidance'->'finalPrice'->>'Reason' reason
,(pricing->'product'->>'cstd_usd_ina')::numeric fstd_usd
,(pricing->'guidance'->>'ltp')::numeric ltp
,(pricing->'guidance'->>'optimization')::numeric optimization
,(pricing->'guidance'->>'inflationFactor')::numeric inflation
,jsonb_pretty(pricing) pricing
FROM
lq
LEFT JOIN LATERAL rlarp.guidance_r1(
rlarp.get_guidance_dseg(lq.billto,lq.shipto,substring(lq.part,1,8),lq.v1ds,lq.units_each,2024)
) pricing ON TRUE
WHERE
lq.qstat ~ 'Submitted'
)
,hist AS (
SELECT
g.*
,gset.chan
--,gset.mold moldh
,gset.v1ds v1dsh
,gset.cust
,gset.vers
,je.k
,seas.*
FROM
lqg g
LEFT OUTER JOIN rlarp.price_pool_dev p ON
p.gset @> jsonb_build_object('mold',g.part_group)
AND p.gset ? 'cust'
AND p.gset ? 'v1ds'
LEFT JOIN LATERAL jsonb_to_record(p.gset) AS gset(
chan text
,mold text
,v1ds text
,v0ds text
,cust text
,vers text
--,nurs text
--,ghse text
) ON TRUE
LEFT JOIN LATERAL jsonb_each(p.season) je(k,v) on true
LEFT JOIN Lateral jsonb_to_record(je.v) as seas(
units numeric
,sales_usd numeric
,price_usd numeric
) ON TRUE
)
SELECT * FROM hist;

View File

@ -15,6 +15,8 @@ DECLARE
_item text; _item text;
_unti text; _unti text;
_pltq numeric; _pltq numeric;
_cstd numeric;
_cstdina numeric;
_fstd numeric; _fstd numeric;
_fstdina numeric; _fstdina numeric;
_cust text; _cust text;
@ -67,6 +69,8 @@ BEGIN
,idxk ,idxk
,prefer ,prefer
,pltq ,pltq
,curstdus
,curstdus_ina
,futstdus ,futstdus
,futstdus_ina ,futstdus_ina
INTO INTO
@ -75,6 +79,8 @@ BEGIN
,_iidx ,_iidx
,_itemr ,_itemr
,_pltq ,_pltq
,_cstd
,_cstdina
,_fstd ,_fstd
,_fstdina ,_fstdina
FROM FROM
@ -86,6 +92,8 @@ BEGIN
,i.v1ds ,i.v1ds
,_ds.dataseg v0ds ,_ds.dataseg v0ds
,i.mpck pltq ,i.mpck pltq
,avg(i.curstdus) FILTER (WHERE aplnt <> 'I') curstdus
,avg(i.curstdus) curstdus_ina
,avg(i.futstdus) FILTER (WHERE aplnt <> 'I') futstdus ,avg(i.futstdus) FILTER (WHERE aplnt <> 'I') futstdus
,avg(i.futstdus) futstdus_ina ,avg(i.futstdus) futstdus_ina
,jsonb_strip_nulls(jsonb_build_object('assc',CASE WHEN i.assc <> '' THEN i.assc ELSE null::text END,'majg',i.majg::int,'coltier',i.coltier)) idxk ,jsonb_strip_nulls(jsonb_build_object('assc',CASE WHEN i.assc <> '' THEN i.assc ELSE null::text END,'majg',i.majg::int,'coltier',i.coltier)) idxk
@ -120,6 +128,8 @@ BEGIN
,'itemrel',_itemr ,'itemrel',_itemr
,'iidx',_iidx ,'iidx',_iidx
,'pltq',_pltq ,'pltq',_pltq
,'cstd_usd',_cstd
,'cstd_usd_ina',_cstdina
,'fstd_usd',_fstd ,'fstd_usd',_fstd
,'fstd_usd_ina',_fstdina ,'fstd_usd_ina',_fstdina
) )

View File

@ -19,7 +19,7 @@ lq AS MATERIALIZED (
,(pricing->'product'->>'pltq')::numeric pltq ,(pricing->'product'->>'pltq')::numeric pltq
,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance ,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance
,pricing->'guidance'->'finalPrice'->>'Reason' reason ,pricing->'guidance'->'finalPrice'->>'Reason' reason
,(pricing->'product'->>'fstd_usd_ina')::numeric fstd_usd ,(pricing->'product'->>'cstd_usd_ina')::numeric fstd_usd
,(pricing->'guidance'->>'ltp')::numeric ltp ,(pricing->'guidance'->>'ltp')::numeric ltp
,(pricing->'guidance'->>'optimization')::numeric optimization ,(pricing->'guidance'->>'optimization')::numeric optimization
,(pricing->'guidance'->>'inflationFactor')::numeric inflation ,(pricing->'guidance'->>'inflationFactor')::numeric inflation

View File

@ -1,7 +1,7 @@
set work_mem TO '4GB'; set work_mem TO '4GB';
DROP VIEW rlarp.live_quotes_review; DROP VIEW rlarp.live_quotes_review;
CREATE OR REPLACE VIEW rlarp.live_quotes_review AS CREATE VIEW rlarp.live_quotes_review AS
WITH WITH
lq AS MATERIALIZED ( lq AS MATERIALIZED (
SELECT SELECT
@ -20,6 +20,7 @@ lq AS MATERIALIZED (
,(pricing->'product'->>'pltq')::numeric pltq ,(pricing->'product'->>'pltq')::numeric pltq
,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance ,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance
,pricing->'guidance'->'finalPrice'->>'Reason' reason ,pricing->'guidance'->'finalPrice'->>'Reason' reason
,(pricing->'product'->>'cstd_usd_ina')::numeric cstd_usd
,(pricing->'product'->>'fstd_usd_ina')::numeric fstd_usd ,(pricing->'product'->>'fstd_usd_ina')::numeric fstd_usd
,(pricing->'guidance'->>'ltp')::numeric ltp ,(pricing->'guidance'->>'ltp')::numeric ltp
,(pricing->'guidance'->>'optimization')::numeric optimization ,(pricing->'guidance'->>'optimization')::numeric optimization