price_api/sql/get_list.pg.sql

234 lines
5.4 KiB
PL/PgSQL

CREATE OR REPLACE FUNCTION rlarp.get_list(_billto text, _shipto text, _item text, _qty numeric)
RETURNS jsonb
LANGUAGE plpgsql AS
--DO
$func$
DECLARE
-- _billto text;
-- _shipto text;
-- _item text;
-- _qty numeric;
_rslt jsonb;
BEGIN
--_billto := 'DIAM0004';
--_shipto := 'DIAM0004';
--_item := 'AMK06000G18B054';
--_qty := 5400;
CREATE TEMP TABLE IF NOT EXISTS cp AS (
--every unqiue price list scenario
SELECT
s.bill_cust
,s.ship_cust
,s.part
,i.unti unit
,s.qtyord
,i.uomp
,CASE WHEN COALESCE(sc.plevel,'') = '' THEN bc.plevel ELSE sc.plevel END plvl
FROM
(SELECT _billto bill_cust, _shipto ship_cust, _item part, _qty qtyord) s
LEFT OUTER JOIN "CMS.CUSLG".itemm i ON
i.item = s.part
LEFT OUTER JOIN rlarp.cust sc ON
sc.code = s.ship_cust
LEFT OUTER JOIN rlarp.cust bc ON
bc.code = s.bill_cust
WHERE
CASE WHEN COALESCE(sc.plevel,'') = '' THEN bc.plevel ELSE sc.plevel END <> ''
GROUP BY
s.bill_cust
,s.ship_cust
,s.part
,i.unti
,s.qtyord
,i.uomp
,CASE WHEN COALESCE(sc.plevel,'') = '' THEN bc.plevel ELSE sc.plevel END
) WITH DATA;
--drop table cp
--SELECT * FROM cp WHERE bill_cust = 'DIST0008' and part = 'TCF06SG0G18C050' and ship_cust = 'DIST0007'
CREATE TEMP TABLE IF NOT EXISTS plfull AS (
--all all rows for relevant part/price levels
WITH
----------unique price points-----------------------
lvl AS (
SELECT DISTINCT
plvl
,part
,unit
FROM
cp
)
------------join prices for price level------------
,plj AS (
SELECT
lvl.plvl
,lvl.part
,lvl.unit
,i.jcplcd
,i.jcunit
,i.jcvoll
,i.jcpric
FROM
lvl
INNER JOIN "CMS.CUSLG".iprcbhc hc ON
hc.jbplvl = lvl.plvl
AND current_date BETWEEN hc.jbfdat AND hc.jbtdat
INNER JOIN lgdat.iprcc i ON
i.jcplcd = hc.jbplcd
AND i.jcpart = lvl.part
)
-----------uom conversions-------------------
,uom AS (
SELECT
uom.p part
,uom.f
,uom.t
,uom.nm/uom.dm rate
FROM
(
SELECT
jsonb_agg(row_to_json(d)::jsonb) jdoc
FROM
(
SELECT DISTINCT
part partn
,jcunit fu
,unit tu
FROM
plj
WHERE
part <> ''
) d
) c
JOIN LATERAL rlarp.uom_array(c.jdoc) uom ON TRUE
)
------price list sorted---------------------
SELECT
plj.plvl
,plj.part
,plj.unit
,plj.jcplcd
--,plj.jcunit
,round(plj.jcvoll * uom.rate,5) vol
,round(plj.jcpric / uom.rate,5) price
--,uom.rate
--dont partition by list code becuase there could be duplicate assignments
,row_number() OVER (PARTITION BY plj.plvl, plj.part, plj.unit ORDER BY round(plj.jcvoll * uom.rate,5) ASC) rn
FROM
plj
INNER JOIN uom ON
uom.part = plj.part
AND uom.f = plj.jcunit
AND uom.t = plj.unit
) WITH DATA;
--select * from plfull
CREATE TEMP TABLE IF NOT EXISTS pl AS (
--create from-to volume range for price list
WITH RECURSIVE
pl(plvl, listcode, part, unit, volf, volt, price1, price2, rn, lvl) AS (
SELECT
p1.plvl
,p1.jcplcd as listcode
,p1.part
,p1.unit
,0::numeric volf
,p1.vol volt
,null::numeric price1
,p1.price price2
,p1.rn
,0 lvl
FROM
plfull p1
WHERE
p1.rn = 1
UNION ALL
SELECT
pl.plvl
,COALESCE(f.jcplcd,pl.listcode) listcode
,pl.part
,pl.unit
,pl.volt volf
,COALESCE(f.vol,999999999) volt
,pl.price2 price1
,f.price price2
,f.rn
,pl.lvl + 1
FROM
pl
LEFT OUTER JOIN plfull f ON
f.plvl = pl.plvl
AND f.part = pl.part
AND f.unit = pl.unit
AND f.rn = pl.rn + 1
WHERE
pl.price2 IS NOT NULL
) SEARCH DEPTH FIRST BY part, plvl, unit SET ordercol
SELECT
plvl
,listcode
,part
,unit
,volf
,volt
,numrange(volf, volt) vrange
,price1 price
--,price2
--,rn
--,lvl
--,ordercol
FROM
pl
ORDER BY
ordercol
) WITH DATA;
--select * from pl
--add primary key to test if there are any price level that overlap the same part number
--alter table pl add primary key (plvl, part, unit, vrange);
CREATE TEMP TABLE IF NOT EXISTS cpj AS (
--go back to every unique scenario and join to modified list with volum range
SELECT
cp.*
,pl.price
,pl.listcode
FROM
cp
INNER JOIN pl ON
pl.part = cp.part
AND pl.plvl = cp.plvl
AND pl.unit = cp.unit
WHERE
pl.vrange @> cp.qtyord
) WITH DATA;
--select * from cpj where part = 'TCF06SG0G18C050'
SELECT
jsonb_build_object('list',cpj.price)
||jsonb_build_object('listcode',cpj.listcode)
||jsonb_build_object('plvl',cpj.plvl)
INTO
_rslt
FROM
cpj;
--RAISE NOTICE 'list: %' ,_rslt;
DROP TABLE IF EXISTS cp;
DROP TABLE IF EXISTS plfull;
DROP TABLE IF EXISTS pl;
DROP TABLE IF EXISTS cpj;
RETURN _rslt;
END;
$func$;