Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
149 changes: 112 additions & 37 deletions docs/cn/guides/56-security/masking-policy.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,47 +6,46 @@ import EEFeature from '@site/src/components/EEFeature';

<EEFeature featureName='MASKING POLICY'/>

动态脱敏策略(Masking Policy)在查询执行期间动态转换列值,从而保护敏感数据。它实现基于角色的机密信息访问:授权用户看到真实数据,其他用户则看到脱敏后的值
动态脱敏策略(Masking Policy)在查询时对列值进行转换,帮助你按照角色控制谁能看到真实数据、谁只能看到脱敏后的结果

## 工作原理
## 脱敏策略如何工作

动态脱敏策略(Masking Policy)根据当前用户的角色,对列数据应用转换表达式:
策略会在查询阶段读取 `current_role()` 等信息并决定返回值。

**对于 managers:**
**Managers 查看真实数据**
```sql
id | email |
---|-----------------|
2 | eric@example.com|
1 | sue@example.com |
```

**对于其他用户:**
**其他角色看到掩码**
```sql
id | email |
---|----------|
2 | *********|
1 | *********|
```

## 关键特性
### 核心特性

- **查询时脱敏**:策略仅在 SELECT 操作期间转换数据
- **基于角色**:访问规则依赖当前用户的角色,通过 `current_role()` 判断
- **列级粒度**:作用于特定表列
- **可复用**:一个策略可保护不同表中的多个列
- **非侵入式**:原始数据在存储中保持不变
- **查询时生效**:仅在 SELECT 中转换值。
- **逻辑灵活**:可结合 `current_role()` 或其他表达式判断。
- **列级控制**:策略附着在列上,可跨表复用。
- **不改原值**:存储中的真实数据不会被修改。

## 读操作与写操作
## 全流程示例

**重要**:动态脱敏策略(Masking Policy)**仅作用于读操作**(SELECT 查询)。写操作(INSERT、UPDATE、DELETE)始终处理原始、未脱敏的数据,从而确保:
下面的步骤展示了如何为列添加脱敏保护。

- 查询结果按用户权限受到保护
- 应用程序可存储并修改真实数据值
- 底层存储的数据完整性得以保持
### 1. 创建目标表

## 快速入门
```sql
CREATE TABLE user_info (id INT, email STRING NOT NULL);
```

### 1. 创建动态脱敏策略(Masking Policy)
### 2. 定义脱敏策略

```sql
CREATE MASKING POLICY email_mask
Expand All @@ -58,38 +57,114 @@ CASE
END;
```

### 2. 应用到表列
### 3. 绑定到列

```sql
ALTER TABLE user_info MODIFY COLUMN email SET MASKING POLICY email_mask;
```

### 3. 测试策略
### 4. 写入并查询

```sql
-- 创建测试数据
CREATE TABLE user_info (id INT, email STRING NOT NULL);
INSERT INTO user_info VALUES (1, 'user@example.com');

-- 以不同角色查询,观察脱敏效果
SELECT * FROM user_info;
```

## 前提条件
**返回结果**

- 创建策略前,先定义用户角色及其访问权限
- 确保用户已分配适当角色
- 角色管理请参考 [User & Role](/sql/sql-commands/ddl/user/)
```sql
id | email
---|----------
1 | *********
```

## 读写行为

脱敏策略只影响读取路径。INSERT/UPDATE/DELETE 始终写入真实值,保证应用逻辑和存储一致。

```sql
-- 写入真实数据
INSERT INTO user_info VALUES (2, 'admin@example.com');

-- 读取时应用脱敏
SELECT * FROM user_info WHERE id = 2;
```

### 所需权限
**返回结果**

- 需要将 `CREATE MASKING POLICY`(通常授予 `*.*`)赋予负责创建或替换脱敏策略的角色。Databend 会在策略创建完成后自动将该策略的 OWNERSHIP 授予当前角色。
- 需要将全局 `APPLY MASKING POLICY` 权限,或使用 `GRANT APPLY ON MASKING POLICY <policy_name>` 为角色授予特定策略的控制权,才能在 `ALTER TABLE` 中设置/解除策略;拥有该策略的 OWNERSHIP 也可执行这些操作。
- 通过 `SHOW GRANTS ON MASKING POLICY <policy_name>` 可以审计哪些角色拥有 APPLY 或 OWNERSHIP 权限。
```sql
id | email
---|----------
2 | *********
```

## 管理策略

### DESCRIBE MASKING POLICY

查看策略的创建时间、签名、返回类型及定义。

```sql
DESCRIBE MASKING POLICY email_mask;
```

**返回结果**

