Compare commits

..

2 Commits

4 changed files with 571 additions and 470 deletions

View File

@ -6,18 +6,18 @@ BEGIN
BEGIN TRY
BEGIN TRAN; -- start transaction
--------------------------------------------------------------------------------
-- Reset target tables
--------------------------------------------------------------------------------
--DROP TABLE IF EXISTS pricing.lastpricedetail;
DELETE FROM pricing.lastpricedetail;
DROP TABLE IF EXISTS #flagged;
--------------------------------------------------------------------------------
-- Reset target tables
--------------------------------------------------------------------------------
--DROP TABLE IF EXISTS pricing.lastpricedetail;
DELETE FROM pricing.lastpricedetail;
DROP TABLE IF EXISTS #flagged;
--------------------------------------------------------------------------------
-- Stage 1: Load cleaned input rows
-- Filters out irrelevant quotes/orders and calculates unit prices
--------------------------------------------------------------------------------
WITH base AS (
--------------------------------------------------------------------------------
-- Stage 1: Load cleaned input rows
-- Filters out irrelevant quotes/orders and calculates unit prices
--------------------------------------------------------------------------------
WITH base AS (
SELECT
o."Customer" AS customer,
o."Part Group" AS partgroup,
@ -45,18 +45,18 @@ WITH base AS (
AND o."Part Group" <> ''
-- Optional filter for testing
-- AND o."Customer" = 'ESBENSHADES GREENHOUSE'
),
--------------------------------------------------------------------------------
-- Stage 2: Rank each row based on recency and volume rules
-- Flags include:
-- - rn_mrs: most recent sale
-- - rn_mrq: most recent quote
-- - rn_lvs: largest sale in last year
-- - rn_lvq: largest quote in last year
-- - rn_dss: most recent sale per dataseg
-- - rn_dsq: most recent quote per dataseg
--------------------------------------------------------------------------------
ranked AS (
),
--------------------------------------------------------------------------------
-- Stage 2: Rank each row based on recency and volume rules
-- Flags include:
-- - rn_mrs: most recent sale
-- - rn_mrq: most recent quote
-- - rn_lvs: largest sale in last year
-- - rn_lvq: largest quote in last year
-- - rn_dss: most recent sale per dataseg
-- - rn_dsq: most recent quote per dataseg
--------------------------------------------------------------------------------
ranked AS (
SELECT
b.*
-- Most recent sale (Actuals only)
@ -104,12 +104,12 @@ ranked AS (
)
END AS rn_dsq
FROM base b
)
--------------------------------------------------------------------------------
-- Stage 2.5: Save only rows that meet any of the above criteria
-- and annotate each with global-level flag (mrs, mrq, lvs, lvq)
--------------------------------------------------------------------------------
SELECT
)
--------------------------------------------------------------------------------
-- Stage 2.5: Save only rows that meet any of the above criteria
-- and annotate each with global-level flag (mrs, mrq, lvs, lvq)
--------------------------------------------------------------------------------
SELECT
*,
CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1,
CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2,
@ -117,9 +117,9 @@ SELECT
CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4,
CASE WHEN rn_dss = 1 AND version = 'Actual' THEN 'dss' END AS f5,
CASE WHEN rn_dsq = 1 AND version = 'Quotes' THEN 'dsq' END AS f6
INTO #flagged
FROM ranked
WHERE
INTO #flagged
FROM ranked
WHERE
rn_mrs = 1
OR rn_mrq = 1
OR rn_lvs = 1
@ -127,26 +127,26 @@ WHERE
OR (rn_dss = 1 AND version = 'Actual')
OR (rn_dsq = 1 AND version = 'Quotes');
CREATE NONCLUSTERED INDEX ix_flagged_lookup
ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten);
CREATE NONCLUSTERED INDEX ix_flagged_lookup
ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten);
--------------------------------------------------------------------------------
-- Stage 3: Build JSON from flagged rows
--------------------------------------------------------------------------------
--------------------------------------------------------------------------------
-- Stage 3: Build JSON from flagged rows
--------------------------------------------------------------------------------
-- Step 3.1: Explode all flags from the #flagged table
WITH exploded_flags AS (
-- Step 3.1: Explode all flags from the #flagged table
WITH exploded_flags AS (
SELECT
customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten,
flag
FROM #flagged
CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag)
WHERE flag IS NOT NULL
)
--SELECT * FROM exploded_flags
-- Step 3.2: Serialize each row into its JSON snippet
-- Carry odate and version for deduplication in seg_pieces
,serialized_flags AS (
)
--SELECT * FROM exploded_flags
-- Step 3.2: Serialize each row into its JSON snippet
-- Carry odate and version for deduplication in seg_pieces
,serialized_flags AS (
SELECT
customer,
partgroup,
@ -171,10 +171,10 @@ WITH exploded_flags AS (
))
) AS json_piece
FROM exploded_flags
)
--SELECT * FROM serialized_flags
-- Step 3.3: Collect all global-level flags (mrs, mrq, lvs, lvq)
,flag_json AS (
)
--SELECT * FROM serialized_flags
-- Step 3.3: Collect all global-level flags (mrs, mrq, lvs, lvq)
,flag_json AS (
SELECT
customer,
partgroup,
@ -182,11 +182,11 @@ WITH exploded_flags AS (
FROM serialized_flags
WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq')
GROUP BY customer, partgroup
)
--SELECT * FROM flag_json
-- Step 3.4: Nest dss/dsq under each dataseg
-- Only keep the most recent dss/dsq per dataseg/version (prevents duplicate keys)
,seg_pieces AS (
)
--SELECT * FROM flag_json
-- Step 3.4: Nest dss/dsq under each dataseg
-- Only keep the most recent dss/dsq per dataseg/version (prevents duplicate keys)
,seg_pieces AS (
SELECT
customer,
partgroup,
@ -207,10 +207,10 @@ WITH exploded_flags AS (
WHERE sf.rn = 1
) deduped
GROUP BY customer, partgroup, dataseg
)
--SELECT * FROM seg_pieces
-- Step 3.5: Wrap the inner_json under dataseg key
,wrapped_segs AS (
)
--SELECT * FROM seg_pieces
-- Step 3.5: Wrap the inner_json under dataseg key
,wrapped_segs AS (
SELECT
customer,
partgroup,
@ -218,24 +218,24 @@ WITH exploded_flags AS (
'"', dataseg, '": {', inner_json, '}'
) AS json_piece
FROM seg_pieces
)
-- Step 3.6: Aggregate all dataseg entries into one JSON block per customer/partgroup
,seg_json AS (
)
-- Step 3.6: Aggregate all dataseg entries into one JSON block per customer/partgroup
,seg_json AS (
SELECT
customer,
partgroup,
STRING_AGG(json_piece, ',') AS json_block
FROM wrapped_segs
GROUP BY customer, partgroup
)
--SELECT * FROM seg_json
--------------------------------------------------------------------------------
-- Stage 4: Merge flags and segment blocks into a single JSON object
-- Write final pricing history to pricing.lastpricedetail
--------------------------------------------------------------------------------
INSERT INTO
)
--SELECT * FROM seg_json
--------------------------------------------------------------------------------
-- Stage 4: Merge flags and segment blocks into a single JSON object
-- Write final pricing history to pricing.lastpricedetail
--------------------------------------------------------------------------------
INSERT INTO
pricing.lastpricedetail
SELECT
SELECT
COALESCE(f.customer, s.customer) AS customer,
COALESCE(f.partgroup, s.partgroup) AS partgroup,
CONCAT(
@ -248,15 +248,15 @@ SELECT
COALESCE(s.json_block, ''),
'}'
) AS part_stats
FROM flag_json f
FULL OUTER JOIN seg_json s
FROM flag_json f
FULL OUTER JOIN seg_json s
ON f.customer = s.customer AND f.partgroup = s.partgroup;
--------------------------------------------------------------------------------
-- Commit if everything succeeded
--------------------------------------------------------------------------------
COMMIT TRAN;
END TRY
--------------------------------------------------------------------------------
-- Commit if everything succeeded
--------------------------------------------------------------------------------
COMMIT TRAN;
END TRY
BEGIN CATCH
-- Ensure transaction is rolled back
IF XACT_STATE() <> 0

