Data Sets with JSON (SQL 2016)

With the release of SQL Server 2016 JSON objects support is now available. With the ever growing popularity and versatility of JSON, including JSON support into SQL Server is good for both database and application developers. In a previous post we looked at how to output a JSON object in a dataset using the FOR XML PATH clause and some string concatenation. This process can be rather difficult to read and updating can be a challenge. In this blog post we are going to use the FOR JSON PATH clause to simplify the JSON building process.

A brief background regarding JSON (JavaScript Object Notation). JSON is a lightweight data interchange format similar to XML, however it is based on specific programing languages such as C and Java. It is a data format that is easily understandable for both humans and machines. JSON is machine and language independent, which makes it a great language for data interchange between different systems. For more information regarding JSON please see the following URL https://www.json.org/json-en.html..

In the previous post our goal was to output the student information with a JSON object that described the courses and grades the student received.

{
  "Grades": [{
    "CourseCode": "[Course Code]",
    "CourseName": "[Course Name]",
    "Grade": "[Course Grade]"
  }]
}

In the previous blog post we used some crazy string concatenation to build out the JSON Object. Here is that query, with the string concatenation and using the SUBSTRING function to clean up the excess commas and whitespace.

SELECT s.StudentID
	 , s.FirstName
	 , s.LastName
	 , GradesJSON = '{"Grades":[' + SUBSTRING((
			SELECT ', {"CourseCode":"'+ c.CourseCode + '", "CourseName":"' + c.CourseName + '", "Grade":"' + sc.Grade + '"}' 
			FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
			WHERE s.StudentID = sc.StudentID
			FOR XML PATH('')),3,1000) + ']}'
FROM #Students s;

Using the FOR JSON PATH clause instead of FOR XML PATH clause will simplify our syntax and make our code easier to read and understand. We will still need to output the same columns and use the correlated sub query idea to map the student course/grade data to the proper student in the outer query. The names of the columns will become the data elements in JSON object.

SELECT s.StudentID
     , s.FirstName
     , s.LastName
     , GradesJSON = (
           SELECT CourseCode = c.CourseCode
                , CourseName = c.CourseName
                , Grade = sc.Grade
           FROM #StudentCourse sc
           JOIN #Courses c ON c.CourseID = sc.CourseID
           WHERE s.StudentID = sc.StudentID
           FOR JSON PATH
       )
FROM #Students s
WHERE StudentID = 10005;
StudentID FirstName LastName Courses
10005WillWilliams[{“CourseCode”:”ICS140″, “CourseName”:”Introduction to Programming”, “Grade”:”A”}]

The only thing that is missing in the root grades element, so lets add that in.

SELECT s.StudentID
     , s.FirstName
     , s.LastName
     , GradesJSON = (
           SELECT CourseCode = c.CourseCode
                , CourseName = c.CourseName
                , Grade = sc.Grade
           FROM #StudentCourse sc
           JOIN #Courses c ON c.CourseID = sc.CourseID
           WHERE s.StudentID = sc.StudentID
           FOR JSON PATH, ROOT('Grades')
       )
FROM #Students s
WHERE StudentID = 10005;
StudentID FirstName LastName Courses
10005WillWilliams{“Grades”:[{“CourseCode”:”ICS140″, “CourseName”:”Introduction to Programming”, “Grade”:”A”}]}

There we have it, the same dataset structure including the nested JSON objects without all of the crazy string concatenation and SUBSTRING Function usage. Here is the full script:

DROP TABLE IF EXISTS #Students
GO
 
DROP TABLE IF EXISTS #Courses
GO
 
DROP TABLE IF EXISTS #StudentCourse
GO
 
CREATE TABLE #Students (
   StudentID INT PRIMARY KEY NOT NULL
 , FirstName NVARCHAR(50) NOT NULL
 , LastName NVARCHAR(50) NOT NULL
 )
GO
 