```sql
Name | Created On | Signature | Return Type | Body | Comment
-----------+-----------------------------+--------------+-------------+----------------------------------------------------------+---------
email_mask | 2025-11-19 10:29:06.005 UTC | (val STRING) | STRING | CASE WHEN current_role() IN('MANAGERS') THEN val ELSE... |
```

### DROP MASKING POLICY

删除不再需要的策略(删除前需先从所有列上解除)。

```sql
DROP MASKING POLICY [IF EXISTS] email_mask;
```

### 解除列上的策略

```sql
ALTER TABLE user_info MODIFY COLUMN email UNSET MASKING POLICY;
```

## 条件脱敏(Conditional Masking)

使用 `USING` 子句可以让策略引用其他列。例如根据 `is_vip` 字段判断是否需要掩码:

```sql
CREATE MASKING POLICY vip_mask
AS (val STRING, is_vip BOOLEAN)
RETURNS STRING ->
CASE
WHEN is_vip = true THEN val
ELSE '*********'
END;

ALTER TABLE user_info MODIFY COLUMN email SET MASKING POLICY vip_mask USING (email, is_vip);
INSERT INTO user_info (id, email, is_vip)
VALUES (1, 'vip@example.com', true), (2, 'normal@example.com', false);
SELECT * FROM user_info;
```

**返回结果**

```sql
id | email | is_vip
---|--------------------|-------
1 | vip@example.com | true
2 | ********* | false
```

## 策略管理
## 权限与参考