View File

@ -2,10 +2,14 @@ CREATE OR ALTER PROCEDURE pricing.rebuild_pricelist
AS
BEGIN
SET NOCOUNT ON;
SET XACT_ABORT ON; -- auto-rollback on most errors
DROP TABLE pricing.pricelist_ranged;
BEGIN TRY
BEGIN TRAN;
CREATE TABLE pricing.pricelist_ranged (
DROP TABLE pricing.pricelist_ranged;
CREATE TABLE pricing.pricelist_ranged (
jcplcd varchar(5) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
jcpart varchar(20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
jcunit varchar(3) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
@ -14,36 +18,36 @@ CREATE TABLE pricing.pricelist_ranged (
vb_from float NULL,
vb_to float NULL,
price float NOT NULL
);
);
CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ;
CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ;
--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX
-----------------------------------------------------------traverse unit of measure graph-----------------------------------------------------------------------
--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX
-------------setup table to hold target conversions---------------------
--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX
-----------------------------------------------------------traverse unit of measure graph-----------------------------------------------------------------------
--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX
-------------setup table to hold target conversions---------------------
SELECT DISTINCT
SELECT DISTINCT
jcpart partn
,jcunit fu
,'PC' tu
,cast(null as numeric) factor
INTO
INTO
#anchor
FROM
FROM
cmsinterfacein.lgdat.iprcc
WHERE
WHERE
1=1;
--SELECT * FROM #anchor
--SELECT * FROM #anchor
-------pre-build punit stacked on itself with the columns flipped so you can go either direction per join---------
SELECT
-------pre-build punit stacked on itself with the columns flipped so you can go either direction per join---------
SELECT
*
INTO
INTO
#g
FROM
FROM
(
SELECT
IHPART IHPART,
@ -76,13 +80,13 @@ FROM
OR pu.ihpart = '&&GLOBAL'
) x ;
CREATE INDEX g_idx on #g(ihpart,ihunt1);
CREATE INDEX g_idx on #g(ihpart,ihunt1);
WITH
--------do the expansion on all paths until the target uom is matched----------------------------------------------
--(complains about types not matching between anchor and recursion, explicitly just casting everything)
uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, uom_list) AS
(
WITH
--------do the expansion on all paths until the target uom is matched----------------------------------------------
--(complains about types not matching between anchor and recursion, explicitly just casting everything)
uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, uom_list) AS
(
SELECT
cast(partn as varchar(20)) --partn
,cast(partn as varchar(20)) --partx
@ -125,27 +129,27 @@ uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, u
AND p.ihunt1 <> uom.mastt
--prevent recursion: newest joined UOM can't be in the history
AND charindex(p.ihunt2,uom.uom_list) = 0
)
--SELECT COUNT(*) FROM UOM
--------------uom is going to have multiple rows per requested conversion, need to use row_number to pick the best row------------------------------
,sorted AS (
SELECT
)
--SELECT COUNT(*) FROM UOM
--------------uom is going to have multiple rows per requested conversion, need to use row_number to pick the best row------------------------------
,sorted AS (
SELECT
partn, mastf from_uom, xt to_uom, xfactor factor, lvl steps, row_number() OVER (PARTITION BY partn, mastf, mastt ORDER BY lvl ASC, factor ASC) rn
FROM
FROM
uom
WHERE
WHERE
xt = mastt
)
SELECT * INTO #uom FROM sorted WHERE rn = 1;
--so far so good
)
SELECT * INTO #uom FROM sorted WHERE rn = 1;
--so far so good
drop table #anchor;
drop table #g;
drop table #anchor;
drop table #g;
TRUNCATE TABLE pricing.pricelist_ranged;
TRUNCATE TABLE pricing.pricelist_ranged;
WITH
conv AS (
WITH
conv AS (
SELECT
p.jcplcd,
p.jcpart,
@ -162,14 +166,14 @@ conv AS (
ON u.partn = p.jcpart
AND u.from_uom = p.jcunit
AND u.to_uom = 'PC'
),
sorted AS (
),
sorted AS (
SELECT
c.*,
ROW_NUMBER() OVER (PARTITION BY c.jcplcd, c.jcpart ORDER BY vol_pc ASC) AS rn
FROM conv c
),
ranged AS (
),
ranged AS (
SELECT
curr.jcplcd,
curr.jcpart,
@ -186,10 +190,10 @@ ranged AS (
ON curr.jcplcd = next.jcplcd
AND curr.jcpart = next.jcpart
AND curr.rn + 1 = next.rn
)
INSERT INTO
)
INSERT INTO
pricing.pricelist_ranged
SELECT
SELECT
RTRIM(jcplcd) jcplcd,
RTRIM(jcpart) jcpart,
jcunit,
@ -198,8 +202,25 @@ SELECT
vb_from,
vb_to,
price_pc AS price
FROM
FROM
ranged;
--CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to);
--CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to);
COMMIT TRAN;
END TRY
BEGIN CATCH
-- Ensure transaction is rolled back
IF XACT_STATE() <> 0
BEGIN
ROLLBACK TRAN;
END
IF OBJECT_ID('tempdb..#anchor') IS NOT NULL DROP TABLE #anchor;
IF OBJECT_ID('tempdb..#g') IS NOT NULL DROP TABLE #g;
IF OBJECT_ID('tempdb..#uom') IS NOT NULL DROP TABLE #uom;
-- Re-throw original error
THROW;
END CATCH;
END;

