Last active
February 6, 2017 22:08
-
-
Save bertwagner/7550f6e225dda485c15ef8a34df55baf to your computer and use it in GitHub Desktop.
SQL Server 2016 JSON's FOR JSON PATH
This file contains hidden or 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
-- PATH will format a result using dot syntax in the column aliases. Here's an example with just default column names | |
SELECT Make, BaseModel, Trim, Year, PurchaseDate | |
FROM ##Garage | |
FOR JSON PATH, ROOT('Cars'); | |
-- Output: {"Cars":[{"Make":"Volkswagen","BaseModel":"Golf","Trim":"GL","Year":2003,"PurchaseDate":"2006-10-05T00:00:00"},{"Make":"Subaru","BaseModel":"Impreza","Trim":"Premium","Year":2016,"PurchaseDate":"2015-08-18T00:00:00"}]} | |
-- And here is the same example, just assigning aliases to define JSON nested structure | |
SELECT Make, BaseModel as [Model.Base], Trim AS [Model.Trim], Year, PurchaseDate | |
FROM ##Garage | |
FOR JSON PATH, ROOT('Cars'); | |
-- Output: {"Cars":[{"Make":"Volkswagen","Model":{"Base":"Golf","Trim":"GL"},"Year":2003,"PurchaseDate":"2006-10-05T00:00:00"},{"Make":"Subaru","Model":{"Base":"Impreza","Trim":"Premium"},"Year":2016,"PurchaseDate":"2015-08-18T00:00:00"}]} | |
-- We can actually go multiple levels deep with this type of alias dot notation nesting | |
SELECT Make, BaseModel as [Model.Base], Trim AS [Model.Trim], 'White' AS [Model.Color.Exterior], 'Black' AS [Model.Color.Interior], Year, PurchaseDate | |
FROM ##Garage | |
FOR JSON PATH, ROOT('Cars'); | |
-- Output: {"Cars":[{"Make":"Volkswagen","Model":{"Base":"Golf","Trim":"GL","Color":{"Exterior":"White","Interior":"Black"}},"Year":2003,"PurchaseDate":"2006-10-05T00:00:00"},{"Make":"Subaru","Model":{"Base":"Impreza","Trim":"Premium","Color":{"Exterior":"White","Interior":"Black"}},"Year":2016,"PurchaseDate":"2015-08-18T00:00:00"}]} | |
-- Concatenating data rows with UNION or UNION ALL just adds the row as a new element as part of the JSON array | |
SELECT Make, BaseModel AS [Model.Base], Trim AS [Model.Trim], Year, PurchaseDate | |
FROM ##Garage WHERE Id = 1 | |
UNION ALL | |
SELECT Make, BaseModel, Trim, Year, PurchaseDate | |
FROM ##Garage WHERE Id = 2 | |
FOR JSON PATH, ROOT('Cars'); | |
-- Output: {"Cars":[{"Make":"Volkswagen","Model":{"Base":"Golf","Trim":"GL"},"Year":2003,"PurchaseDate":"2006-10-05T00:00:00"},{"Make":"Subaru","Model":{"Base":"Impreza","Trim":"Premium"},"Year":2016,"PurchaseDate":"2015-08-18T00:00:00"}]} | |
-- We can even include our FOR JSON in our SELECT statement to generate JSON strings for each row of our result set | |
SELECT g1.*, (SELECT Make, BaseModel AS [Model.Base], Trim AS [Model.Trim], Year, PurchaseDate FROM ##Garage g2 WHERE g2.Id = g1.Id FOR JSON PATH, ROOT('Cars')) AS [Json] | |
FROM ##Garage g1 | |
/* Output: | |
Id Make BaseModel Trim Year PurchaseDate Json | |
--- ------------- ------------ --------- ------- --------------------------- -------------------------------------------------------------------------------------------------------------------------- | |
1 Volkswagen Golf GL 2003 2006-10-05 00:00:00.0000000 {"Cars":[{"Make":"Volkswagen","Model":{"Base":"Golf","Trim":"GL"},"Year":2003,"PurchaseDate":"2006-10-05T00:00:00"}]} | |
2 Subaru Impreza Premium 2016 2015-08-18 00:00:00.0000000 {"Cars":[{"Make":"Subaru","Model":{"Base":"Impreza","Trim":"Premium"},"Year":2016,"PurchaseDate":"2015-08-18T00:00:00"}]} | |
*/ |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment