create function that returns all customer related info and integrate to process
This commit is contained in:
parent
764a6f8ebe
commit
d6c4d71851
69
sql/get_cust.pg.sql
Normal file
69
sql/get_cust.pg.sql
Normal file
@ -0,0 +1,69 @@
|
||||
----takes 2 DBA's and returns the channel----------
|
||||
CREATE OR REPLACE FUNCTION rlarp.get_cust(billcode text, shipcode text)
|
||||
RETURNS jsonb
|
||||
LANGUAGE plpgsql AS
|
||||
$func$
|
||||
DECLARE
|
||||
_chan text;
|
||||
_bill_class text;
|
||||
_ship_class text;
|
||||
_bill_dba text;
|
||||
_ship_dba text;
|
||||
_cust text;
|
||||
_bill_curr text;
|
||||
_bill_rate numeric;
|
||||
_crec jsonb;
|
||||
_ret jsonb;
|
||||
_record jsonb;
|
||||
|
||||
BEGIN
|
||||
SELECT jsonb_agg(row_to_json(c)::jsonb) INTO _crec FROM rlarp.cust c WHERE code IN (billcode, shipcode);
|
||||
|
||||
--RAISE NOTICE '%', jsonb_pretty(_crec);
|
||||
|
||||
FOR _record IN SELECT * FROM jsonb_array_elements(_crec)
|
||||
LOOP
|
||||
-- Check if the record is for billcode or shipcode and assign values accordingly
|
||||
IF (_record->>'code')::text = billcode THEN
|
||||
_bill_dba := (_record->>'dba')::text;
|
||||
_bill_class := (_record->>'cclass')::text;
|
||||
_bill_curr := (_record->>'currency')::text;
|
||||
_bill_rate := (_record->>'fxcurr')::text;
|
||||
-- Add other billcode related assignments here
|
||||
END IF;
|
||||
|
||||
IF (_record->>'code')::text = shipcode THEN
|
||||
_ship_dba := (_record->>'dba')::text;
|
||||
_ship_class := (_record->>'cclass')::text;
|
||||
-- Add other shipcode related assignments here
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
SELECT
|
||||
CASE WHEN SUBSTRING(_bill_class,2,3) = 'DIS'
|
||||
THEN CASE WHEN SUBSTRING(_ship_class,2,3) = 'DIS' THEN 'WHS' ELSE 'DRP' END
|
||||
ELSE 'DIR'
|
||||
END
|
||||
INTO
|
||||
_chan;
|
||||
|
||||
SELECT
|
||||
CASE WHEN _chan = 'DRP' THEN _ship_dba ELSE _bill_dba END
|
||||
INTO
|
||||
_cust;
|
||||
|
||||
_ret := jsonb_build_object('customer',
|
||||
jsonb_build_object(
|
||||
'cust',_cust,
|
||||
'chan',_chan,
|
||||
'curr',_bill_curr,
|
||||
'fxrate',_bill_rate,
|
||||
'bill_dba',_bill_dba,
|
||||
'ship_dba',_ship_dba
|
||||
)
|
||||
);
|
||||
|
||||
RETURN _ret;
|
||||
|
||||
END
|
||||
$func$;
|
@ -120,39 +120,39 @@ BEGIN
|
||||
|
||||
----------------channel-------------------------------------
|
||||
|
||||
SELECT rlarp.channel_code(_bill, _ship) INTO _chan;
|
||||
_customer := jsonb_build_object('chan',_chan);
|
||||
SELECT rlarp.get_cust(_bill, _ship) INTO _customer;
|
||||
--_customer := jsonb_build_object('chan',_chan);
|
||||
|
||||
----------------customer------------------------------------
|
||||
SELECT dba INTO _cust FROM rlarp.cust WHERE code = CASE WHEN _chan = 'DRP' THEN _ship ELSE _bill END ;
|
||||
SELECT
|
||||
currency,
|
||||
(SELECT
|
||||
x.rate
|
||||
FROM
|
||||
rlarp.ffcret x
|
||||
WHERE
|
||||
x.perd = (select fspr from rlarp.gld where drange @> current_date)
|
||||
AND x.rtyp = 'MA'
|
||||
and x.fcur = currency
|
||||
AND x.tcur = 'US'
|
||||
)
|
||||
INTO
|
||||
_curr
|
||||
,_rate
|
||||
FROM
|
||||
rlarp.cust
|
||||
WHERE
|
||||
code = _bill;
|
||||
--SELECT dba INTO _cust FROM rlarp.cust WHERE code = CASE WHEN _chan = 'DRP' THEN _ship ELSE _bill END ;
|
||||
--SELECT
|
||||
-- currency,
|
||||
-- (SELECT
|
||||
-- x.rate
|
||||
-- FROM
|
||||
-- rlarp.ffcret x
|
||||
-- WHERE
|
||||
-- x.perd = (select fspr from rlarp.gld where drange @> current_date)
|
||||
-- AND x.rtyp = 'MA'
|
||||
-- and x.fcur = currency
|
||||
-- AND x.tcur = 'US'
|
||||
-- )
|
||||
--INTO
|
||||
-- _curr
|
||||
-- ,_rate
|
||||
--FROM
|
||||
-- rlarp.cust
|
||||
--WHERE
|
||||
-- code = _bill;
|
||||
|
||||
_customer := jsonb_build_object(
|
||||
'customer',
|
||||
_customer||jsonb_build_object(
|
||||
'cust',_cust
|
||||
,'curr',_curr
|
||||
,'fxrate',_rate
|
||||
)
|
||||
);
|
||||
--_customer := jsonb_build_object(
|
||||
-- 'customer',
|
||||
-- _customer||jsonb_build_object(
|
||||
-- 'cust',_cust
|
||||
-- ,'curr',_curr
|
||||
-- ,'fxrate',_rate
|
||||
-- )
|
||||
--);
|
||||
--RAISE NOTICE 'cust %', jsonb_pretty(_customer);
|
||||
|
||||
----------------price history-------------------------------
|
||||
|
@ -25,7 +25,7 @@ lq AS MATERIALIZED (
|
||||
,jsonb_pretty(pricing) pricing
|
||||
FROM
|
||||
lq
|
||||
JOIN LATERAL rlarp.guidance_r1(
|
||||
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
|
||||
|
Loading…
Reference in New Issue
Block a user