price_api/sql/quote_review.pg.sql

130 lines
3.8 KiB
MySQL
Raw Normal View History

2024-12-13 10:12:49 -05:00
-- set work_mem TO '4GB';
--
2024-12-13 09:28:58 -05:00
DROP VIEW IF EXISTS rlarp.quote_review;
CREATE VIEW rlarp.quote_review AS
2024-12-13 09:28:43 -05:00
WITH
lq AS MATERIALIZED (
SELECT
lq.*
,substring(lq.part,1,8) mold
FROM
pricequote.live_quotes lq
2024-12-13 15:38:23 -05:00
WHERE
2024-12-13 17:56:18 -05:00
qstat LIKE 'Submitted%'
2024-12-13 09:28:43 -05:00
)
,lqg AS (
SELECT
2024-12-13 10:12:49 -05:00
lq.qid
,lq.qline
,lq.rep
,lq.touched
,lq.expires
,lq.request
,lq.qtitle
,lq.qstatid
,lq.qstat
,lq.quotenumber
,lq.billto
,lq.shipto
,lq.qchan
,lq.qcustomer
,lq.part
,lq.qoptions
,lq.partbuilt
,lq.colgrp
,lq.colc
,lq.coltier
,lq.brand
,lq.dataseg
,lq.v1ds
,lq.comment
,lq.units_each
,lq.price
,lq.sales
,lq.histprice
,lq.targetp
,lq.lastsalesprice
,lq.r_curr
,lq.qt_rate
,lq.qrn
,lq.url
,lq.tacticalmodifier
,lq.finalrecommendedprice
2024-12-13 13:27:03 -05:00
,lq.lowerpricelimit
,lq.upperpricelimit
,(lq.upperpricelimit + lq.lowerpricelimit) / 2 midrange
2024-12-13 10:12:49 -05:00
,i.partgroup part_group
-- ,pricing->'product'->>'itemrel' item_fit
,i.mpck pltq
-- ,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance
-- ,pricing->'guidance'->'finalPrice'->>'Reason' reason
2024-12-13 14:40:01 -05:00
,lq.curstdus cstd_usd
,lq.futstdus fstd_usd
2024-12-13 13:27:03 -05:00
,CASE
WHEN i.glec = '1NU' THEN
--if more than 8/24 pallets, use floor
CASE WHEN units_each >= 24*mpck THEN lq.lowerpricelimit
-- if more than a pallet use the target price
ELSE CASE WHEN units_each >= 8*mpck THEN (lq.upperpricelimit + lq.lowerpricelimit) / 2
-- if more than a pallet use the target price
2024-12-13 13:41:15 -05:00
ELSE CASE WHEN units_each >= 4*mpck THEN lq.upperpricelimit
2024-12-13 13:27:03 -05:00
-- if more than a pallet use the target price
2024-12-13 13:41:15 -05:00
ELSE lq.upperpricelimit * 1.15
END END END
2024-12-13 13:27:03 -05:00
ELSE
2024-12-13 13:41:15 -05:00
--at least 8 pallets is lower limit
2024-12-13 13:27:03 -05:00
CASE WHEN units_each >= 08*mpck THEN lq.lowerpricelimit
2024-12-13 13:41:15 -05:00
--at least 2 pallets is mid range
2024-12-13 13:27:03 -05:00
ELSE CASE WHEN units_each >= 2*mpck THEN (lq.upperpricelimit + lq.lowerpricelimit) / 2
2024-12-13 13:41:15 -05:00
--at least 1 pallet is upper range
ELSE CASE WHEN units_each >= 1*mpck THEN lq.upperpricelimit
--less than a pallet is upper + 15%
ELSE lq.upperpricelimit * 1.15
END END END
2024-12-13 13:27:03 -05:00
END guidance
2024-12-13 10:12:49 -05:00
-- ,(pricing->'guidance'->>'ltp')::numeric ltp
-- ,(pricing->'guidance'->>'optimization')::numeric optimization
-- ,(pricing->'guidance'->>'inflationFactor')::numeric inflation
-- ,jsonb_pretty(pricing) pricing
2024-12-13 09:28:43 -05:00
FROM
lq
2024-12-13 10:12:49 -05:00
LEFT OUTER JOIN "CMS.CUSLG".itemm i ON
i.item = lq.part
2024-12-13 09:28:43 -05:00
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
)
2024-12-13 14:40:01 -05:00
SELECT * FROM hist --WHERE qid = 108655