Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server 2016 (13.x) and later
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics (serverless SQL pool only)
To format the output of the FOR JSON clause automatically based on the structure of the SELECT statement, specify the AUTO option.
When you specify the AUTO option, the format of the JSON output is automatically determined based on the order of columns in the SELECT list and their source tables. You can't change this format.
The alternative is to use the PATH option to maintain control over the output.
A query that uses the FOR JSON AUTO option must have a FROM clause.
Here are some examples of the FOR JSON clause with the AUTO option. Azure Data Studio is the recommended query editor for JSON queries because it auto-formats the JSON results (as seen in this article) instead of displaying a flat string.
Query
When a query references only one table, the results of the FOR JSON AUTO clause are similar to the results of FOR JSON PATH . In this case, FOR JSON AUTO doesn't create nested objects. The only difference is that FOR JSON AUTO outputs dot-separated aliases (for example, Info.MiddleName
in the following example) as keys with dots, not as nested objects.
SELECT TOP 5
BusinessEntityID As Id,
FirstName, LastName,
Title As 'Info.Title',
MiddleName As 'Info.MiddleName'
FROM Person.Person
FOR JSON AUTO
Result
[{
"Id": 1,
"FirstName": "Ken",
"LastName": "Sánchez",
"Info.MiddleName": "J"
}, {
"Id": 2,
"FirstName": "Terri",
"LastName": "Duffy",
"Info.MiddleName": "Lee"
}, {
"Id": 3,
"FirstName": "Roberto",
"LastName": "Tamburello"
}, {
"Id": 4,
"FirstName": "Rob",
"LastName": "Walters"
}, {
"Id": 5,
"FirstName": "Gail",
"LastName": "Erickson",
"Info.Title": "Ms.",
"Info.MiddleName": "A"
}]
Query
When you join tables, columns in the first table are generated as properties of the root object. Columns in the second table are generated as properties of a nested object. The table name or alias of the second table (for example, D
in the following example) is used as the name of the nested array.
SELECT TOP 2 SalesOrderNumber,
OrderDate,
UnitPrice,
OrderQty
FROM Sales.SalesOrderHeader H
INNER JOIN Sales.SalesOrderDetail D
ON H.SalesOrderID = D.SalesOrderID
FOR JSON AUTO
Result
[{
"SalesOrderNumber": "SO43659",
"OrderDate": "2011-05-31T00:00:00",
"D": [{
"UnitPrice": 24.99,
"OrderQty": 1
}]
}, {
"SalesOrderNumber": "SO43659",
"D": [{
"UnitPrice": 34.40
}, {
"UnitPrice": 134.24,
"OrderQty": 5
}]
}]
Query
Instead of using FOR JSON AUTO, you can nest a FOR JSON PATH subquery in the SELECT statement, as shown in the following example. This example outputs the same result as the preceding example.
SELECT TOP 2
SalesOrderNumber,
OrderDate,
(SELECT UnitPrice, OrderQty
FROM Sales.SalesOrderDetail AS D
WHERE H.SalesOrderID = D.SalesOrderID
FOR JSON PATH) AS D
FROM Sales.SalesOrderHeader AS H
FOR JSON PATH
Result
[{
"SalesOrderNumber": "SO43659",
"OrderDate": "2011-05-31T00:00:00",
"D": [{
"UnitPrice": 24.99,
"OrderQty": 1
}]
}, {
"SalesOrderNumber": "SO4390",
"D": [{
"UnitPrice": 24.99
}]
}]
For a visual introduction to the built-in JSON support in SQL Server and Azure SQL Database, see the following videos:
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining
Learning path
Automate database tasks for Azure SQL - Training
Automate database tasks for Azure SQL
Certification
Microsoft Certified: Azure Database Administrator Associate - Certifications
Administer an SQL Server database infrastructure for cloud, on-premises and hybrid relational databases using the Microsoft PaaS relational database offerings.