Back in our last instalment, we looked at OPENJSON and how we can get data into a tabular format from a JSON document.
Readers may have noticed that we used data from the sys.configurations table in order to generate the JSON document.
However, when we read the data from the document into tabular format we specified that the columns
- Value
- minimum
- maximum
- value_in_use
- description
Which are of type SQL_VARIANT in the table were actually of type NVARCHAR(200) in the resultset that was brought back from the JSON document.
SELECT [configuration_id] ,[Configuration name] ,[Value] ,[minimum] ,[maximum] ,[value_in_use] ,[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
So, why was that? and can we fix it?
Well, JSON and has a handful of data types and SQL Server has lots. So there’s not a one-to-one match.
The best thing to do would be to being them back as one of the simple types (likely NVARCHAR()) and then CAST them in the SELECT to the actual desired data type.
Like so
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 result set looks the same, however if the values returned are now of the correct data type. So if you wanted to do anything with the resultset like joining on the original table then you would not see any implicit casting.
So, that’s just a small tip of how to handle data type differences between SQL Server and JSON.
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