create an output json that will be easier to work with from a UI standpoint
This commit is contained in:
parent
a1e623b06a
commit
f91e889857
@ -20,7 +20,10 @@ BEGIN
|
|||||||
cust VARCHAR(100),
|
cust VARCHAR(100),
|
||||||
tier VARCHAR(50),
|
tier VARCHAR(50),
|
||||||
pltq NUMERIC(18,6),
|
pltq NUMERIC(18,6),
|
||||||
|
volume_range TEXT,
|
||||||
plevel NVARCHAR(20),
|
plevel NVARCHAR(20),
|
||||||
|
listprice NUMERIC(20,5),
|
||||||
|
listcode VARCHAR(10),
|
||||||
hist NVARCHAR(MAX),
|
hist NVARCHAR(MAX),
|
||||||
last_price NUMERIC(20,5),
|
last_price NUMERIC(20,5),
|
||||||
last_date DATE,
|
last_date DATE,
|
||||||
@ -29,7 +32,8 @@ BEGIN
|
|||||||
tprice NUMERIC(20,5),
|
tprice NUMERIC(20,5),
|
||||||
guidance_price NUMERIC(20,5),
|
guidance_price NUMERIC(20,5),
|
||||||
guidance_reason NVARCHAR(MAX),
|
guidance_reason NVARCHAR(MAX),
|
||||||
expl NVARCHAR(MAX)
|
expl NVARCHAR(MAX),
|
||||||
|
expl_pretty NVARCHAR(MAX)
|
||||||
);
|
);
|
||||||
|
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
@ -94,13 +98,14 @@ BEGIN
|
|||||||
tp.price AS [target_price],
|
tp.price AS [target_price],
|
||||||
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
||||||
CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,5)) AS [exact_pallets],
|
CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,5)) AS [exact_pallets],
|
||||||
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '∞')) AS [volume range],
|
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '∞')) AS [volume_range],
|
||||||
q.cust AS [customer],
|
q.cust AS [customer],
|
||||||
q.chan AS [channel],
|
q.chan AS [channel],
|
||||||
TRIM(q.tier) AS [tier],
|
TRIM(q.tier) AS [tier],
|
||||||
JSON_QUERY(tp.math) AS [target math]
|
JSON_QUERY(tp.math) AS [target_math]
|
||||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||||
)
|
),
|
||||||
|
volume_range = CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '∞'))
|
||||||
FROM @queue q
|
FROM @queue q
|
||||||
INNER JOIN pricing.target_prices tp ON
|
INNER JOIN pricing.target_prices tp ON
|
||||||
q.stlc = tp.stlc
|
q.stlc = tp.stlc
|
||||||
@ -184,6 +189,8 @@ BEGIN
|
|||||||
),
|
),
|
||||||
'$.list_code', rp.jcplcd
|
'$.list_code', rp.jcplcd
|
||||||
)
|
)
|
||||||
|
,listcode = rp.jcplcd
|
||||||
|
,listprice = rp.price
|
||||||
FROM @queue q
|
FROM @queue q
|
||||||
JOIN ranked_prices rp
|
JOIN ranked_prices rp
|
||||||
ON q.bill = rp.bill
|
ON q.bill = rp.bill
|
||||||
@ -217,6 +224,44 @@ BEGIN
|
|||||||
CAST(JSON_VALUE(q.expl, '$.list_price') AS NUMERIC(20,5)),
|
CAST(JSON_VALUE(q.expl, '$.list_price') AS NUMERIC(20,5)),
|
||||||
CAST(JSON_VALUE(q.expl, '$.last_date') AS DATE)
|
CAST(JSON_VALUE(q.expl, '$.last_date') AS DATE)
|
||||||
) g;
|
) g;
|
||||||
|
|
||||||
|
--------------------------------------------------------------------------------
|
||||||
|
-- Step 7: Clean up for UI
|
||||||
|
--------------------------------------------------------------------------------
|
||||||
|
UPDATE q
|
||||||
|
SET expl_pretty =
|
||||||
|
(
|
||||||
|
SELECT
|
||||||
|
'Target Price' AS [target_price.label],
|
||||||
|
q.tprice AS [target_price.value],
|
||||||
|
'Volume Range' AS [volume_range.label],
|
||||||
|
q.volume_range AS [volume_range.value],
|
||||||
|
'Channel' AS [channel.label],
|
||||||
|
q.chan AS [channel.value],
|
||||||
|
'Tier' AS [tier.label],
|
||||||
|
q.tier AS [tier.value],
|
||||||
|
'Last Price' AS [last_price.label],
|
||||||
|
q.last_price AS [last_price.value],
|
||||||
|
'Last Date' AS [last_date.label],
|
||||||
|
q.last_date AS [last_date.value],
|
||||||
|
'Last Order' AS [last_order.label],
|
||||||
|
q.last_order AS [last_order.value],
|
||||||
|
'List Price' AS [list_price.label],
|
||||||
|
q.listprice AS [list_price.value],
|
||||||
|
'List Code' AS [list_code.label],
|
||||||
|
q.listcode AS [list_code.value],
|
||||||
|
'Guidance Reason' AS [guidance_reason.label],
|
||||||
|
q.guidance_reason AS [guidance_reason.value],
|
||||||
|
'Guidance Price' AS [guidance_price.label],
|
||||||
|
q.guidance_price AS [guidance_price.value]
|
||||||
|
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||||
|
)
|
||||||
|
FROM @queue q;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
--------------------------------------------------------------------------------
|
--------------------------------------------------------------------------------
|
||||||
-- Final: Return the enriched result row
|
-- Final: Return the enriched result row
|
||||||
|
Loading…
Reference in New Issue
Block a user