Updated on 2024-01-25 GMT+08:00

CREATE REDACTION POLICY

Function

CREATE REDACTION POLICY creates a data redaction policy for a table.

Precautions

  • Only the table owner has the permission to create a data redaction policy.
  • You can create data redaction policies only for ordinary tables. Redaction policies are unavailable to system catalogs, HDFS tables, foreign tables, temporary tables, UNLOGGED tables, views, and functions.
  • Synonyms cannot be used to create redaction policies for ordinary table objects.
  • Table objects and redaction policies have a one-to-one mapping relationship. A redaction policy is a collection of data redaction functions that can be applied to multiple columns in a table. You can set different redaction functions for different columns.
  • A redaction policy is enabled by default upon its creation, that is, the enable parameter of the policy is true by default.
  • Redaction policies do not take effect on users with the sysadmin permission. Data in the redacted columns is always visible to such users.
  • Data redaction policies can be matched with specified roles.

Syntax

1
2
3
CREATE REDACTION POLICY policy_name ON table_name
    [ WHEN (when_expression) ]
    [ ADD COLUMN column_name WITH redaction_function_name ( [ argument [, ...] ] )] [, ... ];

Parameter Description

  • policy_name

    Specifies the name of a redaction policy.

  • table_name

    Specifies the name of the table to which the redaction policy is applied.

  • WHEN ( when_expression )

    Specifies the expression used for the redaction policy to take effect. The redaction policy takes effect only when this expression is true.

    When a query statement is querying a table where a redaction policy is enabled, the redacted data is invisible in the query only if the WHEN expression for the redaction policy is true. Generally, the WHEN clause is used to specify the users for which the redaction policy takes effect.

    The WHEN clause must comply with the following rules:

    1. The expression can be a combination of multiple subexpressions connected by AND and/or OR.
    2. Each subexpression supports only the =, <>, !=, >=, >, <=, and < operators. The left and right operand values can only be constant values or one of the following system constant values: SESSION_USER, CURRENT_USER, USER, CURRENT_ROLE, and CURRENT_SCHEMA system constants or the SYS_CONTEXT system function.
    3. Each subexpression can be an IN or NOT IN expression. The value for the left operand can be any of the system constant values listed in rule 2, and each element in the array of the right operand must be a constant value.
    4. Each subexpression can be a PG_HAS_ROLE system function.
    5. If you want a redaction policy to be valid in all conditions, that is, you want it to take effect on all users (including the table owner), you are advised to use the (1=1) expression to create this policy.
    6. If the WHEN clause is not specified, the redaction policy is disabled by default. You need to manually specify a WHEN expression for the policy to take effect.
  • column_name

    Specifies the name of the table column to which the redaction policy is applied.

  • function_name

    Specifies the redaction function applied to the specified table column.

  • arguments

    Specifies the list of arguments of the redaction function.

    • MASK_NONE: indicates that no masking is performed.
    • MASK_FULL: indicates that all data is masked to a fixed value.
    • MASK_PARTIAL: indicates that partial masking is performed based on the specified character type, numeric type, or time type.

    You can use the built-in masking functions MASK_NONE, MASK_FULL, and MASK_PARTIAL, or create your own masking functions by using the C language or PL/pgSQL. For details, see Data Masking Functions.

Examples

Create redaction policy for a specified user.

  1. Create users alice and matu:
    1
    2
    CREATE ROLE alice PASSWORD '{password}';
    CREATE ROLE matu PASSWORD '{password}';
    
  2. Create a table object emp as user alice, and insert data into the table.
    1
    2
    CREATE TABLE emp(id int, name varchar(20), salary NUMERIC(10,2));
    INSERT INTO emp VALUES(1, 'July', 1230.10), (2, 'David', 999.99);
    
  3. Create a redaction policy mask_emp for the emp table as user alice to make the salary column invisible to user matu.
    1
    CREATE REDACTION POLICY mask_emp ON emp WHEN(current_user = 'matu') ADD COLUMN salary WITH mask_full(salary);
    
  4. Grant the SELECT permission on the emp table to user matu as user alice.
    1
    GRANT SELECT ON emp TO matu;
    
  5. Switch to user matu.
    1
    SET ROLE matu PASSWORD '{password}';
    
  6. Query the emp table. Data in the salary column has been redacted.
    1
    SELECT * FROM emp;
    

Create redaction policy for the role.

  1. Create a role redact_role.
    1
    CREATE ROLE redact_role PASSWORD '{password}';
    
  2. Add users matu and alice to the role redact_role.
    1
    GRANT redact_role to matu,alice;
    
  3. Create a table object emp1 as the administrator and insert data.
    1
    2
    CREATE TABLE emp1(id int, name varchar(20), salary NUMERIC(10,2)); 
    INSERT INTO emp1 VALUES(3, 'Rose', 2230.20), (4, 'Jack', 899.88);  
    
  4. Create a redaction policy mask_emp1 for the table object emp1 as the administrator to make the salary column invisible to role redact_role.
    1
    CREATE REDACTION POLICY mask_emp1 ON emp1 WHEN(pg_has_role(current_user, 'redact_role', 'member')) ADD COLUMN salary WITH mask_full(salary);
    

    If no user is specified, the current user (current_user) is used by default.

    1
    CREATE REDACTION POLICY mask_emp1 ON emp1 WHEN (pg_has_role('redact_role', 'member')) ADD COLUMN salary WITH mask_full(salary);
    
  5. The administrator grants the SELECT permission on the table emp1 to the user matu.
    1
    GRANT SELECT ON emp1 TO matu;
    
  6. Switch to user matu.
    1
    SET ROLE matu PASSWORD '{password}';
    
  7. Query the emp1 table. Data in the salary column has been redacted.
    1
    SELECT * FROM emp1;