Archive

Archive for the ‘SQL Server 2016’ Category

Reading JSON string with Nested array of elements | SQL Server 2016 – Part 3

November 1, 2015 36 comments

 

In my [previous post] I discussed about how to Import or Read a JSON string and convert it in relational/tabular format in row/column from.

 

Today in this post I’ll talk about how to read/parse JSON string with nested array of elements, just like XML.
Native JSON support in SQL Server 2016 provides you few functions to read and parse your JSON string into relational format and these are:

– OPENJSON() Table valued function: parses JSON text and returns rowset view of JSON.

– JSON_Value() Scalar function: returns a value from JSON on the specified path.

 

We will see usage of both the functions in our example below:

Here, we have just one nested element, and the OPENJSON() function will get you the child elements values:

–> Method #1.a. Using OPENJSON() function:

DECLARE @json NVARCHAR(1000)
SELECT @json = 
N'{
  "OrderHeader": [
    {
      "OrderID": 100,
      "CustomerID": 2000,
 
      "OrderDetail": 
        {
          "ProductID": 2000, 
          "UnitPrice": 350      
        }
    }
  ]
}'
 
SELECT 
    OrderID, 
    CustomerID, 
     
    [OrderDetail.ProductID] AS ProductID, 
    [OrderDetail.UnitPrice] AS UnitPrice 
 
FROM OPENJSON (@json, '$.OrderHeader') 
WITH (
    OrderID INT, 
    CustomerID INT, 
 
    [OrderDetail.ProductID] INT, 
    [OrderDetail.UnitPrice] INT
) AS Orders
OrderID	CustomerID	ProductID	UnitPrice
100	2000		2000		350

 

But, if you have more than one nested elements the same query will give just 1 row with NULL values under the child columns, like this.

–> Method #1.b. In case of multiple child elements:

DECLARE @json NVARCHAR(1000)
SELECT @json = 
N'{
  "OrderHeader": [
    {
      "OrderID": 100,
      "CustomerID": 2000,
 
      "OrderDetail": [
        {
          "ProductID": 2000, 
          "UnitPrice": 350      
        },      
        {             
          "ProductID": 3000,
          "UnitPrice": 450
        }
      ]
    }
  ]
}'
 
SELECT 
    OrderID, 
    CustomerID, 
     
    [OrderDetail.ProductID] AS ProductID, 
    [OrderDetail.UnitPrice] AS UnitPrice 
 
FROM OPENJSON (@json, '$.OrderHeader') 
WITH (
    OrderID INT, 
    CustomerID INT, 
 
    [OrderDetail.ProductID] INT, 
    [OrderDetail.UnitPrice] INT
) AS Orders 
OrderID	CustomerID	ProductID	UnitPrice
100	2000		NULL		NULL

You might be expecting 2 rows with same OrderID & CustomerID, with different ProductID & UnitPrice, right?

Instead you get ProductID & UnitPrice column values as NULL. Because, here you are having array of child elements with OrderDetail node (notice the square-bracket after “OrderDetail”: node), thus the Query is not able to find the key on the path.

 

In this case what you have to do is, use the array positions with square brackets (“[” and “]”) in your query and call out separate columns for each child element, like below:

DECLARE @json NVARCHAR(1000)
SELECT @json = 
N'{
  "OrderHeader": [
    {
      "OrderID": 100,
      "CustomerID": 2000,
 
      "OrderDetail": [
        {
          "ProductID": 2000, 
          "UnitPrice": 350      
        },      
        {             
          "ProductID": 3000,
          "UnitPrice": 450
        }
      ]
    }
  ]
}'
 
SELECT 
    OrderID, 
    CustomerID, 
 
    [OrderDetail[0]].ProductID] AS ProductID1, 
    [OrderDetail[0]].UnitPrice] AS UnitPrice1, 
 
    [OrderDetail[1]].ProductID] AS ProductID2, 
    [OrderDetail[1]].UnitPrice] AS UnitPrice2 
 
FROM OPENJSON (@json, '$.OrderHeader') 
WITH (
    OrderID INT, 
    CustomerID INT, 
 
    [OrderDetail[0]].ProductID] INT, 
    [OrderDetail[0]].UnitPrice] INT, 
 
    [OrderDetail[1]].ProductID] INT, 
    [OrderDetail[1]].UnitPrice] INT
) AS Orders
OrderID	CustomerID	ProductID1	UnitPrice1	ProductID2	UnitPrice2
100	2000		2000		350		3000		450

 

You can also specify the child elements with full path by using the dollar sign “$” inside the WITH() clause (instead at column level above), like below:

–> Method #2. Using OPENJSON() function:

DECLARE @json NVARCHAR(1000)
SELECT @json = 
N'{
  "OrderHeader": [
    {
      "OrderID": 100,
      "CustomerID": 2000,
 
      "OrderDetail": [
        {
          "ProductID": 2000, 
          "UnitPrice": 350      
        },      
        {             
          "ProductID": 3000,
          "UnitPrice": 450
        }
      ]
    }
  ]
}'
 
SELECT
    OrderID, 
    CustomerID, 
 
    ProductID1, 
    UnitPrice1, 
 
    ProductID2, 
    UnitPrice2
 
FROM OPENJSON (@json, '$.OrderHeader')
WITH (
    OrderID    INT '$.OrderID',
    CustomerID INT '$.CustomerID',
 
    ProductID1 INT '$.OrderDetail[0].ProductID',
    UnitPrice1 INT '$.OrderDetail[0].UnitPrice', 
 
    ProductID2 INT '$.OrderDetail[1].ProductID',
    UnitPrice2 INT '$.OrderDetail[1].UnitPrice'
) AS Orders
OrderID	CustomerID	ProductID1	UnitPrice1	ProductID2	UnitPrice2
100	2000		2000		350		3000		450

Ok, so by using the key path and the array position we can get the child elements value in our Query result-set by using above 2 methods.
But instead of having them in separate columns how about pulling them in separate rows, this will also make your query dynamic as you would not know the number of child-elements before hand, right?

 

This can be done by CROSS APPLYing the JSON child node with the parent node and using the JSON_Value() function, like shown below:

–> Method #3. Using JSON_Value() with OPENJSON() function:

DECLARE @json NVARCHAR(1000)
SELECT @json = 
N'{
  "OrderHeader": [
    {
      "OrderID": 100,
      "CustomerID": 2000,
 
      "OrderDetail": [
        {
          "ProductID": 2000, 
          "UnitPrice": 350      
        },      
        {             
          "ProductID": 3000,
          "UnitPrice": 450
        },
        {             
          "ProductID": 4000,
          "UnitPrice": 550
        }
      ]
    }
  ]
}'
 
SELECT
    JSON_Value (c.value, '$.OrderID') as OrderID, 
    JSON_Value (c.value, '$.CustomerID') as CustomerID, 
    JSON_Value (p.value, '$.ProductID') as ProductID, 
    JSON_Value (p.value, '$.UnitPrice') as UnitPrice
 
FROM OPENJSON (@json, '$.OrderHeader') as c
CROSS APPLY OPENJSON (c.value, '$.OrderDetail') as p
OrderID	CustomerID	ProductID	UnitPrice
100	2000		2000		350
100	2000		3000		450
100	2000		4000		550

 

Ok, that’s it for today.

In my [next post] I’ll talk about storing JSON string in a table and doing some hands-on with it.



Import/Read a JSON string and convert it in tabular (row/column) form | SQL Server 2016 – Part 2

October 30, 2015 6 comments

In my [previous post] I discussed on how to format/convert any Query/Table data to a string in JSON format. JSON in SQL Server was limited to this feature only till the CTP 2 version.

But now with the CTP 3 release you can do reverse of it also, means now you can read back JSON data and convert it to tabular or row & column format.
 

Let’s check this by taking same sample data from our previous JSON-Export post.

