Skip to content

Commit 31079c2

Browse files
Add datetime masking method to overview section and update TDE (#35913)
Co-authored-by: Madhumita Tripathy <94600140+Madhumitatripathy@users.noreply.github.com>
1 parent 2031639 commit 31079c2

File tree

2 files changed

+110
-80
lines changed

2 files changed

+110
-80
lines changed

azure-sql/database/dynamic-data-masking-overview.md

Lines changed: 97 additions & 67 deletions
Original file line numberDiff line numberDiff line change
@@ -1,11 +1,11 @@
11
---
2-
title: Dynamic data masking
2+
title: Dynamic Data Masking
33
titleSuffix: Azure SQL Database & Azure SQL Managed Instance & Azure Synapse Analytics
44
description: Dynamic data masking (DDM) limits sensitive data exposure by masking it to nonprivileged users for Azure SQL Database, Azure SQL Managed Instance, and Azure Synapse Analytics.
55
author: madhumitatripathy
66
ms.author: matripathy
77
ms.reviewer: wiassaf, vanto, mathoma, randolphwest
8-
ms.date: 05/17/2024
8+
ms.date: 11/24/2025
99
ms.service: azure-sql
1010
ms.subservice: security
1111
ms.topic: conceptual
@@ -23,27 +23,30 @@ Azure SQL Database, SQL database in Microsoft Fabric, Azure SQL Managed Instance
2323

2424
Dynamic data masking helps prevent unauthorized access to sensitive data by enabling customers to designate how much of the sensitive data to reveal with minimal effect on the application layer. It's a policy-based security feature that hides the sensitive data in the result set of a query over designated database fields, while the data in the database isn't changed.
2525

26-
For example, a service representative at a call center might identify a caller by confirming several characters of their email address, but the complete email address shouldn't be revealed to the service representative. A masking rule can be defined that masks all the email address in the result set of any query. As another example, an appropriate data mask can be defined to protect personal data, so that a developer can query production environments for troubleshooting purposes without violating compliance regulations.
26+
For example, a service representative at a call center might identify a caller by confirming several characters of their email address, but the complete email address shouldn't be revealed to the service representative. A masking rule can be defined that masks the entire email address in the result set of any query. As another example, an appropriate data mask can be defined to protect personal data, so that a developer can query production environments for troubleshooting purposes without violating compliance regulations.
2727

2828
## Dynamic data masking basics
2929

30-
For Azure SQL Database, you set up a dynamic data masking policy in the Azure portal by selecting the **Dynamic Data Masking** pane under **Security** in your SQL Database configuration pane.
30+
For Azure SQL Database, you set up a dynamic data masking policy in the Azure portal by selecting the **Dynamic Data Masking** pane under **Security** in your SQL Database configuration pane.
3131

32-
This feature can't be set using the Azure portal for SQL Managed Instance or SQL database in Fabric. Instead, use T-SQL, as in the [Dynamic Data Masking example in this article](#granular-permission-example). For more information, see [Dynamic Data Masking](/sql/relational-databases/security/dynamic-data-masking).
32+
This feature can't be set using the Azure portal for SQL Managed Instance or SQL database in Fabric. Instead, use Transact-SQL (T-SQL), as in the [Granular permission example](#granular-permission-example) in this article. For more information, see [Dynamic data masking](/sql/relational-databases/security/dynamic-data-masking).
3333

3434
### Dynamic data masking policy
3535

36-
- **SQL users excluded from masking:** A set of SQL users, which can include identities from Microsoft Entra ID ([formerly Azure Active Directory](/entra/fundamentals/new-name)), that get unmasked data in the SQL query results. Users with administrative rights like server admin, Microsoft Entra admin, and db_owner role can view the original data without any mask. (Note: It also applies to sysadmin role in SQL Server)
36+
- **SQL users excluded from masking:** A set of SQL users, which can include identities from Microsoft Entra ID, that get unmasked data in the SQL query results. Users with administrative rights like server admin, Microsoft Entra admin, and db_owner role can view the original data without any mask. (Note: It also applies to sysadmin role in SQL Server)
37+
3738
- **Masking rules:** A set of rules that define the designated fields to be masked and the masking function that is used. The designated fields can be defined using a database schema name, table name, and column name.
39+
3840
- **Masking functions:** A set of methods that control the exposure of data for different scenarios.
3941

40-
| Masking function | Masking logic |
41-
| --- | --- |
42-
| **Default** | **Full masking according to the data types of the designated fields**<br /><br />* Use `XXXX` (or fewer) if the size of the field is fewer than 4 characters for string data types (**nchar**, **ntext**, **nvarchar**).<br />* Use a zero value for numeric data types (**bigint**, **bit**, **decimal**, **int**, **money**, **numeric**, **smallint**, **smallmoney**, **tinyint**, **float**, **real**).<br />* Use `1900-01-01` for date/time data types (**date**, **datetime2**, **datetime**, **datetimeoffset**, **smalldatetime**, **time**).<br />* For **sql_variant**, the default value of the current type is used.<br />* For XML, the document `<masked />` is used.<br />* Use an empty value for special data types (**timestamp**, **table**, **HierarchyID**, **uniqueidentifier**, **binary**, **image**, **varbinary**, and spatial types). |
43-
| **Credit card** | **Masking method, which exposes the last four digits of the designated fields** and adds a constant string as a prefix in the form of a credit card.<br /><br />`XXXX-XXXX-XXXX-1234` |
44-
| **Email** | **Masking method, which exposes the first letter and replaces the domain with XXX.com** using a constant string prefix in the form of an email address.<br /><br />`aXX@XXXX.com` |
45-
| **Random number** | **Masking method, which generates a random number** according to the selected boundaries and actual data types. If the designated boundaries are equal, then the masking function is a constant number.<br /><br /> :::image type="content" source="media/dynamic-data-masking-overview/random-number.png" alt-text="Screenshot that shows the masking method for generating a random number."::: |
46-
| **Custom text** | **Masking method, which exposes the first and last characters** and adds a custom padding string in the middle. If the original string is shorter than the exposed prefix and suffix, only the padding string is used.<br /><br />`prefix[padding]suffix`<br /> :::image type="content" source="media/dynamic-data-masking-overview/custom-text.png" alt-text="Screenshot of the navigation pane."::: |
42+
| Masking function | Masking logic |
43+
| --- | --- |
44+
| **Default** | **Full masking according to the data types of the designated fields**<br /><br />*Use `XXXX` (or fewer) if the size of the field is fewer than 4 characters for string data types (**nchar**, **ntext**, **nvarchar**).<br />* Use a zero value for numeric data types (**bigint**, **bit**, **decimal**, **int**, **money**, **numeric**, **smallint**, **smallmoney**, **tinyint**, **float**, **real**).<br />*Use `1900-01-01` for date/time data types (**date**, **datetime2**, **datetime**, **datetimeoffset**, **smalldatetime**, **time**).<br />* For **sql_variant**, the default value of the current type is used.<br />*For XML, the document `<masked />` is used.<br />* Use an empty value for special data types (**timestamp**, **table**, **HierarchyID**, **uniqueidentifier**, **binary**, **image**, **varbinary**, and spatial types). |
45+
| **Credit card** | **Masking method, which exposes the last four digits of the designated fields** and adds a constant string as a prefix in the form of a credit card.<br /><br />`XXXX-XXXX-XXXX-1234` |
46+
| **Email** | **Masking method, which exposes the first letter and replaces the domain with XXX.com** using a constant string prefix in the form of an email address.<br /><br />`aXX@XXXX.com` |
47+
| **Random number** | **Masking method, which generates a random number** according to the selected boundaries and actual data types. If the designated boundaries are equal, then the masking function is a constant number.<br /><br />:::image type="content" source="media/dynamic-data-masking-overview/random-number.png" alt-text="Screenshot that shows the masking method for generating a random number."::: |
48+
| **Custom text** | **Masking method, which exposes the first and last characters** and adds a custom padding string in the middle. If the original string is shorter than the exposed prefix and suffix, only the padding string is used.<br /><br />`prefix[padding]suffix`<br />:::image type="content" source="media/dynamic-data-masking-overview/custom-text.png" alt-text="Screenshot of the navigation pane."::: |
49+
| **Datetime** | **Enables granular masking for date/time columns**, namely **datetime**, **datetime2**, **date**, **time**, **datetimeoffset**, and **smalldatetime**. You can mask specific components such as year (`datetime("Y")`), month (`datetime("M")`), day (`datetime("D")`), hour (`datetime("h")`), minute (`datetime("m")`), or second (`datetime("s")`). You apply this function using T-SQL.<br /><br />For example:<br /><br />- Mask year: `ALTER COLUMN BirthDay ADD MASKED WITH (FUNCTION = 'datetime("Y")')`.<br />- Mask month: `ALTER COLUMN BirthDay ADD MASKED WITH (FUNCTION = 'datetime("M")')`.<br />- Mask minute: `ALTER COLUMN BirthDay ADD MASKED WITH (FUNCTION = 'datetime("m")')`. |
4750

4851
### Recommended fields to mask
4952

@@ -86,7 +89,7 @@ You can use the REST API to programmatically manage data masking policy and rule
8689

8790
## Permissions
8891

89-
These are the built-in roles to configure dynamic data masking is:
92+
You can configure dynamic data masking with the following built-in roles:
9093

9194
- [SQL Security Manager](/azure/role-based-access-control/built-in-roles#sql-security-manager)
9295
- [SQL DB Contributor](/azure/role-based-access-control/built-in-roles#sql-db-contributor)
@@ -110,7 +113,7 @@ To learn more about permissions when using dynamic data masking with T-SQL comma
110113

111114
## Granular permission example
112115

113-
Prevent unauthorized access to sensitive data and gain control by masking it to an unauthorized user at different levels of the database. You can grant or revoke UNMASK permissions at the database-level, schema-level, table-level or at the column-level to any database user or role. Combined with Microsoft Entra authentication, UNMASK permissions can be managed for users, groups, and applications maintained within your Azure environment. The UNMASK permission provides a granular way to control and limit unauthorized access to data stored in the database and improve data security management.
116+
Prevent unauthorized access to sensitive data and gain control by masking it to an unauthorized user at different levels of the database. You can grant or revoke `UNMASK` permissions at the database-level, schema-level, table-level or at the column-level to any database user or role. Combined with Microsoft Entra authentication, `UNMASK` permissions can be managed for users, groups, and applications maintained within your Azure environment. The `UNMASK` permission provides a granular way to control and limit unauthorized access to data stored in the database and improve data security management.
114117

115118
1. Create schema to contain user tables:
116119

@@ -122,12 +125,13 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
122125
1. Create table with masked columns:
123126

124127
```sql
125-
CREATE TABLE Data.Membership (
126-
MemberID INT IDENTITY(1, 1) NOT NULL,
127-
FirstName VARCHAR(100) MASKED WITH (FUNCTION = 'partial(1, "xxxxx", 1)') NULL,
128-
LastName VARCHAR(100) NOT NULL,
129-
Phone VARCHAR(12) MASKED WITH (FUNCTION = 'default()') NULL,
130-
Email VARCHAR(100) MASKED WITH (FUNCTION = 'email()') NOT NULL,
128+
CREATE TABLE Data.Membership
129+
(
130+
MemberID INT IDENTITY (1, 1) NOT NULL,
131+
FirstName VARCHAR (100) MASKED WITH (FUNCTION = 'partial(1, "xxxxx", 1)') NULL,
132+
LastName VARCHAR (100) NOT NULL,
133+
Phone VARCHAR (12) MASKED WITH (FUNCTION = 'default()') NULL,
134+
Email VARCHAR (100) MASKED WITH (FUNCTION = 'email()') NOT NULL,
131135
DiscountCode SMALLINT MASKED WITH (FUNCTION = 'random(1, 100)') NULL,
132136
BirthDay DATETIME MASKED WITH (FUNCTION = 'default()') NULL
133137
);
@@ -137,11 +141,10 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
137141

138142
```sql
139143
INSERT INTO Data.Membership (FirstName, LastName, Phone, Email, DiscountCode, BirthDay)
140-
VALUES
141-
('Roberto', 'Tamburello', '555.123.4567', 'RTamburello@contoso.com', 10, '1985-01-25 03:25:05'),
142-
('Janice', 'Galvin', '555.123.4568', 'JGalvin@contoso.com.co', 5, '1990-05-14 11:30:00'),
143-
('Shakti', 'Menon', '555.123.4570', 'SMenon@contoso.net', 50, '2004-02-29 14:20:10'),
144-
('Zheng', 'Mu', '555.123.4569', 'ZMu@contoso.net', 40, '1990-03-01 06:00:00');
144+
VALUES ('Roberto', 'Tamburello', '555.123.4567', 'RTamburello@contoso.com', 10, '1985-01-25 03:25:05'),
145+
('Janice', 'Galvin', '555.123.4568', 'JGalvin@contoso.com.co', 5, '1990-05-14 11:30:00'),
146+
('Shakti', 'Menon', '555.123.4570', 'SMenon@contoso.net', 50, '2004-02-29 14:20:10'),
147+
('Zheng', 'Mu', '555.123.4569', 'ZMu@contoso.net', 40, '1990-03-01 06:00:00');
145148
```
146149

147150
1. Create schema to contain service tables:
@@ -154,9 +157,10 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
154157
1. Create service table with masked columns:
155158

156159
```sql
157-
CREATE TABLE Service.Feedback (
158-
MemberID INT IDENTITY(1, 1) NOT NULL,
159-
Feedback VARCHAR(100) MASKED WITH (FUNCTION = 'default()') NULL,
160+
CREATE TABLE Service.Feedback
161+
(
162+
MemberID INT IDENTITY (1, 1) NOT NULL,
163+
Feedback VARCHAR (100) MASKED WITH (FUNCTION = 'default()') NULL,
160164
Rating INT MASKED WITH (FUNCTION = 'default()'),
161165
Received_On DATETIME
162166
);
@@ -166,10 +170,9 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
166170

167171
```sql
168172
INSERT INTO Service.Feedback (Feedback, Rating, Received_On)
169-
VALUES
170-
('Good', 4, '2022-01-25 11:25:05'),
171-
('Excellent', 5, '2021-12-22 08:10:07'),
172-
('Average', 3, '2021-09-15 09:00:00');
173+
VALUES ('Good', 4, '2022-01-25 11:25:05'),
174+
('Excellent', 5, '2021-12-22 08:10:07'),
175+
('Average', 3, '2021-09-15 09:00:00');
173176
```
174177

175178
1. Create different users in the database:
@@ -192,40 +195,53 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
192195

193196
```sql
194197
ALTER ROLE db_datareader ADD MEMBER ServiceAttendant;
195-
196198
ALTER ROLE db_datareader ADD MEMBER ServiceLead;
197-
198199
ALTER ROLE db_datareader ADD MEMBER ServiceManager;
199-
200200
ALTER ROLE db_datareader ADD MEMBER ServiceHead;
201201
```
202202

203-
1. Grant different UNMASK permissions to users:
203+
1. Grant different `UNMASK` permissions to users:
204204

205-
```sql
206-
--Grant column level UNMASK permission to ServiceAttendant
207-
GRANT UNMASK ON Data.Membership(FirstName) TO ServiceAttendant;
205+
- Grant column level `UNMASK` permission to `ServiceAttendant`:
208206

209-
-- Grant table level UNMASK permission to ServiceLead
210-
GRANT UNMASK ON Data.Membership TO ServiceLead;
207+
```sql
208+
GRANT UNMASK ON Data.Membership (FirstName) TO ServiceAttendant;
209+
```
211210

212-
-- Grant schema level UNMASK permission to ServiceManager
213-
GRANT UNMASK ON SCHEMA::Data TO ServiceManager;
214-
GRANT UNMASK ON SCHEMA::Service TO ServiceManager;
211+
- Grant table level `UNMASK` permission to `ServiceLead`:
215212

216-
--Grant database level UNMASK permission to ServiceHead;
217-
GRANT UNMASK TO ServiceHead;
218-
```
213+
```sql
214+
GRANT UNMASK ON Data.Membership TO ServiceLead;
215+
```
216+
217+
- Grant schema level `UNMASK` permission to `ServiceManager`:
218+
219+
```sql
220+
GRANT UNMASK ON SCHEMA::Data TO ServiceManager;
221+
GRANT UNMASK ON SCHEMA::Service TO ServiceManager;
222+
```
223+
224+
- Grant database level `UNMASK` permission to `ServiceHead`;
225+
226+
```sql
227+
GRANT UNMASK TO ServiceHead;
228+
```
219229

220230
1. Query the data under the context of user `ServiceAttendant`:
221231

222232
```sql
223233
EXECUTE AS USER = 'ServiceAttendant';
224234
225-
SELECT MemberID, FirstName, LastName, Phone, Email, BirthDay
235+
SELECT MemberID,
236+
FirstName,
237+
LastName,
238+
Phone,
239+
Email,
240+
BirthDay
226241
FROM Data.Membership;
227-
228-
SELECT MemberID, Feedback, Rating
242+
SELECT MemberID,
243+
Feedback,
244+
Rating
229245
FROM Service.Feedback;
230246
231247
REVERT;
@@ -236,10 +252,16 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
236252
```sql
237253
EXECUTE AS USER = 'ServiceLead';
238254
239-
SELECT MemberID, FirstName, LastName, Phone, Email, BirthDay
255+
SELECT MemberID,
256+
FirstName,
257+
LastName,
258+
Phone,
259+
Email,
260+
BirthDay
240261
FROM Data.Membership;
241-
242-
SELECT MemberID, Feedback, Rating
262+
SELECT MemberID,
263+
Feedback,
264+
Rating
243265
FROM Service.Feedback;
244266
245267
REVERT;
@@ -250,10 +272,16 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
250272
```sql
251273
EXECUTE AS USER = 'ServiceManager';
252274
253-
SELECT MemberID, FirstName, LastName, Phone, Email, BirthDay
275+
SELECT MemberID,
276+
FirstName,
277+
LastName,
278+
Phone,
279+
Email,
280+
BirthDay
254281
FROM Data.Membership;
255-
256-
SELECT MemberID, Feedback, Rating
282+
SELECT MemberID,
283+
Feedback,
284+
Rating
257285
FROM Service.Feedback;
258286
259287
REVERT;
@@ -264,30 +292,32 @@ Prevent unauthorized access to sensitive data and gain control by masking it to
264292
```sql
265293
EXECUTE AS USER = 'ServiceHead';
266294
267-
SELECT MemberID, FirstName, LastName, Phone, Email, BirthDay
295+
SELECT MemberID,
296+
FirstName,
297+
LastName,
298+
Phone,
299+
Email,
300+
BirthDay
268301
FROM Data.Membership;
269-
270-
SELECT MemberID, Feedback, Rating
302+
SELECT MemberID,
303+
Feedback,
304+
Rating
271305
FROM Service.Feedback;
272306
273307
REVERT;
274308
```
275309

276-
1. To revoke UNMASK permissions, use the following T-SQL statements:
310+
1. To revoke `UNMASK` permissions, use the following T-SQL statements:
277311

278312
```sql
279-
REVOKE UNMASK ON Data.Membership(FirstName) FROM ServiceAttendant;
280-
313+
REVOKE UNMASK ON Data.Membership (FirstName) FROM ServiceAttendant;
281314
REVOKE UNMASK ON Data.Membership FROM ServiceLead;
282-
283315
REVOKE UNMASK ON SCHEMA::Data FROM ServiceManager;
284-
285316
REVOKE UNMASK ON SCHEMA::Service FROM ServiceManager;
286-
287317
REVOKE UNMASK FROM ServiceHead;
288318
```
289319

290320
## Related content
291321

292-
- [Dynamic Data Masking](/sql/relational-databases/security/dynamic-data-masking)
322+
- [Dynamic data masking](/sql/relational-databases/security/dynamic-data-masking)
293323
- [Granular Permissions for Azure SQL Dynamic Data Masking](/Shows/Data-Exposed/Granular-Permissions-for-Azure-SQL-Dynamic-Data-Masking)

0 commit comments

Comments
 (0)