-- set work_mem TO '4GB'; -- DROP VIEW IF EXISTS rlarp.quote_review; CREATE VIEW rlarp.quote_review AS WITH ---------------------get quote lines from SQL Server--------------------- lq AS MATERIALIZED ( SELECT lq.* ,substring(lq.part,1,8) mold FROM pricequote.live_quotes lq WHERE qstat LIKE '%Submitted%' ) ---------------------guidance logic--------------------------------------- ,lqg AS ( SELECT 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 ,lq.lowerpricelimit ,lq.upperpricelimit ,(lq.upperpricelimit + lq.lowerpricelimit) / 2 midrange ,i.partgroup part_group -- ,pricing->'product'->>'itemrel' item_fit ,i.mpck pltq -- ,(pricing->'guidance'->'finalPrice'->>'Price')::numeric guidance -- ,pricing->'guidance'->'finalPrice'->>'Reason' reason ,lq.curstdus cstd_usd ,lq.futstdus fstd_usd ,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 ELSE CASE WHEN units_each >= 2*mpck THEN lq.upperpricelimit -- if more than a pallet use the target price ELSE lq.upperpricelimit * 1.05 END END END ELSE CASE WHEN i.pricegroup ~ '(Hanger|Dish)' THEN --at least 1 pallets is lower limit CASE WHEN units_each >= 01*mpck THEN lq.lowerpricelimit --at least 2 pallets is mid range ELSE CASE WHEN units_each >= 0.5*mpck THEN (lq.upperpricelimit + lq.lowerpricelimit) / 2 --less than a pallet is upper + 15% ELSE lq.upperpricelimit END END ELSE --at least 8 pallets is lower limit CASE WHEN units_each >= 08*mpck THEN lq.lowerpricelimit --at least 2 pallets is mid range ELSE CASE WHEN units_each >= 2*mpck THEN (lq.upperpricelimit + lq.lowerpricelimit) / 2 --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 END END guidance ,pl.price pricelist ,pl.listcode ,row_number() OVER (PARTITION BY qid, qline ORDER BY pl.price ASC) bestprice -- ,(pricing->'guidance'->>'ltp')::numeric ltp -- ,(pricing->'guidance'->>'optimization')::numeric optimization -- ,(pricing->'guidance'->>'inflationFactor')::numeric inflation -- ,jsonb_pretty(pricing) pricing FROM lq LEFT OUTER JOIN "CMS.CUSLG".itemm i ON i.item = lq.part LEFT OUTER JOIN rlarp.cust bc ON bc.code = lq.billto LEFT OUTER JOIN rlarp.cust sc ON sc.code = lq.shipto LEFT OUTER JOIN rlarp.plcore_fullcode_ranged pl ON pl.item = lq.part AND jsonb_build_array(pl.listcode) <@ (COALESCE(sc.lists,bc.lists)) AND ( lq.units_each >= pl.vb_f AND lq.units_each < pl.vb_t ) WHERE lq.qstat ~ 'Submitted' ) -- SELECT * FROM lqg where bestprice <> 1 -- SELECT * FROM lqg WHERE qid = 109352 ---------------------------link in sales history---------------------------------------------- ,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 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 WHERE COALESCE(g.bestprice,1) = 1 ) SELECT * FROM hist --WHERE qid = 108655