CREATE TABLE #Courses (
	CourseID INT PRIMARY KEY NOT NULL
  , CourseCode NVARCHAR(50) NOT NULL
  , CourseName NVARCHAR(50) NOT NULL
)
 
CREATE TABLE #StudentCourse(
	StudentID INT NOT NULL
  , CourseID INT NOT NULL
  , Grade VARCHAR(5) NULL
)
 
INSERT   INTO #Students
         (StudentID, FirstName, LastName)
VALUES   (10001, N'Bob',N'Roberts')
	   , (10002, N'John',N'Johnson')
	   , (10003, N'Tom',N'Tompson')
	   , (10004, N'Rich',N'Richardson')
	   , (10005, N'Will',N'Williams');
GO
 
INSERT INTO #Courses (
    CourseID
  , CourseCode
  , CourseName
)
VALUES (140, N'ICS140', N'Introduction to Programming')
     , (225, N'ICS225', N'Web Programming')
     , (240, N'ICS240', N'Advanced Programming')
     , (310, N'ICS310', N'Database Management');
 
INSERT INTO #StudentCourse (StudentID, CourseID, Grade)
VALUES (10001, 140, 'A')
     , (10001, 225, 'B+')
     , (10001, 240, 'B-')
     , (10001, 310, 'B')
     , (10002, 240, 'C+')
     , (10002, 310, 'A-')
     , (10004, 140, 'A')
     , (10004, 225, 'B')
     , (10005, 140, 'A');
 
 
SELECT s.StudentID
     , s.FirstName
     , s.LastName
     , GradesJSON = (
           SELECT CourseCode = c.CourseCode
                , CourseName = c.CourseName
                , Grade = sc.Grade
           FROM #StudentCourse sc
           JOIN #Courses c ON c.CourseID = sc.CourseID
           WHERE s.StudentID = sc.StudentID
           FOR JSON PATH, ROOT('Grades')
       )
FROM #Students s;

Data Sets with JSON

Prior to SQL Server 2016, SQL Server did not provide many options to work with JSON documents. However, JSON has become a favored format for developers to pass data between applications and application layers. This blog post we will take a look at how to build a JSON document and return it in a result set. We are going to build on a previous post where we built a comma separated list of values and returned them in a data set. Here is the result of the previous blog post

StudentID FirstName LastName Courses
10001BobRobertsICS140, ICS225, ICS240, ICS310
10002JohnJohnsonICS240, ICS310
10003TomTompson
10004RichRichardsonICS140, ICS225
10005WillWilliamsICS140

This time we are going to change the output to return a JSON object that will contain the course code, course name and grade the student received. The JSON document structure should look like this:

{
  "Grades": [{
    "CourseCode": "[Course Code]",
    "CourseName": "[Course Name]",
    "Grade": "[Course Grade]"
  }]
}

Before we dig into this blog a brief background regarding JSON (JavaScript Object Notation) may help. JSON is a lightweight data interchange format similar to XML, however it is based on programing languages constructs derived from languages such as C and Java. It is a data format that is easily understandable for both humans and machines, making it ideal for transferring data between applications. JSON is machine and language independent, which makes it a great language for data interchange between different systems. For more information regarding JSON please see the following URL https://www.json.org/json-en.html.

We have one minor tweak to the table structure from the previous blog post where we add the grade to the Student Course weak entity table

CREATE TABLE #StudentCourse(
    StudentID INT NOT NULL
  , CourseID INT NOT NULL
  , Grade VARCHAR(5) NULL
);
GO
 
INSERT INTO #StudentCourse (StudentID, CourseID, Grade)
VALUES (10001, 140, 'A')
     , (10001, 225, 'B+')
     , (10001, 240, 'B-')
     , (10001, 310, 'B')
     , (10002, 240, 'C+')
     , (10002, 310, 'A-')
     , (10004, 140, 'A')
     , (10004, 225, 'B')
     , (10005, 140, 'A');

What we want the script to return is a result set with student details including a JSON document with course and grade information which will look like this:

