SQL Server 2016 added support for working with JSON. Although there isn’t a JSON datatype, there is still the ability to output query results to JSON, and to break down JSON into rows and columns.
This post will run through some basic examples of working with JSON. I’m using SQL Server 2017 although 2016 can be used as well.
First I’ll create some test data.
drop table if exists dbo.JsonTest; create table dbo.JsonTest( FirstName varchar(20) null, LastName varchar(20) not null, StatusCode varchar(10) not null ); insert into dbo.JsonTest(FirstName, LastName, StatusCode) values ('Mike', 'Smith', 'Inactive'); insert into dbo.JsonTest(FirstName, LastName, StatusCode) values ('Jane', 'Doe', 'Active'); insert into dbo.JsonTest(FirstName, LastName, StatusCode) values (NULL, 'Jones', 'Pending');
Next is returning relational data as JSON. Much like the FOR XML clause returns XML, the FOR JSON clause returns the selected data in a JSON string. AUTO will return a default structure, where using PATH will allow more control on the output, like naming the root node and returning NULL values instead of omitting them.
select FirstName, LastName, StatusCode FROM dbo.JsonTest FOR JSON AUTO; select FirstName, LastName, StatusCode, 'Atlanta' as [Address.City], 'GA' as [Address.State] FROM dbo.JsonTest FOR JSON PATH, ROOT('People'); select FirstName, LastName, StatusCode FROM dbo.JsonTest FOR JSON PATH, INCLUDE_NULL_VALUES, WITHOUT_ARRAY_WRAPPER;
The second select also shows how to nest data, in this case in an Address node.
OPENJSON will return one row for each node in a JSON string.
declare @JSON as varchar(4000) = '[{"FirstName":"Mike","LastName":"Smith","StatusCode":"Inactive"},{"FirstName":"Jane","LastName":"Doe","StatusCode":"Active"},{"LastName":"Jones","StatusCode":"Pending"}]'; SELECT * FROM OPENJSON(@JSON);
With OPENJSON, we can also parse JSON into relational rows and columns, provided that the column name matches the JSON attribute name. If the names don’t match then NULLs are returned.
declare @JSON as varchar(4000) = '[{"FirstName":"Mike","LastName":"Smith","StatusCode":"Inactive"},{"FirstName":"Jane","LastName":"Doe","StatusCode":"Active"},{"LastName":"Jones","StatusCode":"Pending"}]'; SELECT * FROM OPENJSON(@JSON) WITH ( FirstName varchar(20), LastName varchar(20), StatusCode varchar(10) );
It is also possible to map a JSON attribute name to a different name for the output, we’ll need to specify which value to match to.
declare @JSON as varchar(4000) = '[{"FirstName":"Mike","LastName":"Smith","StatusCode":"Inactive"},{"FirstName":"Jane","LastName":"Doe","StatusCode":"Active"},{"LastName":"Jones","StatusCode":"Pending"}]'; SELECT * FROM OPENJSON(@JSON) WITH ( GivenName varchar(20) '$.FirstName', Surname varchar(20) '$.LastName', StatusCode varchar(10) );
There are also a few JSON Functions available.
ISJSON will determine if a string is valid JSON or not.
JSON_VALUE will extract a scalar value.
JSON_QUERY will return a JSON fragment or an array of values.
By default, the JSON functions are in Lax mode, which means that an error won’t be raised with an invalid operation, a NULL values will be returned instead. Strict mode can be specified, in which case an error will be raised with an invalid operation.
declare @JSON as varchar(4000) = '[{"FirstName":"Mike","LastName":"Smith","StatusCode":"Inactive", "Language":["English","Spanish"]},{"FirstName":"Jane","LastName":"Doe","StatusCode":"Active"}]'; declare @NotJson as varchar(4000) = 'Not a JSON string'; -- Return bit to determine if a string is valid JSON or not SELECT ISJSON(@JSON); SELECT ISJSON(@NotJson); -- Get scalar value - 0 based array SELECT JSON_VALUE(@JSON, '$[1].FirstName'); -- Return JSON fragment or array of values SELECT JSON_QUERY(@JSON, '$[0].Language'); -- Default is lax mode - returns NULL on error -- Strict will raise error SELECT JSON_QUERY(@JSON, 'lax $[1].Language'); SELECT JSON_QUERY(@JSON, 'strict $[1].Language');
All of the SQL is also posted on GitHub.
Links:
Simple Talk has a good introduction to JSON functionality.
Microsoft Docs – OPENJSON
Microsoft Docs – JSON Functions