Recently we reviewed FOR JSON PATH. That was used for shaping tabular data (data that comes directly from a SQL table) into a JSON document.
The PATH we are talking about here is used with OPENJSON to get to the data that is contained in the JSON document.
We’ve seen an example of OPENJSON and reading data with an explicit schema.
SELECT
[configuration_id]
,[Configuration name]
,[Value] = TRY_CONVERT(sql_variant , [Value])
,[minimum] = TRY_CONVERT(sql_variant , [minimum])
,[maximum] = TRY_CONVERT(sql_variant , [maximum])
,[value_in_use] = TRY_CONVERT(sql_variant , [value_in_use])
,[description] = TRY_CONVERT(sql_variant , [description])
,[is_dynamic]
,[is_advanced]
FROM
OPENJSON
(
'
{
"configuration_id": 101,
"Configuration name": "recovery interval (min)",
"Value": 0,
"minimum": 0,
"maximum": 32767,
"value_in_use": 0,
"description": "Maximum recovery interval in minutes",
"is_dynamic": true,
"is_advanced": true
}
'
)
WITH
(
[configuration_id] INT
,[Configuration name] NVARCHAR(35)
,[Value] NVARCHAR(200)
,[minimum] NVARCHAR(200)
,[maximum] NVARCHAR(200)
,[value_in_use] NVARCHAR(200)
,[description] NVARCHAR(200)
,[is_dynamic] BIT
,[is_advanced] BIT
);
GO
Turns out that in this example, the data is right at the top level of the document.
{
"configuration_id": 101,
"Configuration name": "recovery interval (min)",
"Value": 0,
"minimum": 0,
"maximum": 32767,
"value_in_use": 0,
"description": "Maximum recovery interval in minutes",
"is_dynamic": true,
"is_advanced": true
}
and so we didn’t need to explicitly state the PATH – however we still could have. And here it is.
SELECT
[configuration_id]
,[Configuration name]
,[Value] = TRY_CONVERT(sql_variant , [Value])
,[minimum] = TRY_CONVERT(sql_variant , [minimum])
,[maximum] = TRY_CONVERT(sql_variant , [maximum])
,[value_in_use] = TRY_CONVERT(sql_variant , [value_in_use])
,[description] = TRY_CONVERT(sql_variant , [description])
,[is_dynamic]
,[is_advanced]
FROM
OPENJSON
(
'
{
"configuration_id": 101,
"Configuration name": "recovery interval (min)",
"Value": 0,
"minimum": 0,
"maximum": 32767,
"value_in_use": 0,
"description": "Maximum recovery interval in minutes",
"is_dynamic": true,
"is_advanced": true
}
'
, '$')
WITH
(
[configuration_id] INT
,[Configuration name] NVARCHAR(35)
,[Value] NVARCHAR(200)
,[minimum] NVARCHAR(200)
,[maximum] NVARCHAR(200)
,[value_in_use] NVARCHAR(200)
,[description] NVARCHAR(200)
,[is_dynamic] BIT
,[is_advanced] BIT
);
GO
The query below has the PATH defined explicitly in the WITH clause.
SELECT
[configuration_id]
,[Configuration name]
,[Value] = TRY_CONVERT(sql_variant , [Value])
,[minimum] = TRY_CONVERT(sql_variant , [minimum])
,[maximum] = TRY_CONVERT(sql_variant , [maximum])
,[value_in_use] = TRY_CONVERT(sql_variant , [value_in_use])
,[description] = TRY_CONVERT(sql_variant , [description])
,[is_dynamic]
,[is_advanced]
FROM
OPENJSON
(
'
{
"configuration_id": 101,
"Configuration name": "recovery interval (min)",
"Value": 0,
"minimum": 0,
"maximum": 32767,
"value_in_use": 0,
"description": "Maximum recovery interval in minutes",
"is_dynamic": true,
"is_advanced": true
}
')
WITH
(
[configuration_id] INT '$.configuration_id'
,[Configuration name] NVARCHAR(35) '$."Configuration name"'
,[Value] NVARCHAR(200) '$.Value'
,[minimum] NVARCHAR(200) '$.minimum'
,[maximum] NVARCHAR(200) '$.maximum'
,[value_in_use] NVARCHAR(200) '$.value_in_use'
,[description] NVARCHAR(200) '$.description'
,[is_dynamic] BIT '$.is_dynamic'
,[is_advanced] BIT '$.is_advanced'
);
GO
Notice also that Configuration name has a space in it. So, in the PATH we simply enclose it in double quotes “..” – in a similar way to how square brackets would be used in a T-SQL expression.
Lets, look at a slightly different shaped JSON document and see how we would change the PATH in the WITH clause to locate all of the desired values.
SELECT
[configuration_id]
,[Configuration name]
,[Value] = TRY_CONVERT(sql_variant , [Value])
,[minimum] = TRY_CONVERT(sql_variant , [minimum])
,[maximum] = TRY_CONVERT(sql_variant , [maximum])
,[value_in_use] = TRY_CONVERT(sql_variant , [value_in_use])
,[description] = TRY_CONVERT(sql_variant , [description])
,[is_dynamic]
,[is_advanced]
FROM
OPENJSON(
'
{
"configuration_id": 101,
"Configuration_Property": {
"Configuration name": "recovery interval (min)",
"Value": 0,
"minimum": 0,
"maximum": 32767,
"value_in_use": 0,
"description": "Maximum recovery interval in minutes",
"is_dynamic": true,
"is_advanced": true
}
}
')
WITH
(
[configuration_id] INT '$."configuration_id"'
,[Configuration name] NVARCHAR(35) '$."Configuration_Property"."Configuration name"'
,[Value] NVARCHAR(200) '$."Configuration_Property"."Value"'
,[minimum] NVARCHAR(200) '$."Configuration_Property"."minimum"'
,[maximum] NVARCHAR(200) '$."Configuration_Property"."maximum"'
,[value_in_use] NVARCHAR(200) '$."Configuration_Property"."value_in_use"'
,[description] NVARCHAR(200) '$."Configuration_Property"."description"'
,[is_dynamic] BIT '$."Configuration_Property"."is_dynamic"'
,[is_advanced] BIT '$."Configuration_Property"."is_advanced"'
);
Notice, that no ‘default path’ is specified on the OPENJSON clause (after the document on line 27).
I hope this has helped on your SQL Server JSON journey. We’ll see more real soon.
Have a great day
Cheers
Marty
Download Files