有关创建、修改和管理动态脱敏策略(Masking Policy)的详细命令,请查阅:
- [CREATE MASKING POLICY](/sql/sql-commands/ddl/mask-policy/create-mask-policy)
- [ALTER TABLE](/sql/sql-commands/ddl/table/alter-table#column-operations)
- [Masking Policy Commands](/sql/sql-commands/ddl/mask-policy/)
- 将 `CREATE MASKING POLICY`(通常授予 `*.*`)赋予负责创建或替换策略的角色,创建者会自动获得策略的 OWNERSHIP。
- 需要在全局授予 `APPLY MASKING POLICY`,或针对单个策略授予 `APPLY ON MASKING POLICY <policy_name>`,角色才能使用 `ALTER TABLE` 设置或解除策略;拥有 OWNERSHIP 的角色也可以执行这些操作。
- 使用 `SHOW GRANTS ON MASKING POLICY <policy_name>` 审计哪些角色拥有 APPLY/OWNERSHIP。
- 延伸阅读:
- [User & Role](/sql/sql-commands/ddl/user/)
- [CREATE MASKING POLICY](/sql/sql-commands/ddl/mask-policy/create-mask-policy)
- [ALTER TABLE](/sql/sql-commands/ddl/table/alter-table#column-operations)
- [Masking Policy Commands](/sql/sql-commands/ddl/mask-policy/)
148 changes: 111 additions & 37 deletions docs/en/guides/56-security/masking-policy.md
Original file line number Diff line number Diff line change
Expand Up @@ -8,45 +8,44 @@ import EEFeature from '@site/src/components/EEFeature';

Masking policies protect sensitive data by dynamically transforming column values during query execution. They enable role-based access to confidential information—authorized users see actual data, while others see masked values.

## How It Works
## How Masking Works

Masking policies apply transformation expressions to column data based on the current user's role:
Policies transform column data at query time, usually based on the caller’s role.

**For managers:**
**Managers see actual values**
```sql
id | email |
---|-----------------|
2 | eric@example.com|
1 | sue@example.com |
```

**For other users:**
**Other roles see masked values**
```sql
id | email |
---|----------|
2 | *********|
1 | *********|
```

## Key Characteristics
### Key Traits

- **Query-time masking**: Policies transform data during SELECT operations only
- **Role-based**: Access rules depend on the current user's role using `current_role()`
- **Column-level**: Applied to specific table columns
- **Reusable**: One policy can protect multiple columns across different tables
- **Non-intrusive**: Original data remains unchanged in storage
- **Query-time** – transformations only occur during SELECTs.
- **Role-aware** – expressions can reference `current_role()` or any condition.
- **Column-scoped** – attach a policy per column; reuse across tables.
- **Non-destructive** – stored data never changes.

## Read vs Write Operations
## End-to-End Workflow

**Important**: Masking policies **only apply to read operations** (SELECT queries). Write operations (INSERT, UPDATE, DELETE) always process original, unmasked data. This ensures:
Follow this streamlined sequence to introduce masking on a column.

- Query results are protected based on user permissions
- Applications can store and modify actual data values
- Data integrity is maintained in the underlying storage
### 1. Create the target table

## Quick Start
```sql
CREATE TABLE user_info (id INT, email STRING NOT NULL);
```

### 1. Create a Masking Policy
### 2. Define the masking policy

```sql
CREATE MASKING POLICY email_mask
Expand All @@ -58,39 +57,114 @@ CASE
END;
```

### 2. Apply to Table Column
### 3. Attach the policy

```sql
ALTER TABLE user_info MODIFY COLUMN email SET MASKING POLICY email_mask;
```

### 3. Test the Policy
### 4. Insert and query data

```sql
-- Create test data
CREATE TABLE user_info (id INT, email STRING NOT NULL);
INSERT INTO user_info VALUES (1, 'user@example.com');

-- Query as different roles to see masking in action
SELECT * FROM user_info;
```

## Prerequisites
**Result**

- Define user roles and their access privileges before creating policies
- Ensure users have appropriate roles assigned
- See [User & Role](/sql/sql-commands/ddl/user/) for role management
```sql
id | email
---|----------
1 | *********
```

## Read vs Write Behavior

Masking policies affect read paths only. Write statements always handle true values so applications can store and modify accurate data.

```sql
-- Write original data
INSERT INTO user_info VALUES (2, 'admin@example.com');

-- Read masked data
SELECT * FROM user_info WHERE id = 2;
```

### Required Privileges
**Result**

- Grant `CREATE MASKING POLICY` on `*.*` to any role that needs to create or replace masking policies. Databend automatically grants OWNERSHIP on a newly created policy to the current role.
- Grant either the global `APPLY MASKING POLICY` privilege or `APPLY ON MASKING POLICY <policy_name>` to roles that attach/detach policies using `ALTER TABLE`. OWNERSHIP on the policy also allows these operations.
- Use `SHOW GRANTS ON MASKING POLICY <policy_name>` to audit which roles can apply or own a specific policy.
```sql
id | email
---|----------
2 | *********
```

## Managing Policies

### DESCRIBE MASKING POLICY

View metadata, including creation time, signature, and definition.

```sql
DESCRIBE MASKING POLICY email_mask;
```

**Result**

```sql
Name | Created On | Signature | Return Type | Body | Comment
-----------+-----------------------------+--------------+-------------+----------------------------------------------------------+---------
email_mask | 2025-11-19 09:49:10.949 UTC | (val STRING) | STRING | CASE WHEN current_role() IN('MANAGERS') THEN val ELSE... |
```

### DROP MASKING POLICY

Remove a policy definition you no longer need.

```sql
DROP MASKING POLICY [IF EXISTS] email_mask;
```

### Detach from a column

```sql
ALTER TABLE user_info MODIFY COLUMN email UNSET MASKING POLICY;
```

## Conditional Masking

Use the `USING` clause to reference additional columns when the masking logic depends on other values.

```sql
CREATE MASKING POLICY vip_mask
AS (val STRING, is_vip BOOLEAN)
RETURNS STRING ->
CASE
WHEN is_vip = true THEN val
ELSE '*********'
END;

ALTER TABLE user_info MODIFY COLUMN email SET MASKING POLICY vip_mask USING (email, is_vip);
INSERT INTO user_info (id, email, is_vip)
VALUES (1, 'vip@example.com', true), (2, 'normal@example.com', false);
SELECT * FROM user_info;
```

**Result**

```sql
id | email | is_vip
---|--------------------|-------
1 | vip@example.com | true
2 | ********* | false
```

## Policy Management
## Privileges & References

For detailed commands to create, modify, and manage masking policies, see:
- [CREATE MASKING POLICY](/sql/sql-commands/ddl/mask-policy/create-mask-policy)
- [ALTER TABLE](/sql/sql-commands/ddl/table/alter-table#column-operations)
- [Masking Policy Commands](/sql/sql-commands/ddl/mask-policy/)

- Grant `CREATE MASKING POLICY` on `*.*` to any role responsible for creating or replacing policies; the creator automatically owns the policy.
- Grant the global `APPLY MASKING POLICY` privilege or `APPLY ON MASKING POLICY <policy_name>` to roles that attach or detach policies via `ALTER TABLE`.
- Audit access with `SHOW GRANTS ON MASKING POLICY <policy_name>`.
- Additional references:
- [User & Role](/sql/sql-commands/ddl/user/)
- [CREATE MASKING POLICY](/sql/sql-commands/ddl/mask-policy/create-mask-policy)
- [ALTER TABLE](/sql/sql-commands/ddl/table/alter-table#column-operations)
- [Masking Policy Commands](/sql/sql-commands/ddl/mask-policy/)
Loading