From 533bbd10469639605a54bd624882c2d29ea9c52d Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 5 Aug 2025 17:29:50 -0400 Subject: [PATCH] convert json output to new std --- new_targets/dev.json | 60 ++++++++ new_targets/procs/single_price_call.ms.sql | 108 +++++++++---- .../procs/single_price_call_func.ms.sql | 142 +++++++++--------- new_targets/ui_schema.json | 63 ++++++++ 4 files changed, 272 insertions(+), 101 deletions(-) create mode 100644 new_targets/dev.json create mode 100644 new_targets/ui_schema.json diff --git a/new_targets/dev.json b/new_targets/dev.json new file mode 100644 index 0000000..9f43c43 --- /dev/null +++ b/new_targets/dev.json @@ -0,0 +1,60 @@ +{ + "details": [ + { + "label": "History", + "details": [ + { + "label": "Last Sale: 2025-06-12", + "value": 0.10120, + "type": "currency", + "note": "Ord# 1008338" + } + ] + }, + { + "label": "List", + "details": [ + { + "label": "List:GUAU", + "value": 0.11000, + "type": "currency", + "note": "U.AEA.DI" + } + ] + }, + { + "label": "Target Support", + "details": [ + { + "label": "Anchor:XNS0T1G3", + "value": 0.08000, + "type": "currency", + "note": "+" + }, + { + "label": "Channel:WHS", + "value": 0.20000, + "type": "percentage", + "note": "x" + }, + { + "label": "Volume:1-8", + "value": 0.10000, + "type": "percentage", + "note": "x" + } + ] + }, + { + "label": "Guidance", + "details": [ + { + "label": "Last Price Capped", + "value": 0.10120, + "type": "currency", + "note": "Last price 0.10120 capped at 0.0000000000000%" + } + ] + } + ] +} diff --git a/new_targets/procs/single_price_call.ms.sql b/new_targets/procs/single_price_call.ms.sql index 41b7697..48a6289 100644 --- a/new_targets/procs/single_price_call.ms.sql +++ b/new_targets/procs/single_price_call.ms.sql @@ -33,7 +33,7 @@ BEGIN guidance_price NUMERIC(20,5), guidance_reason NVARCHAR(MAX), expl NVARCHAR(MAX), - expl_pretty NVARCHAR(MAX) + ui_json NVARCHAR(MAX) ); -------------------------------------------------------------------------------- @@ -229,40 +229,88 @@ BEGIN -- 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 + SET ui_json = ( + SELECT + ( + SELECT + panel.label, + JSON_QUERY(panel.details) AS details + FROM ( + -- History Panel + SELECT + 'History' AS label, + ( + SELECT + CASE + WHEN q.last_price IS NOT NULL THEN 'Last Sale: ' + CAST(q.last_date AS varchar(10)) + ELSE 'No Recent' + END AS label, + COALESCE(q.last_price,0) AS value, + CASE + WHEN q.last_price IS NOT NULL THEN 'currency' + ELSE 'currency' + END AS type, + CASE + WHEN q.last_price IS NOT NULL THEN 'Ord# ' + q.last_order + ELSE NULL + END AS note + FOR JSON PATH + ) AS details + + UNION ALL + + -- List Panel + SELECT + 'List' AS label, + ( + SELECT + 'List:' + q.listcode AS label, + q.listprice AS value, + 'currency' AS type, + q.plevel AS note + FOR JSON PATH + ) + + UNION ALL + + -- Target Support Panel + SELECT + 'Target Support' AS label, + ( + SELECT + RTRIM(SUBSTRING(value,1,18)) AS label, + TRY_CAST(SUBSTRING(value,23,7) AS NUMERIC(20,5)) + + CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END AS value, + CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'percentage' END AS type, + CASE SUBSTRING(value,19,1) WHEN '+' THEN 'Price' ELSE 'Premium' END AS note + FROM OPENJSON(q.expl, '$.target_math') + WITH (value NVARCHAR(MAX) '$') + FOR JSON PATH + ) AS details + + UNION ALL + + -- Guidance Panel + SELECT + 'Guidance' AS label, + ( + SELECT + 'Price' AS label, + q.guidance_price AS value, + 'currency' AS type, + q.guidance_reason AS note + FOR JSON PATH + ) + ) AS panel + FOR JSON PATH + ) AS details, + JSON_QUERY(q.expl) AS data -- 👈 adds the full expl content as a JSON object + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER -- 👈 make it a single JSON object ) FROM @queue q; - - - -------------------------------------------------------------------------------- -- Final: Return the enriched result row -------------------------------------------------------------------------------- diff --git a/new_targets/procs/single_price_call_func.ms.sql b/new_targets/procs/single_price_call_func.ms.sql index b543701..5fa676a 100644 --- a/new_targets/procs/single_price_call_func.ms.sql +++ b/new_targets/procs/single_price_call_func.ms.sql @@ -228,77 +228,77 @@ BEGIN -------------------------------------------------------------------------------- -- Step 7: Clean up for UI -------------------------------------------------------------------------------- -UPDATE q -SET ui_json = ( - SELECT - panel.label, - JSON_QUERY(panel.details) AS details - FROM ( - -- History Panel - SELECT - 'History' AS label, - ( - SELECT - 'Last Sale: ' + CAST(q.last_date AS varchar(10)) AS label, - q.last_price AS value, - 'currency' AS type, - 'Ord# ' + q.last_order AS note - FOR JSON PATH - ) AS details - - UNION ALL - - -- List Panel - SELECT - 'List' AS label, - ( - SELECT - 'List:' + q.listcode AS label, - q.listprice AS value, - 'currency' AS type, - q.plevel AS note - FOR JSON PATH - ) - - UNION ALL - - -- Target Support Panel - SELECT - 'Target Support' AS label, - ( - SELECT - -- parse each item in target_math - RTRIM(SUBSTRING(value,1,18)) label, - TRY_CAST(SUBSTRING(value,23,7) AS NUMERIC(20,5)) + CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END AS value, - CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'percentage' END AS type, - SUBSTRING(value,19,1) AS note - FROM OPENJSON(q.expl, '$.target_math') - WITH (value NVARCHAR(MAX) '$') - FOR JSON PATH - ) AS details - - UNION ALL - - -- Guidance Panel - SELECT - 'Guidance' AS label, - ( - SELECT - 'Last Price Capped' AS label, - q.guidance_price AS value, - 'currency' AS type, - CONCAT( - 'Last price ', q.last_price, - ' capped at ', - ROUND((q.last_price - q.guidance_price) / NULLIF(q.last_price, 0) * 100, 2), - '%' - ) AS note - FOR JSON PATH - ) - ) AS panel - FOR JSON PATH, ROOT('details') -) -FROM @queue q; + UPDATE q + SET ui_json = ( + SELECT + panel.label, + JSON_QUERY(panel.details) AS details + FROM ( + -- History Panel + SELECT + 'History' AS label, + ( + SELECT + 'Last Sale: ' + CAST(q.last_date AS varchar(10)) AS label, + q.last_price AS value, + 'currency' AS type, + 'Ord# ' + q.last_order AS note + FOR JSON PATH + ) AS details + + UNION ALL + + -- List Panel + SELECT + 'List' AS label, + ( + SELECT + 'List:' + q.listcode AS label, + q.listprice AS value, + 'currency' AS type, + q.plevel AS note + FOR JSON PATH + ) + + UNION ALL + + -- Target Support Panel + SELECT + 'Target Support' AS label, + ( + SELECT + -- parse each item in target_math + RTRIM(SUBSTRING(value,1,18)) label, + TRY_CAST(SUBSTRING(value,23,7) AS NUMERIC(20,5)) + CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END AS value, + CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'percentage' END AS type, + SUBSTRING(value,19,1) AS note + FROM OPENJSON(q.expl, '$.target_math') + WITH (value NVARCHAR(MAX) '$') + FOR JSON PATH + ) AS details + + UNION ALL + + -- Guidance Panel + SELECT + 'Guidance' AS label, + ( + SELECT + 'Last Price Capped' AS label, + q.guidance_price AS value, + 'currency' AS type, + CONCAT( + 'Last price ', q.last_price, + ' capped at ', + ROUND((q.last_price - q.guidance_price) / NULLIF(q.last_price, 0) * 100, 2), + '%' + ) AS note + FOR JSON PATH + ) + ) AS panel + FOR JSON PATH, ROOT('details') + ) + FROM @queue q; -------------------------------------------------------------------------------- diff --git a/new_targets/ui_schema.json b/new_targets/ui_schema.json new file mode 100644 index 0000000..189f52e --- /dev/null +++ b/new_targets/ui_schema.json @@ -0,0 +1,63 @@ +{ + "details": [ + { + "label": "History", + "details": [ + { + "label": "Last Sale", + "value": 0.081, + "type": "currency" + }, + { + "label": "Last Quote", + "value": 0.079, + "type": "currency" + } + ] + }, + { + "label": "List", + "details": [ + { + "label": "Code", + "value": "GUAU", + "type": "text", + "note": "Griffin East - US A List" + } + ] + }, + { + "label": "Target Support", + "details": [ + { + "label": "Anchor", + "value": 0.080, + "type": "currency", + "note": "Tier 1 Truckload Black" + }, + { + "label": "Color :L", + "value": 0.10, + "type": "percent", + "note": " x " + }, + { + "label": "Tier 2", + "value": 0.02, + "type": "percent", + "note": " x " + } + ] + }, + { + "label": "Guidance", + "details": [ + { + "label": "Last Price Capped", + "value": 0.080, + "type": "Last price 0.079 capped at 1%" + } + ] + } + ] +}