DECLARE @json NVARCHAR(1000)
SELECT @json = N'{"StudList":
[  
   {  
      "ID":1,
      "FirstName":"Manoj",
      "LastName":"Pandey",
      "Class":10,
      "Marks":80.5
   },
   {  
      "ID":2,
      "FirstName":"Saurabh",
      "LastName":"Sharma",
      "Class":11,
      "Marks":82.7
   },
   {  
      "ID":3,
      "FirstName":"Kanchan",
      "LastName":"Pandey",
      "Class":10,
      "Marks":90.5
   },
   {  
      "ID":4,
      "FirstName":"Rajesh",
      "LastName":"Shah",
      "Class":11,
      "Marks":70.3
   },
   {  
      "ID":5,
      "FirstName":"Kunal",
      "LastName":"Joshi",
      "Class":12,
      "Marks":64.7
   }
]'

SELECT ID, FirstName, LastName, Class, Marks
FROM OPENJSON (@json, '$.StudList')
WITH (
	ID INT, 
	FirstName VARCHAR(255), 
	LastName VARCHAR(255), 
	Class INT,
	Marks DECIMAL(3,1)
) AS StudList

– Output:
SQL Server 2016 - JSON export 01

Well, that was simple, isn’t it!!!
 

 

In my [next post] I’ll talk about Nested Properties in a JSON string with single and multiple elements.
 


SQL Server 2016 CTP 3 update is here | download now

October 29, 2015 Leave a comment

Microsoft yesterday (29-Oct-2015) announced the CTP 3 update of the recently and initially released Community Technology Preview (CTP) 2.x version of SQL Server 2016.
 

[Register and Download the CTP 3 Evaluation version (180 days) here]
 

–> Direct download link (~2.3 GB):

– Download the single ISO: SQLServer2016CTP3.0-x64-ENU.iso

– Or download both EXE & BOX files:
– – Box file SQLServer2016-x64-ENU.box
– – EXE file SQLServer2016-x64-ENU.exe

 

–> Check version and SQL build:

select @@version

Microsoft SQL Server 2016 (CTP3) – 13.0.700.139 (X64) Oct 7 2015 04:48:43 Copyright (c) Microsoft Corporation Enterprise Evaluation Edition (64-bit) on Windows 10 Enterprise 6.3 (Build 10240: )
 

–> The Major feature in this preview is the “RRE Integration”:

That is the Advanced Revolution Analytics R Integration, as SQL Server R Service within SQL Server 2016. “R” is the most popular programming language for Advanced Analytics. You can use it to analyze data, uncover patterns and trends and build predictive models. It offers an incredibly rich set of packages and a vibrant and fast-growing developer community.

SQL Server R Services with in-database analytics will help with:

– Data Exploration and Predictive Modeling with R over SQL Server data

– Operationalizing your R code using T-SQL

While installing SQL Server 2016, you will get an option to integrate R, it mentions “Includes Advanced Analytics Extensions that enables integration with R language using standard T-SQL statements.”, as shown below:

SQL Server 2016 - R - Advance Analytics

Post installation you need to go thru these steps to configure “R” with SQL Server, [link].
 

–> Another major feature is “Transactional Replication from SQL Server to Azure SQL DB”

Now you can setup Azure SQL DB as a subscriber of transaction replication, allowing you to migrate data from SQL Server instance on-premises or in IaaS to Azure SQL database without downtime.
 

–> With this release SQL Server team has added and improved lot of new features. Some of the important Enhancements and Issues fixed in this release are:
 

1. In-Memory improvements: [read more]

– Support for FOREIGN KEY, CHECK and UNIQUE constraints.

– Inline table-values functions.

– Existing NonClustered ColumnStore indexes are updateable without requiring index rebuild.

– Parallel Index build for NonClustered ColumnStore indexes.

– Performance improvements (INSERT, String pushdown, bypassing delete buffer when processing deleted rows).
 

2. Stretch Database improvements: [read more]

– Create/Drop index support

– Improved credential management for remote Stretch database stores.

– Improved performance for joins between stretched tables.

– SSMS GUI updates:
– – Database and Table level fly out menu options.
– – Stretch monitor functionality added to allow users to monitor current migration status, including the ability to pause the migration at the table level.
– – Added ability to Stretch individual tables, and added option to Stretch to new SQL Azure or existing SQL Azure server.
 

3. JSON improvements: [read more]

– OPENJSON() Table value function, parses JSON text and returns rowset.

– JSON_VALUE() Scalar function, returns a value from JSON on the specified path.

– ISJSON() function, validates that JSON is properly formatted.

– JSON_QUERY function, returns a fragment from the JSON text.
 

4. Temporal improvements: [read more]

– Support for using Temporal with In-Memory OLTP. Combining disk-based table for cost-effective storing of history data with memory-optimized tables for storing latest (actual) data.

– Direct ALTER for system-versioned temporal tables.

– New clause FOR SYSTEM_TIME ALL for querying entire data history easily without specifying period boundaries.

 

5. Row-Level Security (RLS) with Block Predicates: [read more]

– Preventing users from Inserting, Updating, and/or Deleting rows that violate the predicate.

– Security policies can now be created with SCHEMABINDING = OFF.
 

5. Query Store improvements [read more]

– Performance monitoring supported for In-Memory OLTP workloads.
 

–> Integration Services (SSIS) improvements:

– SSIS control flow template enables customers to save a commonly used control flow task or container to a standalone template file and reuse it multiple times in a package or multiple packages in a project.

– Added Azure blob source support for the Import/Export wizard.

– Relaxed Max Buffer Size of Data Flow Task.
 

–> Analysis Services (SSAS) improvements:

– DBCC support

– SSMS and SSDT updates for Tabular

– Check more at SSAS team blog.
 

–> Reporting Services (SSRS) improvements:

– Pin Reporting Services report items.

– Check more at SSRS team blog.
 

I’ve covered very few and important points here, you can check all the updates here in [SQL Server blog for CTP 3] with details.
 

For all these new features released in SQL Server 2016, check my blog posts here.
 

So, download the Preview today and start playing with the new features and plan your DB migration/upgrade.
 

 

Check & Like my FB Page.
 


SQL Server 2016 CTP 2.4 update is here | download now

October 1, 2015 Leave a comment

As pert of Microsoft’s rapid release model for SQL Server, Microsoft today announced the CTP 2.4 update of the recently and initially released Community Technology Preview (CTP) 2.2 version of SQL Server 2016 and the CTP 2.3, link.
 

[Register and Download the CTP 2.4 Evaluation version (180 days) here]
 

–> Direct download link (~2.3 GB):

– Box file SQLServer2016-x64-ENU.box
– EXE file SQLServer2016-x64-ENU.exe

 

–> Check version and SQL build:

select @@version

Microsoft SQL Server 2016 (CTP2.4) – 13.0.600.65 (X64) Sep 20 2015 01:45:59 Copyright (c) Microsoft Corporation Enterprise Evaluation Edition (64-bit) on Windows 10 Enterprise 6.3 (Build 10240: )
 

–> Enhancements and Issues fixed in this release:

1. Operational Analytics and In-Memory Data Warehouse improvements

– Existing Non-Clustered ColumnStore Indexes (NCCI) are updateable without requiring index rebuild.

– Parallel Index build of Non-Clustered ColumnStore Index (NCCI), leveraging available cores/logical processors available on the server for significant performance improvement.

– INSERT operations performance in delta Row Group. (Prior to CTP2.4, the delta rowgroup data was PAGE compressed, which added overhead for Insert operations. With CTP2.4, the data in delta rowgroup is no longer PAGE compressed.)

– Better Query performance with Non-Clustered ColumnStore Index (NCCI), with:
a. String predicate pushdown.
b. Improved query path when processing deleted rows by bypassing delete buffer when possible.

2. SQL Server Smart Maintenance Plans for effective database maintenance

– Consistency-checking strategy

