Last active
September 22, 2017 12:30
-
-
Save bertwagner/73b47a245f2eccfe30a3cad52d8f3d45 to your computer and use it in GitHub Desktop.
SQL Server 2016 JSON's JSON_VALUE() Function
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- See https://gist.github.com/bertwagner/356bf47732b9e35d2156daa943e049e9 for a formatted version of this JSON | |
DECLARE @garage nvarchar(1000) = N'{ "Cars": [{ "Make": "Volkswagen", "Model": { "Base": "Golf", "Trim": "GL" }, "Year": 2003, "PurchaseDate": "2006-10-05T00:00:00.000Z" }, { "Make": "Subaru", "Model": { "Base": "Impreza", "Trim": "Premium" }, "Year": 2016, "PurchaseDate": "2015-08-18T00:00:00.000Z" }] }' | |
SELECT JSON_VALUE(@garage, '$.Cars[0].Make') -- Return the make of the first car in our array | |
-- Output: Volkswagen | |
SELECT CAST(JSON_VALUE(@garage, '$.Cars[0].PurchaseDate') as datetime2) -- Return the Purchase Date of the first car in our array and convert it into a DateTime2 datatype | |
-- Output: 2006-10-05 00:00:00.0000000 | |
SELECT JSON_VALUE(@garage, '$.Cars') -- This returns NULL because the values of Cars is an array instead of a simple object | |
-- Output: NULL | |
SELECT JSON_VALUE(@garage, '$.Cars[1].Model') -- This is also invalid because JSON_VALUE cannot return an array...only scalar values allowed! | |
-- Output: NULL | |
SELECT JSON_VALUE(@garage, '$.Cars[1].Model.Base') -- Much better | |
-- Output: Impreza |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment