new last price schema
This commit is contained in:
parent
18b8883dde
commit
8b6df1c917
@ -1,12 +1,13 @@
|
|||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
-- Clear old data
|
-- Reset target tables
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
DROP TABLE IF EXISTS pricing.lastpricedetail;
|
--DROP TABLE IF EXISTS pricing.lastpricedetail;
|
||||||
DELETE FROM pricing.lastpricedetail;
|
DELETE FROM pricing.lastpricedetail;
|
||||||
DROP TABLE IF EXISTS #flagged;
|
DROP TABLE IF EXISTS #flagged;
|
||||||
|
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
-- Base cleaned input
|
-- Stage 1: Load cleaned input rows
|
||||||
|
-- Filters out irrelevant quotes/orders and calculates unit prices
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
WITH base AS (
|
WITH base AS (
|
||||||
SELECT
|
SELECT
|
||||||
@ -34,25 +35,33 @@ WITH base AS (
|
|||||||
AND o."Order Status" <> 'CANCELLED'
|
AND o."Order Status" <> 'CANCELLED'
|
||||||
AND o."Units" > 0
|
AND o."Units" > 0
|
||||||
AND o."Part Group" <> ''
|
AND o."Part Group" <> ''
|
||||||
|
-- Optional filter for testing
|
||||||
-- AND o."Customer" = 'ESBENSHADES GREENHOUSE'
|
-- AND o."Customer" = 'ESBENSHADES GREENHOUSE'
|
||||||
),
|
),
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
-- Rank rows for recency and volume
|
-- 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 (
|
ranked AS (
|
||||||
SELECT
|
SELECT
|
||||||
b.*
|
b.*
|
||||||
-- most recent sale
|
-- Most recent sale
|
||||||
,ROW_NUMBER() OVER (
|
,ROW_NUMBER() OVER (
|
||||||
PARTITION BY b.customer, b.partgroup
|
PARTITION BY b.customer, b.partgroup
|
||||||
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
|
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
|
||||||
) AS rn_mrs
|
) AS rn_mrs
|
||||||
-- most recent quote
|
-- Most recent quote
|
||||||
,ROW_NUMBER() OVER (
|
,ROW_NUMBER() OVER (
|
||||||
PARTITION BY b.customer, b.partgroup
|
PARTITION BY b.customer, b.partgroup
|
||||||
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
|
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
|
||||||
) AS rn_mrq
|
) AS rn_mrq
|
||||||
-- largest volume sale
|
-- Largest volume sale (last 12 months)
|
||||||
,ROW_NUMBER() OVER (
|
,ROW_NUMBER() OVER (
|
||||||
PARTITION BY b.customer, b.partgroup
|
PARTITION BY b.customer, b.partgroup
|
||||||
ORDER BY CASE
|
ORDER BY CASE
|
||||||
@ -60,7 +69,7 @@ ranked AS (
|
|||||||
THEN b.qty ELSE NULL
|
THEN b.qty ELSE NULL
|
||||||
END DESC
|
END DESC
|
||||||
) AS rn_lvs
|
) AS rn_lvs
|
||||||
-- largest volume quote
|
-- Largest volume quote (last 12 months)
|
||||||
,ROW_NUMBER() OVER (
|
,ROW_NUMBER() OVER (
|
||||||
PARTITION BY b.customer, b.partgroup
|
PARTITION BY b.customer, b.partgroup
|
||||||
ORDER BY CASE
|
ORDER BY CASE
|
||||||
@ -68,66 +77,63 @@ ranked AS (
|
|||||||
THEN b.qty ELSE NULL
|
THEN b.qty ELSE NULL
|
||||||
END DESC
|
END DESC
|
||||||
) AS rn_lvq
|
) AS rn_lvq
|
||||||
-- most recent sale for data segment
|
-- Most recent sale per data segment
|
||||||
,ROW_NUMBER() OVER (
|
,ROW_NUMBER() OVER (
|
||||||
PARTITION BY b.customer, b.partgroup, b.dataseg, b.version
|
PARTITION BY b.customer, b.partgroup, b.dataseg, b.version
|
||||||
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
|
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
|
||||||
) AS rn_dss
|
) AS rn_dss
|
||||||
-- most recent quote for data segment
|
-- Most recent quote per data segment
|
||||||
,ROW_NUMBER() OVER (
|
,ROW_NUMBER() OVER (
|
||||||
PARTITION BY b.customer, b.partgroup, b.dataseg, b.version
|
PARTITION BY b.customer, b.partgroup, b.dataseg, b.version
|
||||||
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
|
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
|
||||||
) AS rn_dsq
|
) AS rn_dsq
|
||||||
FROM base b
|
FROM base b
|
||||||
)
|
)
|
||||||
SELECT * INTO #flagged FROM ranked
|
--------------------------------------------------------------------------------
|
||||||
|
-- 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,
|
||||||
|
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
|
||||||
|
INTO #flagged
|
||||||
|
FROM ranked
|
||||||
WHERE
|
WHERE
|
||||||
1=1
|
|
||||||
-- AND partgroup = 'XNS0T1G3'
|
|
||||||
AND (
|
|
||||||
rn_mrs = 1
|
rn_mrs = 1
|
||||||
OR rn_mrq = 1
|
OR rn_mrq = 1
|
||||||
OR rn_lvs = 1
|
OR rn_lvs = 1
|
||||||
OR rn_lvq = 1
|
OR rn_lvq = 1
|
||||||
OR rn_dss = 1
|
OR rn_dss = 1
|
||||||
OR rn_dsq = 1
|
OR rn_dsq = 1;
|
||||||
)
|
|
||||||
|
|
||||||
CREATE NONCLUSTERED INDEX ix_flagged_lookup
|
CREATE NONCLUSTERED INDEX ix_flagged_lookup
|
||||||
ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten);
|
ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten);
|
||||||
|
|
||||||
--SELECT * FROM #flagged WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3'
|
|
||||||
|
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
-- Assumes you already have #flagged built from ranked rows
|
-- Stage 3: Build JSON from flagged rows
|
||||||
-- with columns: customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten,
|
|
||||||
-- and rank columns: rn_mrs, rn_mrq, rn_lvs, rn_lvq, rn_dss, rn_dsq
|
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
|
|
||||||
-- Step 1: Flatten flag-based records
|
-- Step 3.1: Explode all flags from the #flagged table
|
||||||
WITH exploded AS (
|
WITH exploded_flags 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
|
|
||||||
FROM #flagged
|
|
||||||
-- WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3'
|
|
||||||
)
|
|
||||||
,flags AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten,
|
customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten,
|
||||||
flag
|
flag
|
||||||
FROM exploded
|
FROM #flagged
|
||||||
CROSS APPLY (VALUES (f1), (f2), (f3), (f4)) AS f(flag)
|
CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag)
|
||||||
WHERE flag IS NOT NULL
|
WHERE flag IS NOT NULL
|
||||||
)
|
)
|
||||||
--SELECT * FROM flags
|
--SELECT * FROM exploded_flags
|
||||||
-- Step 2: JSON object for each flag (mrs/mrq/lvs/lvq)
|
-- Step 3.2: Serialize each row into its JSON snippet
|
||||||
,serialized_flags AS (
|
,serialized_flags AS (
|
||||||
SELECT
|
SELECT
|
||||||
customer,
|
customer,
|
||||||
partgroup,
|
partgroup,
|
||||||
|
dataseg,
|
||||||
flag,
|
flag,
|
||||||
CONCAT(
|
CONCAT(
|
||||||
'"', flag, '":',
|
'"', flag, '":',
|
||||||
@ -145,65 +151,58 @@ WITH exploded AS (
|
|||||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||||
))
|
))
|
||||||
) AS json_piece
|
) AS json_piece
|
||||||
FROM flags
|
FROM exploded_flags
|
||||||
)
|
)
|
||||||
|
--SELECT * FROM serialized_flags
|
||||||
|
-- Step 3.3: Collect all global-level flags (mrs, mrq, lvs, lvq)
|
||||||
,flag_json AS (
|
,flag_json AS (
|
||||||
SELECT
|
SELECT
|
||||||
customer,
|
customer,
|
||||||
partgroup,
|
partgroup,
|
||||||
STRING_AGG(json_piece, ',') AS json_block
|
STRING_AGG(json_piece, ',') AS json_block
|
||||||
FROM serialized_flags
|
FROM serialized_flags
|
||||||
|
WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq')
|
||||||
GROUP BY customer, partgroup
|
GROUP BY customer, partgroup
|
||||||
)
|
)
|
||||||
--SELECT * FROM flag_json
|
--SELECT * FROM flag_json
|
||||||
-- Step 3: One row per (customer, partgroup, dataseg) — most recent
|
-- Step 3.4: Nest dss/dsq under each dataseg
|
||||||
,seg_rows AS (
|
,seg_pieces AS (
|
||||||
SELECT *
|
|
||||||
FROM (
|
|
||||||
SELECT *,
|
|
||||||
ROW_NUMBER() OVER (
|
|
||||||
PARTITION BY customer, partgroup, dataseg
|
|
||||||
ORDER BY odate DESC
|
|
||||||
) AS rk
|
|
||||||
FROM #flagged
|
|
||||||
-- WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3'
|
|
||||||
) x
|
|
||||||
WHERE rk = 1
|
|
||||||
)
|
|
||||||
--SELECT * FROM seg_rows
|
|
||||||
-- Step 4: JSON object for each dataseg
|
|
||||||
, serialized_segs AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
customer,
|
customer,
|
||||||
partgroup,
|
partgroup,
|
||||||
dataseg,
|
dataseg,
|
||||||
CONCAT(
|
STRING_AGG(json_piece, ',') AS inner_json
|
||||||
'"', dataseg, '":',
|
FROM serialized_flags
|
||||||
JSON_QUERY((
|
WHERE flag IN ('dss', 'dsq')
|
||||||
|
GROUP BY customer, partgroup, dataseg
|
||||||
|
)
|
||||||
|
--SELECT * FROM seg_pieces
|
||||||
|
-- Step 3.5: Wrap the inner_json under dataseg key
|
||||||
|
,wrapped_segs AS (
|
||||||
SELECT
|
SELECT
|
||||||
version,
|
customer,
|
||||||
dataseg AS datasegment,
|
partgroup,
|
||||||
part,
|
CONCAT(
|
||||||
qty,
|
'"', dataseg, '": {', inner_json, '}'
|
||||||
price,
|
|
||||||
odate,
|
|
||||||
ordnum,
|
|
||||||
quoten
|
|
||||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
|
||||||
))
|
|
||||||
) AS json_piece
|
) AS json_piece
|
||||||
FROM seg_rows
|
FROM seg_pieces
|
||||||
),
|
)
|
||||||
seg_json AS (
|
-- Step 3.6: Aggregate all dataseg entries into one JSON block per customer/partgroup
|
||||||
|
,seg_json AS (
|
||||||
SELECT
|
SELECT
|
||||||
customer,
|
customer,
|
||||||
partgroup,
|
partgroup,
|
||||||
STRING_AGG(json_piece, ',') AS json_block
|
STRING_AGG(json_piece, ',') AS json_block
|
||||||
FROM serialized_segs
|
FROM wrapped_segs
|
||||||
GROUP BY customer, partgroup
|
GROUP BY customer, partgroup
|
||||||
)
|
)
|
||||||
--SELECT * FROM seg_json
|
--SELECT * FROM seg_json
|
||||||
-- Step 5: Merge into final JSON per (customer, partgroup)
|
--------------------------------------------------------------------------------
|
||||||
|
-- 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.customer, s.customer) AS customer,
|
||||||
COALESCE(f.partgroup, s.partgroup) AS partgroup,
|
COALESCE(f.partgroup, s.partgroup) AS partgroup,
|
||||||
@ -217,11 +216,6 @@ SELECT
|
|||||||
COALESCE(s.json_block, ''),
|
COALESCE(s.json_block, ''),
|
||||||
'}'
|
'}'
|
||||||
) AS part_stats
|
) AS part_stats
|
||||||
INTO #final_json
|
|
||||||
FROM flag_json f
|
FROM flag_json f
|
||||||
FULL OUTER JOIN seg_json s
|
FULL OUTER JOIN seg_json s
|
||||||
ON f.customer = s.customer AND f.partgroup = s.partgroup;
|
ON f.customer = s.customer AND f.partgroup = s.partgroup;
|
||||||
-- Final output
|
|
||||||
|
|
||||||
SELECT * FROM #FINAL_JSON WHERE customer = 'GRIFFIN' AND partgroup = 'XNS0T1G3'
|
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user