DROP FUNCTION rlarp.get_guidance; CREATE OR REPLACE FUNCTION rlarp.get_guidance(_bill text, _ship text, _item text, _qty numeric, _seas int) RETURNS jsonb LANGUAGE plpgsql AS --DO $func$ DECLARE --_item text; --_bill text; --_ship text; --_qty numeric; --_seas int; _mold text; _cust text; _v1ds text; _chan text; _regn text; _rslt jsonb; _targ jsonb; _list jsonb; BEGIN --_item := 'AMK06000G18B054'; --_bill := 'DIAM0004'; --_ship := 'DIAM0004'; --_qty := 5000; --_seas := 2024; ----------------base product-------------------------------- SELECT m.part_group, i.v1ds INTO _mold,_v1ds FROM "CMS.CUSLG".itemmv i INNER JOIN rlarp.molds m ON m.stlc = i.stlc WHERE i.item = _item; RAISE NOTICE 'mold %', _mold; RAISE NOTICE 'v1ds %', _v1ds; ----------------channel------------------------------------- SELECT rlarp.channel_code(_bill, _ship) INTO _chan; RAISE NOTICE '%', _chan; ----------------customer------------------------------------ SELECT dba INTO _cust FROM rlarp.cust WHERE code = CASE WHEN _chan = 'DRP' THEN _ship ELSE _bill END ; RAISE NOTICE 'cust %', _cust; ----------------price history------------------------------- SELECT jsonb_build_object('hist',rlarp.gethist(_mold, _cust)) INTO _rslt ; RAISE NOTICE '%', _rslt; ----------------target pricing------------------------------ SELECT jsonb_build_object( 'v1tp', target_price, 'stdv', stdev_price ) INTO _targ FROM pricequote.market_setavgprice WHERE mold = _mold AND season = _seas AND data_segment = _v1ds AND region = 'ALL'; RAISE NOTICE 'target: %', jsonb_pretty(_targ); ----------------list ppricing------------------------------- SELECT rlarp.get_list(_bill, _ship, _item, _qty) INTO _list; RAISE NOTICE 'list: %', jsonb_pretty(_list); RETURN _rslt; END; $func$;