work on syncing up logic
This commit is contained in:
parent
b934bdda56
commit
4b1f6a3136
@ -1,9 +1,8 @@
|
||||
SELECT * FROM
|
||||
SELECT jsonb_pretty(expl) FROM
|
||||
pricequote.single_price_call(
|
||||
'CYGR0002' ,
|
||||
'CYGR0002' ,
|
||||
'SVP03002G18C800' ,
|
||||
'SVP03000',
|
||||
'GRIF0001' ,
|
||||
'GRIF0001' ,
|
||||
'XNS0T1G3G18B096' ,
|
||||
'v1:B..PLT..',
|
||||
100000
|
||||
)
|
||||
|
@ -1,10 +1,9 @@
|
||||
DROP FUNCTION IF EXISTS pricequote.single_price_call;
|
||||
DROP FUNCTION IF EXISTS pricequote.single_price_call() CASCADE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
|
||||
_bill TEXT,
|
||||
_ship TEXT,
|
||||
_part TEXT,
|
||||
_stlc TEXT,
|
||||
_v1ds TEXT,
|
||||
_vol NUMERIC
|
||||
)
|
||||
@ -20,15 +19,24 @@ RETURNS TABLE (
|
||||
tier TEXT,
|
||||
pltq NUMERIC,
|
||||
plevel TEXT,
|
||||
-- hist JSONB,
|
||||
partgroup TEXT,
|
||||
-- history JSONB,
|
||||
last_price NUMERIC,
|
||||
last_qty NUMERIC,
|
||||
last_dataseg TEXT,
|
||||
last_date DATE,
|
||||
last_order TEXT,
|
||||
last_quote TEXT,
|
||||
last_source TEXT,
|
||||
tprice NUMERIC,
|
||||
tmath JSONB,
|
||||
volume_range TEXT,
|
||||
listprice NUMERIC,
|
||||
listcode TEXT,
|
||||
guidance_price NUMERIC,
|
||||
guidance_reason TEXT,
|
||||
expl JSONB
|
||||
expl JSONB,
|
||||
ui_json JSONB
|
||||
) AS $$
|
||||
DECLARE
|
||||
_pltq NUMERIC;
|
||||
@ -36,78 +44,78 @@ DECLARE
|
||||
_tier TEXT;
|
||||
_cust TEXT;
|
||||
_plevel TEXT;
|
||||
_partgroup TEXT;
|
||||
_stlc TEXT;
|
||||
_tprice NUMERIC;
|
||||
_tmath JSONB;
|
||||
_volume_range TEXT;
|
||||
_list_price NUMERIC;
|
||||
_list_code TEXT;
|
||||
_guidance_price NUMERIC;
|
||||
_guidance_reason TEXT;
|
||||
_hist JSONB := '{}'::jsonb;
|
||||
-- Last sale/quote/volume/segment fields
|
||||
mrs JSONB; mrq JSONB; lvs JSONB; lvq JSONB;
|
||||
dss JSONB; dsq JSONB;
|
||||
-- Precedence chain
|
||||
_last_price NUMERIC;
|
||||
_last_qty NUMERIC;
|
||||
_last_dataseg TEXT;
|
||||
_last_date DATE;
|
||||
_last_order TEXT;
|
||||
_last_quote TEXT;
|
||||
_list_price NUMERIC;
|
||||
_list_code TEXT;
|
||||
_hist JSONB := '{}'::jsonb;
|
||||
_last_source TEXT;
|
||||
_expl JSONB := '{}'::jsonb;
|
||||
_this JSONB := '{}'::jsonb;
|
||||
_guidance_price NUMERIC;
|
||||
_guidance_reason TEXT;
|
||||
_partgroup TEXT;
|
||||
_ui_json JSONB := '{}'::jsonb;
|
||||
BEGIN
|
||||
------------------------------------------------------------------
|
||||
-- Step 1: Resolve customer metadata
|
||||
------------------------------------------------------------------
|
||||
SELECT
|
||||
i.mpck,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN 'WHS'
|
||||
ELSE 'DRP'
|
||||
END
|
||||
ELSE 'DIR'
|
||||
END,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE COALESCE(sc.tier, bc.tier)
|
||||
END,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN bc.dba
|
||||
ELSE sc.dba
|
||||
END
|
||||
ELSE bc.dba
|
||||
END,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN sc.plevel
|
||||
ELSE bc.plevel
|
||||
END
|
||||
ELSE bc.plevel
|
||||
END,
|
||||
i.partgroup
|
||||
INTO _pltq, _chan, _tier, _cust, _plevel, _partgroup
|
||||
FROM rlarp.cust bc
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = _ship
|
||||
LEFT JOIN "CMS.CUSLG".itemm i ON i.item = _part
|
||||
WHERE bc.code = _bill;
|
||||
|
||||
-- RAISE NOTICE 'Step 1: %', _expl;
|
||||
SELECT
|
||||
i.mpck,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN 'WHS'
|
||||
ELSE 'DRP'
|
||||
END
|
||||
ELSE 'DIR'
|
||||
END,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE COALESCE(sc.tier, bc.tier)
|
||||
END,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN bc.dba
|
||||
ELSE sc.dba
|
||||
END
|
||||
ELSE bc.dba
|
||||
END,
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN sc.plevel
|
||||
ELSE bc.plevel
|
||||
END
|
||||
ELSE bc.plevel
|
||||
END,
|
||||
i.partgroup,
|
||||
substring(_part,1,8)
|
||||
INTO _pltq, _chan, _tier, _cust, _plevel, _partgroup, _stlc
|
||||
FROM rlarp.cust bc
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = _ship
|
||||
LEFT JOIN "CMS.CUSLG".itemm i ON i.item = _part
|
||||
WHERE bc.code = _bill;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 2: Target price logic
|
||||
------------------------------------------------------------------
|
||||
SELECT tp.price,
|
||||
jsonb_build_object(
|
||||
'source', 'target price',
|
||||
'target_price', tp.price,
|
||||
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),
|
||||
'exact_pallets', ROUND(_vol / NULLIF(_pltq, 0), 5),
|
||||
'volume range', tp.vol::TEXT,
|
||||
'customer', _cust,
|
||||
'channel', _chan,
|
||||
'tier', TRIM(_tier),
|
||||
'target math', tp.math
|
||||
)
|
||||
INTO _tprice, _this
|
||||
tp.math,
|
||||
tp.vol::text
|
||||
INTO _tprice, _tmath, _volume_range
|
||||
FROM pricequote.target_prices tp
|
||||
WHERE tp.stlc = _stlc
|
||||
AND tp.ds = _v1ds
|
||||
@ -115,82 +123,170 @@ BEGIN
|
||||
AND tp.tier = _tier
|
||||
AND FLOOR(_vol / NULLIF(_pltq, 0))::int <@ tp.vol;
|
||||
|
||||
IF _this IS NOT NULL THEN
|
||||
_expl := _expl || _this;
|
||||
END IF;
|
||||
|
||||
-- RAISE NOTICE 'Step 2: %', _expl;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 3: Last sale data
|
||||
-- Step 3: Last sale/quote/volume/segment data
|
||||
------------------------------------------------------------------
|
||||
SELECT
|
||||
(lp.dataseg_stats -> _v1ds) ->> 'price',
|
||||
(lp.dataseg_stats -> _v1ds) ->> 'odate',
|
||||
(lp.dataseg_stats -> _v1ds) ->> 'ordnum',
|
||||
(lp.dataseg_stats -> _v1ds) ->> 'quoten',
|
||||
lp.dataseg_stats
|
||||
lp.part_stats
|
||||
INTO
|
||||
_last_price, _last_date, _last_order, _last_quote, _hist
|
||||
FROM pricequote.lastprice lp
|
||||
_hist
|
||||
FROM pricequote.lastpricedetail lp
|
||||
WHERE lp.customer = _cust
|
||||
AND lp.partgroup = _partgroup;
|
||||
|
||||
_expl := _expl || jsonb_build_object(
|
||||
'last_price', _last_price,
|
||||
'last_date', _last_date,
|
||||
'last_order', _last_order,
|
||||
'last_quote', _last_quote
|
||||
-- 'full_history_________', _hist
|
||||
);
|
||||
-- Extract top-level keys
|
||||
mrs := _hist -> 'mrs';
|
||||
mrq := _hist -> 'mrq';
|
||||
lvs := _hist -> 'lvs';
|
||||
lvq := _hist -> 'lvq';
|
||||
|
||||
-- RAISE NOTICE 'Step 3: %', _expl;
|
||||
-- Extract per-datasegment block matching the input v1ds
|
||||
dss := (_hist -> _v1ds) -> 'dss';
|
||||
dsq := (_hist -> _v1ds) -> 'dsq';
|
||||
|
||||
-- Precedence chain for last_price, etc.
|
||||
_last_price := COALESCE(
|
||||
(dsq->>'price')::numeric,
|
||||
(dss->>'price')::numeric,
|
||||
(mrq->>'price')::numeric,
|
||||
(mrs->>'price')::numeric
|
||||
);
|
||||
_last_qty := COALESCE(
|
||||
(dsq->>'qty')::numeric,
|
||||
(dss->>'qty')::numeric,
|
||||
(mrq->>'qty')::numeric,
|
||||
(mrs->>'qty')::numeric
|
||||
);
|
||||
_last_dataseg := COALESCE(
|
||||
dsq->>'datasegment',
|
||||
dss->>'datasegment',
|
||||
mrq->>'datasegment',
|
||||
mrs->>'datasegment'
|
||||
);
|
||||
_last_date := COALESCE(
|
||||
(dsq->>'odate')::date,
|
||||
(dss->>'odate')::date,
|
||||
(mrq->>'odate')::date,
|
||||
(mrs->>'odate')::date
|
||||
);
|
||||
_last_order := COALESCE(
|
||||
dsq->>'ordnum',
|
||||
dss->>'ordnum',
|
||||
mrq->>'ordnum',
|
||||
mrs->>'ordnum'
|
||||
);
|
||||
_last_quote := COALESCE(
|
||||
dsq->>'quoten',
|
||||
dss->>'quoten',
|
||||
mrq->>'quoten',
|
||||
mrs->>'quoten'
|
||||
);
|
||||
_last_source := CASE
|
||||
WHEN dsq->>'price' IS NOT NULL THEN 'dsq'
|
||||
WHEN dss->>'price' IS NOT NULL THEN 'dss'
|
||||
WHEN mrq->>'price' IS NOT NULL THEN 'mrq'
|
||||
WHEN mrs->>'price' IS NOT NULL THEN 'mrs'
|
||||
ELSE NULL
|
||||
END;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 4: List price
|
||||
------------------------------------------------------------------
|
||||
SELECT
|
||||
pr.price::numeric(20,5), pr.jcplcd
|
||||
pr.price::numeric(20,5), pr.jcplcd
|
||||
INTO
|
||||
_list_price, _list_code
|
||||
_list_price, _list_code
|
||||
FROM
|
||||
"CMS.CUSLG".IPRCBHC i
|
||||
JOIN pricequote.pricelist_ranged pr
|
||||
ON pr.jcplcd = TRIM(i.jbplcd)
|
||||
AND pr.jcpart = _part
|
||||
AND _vol >= pr.vb_from
|
||||
AND _vol < pr.vb_to
|
||||
"CMS.CUSLG".IPRCBHC i
|
||||
JOIN pricequote.pricelist_ranged pr
|
||||
ON pr.jcplcd = TRIM(i.jbplcd)
|
||||
AND pr.jcpart = _part
|
||||
AND _vol >= pr.vb_from
|
||||
AND (_vol < pr.vb_to OR pr.vb_to IS NULL)
|
||||
WHERE TRIM(i.jbplvl) = TRIM(_plevel)
|
||||
AND CURRENT_DATE BETWEEN i.jbfdat AND i.jbtdat
|
||||
ORDER BY pr.price ASC
|
||||
LIMIT 1;
|
||||
|
||||
_expl := _expl || jsonb_build_object(
|
||||
'list_price', _list_price,
|
||||
'list_code', _list_code
|
||||
);
|
||||
|
||||
-- RAISE NOTICE 'Step 4: %', _expl;
|
||||
------------------------------------------------------------------
|
||||
-- Step 5: Compute guidance price and embed it
|
||||
------------------------------------------------------------------
|
||||
SELECT
|
||||
gl.guidance_price, gl.guidance_reason
|
||||
INTO
|
||||
_guidance_price, _guidance_reason
|
||||
FROM
|
||||
pricequote.guidance_logic(_tprice, _last_price, _list_price, _last_date) gl;
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Step 5: Compute guidance price and embed it
|
||||
------------------------------------------------------------------
|
||||
|
||||
|
||||
SELECT
|
||||
gl.guidance_price, gl.guidance_reason
|
||||
INTO
|
||||
_guidance_price, _guidance_reason
|
||||
FROM
|
||||
pricequote.guidance_logic(_tprice, _last_price, _list_price, _last_date) gl;
|
||||
|
||||
_expl := _expl || jsonb_build_object(
|
||||
-- Step 6: Build explanation JSON
|
||||
------------------------------------------------------------------
|
||||
_expl := jsonb_build_object(
|
||||
'last_price', _last_price,
|
||||
'last_qty', _last_qty,
|
||||
'last_dataseg', _last_dataseg,
|
||||
'last_source', _last_source,
|
||||
'last_date', _last_date,
|
||||
'target_price', _tprice,
|
||||
'target_math', _tmath,
|
||||
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),
|
||||
'exact_pallets', ROUND(_vol / NULLIF(_pltq, 0), 5),
|
||||
'customer', _cust,
|
||||
'channel', _chan,
|
||||
'tier', TRIM(_tier),
|
||||
'list_price', _list_price,
|
||||
'list_code', _list_code,
|
||||
'guidance_price', _guidance_price,
|
||||
'guidance_reason', _guidance_reason
|
||||
);
|
||||
|
||||
|
||||
-- RAISE NOTICE 'Step 5: %', _expl;
|
||||
------------------------------------------------------------------
|
||||
-- Step 7: Build UI JSON (optional, similar to MSSQL)
|
||||
------------------------------------------------------------------
|
||||
_ui_json := jsonb_build_object(
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'History',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', CASE WHEN _last_price IS NOT NULL THEN 'Last Sale: ' || _last_date ELSE 'No Recent' END,
|
||||
'value', COALESCE(_last_price,0),
|
||||
'type', 'currency',
|
||||
'note', CASE WHEN _last_price IS NOT NULL THEN _last_source ||
|
||||
CASE WHEN COALESCE(_last_order, '0') = '0' THEN ' Qt# ' || COALESCE(_last_quote, '') ELSE ' Ord# ' || COALESCE(_last_order, '') END
|
||||
ELSE NULL END
|
||||
)
|
||||
)
|
||||
),
|
||||
jsonb_build_object(
|
||||
'label', 'List',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'List:' || COALESCE(_list_code, ''),
|
||||
'value', _list_price,
|
||||
'type', 'currency',
|
||||
'note', _plevel
|
||||
)
|
||||
)
|
||||
),
|
||||
jsonb_build_object(
|
||||
'label', 'Target Support',
|
||||
'details', _tmath -- You may need to transform this to match the MSSQL panel
|
||||
),
|
||||
jsonb_build_object(
|
||||
'label', 'Guidance',
|
||||
'details', jsonb_build_array(
|
||||
jsonb_build_object(
|
||||
'label', 'Price',
|
||||
'value', _guidance_price,
|
||||
'type', 'currency',
|
||||
'note', _guidance_reason
|
||||
)
|
||||
)
|
||||
)
|
||||
),
|
||||
'data', _expl
|
||||
);
|
||||
|
||||
------------------------------------------------------------------
|
||||
-- Final: Return row
|
||||
@ -198,12 +294,12 @@ BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
_bill, _ship, _part, _stlc, _v1ds, _vol,
|
||||
_chan, _cust, _tier, _pltq, _plevel,
|
||||
_chan, _cust, _tier, _pltq, _plevel, _partgroup,
|
||||
-- _hist,
|
||||
_last_price, _last_date, _last_order, _last_quote,
|
||||
_tprice,
|
||||
_guidance_price,
|
||||
_guidance_reason,
|
||||
_expl;
|
||||
_last_price, _last_qty, _last_dataseg, _last_date, _last_order, _last_quote, _last_source,
|
||||
_tprice, _tmath, _volume_range,
|
||||
_list_price, _list_code,
|
||||
_guidance_price, _guidance_reason,
|
||||
_expl, _ui_json;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
124
new_targets/tables/lastpricedetail.pg.sql
Normal file
124
new_targets/tables/lastpricedetail.pg.sql
Normal file
@ -0,0 +1,124 @@
|
||||
CREATE TABLE pricequote.lastpricedetail AS
|
||||
WITH base AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
dataseg,
|
||||
version,
|
||||
qtyord AS qty,
|
||||
ROUND(sales_usd/qty,5) AS price,
|
||||
odate,
|
||||
ordnum,
|
||||
quoten
|
||||
FROM rlarp.osm_stack
|
||||
WHERE
|
||||
version IN ('Actual','Quotes')
|
||||
AND customer IS NOT NULL
|
||||
AND fs_line = '41010'
|
||||
AND calc_status <> 'CANCELLED'
|
||||
AND qty <> 0
|
||||
AND partgroup <> ''
|
||||
AND version IN ('Actual', 'Quotes')
|
||||
),
|
||||
ranked AS (
|
||||
SELECT *,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC
|
||||
) AS rn_mrs,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC
|
||||
) AS rn_mrq,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Actual' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC
|
||||
) AS rn_lvs,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup
|
||||
ORDER BY CASE WHEN version = 'Quotes' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC
|
||||
) AS rn_lvq,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup, dataseg, version
|
||||
ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC
|
||||
) AS rn_dss,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY customer, partgroup, dataseg, version
|
||||
ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC
|
||||
) AS rn_dsq
|
||||
FROM base
|
||||
),
|
||||
flagged AS (
|
||||
SELECT *,
|
||||
CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1,
|
||||
CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2,
|
||||
CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3,
|
||||
CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4,
|
||||
CASE WHEN rn_dss = 1 THEN 'dss' END AS f5,
|
||||
CASE WHEN rn_dsq = 1 THEN 'dsq' END AS f6
|
||||
FROM ranked
|
||||
WHERE
|
||||
rn_mrs = 1 OR rn_mrq = 1 OR rn_lvs = 1 OR rn_lvq = 1 OR rn_dss = 1 OR rn_dsq = 1
|
||||
),
|
||||
exploded_flags AS (
|
||||
SELECT
|
||||
customer, partgroup, dataseg, version, qty, price, odate, ordnum, quoten,
|
||||
unnest(ARRAY[f1, f2, f3, f4, f5, f6]) AS flag
|
||||
FROM flagged
|
||||
),
|
||||
serialized_flags AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
dataseg,
|
||||
flag,
|
||||
jsonb_build_object(
|
||||
'version', version,
|
||||
'datasegment', dataseg,
|
||||
'qty', qty,
|
||||
'price', price,
|
||||
'odate', odate,
|
||||
'ordnum', ordnum,
|
||||
'quoten', quoten,
|
||||
'flag', flag
|
||||
) AS json_piece
|
||||
FROM exploded_flags
|
||||
WHERE flag IS NOT NULL
|
||||
),
|
||||
flag_json AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
jsonb_object_agg(flag, json_piece) AS global_flags
|
||||
FROM serialized_flags
|
||||
WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq')
|
||||
GROUP BY customer, partgroup
|
||||
),
|
||||
seg_pieces AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
dataseg,
|
||||
jsonb_object_agg(flag, json_piece) AS seg_flags
|
||||
FROM serialized_flags
|
||||
WHERE flag IN ('dss', 'dsq')
|
||||
GROUP BY customer, partgroup, dataseg
|
||||
),
|
||||
seg_json AS (
|
||||
SELECT
|
||||
customer,
|
||||
partgroup,
|
||||
jsonb_object_agg(dataseg, seg_flags) AS dataseg_block
|
||||
FROM seg_pieces
|
||||
GROUP BY customer, partgroup
|
||||
)
|
||||
SELECT
|
||||
COALESCE(f.customer, s.customer) AS customer,
|
||||
COALESCE(f.partgroup, s.partgroup) AS partgroup,
|
||||
(COALESCE(f.global_flags, '{}'::jsonb) || COALESCE(s.dataseg_block, '{}'::jsonb)) AS part_stats
|
||||
FROM flag_json f
|
||||
FULL OUTER JOIN seg_json s
|
||||
ON f.customer = s.customer AND f.partgroup = s.partgroup
|
||||
WITH DATA;
|
||||
|
||||
--SELECT * FROM pricequote.lastpricedetail;
|
Loading…
Reference in New Issue
Block a user