StudentID FirstName LastName Courses
10001BobRoberts{“Grades”:[{“CourseCode”:”ICS140″, “CourseName”:”Introduction to Programming”, “Grade”:”A”}, {“CourseCode”:”ICS225″, “CourseName”:”Web Programming”, “Grade”:”B+”}, {“CourseCode”:”ICS240″, “CourseName”:”Advanced Programming”, “Grade”:”B-“}, {“CourseCode”:”ICS310″, “CourseName”:”Database Management”, “Grade”:”B”}]}
10002JohnJohnson{“Grades”:[{“CourseCode”:”ICS240″, “CourseName”:”Advanced Programming”, “Grade”:”C+”}, {“CourseCode”:”ICS310″, “CourseName”:”Database Management”, “Grade”:”A-“}]}
10003TomTompson
10004RichRichardson{“Grades”:[{“CourseCode”:”ICS140″, “CourseName”:”Introduction to Programming”, “Grade”:”A”}, {“CourseCode”:”ICS225″, “CourseName”:”Web Programming”, “Grade”:”B”}]}
10005WillWilliams{“Grades”:[{“CourseCode”:”ICS140″, “CourseName”:”Introduction to Programming”, “Grade”:”A”}]}

We will reuse most of the query and simply add some additional string concatenation. The previous sub query just concatenated a comma to the course code, this time we are going to build repeating JSON objects within the array.

{"CourseCode": "[Course Code]","CourseName": "[Course Name]","Grade": "[Course Grade]"}
-- CSV Version
SELECT ', ' + sc.Grade 
FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
WHERE s.StudentID = sc.StudentID
FOR XML PATH('')
 
-- New JSON Version
SELECT ', {"CourseCode":"'+ c.CourseCode + '", "CourseName":"' + c.CourseName + '", "Grade":"' + sc.Grade + '"}' 
FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
WHERE s.StudentID = sc.StudentID
FOR XML PATH('')

Now that we have the repeating JSON objects within the array, we need to build out the top object in the document and the array structure. We can accomplish this by adding additional string concatenation in the outer portion of the query.

SELECT s.StudentID
	 , s.FirstName
	 , s.LastName
	 , GradesJSON = '{"Grades":[' + SUBSTRING((
			SELECT ', {"CourseCode":"'+ c.CourseCode + '", "CourseName":"' + c.CourseName + '", "Grade":"' + sc.Grade + '"}' 
			FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
			WHERE s.StudentID = sc.StudentID
			FOR XML PATH('')),3,1000) + ']}'
FROM #Students s;

Here is the full script:

DROP TABLE IF EXISTS #Students
GO
 
DROP TABLE IF EXISTS #Courses
GO
 
DROP TABLE IF EXISTS #StudentCourse
GO
 
CREATE TABLE #Students (
   StudentID INT PRIMARY KEY NOT NULL
 , FirstName NVARCHAR(50) NOT NULL
 , LastName NVARCHAR(50) NOT NULL
 )
GO
 
CREATE TABLE #Courses (
	CourseID INT PRIMARY KEY NOT NULL
  , CourseCode NVARCHAR(50) NOT NULL
  , CourseName NVARCHAR(50) NOT NULL
)
 
CREATE TABLE #StudentCourse(
	StudentID INT NOT NULL
  , CourseID INT NOT NULL
  , Grade VARCHAR(5) NULL
)
 
INSERT   INTO #Students
         (StudentID, FirstName, LastName)
VALUES   (10001, N'Bob',N'Roberts')
	   , (10002, N'John',N'Johnson')
	   , (10003, N'Tom',N'Tompson')
	   , (10004, N'Rich',N'Richardson')
	   , (10005, N'Will',N'Williams');
GO
 
INSERT INTO #Courses (
    CourseID
  , CourseCode
  , CourseName
)
VALUES (140, N'ICS140', N'Introduction to Programming')
     , (225, N'ICS225', N'Web Programming')
     , (240, N'ICS240', N'Advanced Programming')
     , (310, N'ICS310', N'Database Management');
 