– Backup strategy

– Index and statistics maintenance strategy

3. Tempdb scalability improvement

– Now provides a separate tab for tempdb files configuration.

SQL Server 2016 CTP 2.4 Setup 02

– optimistic latching of system pages when dropping temp tables.

 

–> Integration Services (SSIS) improvements:

1. Complex data feed including Data Streaming destination.

2. Balanced data distributor (BDD).

3. Excel 2013 source and destination (requires Access runtime 2013).

4. AlwaysOn support.

5. oData v4 source component in addition to oData v3.
 

–> Reporting Services (SSRS) improvements:

– Design-time control over layout of report parameters

– Export to PowerPoint

– A new printing feature that works across modern browsers.

– Check more at: http://blogs.msdn.com/b/sqlrsteamblog/archive/2015/09/30/more-reporting-services-enhancements-in-sql-server-2016-ctp-2-4.aspx
 

–> Deprecation:

– x86 Server deprecation, although all the x86 client tools and components are still available.
 

For all other new features released in SQL Server 2016, please check my blog posts here.
 

So, download the Preview today and start playing with the new features and plan your DB migration/upgrade.
 

Check the [SQL Server blog] for all these updates in detail.
 

 

Check & Like my FB Page.
 


Stretch your on-premise Database/Table to Azure SQL Database with StretchDB – SQL Server 2016

September 15, 2015 4 comments

Stretch Database lets you archive your historical data transparently and securely in the Azure SQL Database (i.e. Microsoft PaaS Cloud).

The idea is to have an On-Prem database configured to allow extension of one or more of its tables to a SQL Azure Database.

This extension to Azure can archive transparently “cold” data without change access to information requirements when the table is queried, all this while enjoying the very attractive storage cost proposed by Microsoft Azure.

SQL Server 2016 - StretchDB.JPG
 

–> We will see here how we can configure a Database for Stretch and enable it in a table in simple steps.

Step #1. Configure SQL Server instance to enable “Remote Data Archive”

USE [master]
GO

EXEC sp_configure 'remote data archive', '1';
RECONFIGURE;
GO

 

Step #2. Enable Database for Stretch to Azure

2.a. Enable a Database for Stretch from SSMS:

SQL Server 2016 - StretchDB 01

2.b. Sign-in to Microsoft Azure with your subscription ID:

SQL Server 2016 - StretchDB 02

2.c. Provide your preference for Azure Datacenter and login credentials:

SQL Server 2016 - StretchDB 03

2.d. Final page showing successful completion of enabling StretchDB:

SQL Server 2016 - StretchDB 04

2.e. Now go to the Azure portal and check the new SQL DB created by the Enable process:

SQL Server 2016 - StretchDB 05

2.f. Check the SQL Instance settings and DB Server name to connect it from SSMS:

SQL Server 2016 - StretchDB 06

Now we have a new Azure SQL Database created that is paired up with our On-prem SQL Server instance Database. We can not enable individual tables that we want to stretch to Azure.
 

Step #3. Now Create a table and insert some sample data in batches

USE [StretchDB]
GO

CREATE TABLE dbo.EmployeeStretch (
	EmployeeID	INT IDENTITY(1,1),
	EmployeeName VARCHAR(1000)
)

-- Batch 1
INSERT INTO dbo.EmployeeStretch (EmployeeName)
SELECT 'Manoj P'
UNION ALL
SELECT 'Saurabh S'
UNION ALL
SELECT 'Keshav K'
UNION ALL
SELECT 'Vivek S'
UNION ALL
SELECT 'Ganesh S'

select * from dbo.EmployeeStretch

 

Step #4. Enable Table for Stretch

With SSMS only you can enable a table for Stretch with 1-2 simple clicks, check the image below:

SQL Server 2016 - StretchDB 07

So, as soon as you enable this table for stretch the process creates an mutually equivalent table in Azure SQL DB with similar name which can be seen immediately via SSMS, check below:

SQL Server 2016 - StretchDB 08

