Category Archives: Sql Server 2016

JSON_MODIFY Function in Sql Server 2016

JSON_MODIFY is one of the new JSON function introduced in Sql Server 2016. This function can be used to update the value of the property in a JSON string and returns the updated JSON string.

SYNTAX:

JSON_MODIFY (json_string, json_path , new_value)

WHERE
json_string : Is the JSON String which needs to be updated
json_path : Is the location of the property in the json_string, whose value needs to be updated
new_value : The new value for the property in the json_string

Let us understand this function with extensive list of examples.

EXAMPLE 1: Updating JSON Property Value

In this example the JSON_MODIFY function is used to update the FirstName property value from Basavaraj to Basav

SELECT
 JSON_MODIFY('{"FirstName":"Basavaraj","Last Name":"Biradar"}',
                   '$.FirstName','Basav') AS 'Updated JSON'

RESULT:
JSON_MODIFY Example 1

[ALSO READ] ISJSON Function in Sql Server 2016

EXAMPLE 2: Updating JSON property value where JSON_MODIFY function json_string and new_value are variables

This example is same as Example 1, the only difference here is instead of passing JSON string as a constant assigning it to the variable @json_string and passing this variable to the function. And the new value is set to the variable @new_value and passed it to the function.

DECLARE @json_string VARCHAR(100) 
	= '{"FirstName":"Basavaraj","Last Name":"Biradar"}',
	@new_value VARCHAR(50) = 'Basav'
SELECT JSON_MODIFY(@json_string,'$.FirstName',
                     @new_value) AS 'Updated JSON'

RESULT:
JSON_MODIFY Example 2

In the above example we can see that only the json_path is a string literal. Let us assign this also to a variable and pass it to the JSON_MODIFY function.

DECLARE @json_string VARCHAR(100) 
		= '{"FirstName":"Basavaraj","Last Name":"Biradar"}',
	@json_path VARCHAR(50) = '$.FirstName',
@new_value VARCHAR(50) = 'Basav'
SELECT JSON_MODIFY(@json_string, @json_path, 
                     @new_value) AS 'Updated JSON'

RESULT:

Msg 13610, Level 16, State 2, Line 5
The argument 2 of the “JSON_MODIFY” must be a string literal.

From the result we can see that the JSON PATH expression should always be a string literal

[ALSO READ] JSON_VALUE Function in Sql Server 2016

EXAMPLE 3: Adding Id property and it’s value to the JSON string

The below script adds the Id property to the JSON string

SELECT JSON_MODIFY(
   '{"FirstName":"Basavaraj","Last Name":"Biradar"}'
   , '$.Id', 1) AS 'Updated JSON'

RESULT:
JSON_MODIFY Insert Property Example 3

[ALSO READ] lax and strict JSON Path modes in Sql Server 2016

EXAMPLE 4: Impact of JSON Path mode on adding a new property to the existing JSON string

Execute the following statement which is same as the example 3 script, the only difference is in the json_path the JSON path mode strict is specified.

SELECT JSON_MODIFY(
      '{"FirstName":"Basavaraj","Last Name":"Biradar"}'
      , '$.Id', 1) AS 'Updated JSON'

RESULT:

Msg 13608, Level 16, State 2, Line 1
Property cannot be found on the specified JSON path.

From the result we can see that the strict path mode will not allow adding of a new property to the JSON string

Execute the following statement which is same as the above example script, the only difference is in the JSON path mode. Here in this statement the JSON path mode is lax and it is the default path mode when it is not specified.

SELECT JSON_MODIFY(
        '{"FirstName":"Basavaraj","Last Name":"Biradar"}'
		,'lax$.Id', 1 )	 AS 'Updated JSON'

RESULT:
JSON_MODIFY Insert Property lax path mode Example 4

From the result we can see that lax JSON Path mode allows adding a new JSON property. The JSON Path mode lax is the default path mode and if path mode is not specified it will consider it as lax. We can see that in example 3 when path mode is not specified we are able to add the new property.

[ALSO READ] JSON_QUERY Function in Sql Server 2016

EXAMPLE 5: This example shows how setting a NULL value for the JSON property will remove that property from the JSON string