INSERT INTO #StudentCourse (StudentID, CourseID, Grade)
VALUES (10001, 140, 'A')
     , (10001, 225, 'B+')
     , (10001, 240, 'B-')
     , (10001, 310, 'B')
     , (10002, 240, 'C+')
     , (10002, 310, 'A-')
     , (10004, 140, 'A')
     , (10004, 225, 'B')
     , (10005, 140, 'A');
 
 
SELECT s.StudentID
	 , s.FirstName
	 , s.LastName
	 , GradesJSON = '{"Grades":[' + SUBSTRING((
			SELECT ', {"CourseCode":"'+ c.CourseCode + '", "CourseName":"' + c.CourseName + '", "Grade":"' + sc.Grade + '"}' 
			FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
			WHERE s.StudentID = sc.StudentID
			FOR XML PATH('')),3,1000) + ']}'
FROM #Students s;

In a future post I will show how to build this Data Set using JSON functions in SQL 2016.

Comma Separated Values using the FOR XML PATH clause

In a previous post we looked at how we can build out a delimited list using the ISNULL and COALESCE functions. This functionality is great if you need to return the delimited list through a function or persist into a variable, however what if you need to return a comma separated list in a result set? This blog post will look at, and describe, how to build out a delimited or comma separated list using FOR XML PATH clause. Using tricks with the FOR XML PATH clause, a correlated subqueries, and un-named columns will give us all the tools needed to return a delimited list within a result set.

So the idea for this blog post is that we take a list of student’s details and include a comma separated list of the course codes that they have registered for. Here is a data diagram that represents our sample dataset.

CSV FOR XML PATH

Here are the populated tables.

StudentID FirstName LastName
10001 Bob Roberts
10002 John Johnson
10003 Tom Thompson
10004 Rich Richardson
10005 Will Williams

310ICS310Database Management

CourseID CourseCode CourseName
140 ICS140 Introduction to Programming
225 ICS225 Web Programming
240 ICS240 Advanced Programming
StudentID CourseID
10001 140
10001 225
10001 240
10001 310
10002 240
10002 310
10004 140
10004 225
10005 140

What we would expect the script to return is a result set with student details including a comma separated list of courses that looks like this:

StudentID FirstName LastName Courses
10001 Bob Roberts ICS140, ICS225, ICS240, ICS310
10002 John Johnson ICS240, ICS310
10003 Tom Tompson  
10004 Rich Richardson ICS140, ICS225
10005 Will Williams ICS140

Using the following temp table structure and sampling of student and course data gives us the data that we will need for this example.

DROP TABLE IF EXISTS #Students
GO
DROP TABLE IF EXISTS #Courses
GO
DROP TABLE IF EXISTS #StudentCourse
GO
 
CREATE TABLE #Students (
   StudentID INT PRIMARY KEY NOT NULL
 , FirstName NVARCHAR(50) NOT NULL
 , LastName NVARCHAR(50) NOT NULL
 )
GO
 
CREATE TABLE #Courses (
    CourseID INT PRIMARY KEY NOT NULL
  , CourseCode NVARCHAR(50) NOT NULL
  , CourseName NVARCHAR(50) NOT NULL
)
 
CREATE TABLE #StudentCourse(
    StudentID INT NOT NULL
  , CourseID INT NOT NULL
)
 
INSERT   INTO #Students (StudentID, FirstName, LastName)
VALUES   (10001, N'Bob',N'Roberts')
       , (10002, N'John',N'Johnson')
       , (10003, N'Tom',N'Tompson')
       , (10004, N'Rich',N'Richardson')
       , (10005, N'Will',N'Williams');
GO
 
INSERT INTO #Courses (
    CourseID
  , CourseCode
  , CourseName
)
VALUES (140, N'ICS140', N'Introduction to Programming')
     , (225, N'ICS225', N'Web Programming')
     , (240, N'ICS240', N'Advanced Programming')
     , (310, N'ICS310', N'Database Management');
 
INSERT INTO #StudentCourse (StudentID, CourseID)
VALUES (10001, 140)
     , (10001, 225)
     , (10001, 240)
     , (10001, 310)
     , (10002, 240)
     , (10002, 310)
     , (10004, 140)
     , (10004, 225)
     , (10005, 140);

We are going to start out by creating a simple query that returns all of the data we need, to generate the output. This will include all data from the student table, all data from the student course weak entity table, and only course code data from the course table.

SELECT s.StudentID, s.FirstName, s.LastName, c.CourseCode
FROM #Students s
LEFT JOIN #StudentCourse sc ON sc.StudentID = s.StudentID
LEFT JOIN #Courses c ON c.CourseID = sc.CourseID
StudentID FirstName LastName CourseCode
10001 Bob Roberts ICS140
10001 Bob Roberts ICS225
10001 Bob Roberts ICS240
10001 Bob Roberts ICS310
10002 John Johnson ICS240
10002 John Johnson ICS310
10003 Tom Tompson  
10004 Rich Richardson ICS140
10004 Rich Richardson ICS225
10005 Will Williams ICS140

Now that we have our dataset, let’s turn our focus on creating the comma separated list of course codes. Here we will implement our firsts bit of trickery. We are going to use the FOR XML clause, however we are going to pass an empty string to the PATH function. This will rename the XML root node as an empty string, thus not returning a root node. You can test this by running both queries, the first query will have a root node of <row> whereas the second query only returns the <CourseCode> nodes.

SELECT c.CourseCode
FROM #Students s
LEFT JOIN #StudentCourse sc ON sc.StudentID = s.StudentID
LEFT JOIN #Courses c ON c.CourseID = sc.CourseID
FOR XML PATH;
 
SELECT c.CourseCode
FROM #Students s
LEFT JOIN #StudentCourse sc ON sc.StudentID = s.StudentID
LEFT JOIN #Courses c ON c.CourseID = sc.CourseID
FOR XML PATH('');

Being that we were able to remove the root node by simply renaming the node, we need to do the same for the column name CourseCode. Here comes some more trickery, if we concatenate a string and do not provide an alias, the column name is undefined and thus is empty. In Management Studio you should see something like this “(No column name)”. This trickery actually works out to have an advantage because we need to concatenate our strings with a comma to create a comma separated list of values. So running the following query will give us all of the values in a comma separated list.

SELECT ', ' + c.CourseCode
FROM #Students s
LEFT JOIN #StudentCourse sc ON sc.StudentID = s.StudentID
LEFT JOIN #Courses c ON c.CourseID = sc.CourseID
FOR XML PATH('');
, ICS140, ICS225, ICS240, ICS310, ICS240, ICS310, ICS140, ICS225, ICS140

So now we have all of the course codes in one big comma separated list, we need to get them into sub lists for each student. If we nest the query with the FOR XML clause in a sub query and reference the student id from the outer query, this will limit the comma separated lists to only the course codes that are linked to the students.

SELECT s.StudentID
	 , s.FirstName
	 , s.LastName
	 , Courses = (
			SELECT ', ' + c.CourseCode
			FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
			WHERE s.StudentID = sc.StudentID
			FOR XML PATH(''))
FROM #Students s;

The last piece is a bit of data clean up, using a STUFF or SUBSTRING we can remove the extra comma and white space from the comma separated list. Here is the final query that will return the result with a comma separated list in the result set.

SELECT s.StudentID
	 , s.FirstName
	 , s.LastName
	 , Courses = SUBSTRING((
			SELECT ', ' + c.CourseCode
			FROM #StudentCourse sc JOIN #Courses c ON c.CourseID = sc.CourseID
			WHERE s.StudentID = sc.StudentID
			FOR XML PATH('')),3,1000)
FROM #Students s;