Exploring SQL Server 2016 – JSON data – Part 2

In Part 1 of this series, it was shown how to generate JSON data from the existing table. In this post we can explore how to import JSON data into a table

SQL Server 2016 supports OPENJSON, a table-value function that parses the JSON data and return the column names and their values as key and value columns

Simple example is

select * FROM OPENJSON(
'{
"emp_name": "Madhivanan",
"dob": "2000-10-19"
}
')

The result is

key             value               type
-------------   -----------------   ----------
emp_name        Madhivanan          1
dob             2000-10-19          1

If you want to get the values not in key/value pairs but in normalised structure (column and rows), you can specify the schema using WITH option as shown below

select * FROM OPENJSON(
'
{
 "emp_name": "Madhivanan",
 "dob": "2000-10-19"
 }
 ') with ([emp_name] varchar(100),[dob] date)

The result is

emp_name        dob
--------------  -----------
Madhivanan      2000-10-19

The above works well for single JSON array. If there are multiple arrays, you need to specify the root element to get all of them.

Let us consider the following example

Create a new table

create table #emp(emp_name varchar(100), dob date)

Now the following code will load the JSON data into this table

DECLARE @json NVARCHAR(MAX) = N'
 {
 "Employee": [{
 "emp_name": "Madhivanan",
 "dob": "2000-10-19"
 }, {
 "emp_name": "Saran",
 "dob": "1998-04-22"
 }, {
 "emp_name": "Mugil",
 "dob": "1978-02-14"
 }]
 }'

create table #emp(emp_name varchar(100), dob date)

Insert into #emp(emp_name,dob)
select * from OPENJSON(@json,'$.Employee')
with ([emp_name] varchar(100),[dob] date)

select * from #emp

The result is

emp_name          dob
----------------  --------------
Madhivanan        2000-10-19
Saran             1998-04-22
Mugil             1978-02-14

So this way you get JSON data in a structure format and then import them to a table

Other posts on new features of SQL Server 2016
Exploring SQL Server 2016 T-SQL functions – STRING_SPLIT
SQL Server 2016 – Drop If Exists
Exploring SQL server 2016 T-SQL functions- COMPRESS
Exploring SQL server 2016 T-SQL functions- DECOMPRESS
Exploring SQL Server 2016 – JSON data – Part 1

Advertisements

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s