SHOW MASKING POLICIES

Lists masking policy information, including the creation date, database and schema names, owner, and any available comments.

See also:

Masking policy DDL

Syntax

SHOW MASKING POLICIES  [ LIKE '<pattern>' ]
                       [ IN
                            {
                              ACCOUNT                                         |

                              DATABASE                                        |
                              DATABASE <database_name>                        |

                              SCHEMA                                          |
                              SCHEMA <schema_name>                            |
                              <schema_name>

                              APPLICATION <application_name>                  |
                              APPLICATION PACKAGE <application_package_name>  |
                            }
                       ]
Copy

Parameters

LIKE 'pattern'

Optionally filters the command output by object name. The filter uses case-insensitive pattern matching, with support for SQL wildcard characters (% and _).

For example, the following patterns return the same results:

... LIKE '%testing%' ...
... LIKE '%TESTING%' ...

. Default: No value (no filtering is applied to the output).

[ IN ... ]

Optionally specifies the scope of the command. Specify one of the following:

ACCOUNT

Returns records for the entire account.

DATABASE, . DATABASE db_name

Returns records for the current database in use or for a specified database (db_name).

If you specify DATABASE without db_name and no database is in use, the keyword has no effect on the output.

SCHEMA, . SCHEMA schema_name, . schema_name

Returns records for the current schema in use or a specified schema (schema_name).

SCHEMA is optional if a database is in use or if you specify the fully qualified schema_name (for example, db.schema).

If no database is in use, specifying SCHEMA has no effect on the output.

APPLICATION application_name, . APPLICATION PACKAGE application_package_name

Returns records for the named Snowflake Native App or application package.

Default: Depends on whether the session currently has a database in use:

  • Database: DATABASE is the default (that is, the command returns the objects you have privileges to view in the database).

  • No database: ACCOUNT is the default (that is, the command returns the objects you have privileges to view in your account).

Access control requirements

A role used to execute this SQL command must have at least one of the following privileges at a minimum:

Privilege

Object

Notes

APPLY MASKING POLICY

Account

APPLY

Masking policy

OWNERSHIP

Masking policy

OWNERSHIP is a special privilege on an object that is automatically granted to the role that created the object, but can also be transferred using the GRANT OWNERSHIP command to a different role by the owning role (or any role with the MANAGE GRANTS privilege).

The USAGE privilege on the parent database and schema are required to perform operations on any object in a schema.

For instructions on creating a custom role with a specified set of privileges, see Creating custom roles.

For general information about roles and privilege grants for performing SQL actions on securable objects, see Overview of Access Control.

For additional details on masking policy DDL and privileges, see Managing Column-level Security.

Usage notes

  • The command does not require a running warehouse to execute.

  • The value for LIMIT rows cannot exceed 10000. If LIMIT rows is omitted, the command results in an error if the result set is larger than 10K rows.

    To view results for which more than 10K records exist, either include LIMIT rows or query the corresponding view in the Snowflake Information Schema.

  • To post-process the output of this command, you can use the RESULT_SCAN function, which treats the output as a table that can be queried.

  • The OPTIONS column returns an empty string (i.e. "") when the masking policy property EXEMPT_OTHER_POLICIES is set to FALSE.

Example

SHOW MASKING POLICIES IN SCHEMA governance.policies;
Copy
+-------------------------------+------------+---------------+-------------+----------------+---------------+------------------------------+-----------------------------------+-----------------+
| created_on                    | name       | database_name | schema_name | kind           | owner         | comment                      | options                           | owner_role_type |
+-------------------------------+------------+---------------+-------------+----------------+---------------+------------------------------+-----------------------------------+-----------------+
| 2022-08-13 16:59:59.733 +0000 | EMAIL_MASK | GOVERNANCE    | POLICIES    | MASKING_POLICY | MASKING_ADMIN | SPECIFY IN ROW ACCESS POLICY | {“EXEMPT_OTHER_POLICIES”: "TRUE"} | ROLE            |
+-------------------------------+------------+---------------+-------------+----------------+---------------+------------------------------+-----------------------------------+-----------------+