View File

@ -2,12 +2,16 @@ CREATE OR ALTER PROCEDURE pricing.rebuild_targets
AS
BEGIN
SET NOCOUNT ON;
SET XACT_ABORT ON; -- auto-rollback on most runtime errors
DELETE FROM pricing.target_prices;
BEGIN TRY
BEGIN TRAN;
INSERT INTO
DELETE FROM pricing.target_prices;
INSERT INTO
pricing.target_prices
SELECT
SELECT
stlc,
ds,
chan,
@ -22,7 +26,17 @@ SELECT
END AS upper_bound,
price,
math
FROM
FROM
usmidsap02.ubm.pricequote.target_prices_view;
END;
COMMIT TRAN;
END TRY
BEGIN CATCH
IF XACT_STATE() <> 0
ROLLBACK TRAN;
-- Rethrow original error
THROW;
END CATCH;
END

View File

@ -0,0 +1,66 @@
CREATE OR ALTER PROCEDURE pricing.sync_external
AS
BEGIN
SET NOCOUNT ON;
SET XACT_ABORT ON; -- causes runtime errors to auto-rollback
BEGIN TRY
BEGIN TRAN;
-- Refresh pricing.ffcret
TRUNCATE TABLE pricing.ffcret;
INSERT INTO pricing.ffcret
SELECT *
FROM fanalysis.rlarp.ffcret;
-- Refresh pricing.ffterr
TRUNCATE TABLE pricing.ffterr;
INSERT INTO pricing.ffterr
SELECT *
FROM fanalysis.rlarp.ffterr;
-- Refresh pricing.gld
TRUNCATE TABLE pricing.gld;
INSERT INTO pricing.gld
SELECT *
FROM fanalysis.rlarp.gld;
-- Refresh pricing.qrh
TRUNCATE TABLE pricing.qrh;
INSERT INTO pricing.qrh
SELECT *
FROM fanalysis.rlarp.qrh;
-- Refresh pricing.sach
TRUNCATE TABLE pricing.sach;
INSERT INTO pricing.sach
SELECT *
FROM fanalysis.lgdat.sach;
COMMIT TRAN;
-- rebuild last price
EXEC pricing.rebuild_lastprice;
-- rebuild ranged price list
EXEC pricing.rebuild_pricelist;
-- rebuild target prices
EXEC pricing.rebuild_targets;
END TRY
BEGIN CATCH
-- Rollback if any error
IF XACT_STATE() <> 0
ROLLBACK TRAN;
-- rethrow original error with context
DECLARE @ErrMsg NVARCHAR(4000) = ERROR_MESSAGE();
DECLARE @ErrSec NVARCHAR(200) = ERROR_SEVERITY();
DECLARE @ErrState INT = ERROR_STATE();
RAISERROR('refresh_pricing_tables failed: %s', 16, 1, @ErrMsg);
THROW; -- rethrow original error for callers to handle
END CATCH;
END