SELECT JSON_MODIFY(
        '{"Id":1,"FirstName":"Basavaraj","Last Name":"Biradar"}'
		,'$.Id', NULL)	 AS 'Updated JSON'

RESULT:
Removing an Existing Property Example 5

[ALSO READ] FOR JSON Clause in Sql Server 2016

Example 6: This example explains how we can set a NULL value for a JSON property

In the example 5 we saw that setting a NULL value for a JSON property resulted in that property getting deleted from the JSON string. But if we have requirement where we need to set the NULL value for a JSON property value then in the JSON path we have to specify strict JSON path mode as in the below script:

SELECT JSON_MODIFY(
        '{"Id":1,"FirstName":"Basavaraj","Last Name":"Biradar"}'
		,'strict$.Id', NULL)	 AS 'Updated JSON'

RESULT:
Setting NULL value for a JSON property Example 6

[ALSO READ] OPENJSON Function in Sql Server 2016

EXAMPLE 7: This example shows how we can append a value to the JSON Array.

Execute the below statement to add the hobby Tennis to the Hobbies array:

SELECT JSON_MODIFY(
            '{"Id":1,"Name":"Basavaraj",
            "Hobbies":["Blogging","Cricket"]}',
            'append $.Hobbies','Tennis') AS 'Updated JSON'

RESULT:
Adding value to the JSON Array Example 7

[ALSO READ] STRING_SPLIT function in Sql Server 2016

EXAMPLE 8: This example shows how we can add a JSON object to the JSON string.

Execute the following statement to add Address which is of type JSON object to the JSON string:

SELECT JSON_MODIFY(
	'{"Id":1,"Name":"Basavaraj"}'
	,'$.Address'
	,'{"State":"KA","Country":"India"}') AS 'Updated JSON'

RESULT:
Adding JSON Object to JSON string Example 8

From the result we can see that JSON_MODIFY function is escaping the double quote in the JSON object which is getting added. The reason for this is JSON_MODIFY function is treating the JSON object as a normal text instead of valid JSON.

But if you want to avoid the escaping the JSON object which is getting added, use the JSON_QUERY function as shown below:

SELECT JSON_MODIFY(
    '{"Id":1,"Name":"Basavaraj"}'
    ,'$.Address'
    ,JSON_QUERY('{"State":"KA","Country":"India"}')) 
           AS 'Updated JSON'

RESULT:
Adding JSON Object to JSON string Example 8 1

[ALSO READ] DATEDIFF_BIG Function in Sql Server 2016

EXAMPLE 9: This example shows how we can modify the property value of JSON string stored in the Table Column.

Create a Customer table as shown in the below image with sample data by the following script

Customer Table
Script:

CREATE DATABASE SqlHintsJSONModify
GO
USE SqlHintsJSONModify
GO
CREATE TABLE dbo.Customer( 
    Id INT IDENTITY(1,1) NOT NULL PRIMARY KEY,
    Name NVARCHAR(50), Detail NVARCHAR(MAX))
GO
INSERT INTO dbo.Customer ( Name, Detail )
VALUES 
  ('Basavaraj','{"Address":{"State":"KA","Country":"India"}}'),
  ('Kalpana','{"Address":{"State":"MH","Country":"India"}}')

Execute the following statement and observe that the customer Kalpana’s state property value in the Detail column is MH.

SELECT * FROM dbo.Customer WHERE Name = 'Kalpana'

RESULT:
DataBeforeUpdate

Execute the following statement to update the Customer Kalpana’s State to KA from MH.

UPDATE Customer
SET Detail = JSON_MODIFY(Detail , '$.Address.State','KA')
WHERE Name = 'Kalpana'

Now execute the following statement to check whether the customer Kalpana’s state value is updated to KA from MH.

SELECT * FROM dbo.Customer WHERE Name = 'Kalpana'

RESULT:
DataAfterUpdate

[ALSO READ]

New features in SQL SERVER 2016

STRING_SPLIT function in Sql Server 2016

STRING_SPLIT is one of the new built-in table valued function introduced in Sql Server 2016. This table valued function splits the input string by the specified character separator and returns output as a table.

SYNTAX:

STRING_SPLIT (string, separator)

Where string is a character delimited string of type CHAR, VARCHAR, NVARCHAR and NCHAR.
Separator is a single character delimiter by which the input string need to be split. The separator character can be one of the type: CHAR(1), VARCHAR(1), NVARCHAR(1) and NCHAR(1).
Result of this function is a table with one column with column name as value.

Let us understand this function with extensive list of examples:

EXAMPLE 1: This example shows how we can use STRING_SPLIT function to splits the comma separated string.

SELECT * 
FROM STRING_SPLIT('Basavaraj,Kalpana,Shree',',')

RESULT:
Sql STRING_SPLIT Function Example 1

EXAMPLE 2: In this example, passing string and separator parameters as variables.

DECLARE @string VARCHAR(100) = 'Basavaraj,Kalpana,Shree',
        @separator CHAR(1) =',' 
SELECT * 
FROM STRING_SPLIT(@string,@separator)

RESULT:
Sql STRING_SPLIT Function Example 2

Let us execute the following statement which is moving the split result into a temp table. After inserting the split result into the temp table we are verifying the split result column type by using the sp_columns system stored procedure.

DECLARE @string VARCHAR(100) = 'Basavaraj,Kalpana,Shree',
        @separator CHAR(1) =',' 
SELECT *
	INTO #TempTable
FROM STRING_SPLIT(@string,@separator)
GO
TEMPDB..sp_Columns #TempTable

RESULT:
Sql STRING_SPLIT Function Example 21

From the result we can conclude that the size of the value column in the table returned by the STRING_SPLIT function will be same as that of the string which needs to split and type will be VARCHAR if the string which needs to be split is of type CHAR or VARCHAR.

EXAMPLE 3: This example demonstrates that the separator can be of only one character.

DECLARE @string VARCHAR(100) = 'Basavaraj#@Kalpana#@Shree',
        @separator CHAR(2) ='#@' 
SELECT * FROM STRING_SPLIT(@string,@separator)

RESULT:

Msg 214, Level 16, State 11, Line 3
Procedure expects parameter ‘separator’ of type ‘nchar(1)/nvarchar(1)’.

Let us re-try this example by using a single character separator instead of two characters

DECLARE @string VARCHAR(100) = 'Basavaraj#@Kalpana#@Shree',
        @separator CHAR(2) ='@' 
SELECT * FROM STRING_SPLIT(@string,@separator)

RESULT:
Sql STRING_SPLIT Function Example 3

From the above example results it is clear that the separator should always be a single character of any one of the data type CHAR(1), VARCHAR(1), NVARCHAR(1) and NCHAR(1).

EXAMPLE 4: In this example both the string which needs to be split and the separator are double byte characters.

DECLARE @string NVARCHAR(100) = N'你好中你好',
        @separator NCHAR(1) =N'中' 
SELECT * FROM STRING_SPLIT(@string,@separator)

RESULT:
Sql STRING_SPLIT Function Example 4

Let us execute the following statement which is moving the split result into a temp table. After inserting the split result into the temp table we are verifying the split result column type by using the sp_columns system stored procedure.

DECLARE @string NVARCHAR(100) = N'你好中你好',
        @separator NCHAR(1) =N'中' 
SELECT * 
	INTO #TempTbl
FROM STRING_SPLIT(@string,@separator)
GO
TEMPDB..sp_Columns #TempTbl

RESULT:
Sql STRING_SPLIT Function Example 41

From the result we can conclude that the size of the value column in the table returned by the STRING_SPLIT function will be same as that of the string which needs to split and type will be NVARCHAR if the string which needs to be split is of type NCHAR or NVARCHAR.

EXAMPLE 5: This example explains the behavior of the STRING_SPLIT function if the parameters are null

Let us execute the following statement where the Separator is NULL

SELECT * FROM STRING_SPLIT('Basavaraj,Kalpana,Shree',NULL)

RESULT:

Msg 214, Level 16, State 11, Line 1
Procedure expects parameter ‘separator’ of type ‘nchar(1)/nvarchar(1)’.

Let us execute the following statement where the string which needs to be split is NULL.

SELECT * FROM STRING_SPLIT(NULL,',')

RESULT:
Sql STRING_SPLIT Function Example 5

EXAMPLE 6: In this example we are splitting the string and the resultant table is joined with another table

Let us create a customer table with sample records by executing the following script

--Create customer table
CREATE TABLE Customer 
( CustomerId INT IDENTITY (1, 1) NOT NULL ,
  FirstName NVARCHAR(50), LastName NVARCHAR(50))
GO
--Insert 3 sample records into the customer table 
INSERT INTO dbo.Customer ( FirstName, LastName )
VALUES ('Basavaraj','Biradar'),
       ('Kalpana','Patil'),
       ('Shree','Biradar')

Execute the below state to split the string and the resultant table is joined with another table

SELECT *
FROM dbo.Customer C 
		INNER JOIN STRING_SPLIT('Basavaraj,Shree',',') SF
			ON C.FirstName = SF.value

RESULT:
Sql STRING_SPLIT Function Example 6

EXAMPLE 7: This example explains the behavior of the STRING_SPLIT function if the string to be split is an empty string

SELECT * FROM STRING_SPLIT('',',')

RESULT:
Sql STRING_SPLIT Function Example 7

EXAMPLE 8: This example shows the behavior of the STRING_SPLIT function if the string to be split is terminated by the separator character

SELECT * FROM STRING_SPLIT('Basavaraj,Shree,',',')

RESULT:
Sql STRING_SPLIT Function Example 8
[ALSO READ]

SQL SERVER 2016

Dynamic Data Masking in Sql Server 2016

Dynamic data masking is one of the new Security Feature introduced in Sql Server 2016. It provides a mechanism to obfuscate or mask the data from non-privileged users. And the users with sufficient permission will have complete access to the actual or un-masked data.

Traditionally, if we see the application layer takes care of masking the data and displaying it. For example: from database layer we will get a clear SSN number like 123-321-4567, but the application will mask and display it to the user as XXX-XXX-4567. With dynamic data masking from database layer only we can return the query result with masked data if user doesn’t have sufficient permission to view the actual/Unmasked data.

[ALSO READ] Row level security in Sql Server 2016

Dynamic data masking functions/rule can be defined on the table columns for which we need the masked out-put in the query result. It doesn’t change the actual value stored in the column. Masking function is applied on the query result just before returning the data, if user doesn’t have the enough permission to get the un-masked data. But user with db-owner or UNMASK permission will get the un-masked data in the query result for the masked columns. Masked out-put will be of the same data type as the column data type, in that way we can readily use this feature without really needing changes to the application layer.

[ALSO READ] New Features in Sql Server 2016

Following are the four masking functions which can be defined on table column

  1. Default
  2. Email
  3. Partial
  4. Random

To understand each of these masking function let us create a Customer Table as shown in the following image by the following script:

Example Dynamic Data Masking Table
SCRIPT:

CREATE DATABASE SqlHintsDDMDemo
GO
USE SqlHintsDDMDemo
GO
CREATE TABLE dbo.Employee
(
 EmployeeId INT IDENTITY(1,1), Name NVARCHAR(100), DOJ DATETIME,
 EmailAddress NVARCHAR(100), Phone Varchar(15),	Salary INT
)
GO
INSERT INTO dbo.Employee (Name, DOJ, EmailAddress,Phone, Salary)
Values
 ('Basavaraj', '02/20/2005', 'basav@sqlhints.com',
   '123-4567-789',900000),
 ('Kalpana', '07/01/2015', 'kalpana@sqlhints.co.in',
   '123-4567-789',100000)
GO

Let us now understand one-by-one the dynamic data masking functions. These functions can be applied to columns during table creation or can be added to the existing table columns.

1. Default()

This dynamic data masking functions behavior is based on the data type of the column on which it is applied

  • For string types it shows X for each character and max it displays 4 X’s.
  • For numeric types it shows 0
  • For dates shows 1900-01-01 00:00:00.000

Let us apply the DEFAULT dynamic data masking function on the Name and DOJ columns of the Employee table by executing the following statement

---Add DEFAULT() masking function on the Name column
ALTER Table Employee
ALTER COLUMN NAME ADD MASKED WITH (FUNCTION='DEFAULT()')

---Add DEFAULT() masking function on the Name column
ALTER Table Employee
ALTER COLUMN DOJ ADD MASKED WITH (FUNCTION='DEFAULT()')

Let us create a new user and grant select permission on the Employee table by executing the following query.

--Create user reader
CREATE USER reader WITHOUT LOGIN
--Grant select permission to the user: reader
GRANT SELECT ON Employee TO reader