On Querying this table the Stretch process adds an extra column with name “batchid–[object_id]” suffixed with the table ID belonging to On-prem SQL DB, check below:

SQL Server 2016 - StretchDB 09
 

Step #5. Load some more data in batches

-- Batch 2
INSERT INTO dbo.EmployeeStretch (EmployeeName)
SELECT 'Kaushik S'
UNION ALL
SELECT 'Deepak B'

select * from dbo.EmployeeStretch

-- Batch 3
INSERT INTO dbo.EmployeeStretch (EmployeeName)
SELECT 'Nitya S'
UNION ALL
SELECT 'Hema S'

select * from dbo.EmployeeStretch

-- Batch 4
INSERT INTO dbo.EmployeeStretch (EmployeeName)
SELECT TOP 100 CONCAT([FirstName], ' ', [LastName]) FROM [AdventureWorks2014].[Person].[Person]

select * from dbo.EmployeeStretch

As we’ve done INSERT in separate 4 Batches, thus you can see Batch IDs assigned to records from 1-4 under the batchid column of the Stretch table on Azure SQL DB, below:
SQL Server 2016 - StretchDB 10
 

–> Check the stats, i.e. space used by the table in on-prem and Azure DB:

sp_spaceused @objname = 'dbo.EmployeeStretch'
--Output: 
--name	               rows  reserved  data   index_size  unused
--dbo.EmployeeStretch  109   48 KB     16 KB  32 KB	  0 KB

sp_spaceused @objname = 'dbo.EmployeeStretch', @mode = N'LOCAL_ONLY'
--Output: 
--name	               rows  reserved  data   index_size  unused
--dbo.EmployeeStretch  0     16 KB     8 KB   8 KB        0 KB

sp_spaceused @objname = 'dbo.EmployeeStretch', @mode = N'REMOTE_ONLY'
--Output: 
--name	               rows  reserved  data   index_size  unused
--dbo.EmployeeStretch  109   32 KB     8 KB   24 KB       0 KB

The above stats clearly shows that the space used by Stretch enabled table in On-premise and On Azure SQL DB. As the data is moved behind the scenes from On-Prem to Azure SQL DB the space used by the table in On-prem is negligible i.e. some minimal default space.

–> Let’s load some more data as a 5th batch

-- Batch 5
INSERT INTO dbo.EmployeeStretch (EmployeeName)
SELECT TOP 1000 CONCAT([FirstName], ' ', [LastName]) FROM [AdventureWorks2014].[Person].[Person]

select * from dbo.EmployeeStretch

–> Now again check the space used:

sp_spaceused @objname = 'dbo.EmployeeStretch', @mode = N'REMOTE_ONLY'
--Output: 
--name	               rows  reserved  data   index_size  unused
--dbo.EmployeeStretch  1509  288 KB    80 KB  80 KB       128 KB

This again shows that whatever data you load on an On-Prem Stretch-enabled table it moves all data to Azure SQL DB without taking any space in On-prem DB, but on Azure SQL DB.
 

–> Some DMVs that you can use to check the stats of the data migration and Database’s & Table’s Stretch status:

select * from sys.dm_db_rda_migration_status

select * from sys.remote_data_archive_databases

select object_name (885578193), * from sys.remote_data_archive_tables

 

–> Let’s try to DELETE the Stretch Enabled table:

DELETE FROM dbo.EmployeeStretch WHERE EmployeeID >= 10

It throws following error:

Msg 14826, Level 14, State 1, Procedure trigger_RemoteDataArchive_885578193, Line 94
Update and delete of rows eligible for migration in table ‘EmployeeStretch’ is not allowed because of the use of REMOTE_DATA_ARCHIVE.
Msg 3609, Level 16, State 1, Line 79
The transaction ended in the trigger. The batch has been aborted.

 

Please Note: As of CTE 2.3 release you can’t run UPDATE or DELETE operations on a Stretch-enabled table.
 

You can check the same demo to configure StretchDB here:

 

Check & Like my FB Page.