Tags
Advanced SQL Interview Questions and Answers, Advanced SQL tutorial pdf, any recommended websites for sql puzzles, Best SQL Puzzles, Buy SQL Server Interview Questions Book Online at Low Price, COmples tSQL puzzles, Complex SQL Challenges, complex sql statement(puzzle), Complex tsql, Complex TSQL Challenge, convert string to proper case in sql server, Divide rows into two columns, Download SQL Questions, Download SQL Server Interview Question in PDF, Download SQL SERVER Interview questions, Download SQL Server Interview questions and answers, download sql server interview questions and answers pdf, download sql server interview questions by Pawan Khowal, download sql server interview questions by Pawan Kumar, download sql server interview questions by Pawan Kumar Khowal, Download T-SQL Interview Questions, Free Download SQL SERVER Interview questions, Get Next Value Puzzle, Huge blank areas in database field, Improve SQL Skills, Interview Puzzles in SQL Server, Interview Qs.SQL SERVER Questions, Interview questions and Answers for MS SQL Server designing, Interview Questions and Answers For SQL, Interview questions on Joins, Interview Questions on SQL, Interview SQL Puzzles, InterviewQuestions, InterviewQuestions for SQL, JSON Functions in Sql, JSON Functions in Sql Server, JSON Functions in Sql Server 2016, JSON in Sql, JSON in Sql Server, JSON in Sql Server 2016, JSON rowset view, JSON text to result set, JSON to rows in Sql, Learn complex SQL, Learn SQL, Learn T-SQL, Microsoft SQL Server interview questions for DBA, MS SQL Server interview questions, MSBI Interview Questions, Objective Puzzle, OPENJSON, OPENJSON Sql, OPENJSON Sql function, OPENJSON Sql Server, OPENJSON with Schema declaration, OPENJSON with Schema definition, Pawan, Pawan Khowal, Pawan Kumar, Pawan Kumar Khowal, PL/SQL Challenges, Puzzle SQL, puzzle sql developer, Puzzle SQl Server, Puzzles, PUzzles in SQL SERVER, Queries for SQL Interview, Remove Huge Multiple Spaces from a DB Fields, Remove Multiple Spaces from a DB Fields, Separate Int and char from a string column, Single Quote update SQL, SQL, SQL - The Pattern Puzzles, SQL 2012, SQL 2014, SQL 2014 Interview Questions, SQL Challenge, SQL Challenges, SQL Extreme Difficult Puzzle, SQL FAQ, SQL FAQs, sql group by only rows which are in sequence, SQL Interview Q & A, SQL Interview Questions, SQL Interview Questions - Part 2, SQL Interview Questions for SQL Professionals, SQL Joins, SQL Pattern Puzzles, SQL pl/sql puzzles, SQL prime number puzzle, SQL puzzle, SQL Puzzles, sql puzzles & answers, sql puzzles and answers free download, sql puzzles and answers pdf, sql puzzles for interview, sql puzzles oracle, SQL Queries, SQL Queries asked in interviews, SQL QUERY PUZZLES, SQL Query to Find Nth Highest Salary of Employee, SQL Questions, SQL Quiz, SQL Replace Puzzle, SQL Server, SQL Server - Common Interview Questions and Answers, SQL SERVER - Find Nth Highest Salary of Employee, SQL Server - General Interview Questions and Answers, sql server 2008 interview questions, SQL Server 2008 Interview Questions and Answers, Sql Server 2016, Sql Server 2016JSON Functions, SQL Server Database, SQL Server database developer interview questions and answers, sql server dba interview questions, SQL Server developer Interview questions and answers, SQL Server developer Interview questions with answers, SQL Server Developer T-SQL Interview Questions, SQL server filter index with LIKE and RIGHT function?, SQL Server Interview Puzzle, SQL SERVER Interview questions, SQL SERVER Interview questions & Answers, SQL Server Interview Questions - Part 1, SQL Server Interview questions and answers, SQL Server Interview Questions and Answers - Free PDF, SQL SERVER Interview questions and answers for experienced, sql server interview questions and answers for net developers, SQL Server Interview Questions And Answers.pdf, sql server interview questions by Pawan Khowal sql interview questions, SQL SERVER Interview questions pdf, SQL Server Interview Questions | MSBISKILLS.Com, SQL Server Interview Questions | MSBISKILLS.com Top 50 SQL Server Questions & Answers, SQL Server Interview Questions/Answers Part-1, SQL Server Puzzle, SQL SERVER Puzzles, SQL server Questions and Answers, SQL SERVER Tips, SQL Skills, SQL Sudoku, SQL Tips & Tricks, SQL Tips and Tricks, SQL Top clause, SQL Tough Puzzle, SQL Tricks, SQL Trikcy question, sql/database interview for puzzle sql developer, SQLBI Interview Questions, SQLSERVER, SUM of grouped COUNT in SQL Query, T SQL Puzzles, T-SQL Challenge, T-SQL Interview Questions | SQL Server Interviews and Jobs, T-SQL Puzzle, T-SQL Server Interview Questions, T-SQL Tricky Puzzles, The Status Puzzle, Top 10 Frequently Asked SQL Query Interview Questions, TOP 100 SQL SERVER INTERVIEW QUESTIONS QUERIES, Top 50 SQL Server Interview Question for Testers, Tough SQL Challenges, Tough SQL Puzzles, Tricky Questions, TSQL, TSQL Challenge, TSQL Challenges, TSQL Interview questions, TSQL Puzzle, TSQL Puzzles, TSQL Queries
NEW T-SQL FEATURES IN SQL SERVER 2016 – XII | OPENJSON Function (SQL Server)
In this post we shall check out the new features Microsoft introduced in SQL Server 2016 | OPENJSON Function (SQL Server)
New feature – XII | OPENJSON Function (SQL Server)
From Microsoft – The OPENJSON rowset function converts JSON text into a set of rows and columns. After you transform a JSON collection into a rowset with OPENJSON, you can run any SQL query on the returned data or insert it into a SQL Server table.
The OPENJSON function takes a single JSON object or a collection of JSON objects and transforms them into one or more rows. By default, the OPENJSON function returns the following data:+
1. From a JSON object, the function returns all the key:value pairs that it finds at the first level.
2. From a JSON array, the function returns all the elements of the array with their indexes.
You can add an optional WITH clause to provide a schema that explicitly defines the structure of the output.
Notes
1. The OPENJSON function is available only under compatibility level 130. We can’t find and run the OPENJSON function below this
compatibility level. You can change the compatibility level of a database by using the following command:
-- ALTER DATABASE <DatabaseName> SET COMPATIBILITY_LEVEL = 130 -- |
2. The OPENJSON has two flavors – default output and explicit structure.
3. OPENJSON with the default output
When you use the OPENJSON function without providing an explicit schema for the results – that is, without a WITH clause after OPENJSON – the function returns a table with the following three columns:
Key -> Name of the property(If Present) else index
value -> Property value(Data)
type -> An integer value means the type of the value.
4. OPENJSON output with an explicit structure
When you specify a schema for the results by using the WITH clause of the OPENJSON function, the function returns a table with only the columns that you define in the WITH clause. In the optional WITH clause, you specify a set of output columns, their types, and the paths of the JSON source properties for each output value. OPENJSON iterates through the array of JSON objects, reads the value on the specified path for each column, and converts the value to the specified type.
Examples
/* Using Option 1 – OPENJSON with the default output | Default Columns key, value and type */
-- DECLARE @j NVARCHAR(MAX) SET @j='{"name":"Pawan","MiddleName":"Kumar","Surname":"Khowal","Class":10,"SkillSet":["SQL","SSIS","SSRS","SSAS"],"IsDatabaseDeveloper":true}'; SELECT * FROM OPENJSON(@j) GO OUTPUT key value type --------------------------- --------------------------------------------- ---- name Pawan 1 MiddleName Kumar 1 Surname Khowal 1 Class 10 2 SkillSet ["SQL","SSIS","SSRS","SSAS"] 4 IsDatabaseDeveloper true 3 (6 rows affected) -- |
/* Using Option 1 – OPENJSON with the default output | Columns key and value */
-- DECLARE @j NVARCHAR(MAX) SET @j='{"name":"Pawan","MiddleName":"Kumar","Surname":"Khowal","Class":10,"SkillSet":["SQL","SSIS","SSRS","SSAS"],"IsDatabaseDeveloper":true}'; SELECT [Key],[Value] FROM OPENJSON(@j) GO OUTPUT Key Value --------------------------------- ---------------------------------- name Pawan MiddleName Kumar Surname Khowal Class 10 SkillSet ["SQL","SSIS","SSRS","SSAS"] IsDatabaseDeveloper true (6 rows affected) -- |
/* Using Option 1 – OPENJSON with the default output | Get DATA FROM Object/Array from JSON without Property – SkillSet */
-- DECLARE @j NVARCHAR(MAX) SET @j='{"name":"Pawan","MiddleName":"Kumar","Surname":"Khowal","Class":10,"SkillSet":["SQL","SSIS","SSRS","SSAS"],"IsDatabaseDeveloper":true}'; SELECT [Key],[Value] FROM OPENJSON(@j,'$.SkillSet') GO OUTPUT Key Value --------------------- ----------- 0 SQL 1 SSIS 2 SSRS 3 SSAS (4 rows affected) -- |
/* Using Option 1 – OPENJSON with the default output | Get DATA FROM Object/Array from JSON with Property – Add */
-- DECLARE @j NVARCHAR(MAX) SET @j = '{"Name":"Pawan","Add":{"State":"Illinois","Country":"Chicago"}}' SELECT [Key],[Value] FROM OPENJSON(@j, '$.Add') GO OUTPUT Key Value --------------------- ------------- State Illinois Country Chicago (2 rows affected) -- |
/* Using Option 1 – OPENJSON with the default output | Get DATA FROM single object..Just to split the data */
-- DECLARE @j NVARCHAR(MAX) SET @j = '[1,2,8,121,121,12,8910,17]' SELECT [Key],[Value] FROM OPENJSON(@j) GO OUTPUT Key Value -------------------------- -------------- 0 1 1 2 2 8 3 121 4 121 5 12 6 8910 7 17 (8 rows affected) -- |
/* Using Option 2 – OPENJSON output with an explicit structure | Get DATA FROM object..Add */
-- DECLARE @j NVARCHAR(MAX) SET @j = '{"Name":"Pawan","Add":{"State":"Illinois","Country":"Chicago"}}' SELECT * FROM OPENJSON(@j, '$.Add') WITH ( [State] VARCHAR(20) , [Country] VARCHAR(50) ) GO OUTPUT State Country -------------------- -------------------------------------------------- Illinois Chicago (1 row affected -- |
/* Using Option 2 – OPENJSON output with an explicit structure | Get DATA FROM object..Add and Name from the outer data */
-- DECLARE @j NVARCHAR(MAX) SET @j = '{"Devs":[{"Name":"Pawan","Adda":{"State":"Illinois","Country":"Chicago"}}]}' SELECT * FROM OPENJSON(@j,'$.Devs') WITH ( [Name] VARCHAR(10) '$.Name', [State] VARCHAR(20) '$.Adda.State', [Country] VARCHAR(20) '$.Adda.Country' ) GO OUTPUT Name State Country ---------- -------------------- -------------------- Pawan Illinois Chicago (1 row affected) -- |
/* Using Option 2 – OPENJSON output with an explicit structure | Get DATA FROM object..Add and Name from the outer data */
-- DECLARE @j NVARCHAR(MAX) SET @j = '{"Name":"Pawan","Adda":{"State":"Illinois","Country":"Chicago"}}' SELECT * FROM OPENJSON(@j) WITH ( [Name] VARCHAR(10), [State] VARCHAR(20) '$.Adda.State', [Country] VARCHAR(20) '$.Adda.Country' ) GO OUTPUT Name State Country ---------- -------------------- -------------------- Pawan Illinois Chicago (1 row affected) -- |
Refer Microsoft LINK below for more details-
Enjoy !!! Keep Learning
Pawan Khowal
Http://MSBISkills.com
Pingback: NEW T-SQL FEATURES IN SQL SERVER 2016 – XIII | ISJSON() | Improving my SQL BI Skills
Pingback: NEW T-SQL FEATURES IN SQL SERVER 2016 – XV | JSON_VALUE() | Improving my SQL BI Skills
Pingback: NEW T-SQL FEATURES IN SQL SERVER 2016 | Complete List | Improving my SQL BI Skills
Pingback: SQL Puzzle | Convert JSON Integer array to Table rows | SQL Interview Question | Improving my SQL BI Skills