Let us try to fetch the records from the Employee table by executing the query in the context of this new user

EXECUTE AS USER = 'reader'
SELECT * FROM Employee
REVERT

RESULT:
Default Dynamic Data Masking Function

From the result we can see that Name column values are replaced by XXXX and DOJ column values are replaced by 1900-01-01 00:00:00.000 in the query result.

Grant UNMASK permission to the newly created user reader to allow viewing of the un-masked data by executing the following query.

--Grant Unmask permission to the user: reader
GRANT UNMASK TO reader

Now try re-executing the previously executed query to fetch the records from the Employee table in the context of the user reader

EXECUTE AS USER = 'reader'
SELECT * FROM Employee
REVERT

RESULT:
UnMask Permission Dynamic Data Masking

From the result we can see that now the reader user can see the un-masked or actual data of the masked columns Name and DOJ

Let us remove the UNMASK permission from the user reader by executing the following statement

--Remove Unmask permission from the user: reader
REVOKE UNMASK TO reader

2. Email()

This dynamic data masking function returns first character as it is and rest is replaced by XXX@XXXX.com.

Let us apply the EMAIL dynamic data masking function on the EmailAddress Column of the Employee table by executing the following statement

---Add Email() masking function on the Name column
ALTER Table Employee
ALTER COLUMN EmailAddress 
 ADD MASKED WITH (FUNCTION='Email()')

Let us try to fetch the records from the Employee table by executing the query in the context of the user reader

EXECUTE AS USER = 'reader'
SELECT * FROM Employee
REVERT

RESULT:
Email Dynamic Data Masking Function

From the result we can see that Email column values are replaced by first character as it is followed by XXX@XXXX.com in the query result.

Let us verify whether we can query a masked column value by the actual value. In the below example trying to fetch a employee record whose EmailAddress is kalpana@sqlhints.co.in in the context of the user reader

EXECUTE AS USER = 'reader'
SELECT * FROM Employee 
WHERE EmailAddress = 'kalpana@sqlhints.co.in'
REVERT

RESULT:
Where clause on masked column

3. Partial()

This dynamic data masking function provides a mechanism where we can reveal first and last few specified number of characters with a custom padding string in the middle.

partial (prefix ,padding , suffix)

Where: prefix is the starting number of characters to be revealed and suffix is the last number of characters to be revealed from the column value. Padding is the custom padding string in the middle.

Let us apply the PARTIAL dynamic data masking function on the Phone column of the Employee table by executing the following statement

ALTER Table Employee
ALTER COLUMN Phone 
 ADD MASKED WITH (FUNCTION='Partial(2,"-ZZZ-",2)')

Let us try to fetch the records from the Employee table by executing the query in the context of the user reader

EXECUTE AS USER = 'reader'
SELECT * FROM Employee
REVERT

RESULT:
Partial Dynamic Data Masking Function

From the result we can see that Phone’s first and last 2 characters are revealed in the masked result and in the middle it is padded by the string -ZZZ-.

4. Random()

This dynamic data masking function can be applied on a column of numeric type. It returns a random value between the specified ranges.

Let us apply the RANDOM dynamic data masking function with a random value range from 1 to 9 on the Salary column of the Employee table by executing the following statement

ALTER Table Employee
ALTER COLUMN Salary ADD MASKED WITH (FUNCTION='Random(1,9)')

Let us try to fetch the records from the Employee table by executing the query in the context of the user reader

EXECUTE AS USER = 'reader'
SELECT * FROM Employee
REVERT

RESULT:
Random Dynamic Data Masking Function
Removing MASK definition from the Table Column

Below example shows how we can remove masked definition from the table column. Here in this example we are removing mask definition from the Phone column of the Employee table.

ALTER TABLE Employee 
ALTER COLUMN Phone DROP MASKED

Conclusion:

Dynamic Data masking provides a mechanism to mask or obfuscate the query result at the database level. The data stored in the data base is still in the clear or un-masked format. It is not a physical data encryption feature, an admin user or user with sufficient unmask permission can still see the complete un-masked data. This is a complementary security feature which is best-advised to use in-conjunction with other Sql Server Security features.

[ALSO READ]:

SQL SERVER 2016