From 20ddc91a943ffe0dfa730436456118520cb672ba Mon Sep 17 00:00:00 2001 From: Rich Loveland Date: Mon, 14 Apr 2025 17:04:50 -0400 Subject: [PATCH 1/6] Add docs for Row-level security (RLS) Fixes DOC-10439, DOC-12948 Summary of changes: - Add 'Row-level security' overview page - Add or update SQL statement docs for: - `CREATE POLICY` - `ALTER POLICY` - `DROP POLICY` - `SHOW POLICIES` - `ALTER TABLE {ENABLE,DISABLE} ROW LEVEL SECURITY` - `ALTER TABLE {FORCE,UNFORCE} ROW LEVEL SECURITY` - `CREATE ROLE ... WITH BYPASSRLS` - `ALTER ROLE ... WITH BYPASSRLS` --- .../v25.2/sidebar-data/reference.json | 6 + .../_includes/v25.2/sidebar-data/sql.json | 24 + src/current/_includes/v25.2/sql/privileges.md | 1 + .../_includes/v25.2/sql/role-options.md | 1 + src/current/v25.2/alter-policy.md | 138 +++++ src/current/v25.2/alter-role.md | 85 ++- src/current/v25.2/alter-table.md | 86 +++ src/current/v25.2/create-policy.md | 92 +++ src/current/v25.2/create-role.md | 75 ++- src/current/v25.2/drop-policy.md | 118 ++++ src/current/v25.2/row-level-security.md | 581 ++++++++++++++++++ src/current/v25.2/show-policies.md | 139 +++++ 12 files changed, 1306 insertions(+), 40 deletions(-) create mode 100644 src/current/v25.2/alter-policy.md create mode 100644 src/current/v25.2/create-policy.md create mode 100644 src/current/v25.2/drop-policy.md create mode 100644 src/current/v25.2/row-level-security.md create mode 100644 src/current/v25.2/show-policies.md diff --git a/src/current/_includes/v25.2/sidebar-data/reference.json b/src/current/_includes/v25.2/sidebar-data/reference.json index 3c6fe8ff298..efcd6296367 100644 --- a/src/current/_includes/v25.2/sidebar-data/reference.json +++ b/src/current/_includes/v25.2/sidebar-data/reference.json @@ -382,6 +382,12 @@ "/${VERSION}/column-level-encryption.html" ] }, + { + "title": "Row-level Security", + "urls": [ + "/${VERSION}/row-level-security.html" + ] + }, { "title": "PKI and TLS", "urls": [ diff --git a/src/current/_includes/v25.2/sidebar-data/sql.json b/src/current/_includes/v25.2/sidebar-data/sql.json index 148d7a6a3a7..16266ee4459 100644 --- a/src/current/_includes/v25.2/sidebar-data/sql.json +++ b/src/current/_includes/v25.2/sidebar-data/sql.json @@ -64,6 +64,12 @@ "/${VERSION}/alter-partition.html" ] }, + { + "title": "ALTER POLICY", + "urls": [ + "/${VERSION}/alter-policy.html" + ] + }, { "title": "ALTER PROCEDURE", "urls": [ @@ -220,6 +226,12 @@ "/${VERSION}/create-logical-replication-stream.html" ] }, + { + "title": "CREATE POLICY", + "urls": [ + "/${VERSION}/create-policy.html" + ] + }, { "title": "CREATE PROCEDURE", "urls": [ @@ -340,6 +352,12 @@ "/${VERSION}/drop-owned-by.html" ] }, + { + "title": "DROP POLICY", + "urls": [ + "/${VERSION}/drop-policy.html" + ] + }, { "title": "DROP TRIGGER", "urls": [ @@ -694,6 +712,12 @@ "/${VERSION}/show-partitions.html" ] }, + { + "title": "SHOW POLICIES", + "urls": [ + "/${VERSION}/show-policies.html" + ] + }, { "title": "SHOW RANGES", "urls": [ diff --git a/src/current/_includes/v25.2/sql/privileges.md b/src/current/_includes/v25.2/sql/privileges.md index 428e58091cb..f5f683f15ae 100644 --- a/src/current/_includes/v25.2/sql/privileges.md +++ b/src/current/_includes/v25.2/sql/privileges.md @@ -2,6 +2,7 @@ Privilege | Levels | Description ----------|--------|------------ `ALL` | System, Database, Schema, Table, Sequence, Type | For the object to which `ALL` is applied, grants all privileges at the system, database, schema, table, sequence, or type level. `BACKUP` | System, Database, Table | Grants the ability to create [backups]({% link {{ page.version.version }}/backup-and-restore-overview.md %}) at the system, database, or table level. + `BYPASSRLS` | **New in v25.2** Grants the ability for a role to bypass [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies on a table using the `BYPASSRLS`/`NOBYPASSRLS` role options, granting unrestricted read and write access to all rows. `CANCELQUERY` | System | Grants the ability to cancel queries. `CHANGEFEED` | Table | Grants the ability to create [changefeeds]({% link {{ page.version.version }}/change-data-capture-overview.md %}) on a table. `CONNECT` | Database | Grants the ability to view a database's metadata, which consists of objects in a database's `information_schema` and `pg_catalog` system catalogs. This allows the role to view the database's table, schemas, user-defined types, and list the database when running `SHOW DATABASES`. The `CONNECT` privilege is also required to run backups of the database. diff --git a/src/current/_includes/v25.2/sql/role-options.md b/src/current/_includes/v25.2/sql/role-options.md index 44288bff11f..199c19ea1e1 100644 --- a/src/current/_includes/v25.2/sql/role-options.md +++ b/src/current/_includes/v25.2/sql/role-options.md @@ -1,5 +1,6 @@ Role option | Description ------------|------------- + `BYPASSRLS`/`NOBYPASSRLS` | **New in v25.2**: Grants the ability to bypass [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies on a table, granting unrestricted read and write access to all rows. `CANCELQUERY`/`NOCANCELQUERY` | **Deprecated in v22.2: Use the `CANCELQUERY` [system privilege]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges).** Allow or disallow a role to cancel [queries]({% link {{ page.version.version }}/cancel-query.md %}) and [sessions]({% link {{ page.version.version }}/cancel-session.md %}) of other roles. Without this role option, roles can only cancel their own queries and sessions. Even with the `CANCELQUERY` role option, non-`admin` roles cannot cancel `admin` queries or sessions. This option should usually be combined with `VIEWACTIVITY` so that the role can view other roles' query and session information.

By default, the role option is set to `NOCANCELQUERY` for all non-`admin` roles. `CONTROLCHANGEFEED`/`NOCONTROLCHANGEFEED` | **Deprecated in v23.1: Use the `CHANGEFEED` [privilege]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges).** Allow or disallow a role to run [`CREATE CHANGEFEED`]({% link {{ page.version.version }}/create-changefeed.md %}) on tables they have `SELECT` privileges on.

By default, the role option is set to `NOCONTROLCHANGEFEED` for all non-`admin` roles. `CONTROLJOB`/`NOCONTROLJOB` | Allow or disallow a role to [pause]({% link {{ page.version.version }}/pause-job.md %}), [resume]({% link {{ page.version.version }}/resume-job.md %}), and [cancel]({% link {{ page.version.version }}/cancel-job.md %}) jobs. Non-`admin` roles cannot control jobs created by `admin` roles.

By default, the role option is set to `NOCONTROLJOB` for all non-`admin` roles. diff --git a/src/current/v25.2/alter-policy.md b/src/current/v25.2/alter-policy.md new file mode 100644 index 00000000000..3408fb38f25 --- /dev/null +++ b/src/current/v25.2/alter-policy.md @@ -0,0 +1,138 @@ +--- +title: ALTER POLICY +summary: The ALTER POLICY statement changes an existing row-level security (RLS) policy on a table. +toc: true +keywords: security, row level security, RLS +docs_area: reference.sql +--- + +The `ALTER POLICY` statement changes an existing [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy on a table. + +Allowed changes to a policy using `ALTER POLICY` include: + +- Rename the policy. +- Change the applicable [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles). +- Modify the [`USING` expression](#parameters). +- Modify the [`WITH CHECK` expression](#parameters). + +{{site.data.alerts.callout_info}} +You cannot use `ALTER POLICY` to change the `PERMISSIVE` or `RESTRICTIVE` nature of the policy, nor its applicable `FOR` command (as defined by `CREATE POLICY ... ON ... { PERMISSIVE | RESTRICTIVE } ... FOR { ALL | SELECT | ... }`). If you want to make these changes, you must start over with [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) and [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}). For an example, see [Replace a policy]({% link {{ page.version.version }}/drop-policy.md %}#replace-a-policy). +{{site.data.alerts.end}} + +## Syntax + + + +{% include_cached copy-clipboard.html %} +~~~ +ALTER POLICY policy_name ON table_name RENAME TO new_policy_name; + +ALTER POLICY policy_name ON table_name + [ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ] + [ USING ( using_expression ) ] + [ WITH CHECK ( check_expression ) ]; +~~~ + +## Parameters + +Parameter | Description +----------|------------ +`policy_name` | The identifier of the existing policy to be modified. Must be unique for the specified `table_name`. +`ON table_name` | The name of the table on which the policy `policy_name` is defined. +`RENAME TO { new_policy_name }` | The new identifier for the policy. The `new_policy_name` must be a unique name on `table_name`. +`TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...]` | Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the altered policy applies. These role(s) replace the existing set of roles for the policy (`PUBLIC` refers to all roles). `CURRENT_USER` and `SESSION_USER` refer to the current execution context's user (also available via [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) `current_user()` and `session_user()`). +`USING ( using_expression )` | Replaces the previous value of this expression. For details about this expression, see [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}#parameters). +`WITH CHECK ( check_expression )` | Replaces the previous value of this expression. For details about this expression, see [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}#parameters). + +## Examples + +In this example, we start by only allowing users to see or modify their own rows in an `orders` table. Then, as the schema is updated due to business requirements, we must refine the policy to take into account the new requirements. + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE TABLE orders (user_id TEXT PRIMARY KEY, order_details TEXT); +~~~ + +The original policy on the table was as follows: + +{% include_cached copy-clipboard.html %} +~~~ sql + CREATE POLICY user_orders_policy ON orders + FOR ALL + TO PUBLIC + USING ( user_id = current_user ) + WITH CHECK ( user_id = current_user ); +~~~ + +However, the `orders` table schema has been updated to include an `is_archived` flag, and the initial policy needs refinement. + +{% include_cached copy-clipboard.html %} +~~~ sql +-- Assume this change was made after the initial policy was created +ALTER TABLE orders ADD COLUMN is_archived BOOLEAN DEFAULT FALSE NOT NULL; +CREATE INDEX idx_orders_user_id_is_archived ON orders(user_id, is_archived); -- For performance +~~~ + +The policy requirements have changed as follows: + +1. The policy should now only apply to users belonging to the `customer_service` role, not `PUBLIC`. +1. Users (in `customer_service`) should only be able to view and modify orders that are **not** archived (`is_archived = FALSE`). Archived orders should be invisible/immutable via this policy. + +This assumes the `customer_service` role has been created: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE ROLE customer_service; +~~~ + +This leads to the following `ALTER POLICY` statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER POLICY user_orders_policy ON orders + -- 1. Change the applicable role(s) + TO customer_service + -- 2. Update the USING clause to filter out archived orders + USING ( user_id = current_user AND is_archived = FALSE ) + -- 3. Update the WITH CHECK clause to prevent archiving/modifying archived orders via this policy + WITH CHECK ( user_id = current_user AND is_archived = FALSE ); +~~~ + +The changes to the `ALTER POLICY` statement can be explained as follows: + +- `TO customer_service`: Restricts the policy's application from all users (`PUBLIC`) to only those who are members of the `customer_service` role. Other users will no longer be affected by this specific policy (they would need other applicable policies or RLS would deny access by default). +- `USING ( user_id = current_user AND is_archived = FALSE )`: Modifies the visibility rule. Now, `customer_service` users can only see rows matching their `user_id` *and* where `is_archived` is false. +- `WITH CHECK ( user_id = current_user AND is_archived = FALSE )`: Modifies the constraint for `INSERT`/`UPDATE`. Users attempting modifications must satisfy the `user_id` match, and the resulting row must have `is_archived = FALSE`. This prevents them from inserting archived orders or updating an order to set `is_archived = TRUE` via operations governed by this policy. + +This `ALTER POLICY` statement reflects a typical evolution: refining role targeting and adapting the policy logic to accommodate schema changes and evolving access control requirements. + +## See also + +- [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %}) +- [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) +- [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) +- [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) +- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) +- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) + + + + diff --git a/src/current/v25.2/alter-role.md b/src/current/v25.2/alter-role.md index eb644b6d4ec..64d1b86f66c 100644 --- a/src/current/v25.2/alter-role.md +++ b/src/current/v25.2/alter-role.md @@ -50,7 +50,12 @@ The following statements are run by the `root` user that is a member of the `adm The following example allows a role to log in to the database with a [password]({% link {{ page.version.version }}/authentication.md %}#client-authentication): ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH LOGIN PASSWORD 'An0ther$tr0nGpassW0rD' VALID UNTIL '2021-10-10'; +CREATE ROLE carl; +~~~ + +~~~ sql +-- sqlchecker: ignore +ALTER ROLE carl WITH LOGIN PASSWORD 'An0ther$tr0nGpassW0rD' VALID UNTIL '2021-10-10'; ~~~ ### Prevent a role from using password authentication @@ -59,7 +64,7 @@ The following statement prevents the user from using password authentication and {% include_cached copy-clipboard.html %} ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH PASSWORD NULL; +ALTER ROLE carl WITH PASSWORD NULL; ~~~ ### Allow a role to create other roles and manage authentication methods for the new roles @@ -67,7 +72,7 @@ root@:26257/defaultdb> ALTER ROLE carl WITH PASSWORD NULL; The following example allows the role to [create other roles]({% link {{ page.version.version }}/create-role.md %}) and [manage authentication methods]({% link {{ page.version.version }}/authentication.md %}#client-authentication) for them: ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH CREATEROLE CREATELOGIN; +ALTER ROLE carl WITH CREATEROLE CREATELOGIN; ~~~ ### Allow a role to create and rename databases @@ -75,7 +80,7 @@ root@:26257/defaultdb> ALTER ROLE carl WITH CREATEROLE CREATELOGIN; The following example allows the role to [create]({% link {{ page.version.version }}/create-database.md %}) or [rename]({% link {{ page.version.version }}/alter-database.md %}#rename-to) databases: ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH CREATEDB; +ALTER ROLE carl WITH CREATEDB; ~~~ ### Allow a role to pause, resume, and cancel non-admin jobs @@ -83,7 +88,7 @@ root@:26257/defaultdb> ALTER ROLE carl WITH CREATEDB; The following example allows the role to [pause]({% link {{ page.version.version }}/pause-job.md %}), [resume]({% link {{ page.version.version }}/resume-job.md %}), and [cancel]({% link {{ page.version.version }}/cancel-job.md %}) jobs: ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH CONTROLJOB; +ALTER ROLE carl WITH CONTROLJOB; ~~~ ### Allow a role to see and cancel non-admin queries and sessions @@ -91,7 +96,7 @@ root@:26257/defaultdb> ALTER ROLE carl WITH CONTROLJOB; The following example allows the role to cancel [queries]({% link {{ page.version.version }}/cancel-query.md %}) and [sessions]({% link {{ page.version.version }}/cancel-session.md %}) for other non-`admin` roles: ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH CANCELQUERY VIEWACTIVITY; +ALTER ROLE carl WITH CANCELQUERY VIEWACTIVITY; ~~~ ### Allow a role to control changefeeds @@ -99,7 +104,7 @@ root@:26257/defaultdb> ALTER ROLE carl WITH CANCELQUERY VIEWACTIVITY; The following example allows the role to run [`CREATE CHANGEFEED`]({% link {{ page.version.version }}/create-changefeed.md %}): ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH CONTROLCHANGEFEED; +ALTER ROLE carl WITH CONTROLCHANGEFEED; ~~~ ### Allow a role to modify cluster settings @@ -107,7 +112,30 @@ root@:26257/defaultdb> ALTER ROLE carl WITH CONTROLCHANGEFEED; The following example allows the role to modify [cluster settings]({% link {{ page.version.version }}/cluster-settings.md %}): ~~~ sql -root@:26257/defaultdb> ALTER ROLE carl WITH MODIFYCLUSTERSETTING; +ALTER ROLE carl WITH MODIFYCLUSTERSETTING; +~~~ + +### Allow a role to bypass row-level security (RLS) + +To allow a [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles) to bypass [row-level security]({% link {{ page.version.version }}/row-level-security.md %}), execute the following statement to grant the [`BYPASSRLS`]({% link {{ page.version.version }}/security-reference/authorization.md %}#bypassrls) privilege: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER ROLE carl WITH BYPASSRLS; +~~~ + +To disable the role's ability to bypass RLS, execute the following statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER ROLE carl WITH NOBYPASSRLS; +~~~ + +To see all of the roles that can bypass RLS, execute the following query as an [`admin` role]({% link {{ page.version.version }}/security-reference/authorization.md %}#admin-role): + +{% include_cached copy-clipboard.html %} +~~~ sql +SELECT rolname FROM pg_roles WHERE rolbypassrls = true ~~~ ### Set default session variable values for a role @@ -115,17 +143,17 @@ root@:26257/defaultdb> ALTER ROLE carl WITH MODIFYCLUSTERSETTING; In the following example, the `root` user creates a role named `max`, and sets the default value of the `timezone` [session variable]({% link {{ page.version.version }}/set-vars.md %}#supported-variables) for the `max` role. ~~~ sql -root@:26257/defaultdb> CREATE ROLE max WITH LOGIN; +CREATE ROLE max WITH LOGIN; ~~~ ~~~ sql -root@:26257/defaultdb> ALTER ROLE max SET timezone = 'America/New_York'; +ALTER ROLE max SET timezone = 'America/New_York'; ~~~ This statement does not affect the default `timezone` value for any role other than `max`: ~~~ sql -root@:26257/defaultdb> SHOW timezone; +SHOW timezone; ~~~ ~~~ @@ -138,7 +166,7 @@ root@:26257/defaultdb> SHOW timezone; To see the default `timezone` value for the `max` role, run the `SHOW` statement as a member of the `max` role: ~~~ sql -max@:26257/defaultdb> SHOW timezone; +SHOW timezone; ~~~ ~~~ @@ -155,21 +183,21 @@ max@:26257/defaultdb> SHOW timezone; In the following example, the `root` user creates a role named `max` and a database named `movr`, and sets the default value of the `statement_timeout` [session variable]({% link {{ page.version.version }}/set-vars.md %}#supported-variables) for the `max` role in the `movr` database. ~~~ sql -root@:26257/defaultdb> CREATE DATABASE movr; +CREATE DATABASE IF NOT EXISTS movr; ~~~ ~~~ sql -root@:26257/defaultdb> CREATE ROLE max WITH LOGIN; +CREATE ROLE IF NOT EXISTS max WITH LOGIN; ~~~ ~~~ sql -root@:26257/defaultdb> ALTER ROLE max IN DATABASE movr SET statement_timeout = '10s'; +ALTER ROLE max IN DATABASE movr SET statement_timeout = '10s'; ~~~ This statement does not affect the default `statement_timeout` value for any role other than `max`, or in any database other than `movr`. ~~~ sql -root@:26257/defaultdb> SHOW statement_timeout; +SHOW statement_timeout; ~~~ ~~~ @@ -186,7 +214,7 @@ cockroach sql --url 'postgresql://max@localhost:26257/movr?sslmode=disable' ~~~ ~~~ sql -max@:26257/movr> SHOW statement_timeout; +SHOW statement_timeout; ~~~ ~~~ @@ -203,11 +231,11 @@ max@:26257/movr> SHOW statement_timeout; In the following example, the `root` user creates a database named `movr`, and sets the default value of the `timezone` [session variable]({% link {{ page.version.version }}/set-vars.md %}#supported-variables) for all roles in that database. ~~~ sql -root@:26257/defaultdb> CREATE DATABASE movr; +CREATE DATABASE IF NOT EXISTS movr; ~~~ ~~~ sql -root@:26257/defaultdb> ALTER ROLE ALL IN DATABASE movr SET timezone = 'America/New_York'; +ALTER ROLE ALL IN DATABASE movr SET timezone = 'America/New_York'; ~~~ {{site.data.alerts.callout_info}} @@ -217,7 +245,7 @@ This statement is identical to [`ALTER DATABASE movr SET timezone = 'America/New This statement does not affect the default `timezone` value for any database other than `movr`: ~~~ sql -root@:26257/defaultdb> SHOW timezone; +SHOW timezone; ~~~ ~~~ @@ -230,7 +258,7 @@ root@:26257/defaultdb> SHOW timezone; To see the default `timezone` value for the `max` role, run the `SHOW` statement as a member of the `max` role: ~~~ sql -root@:26257/movr> SHOW timezone; +SHOW timezone; ~~~ ~~~ @@ -265,7 +293,7 @@ ALTER ROLE {% include_cached copy-clipboard.html %} ~~~ sql -ALTER ROLE maxroach WITH SUBJECT 'CN=myName2,OU=myOrgUnit2,O=myOrg2,L=myLocality2,ST=myState2,C=myCountry2' LOGIN; +ALTER ROLE max WITH SUBJECT 'CN=myName2,OU=myOrgUnit2,O=myOrg2,L=myLocality2,ST=myState2,C=myCountry2' LOGIN; ~~~ {% include {{page.version.version}}/misc/cert-auth-using-x509-subject.md %} @@ -280,3 +308,16 @@ ALTER ROLE maxroach WITH SUBJECT 'CN=myName2,OU=myOrgUnit2,O=myOrg2,L=myLocality - [SQL Statements]({% link {{ page.version.version }}/sql-statements.md %}) - [Authorization Best Practices]({% link {{ page.version.version }}/security-reference/authorization.md %}#authorization-best-practices) - [`SHOW DEFAULT SESSION VARIABLES FOR ROLE`]({% link {{ page.version.version }}/show-default-session-variables-for-role.md %}) + + + + diff --git a/src/current/v25.2/alter-table.md b/src/current/v25.2/alter-table.md index 34915dacc01..67ff8a99e87 100644 --- a/src/current/v25.2/alter-table.md +++ b/src/current/v25.2/alter-table.md @@ -59,6 +59,8 @@ Subcommand | Description | Can combine with other subcommands? [`RENAME CONSTRAINT`](#rename-constraint) | Change constraints columns. | Yes [`RENAME TO`](#rename-to) | Change the names of tables. | No [`RESET {storage parameter}`](#reset-storage-parameter) | Reset a storage parameter on a table to its default value. | Yes +[`(ENABLE, DISABLE) ROW LEVEL SECURITY`](#enable-disable-row-level-security) | Enable or disable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) for a table. | No +[`(FORCE, UNFORCE) ROW LEVEL SECURITY`](#force-unforce-row-level-security) | Force the table owner to be subject to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies defined on a table. | No [`SET {storage parameter}`](#set-storage-parameter) | Set a storage parameter on a table. | Yes [`SET LOCALITY`](#set-locality) | Set the table locality for a table in a [multi-region database]({% link {{ page.version.version }}/multiregion-overview.md %}). | No [`SET SCHEMA`](#set-schema) | Change the [schema]({% link {{ page.version.version }}/sql-name-resolution.md %}) of a table. | No @@ -468,6 +470,50 @@ Parameter | Description | For usage, see [Synopsis](#synopsis). +### `(ENABLE, DISABLE) ROW LEVEL SECURITY` + +[Row-level security]({% link {{ page.version.version }}/row-level-security.md %}) must be explicitly enabled per [table]({% link {{ page.version.version }}/schema-design-table.md %}). Typically, this is controlled by the [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) that owns the table. + +For examples, see [Enable and disable row-level security](#enable-and-disable-row-level-security). + +{{site.data.alerts.callout_info}} +RLS applies to a table **only when explicitly enabled** using `ALTER TABLE ... ENABLE ROW LEVEL SECURITY`. Roles exempt from RLS policies include [admins]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), [table owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) (unless the table is set to [`FORCE ROW LEVEL SECURITY`](#force-and-unforce-row-level-security)), and [roles with `BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). +{{site.data.alerts.end}} + +#### Required privileges + +The user must be a member of the [`admin`]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) or [owner]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) roles. + +#### Parameters + +| Parameter | Description | +|---------------------|----------------------------------------------------------------------------------------------------------------------------------------------------| +| `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | +| `(ENABLE, DISABLE)` | Whether to enable or disable RLS. | + +### `{FORCE, UNFORCE} ROW LEVEL SECURITY` + +`ALTER TABLE ... FORCE ROW LEVEL SECURITY` prevents table [owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) from bypassing [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) policies. + +Use this statement when you need to ensure that all access, including by the table owner, adheres to the defined RLS policies. For example, in production or multi-tenant environments where all roles (including administrators) must operate under policy constraints. + +For examples, see [Force and unforce row-level security](#force-and-unforce-row-level-security). + +{{site.data.alerts.callout_danger}} +Users with the `BYPASSRLS` [role option]({% link {{ page.version.version }}/security-reference/authorization.md %}#role-options) can still bypass RLS even when `ALTER TABLE ... FORCE ROW LEVEL SECURITY` is enabled. To see the roles with this option, run: `SELECT rolname FROM pg_roles WHERE rolbypassrls = true;`. +{{site.data.alerts.end}} + +#### Required privileges + +The user must be a member of the [`admin`]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) or [owner]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) roles. + +#### Parameters + +| Parameter | Description | +|--------------------|------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| +| `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | +| `(FORCE, UNFORCE)` | `FORCE` ensures that all access (even by the table owner) adheres to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies. `UNFORCE` removes that restriction. | + ### `SET {storage parameter}` `ALTER TABLE ... SET {storage parameter}` sets a storage parameter on an existing table. @@ -3032,6 +3078,46 @@ To ensure that the data added to the `vehicles` table prior to the creation of t If present in a [`CREATE TABLE`]({% link {{ page.version.version }}/create-table.md %}) statement, the table is considered validated because an empty table trivially meets its constraints. {{site.data.alerts.end}} +### Enable and disable row-level security + +To enable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) on a table, issue the following statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE orders ENABLE ROW LEVEL SECURITY; +~~~ + +To disable row-level security, use the following statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE orders DISABLE ROW LEVEL SECURITY; +~~~ + +{{site.data.alerts.callout_info}} +RLS applies to a table **only when explicitly enabled** using `ALTER TABLE ... ENABLE ROW LEVEL SECURITY`. Roles exempt from RLS policies include [admins]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), [table owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) (unless the table is set to [`FORCE ROW LEVEL SECURITY`](#force-and-unforce-row-level-security)), and [roles with `BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). +{{site.data.alerts.end}} + +### Force and unforce row-level security + +To ensure that all access, including by the table [owner]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership), adheres to the defined [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies, issue the following statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE orders FORCE ROW LEVEL SECURITY; +~~~ + +To remove this restriction, and allow the table owner to bypass RLS policies, issue the following statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE orders UNFORCE ROW LEVEL SECURITY; +~~~ + +{{site.data.alerts.callout_danger}} +Users with the `BYPASSRLS` [role option]({% link {{ page.version.version }}/security-reference/authorization.md %}#role-options) can still bypass RLS even when `ALTER TABLE ... FORCE ROW LEVEL SECURITY` is enabled. To see the roles with this option, run: `SELECT rolname FROM pg_roles WHERE rolbypassrls = true;`. +{{site.data.alerts.end}} + ## See also - [Multi-Region Capabilities Overview]({% link {{ page.version.version }}/multiregion-overview.md %}) diff --git a/src/current/v25.2/create-policy.md b/src/current/v25.2/create-policy.md new file mode 100644 index 00000000000..4f6ac25cb0d --- /dev/null +++ b/src/current/v25.2/create-policy.md @@ -0,0 +1,92 @@ +--- +title: CREATE POLICY +summary: The CREATE POLICY statement defines a new row-level security policy on a table. +toc: true +keywords: security, row level security, RLS +docs_area: reference.sql +--- + +The `CREATE POLICY` statement defines a new [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy on a [table]({% link {{ page.version.version }}/schema-design-table.md %}). + +## Syntax + + + +{% include_cached copy-clipboard.html %} +~~~ +CREATE POLICY policy_name ON table_name + [ AS { PERMISSIVE | RESTRICTIVE } ] + [ FOR { ALL | SELECT | INSERT | UPDATE | DELETE } ] + [ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ] + [ USING ( using_expression ) ] + [ WITH CHECK ( check_expression ) ]; +~~~ + +## Parameters + +Parameter | Description +----------|------------ +`policy_name` | Unique identifier for the policy on the table. +`table_name` | The [table]({% link {{ page.version.version }}/schema-design-table.md %}) to which the policy applies. +`AS { PERMISSIVE, RESTRICTIVE }` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, policies are combined using `OR`. A row is accessible if *any* permissive policy grants access. For `RESTRICTIVE`, policies are combined using `AND`. The overall policy enforcement is determined by evaluating a logical expression of the form: `(permissive policies) AND (restrictive policies)`. This means that all restrictive policies must grant access for a row to be accessible, and restrictive policies are evaluated *after* permissive policies. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. +`FOR { ALL, SELECT, INSERT, UPDATE, DELETE } ` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). +`TO { role_name, ...}` | (**Default**: `PUBLIC`.) Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the policy applies. +`USING ( using_expression )` | Defines the filter condition such that only rows for which the `using_expression` evaluates to `TRUE` are visible or available for modification. Rows evaluating to `FALSE` or `NULL` are silently excluded. Note this the expression is evaluated **before** any data modifications are attempted. The filter condition applies to [`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %}), and [`INSERT`]({% link {{ page.version.version }}/insert.md %}) (for `INSERT ... ON CONFLICT DO UPDATE`). +`WITH CHECK ( check_expression )` | Defines a constraint condition such that rows being inserted or updated must satisfy `check_expression` (i.e., must evaluate to `TRUE`). This expression is evaluated **after** the row data is prepared but **before** it is written. If the expression evaluates to `FALSE` or `NULL`, the operation fails with an RLS policy violation error. Applies to [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}). + +{{site.data.alerts.callout_info}} +THe `USING` and `WITH CHECK` expressions can reference table columns and use session-specific [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) (e.g., `current_user()`, `session_user()`) and [variables]({% link {{ page.version.version }}/session-variables.md %}). +{{site.data.alerts.end}} + +## Examples + +In this example, we only allow users to see or modify their own rows in an `orders` table. + +{% include_cached copy-clipboard.html %} +~~~ sql +-- Minimal schema for the 'orders' table example. +CREATE TABLE orders (user_id TEXT PRIMARY KEY, order_details TEXT); +~~~ + +{% include_cached copy-clipboard.html %} +~~~ sql +-- Assume 'orders' table has a 'user_id' column matching logged-in user names. +ALTER TABLE orders ENABLE ROW LEVEL SECURITY; + +CREATE POLICY user_orders_policy ON orders + FOR ALL + TO PUBLIC -- Applies to all roles + USING ( user_id = current_user ) + WITH CHECK ( user_id = current_user ); +~~~ + +## See also + +- [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %}) +- [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) +- [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) +- [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) +- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER TABLE {FORCE, UNFORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security) +- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) +- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) + + + + diff --git a/src/current/v25.2/create-role.md b/src/current/v25.2/create-role.md index ee6cb680d43..0a09c67af33 100644 --- a/src/current/v25.2/create-role.md +++ b/src/current/v25.2/create-role.md @@ -84,11 +84,11 @@ The following statements are run by the `root` user that is a member of the `adm Role names are case-insensitive; must start with a letter, number, or underscore; must contain only letters, numbers, periods, or underscores; and must be between 1 and 63 characters. ~~~ sql -root@:26257/defaultdb> CREATE ROLE no_options; +CREATE ROLE no_options; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -105,11 +105,12 @@ After creating roles, you must [grant them privileges to databases]({% link {{ p ### Create a role that can log in to the database ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_login WITH LOGIN PASSWORD '$tr0nGpassW0rD' VALID UNTIL '2021-10-10'; +-- sqlchecker: ignore +CREATE ROLE can_login WITH LOGIN PASSWORD '$tr0nGpassW0rD' VALID UNTIL '2021-10-10'; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -128,11 +129,11 @@ The following statement prevents the role from using password authentication and {% include_cached copy-clipboard.html %} ~~~ sql -> CREATE ROLE no_password WITH PASSWORD NULL; +CREATE ROLE no_password WITH PASSWORD NULL; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -151,11 +152,11 @@ root | | {admin} The following example allows the role to [create other users]({% link {{ page.version.version }}/create-role.md %}) and [manage authentication methods]({% link {{ page.version.version }}/authentication.md %}#client-authentication) for them: ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_create_role WITH CREATEROLE CREATELOGIN; +CREATE ROLE can_create_role WITH CREATEROLE CREATELOGIN; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -175,11 +176,11 @@ root | | {admin} The following example allows the role to [create]({% link {{ page.version.version }}/create-database.md %}) or [rename]({% link {{ page.version.version }}/alter-database.md %}#rename-to) databases: ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_create_db WITH CREATEDB; +CREATE ROLE can_create_db WITH CREATEDB; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -200,11 +201,11 @@ root | | {admin} The following example allows the role to [pause]({% link {{ page.version.version }}/pause-job.md %}), [resume]({% link {{ page.version.version }}/resume-job.md %}), and [cancel]({% link {{ page.version.version }}/cancel-job.md %}) jobs: ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_control_job WITH CONTROLJOB; +CREATE ROLE can_control_job WITH CONTROLJOB; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -227,11 +228,11 @@ root | | {admin} The following example allows the role to cancel [queries]({% link {{ page.version.version }}/cancel-query.md %}) and [sessions]({% link {{ page.version.version }}/cancel-session.md %}) for other non-`admin` roles: ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_manage_queries WITH CANCELQUERY VIEWACTIVITY; +CREATE ROLE can_manage_queries WITH CANCELQUERY VIEWACTIVITY; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -254,11 +255,11 @@ root | | {admin} The following example allows the role to run [`CREATE CHANGEFEED`]({% link {{ page.version.version }}/create-changefeed.md %}): ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_control_changefeed WITH CONTROLCHANGEFEED; +CREATE ROLE can_control_changefeed WITH CONTROLCHANGEFEED; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -282,11 +283,11 @@ root | | {admin} The following example allows the role to modify [cluster settings]({% link {{ page.version.version }}/cluster-settings.md %}): ~~~ sql -root@:26257/defaultdb> CREATE ROLE can_modify_cluster_setting WITH MODIFYCLUSTERSETTING; +CREATE ROLE can_modify_cluster_setting WITH MODIFYCLUSTERSETTING; ~~~ ~~~ sql -root@:26257/defaultdb> SHOW ROLES; +SHOW ROLES; ~~~ ~~~ @@ -306,6 +307,24 @@ root | | {admin} (11 rows) ~~~ +### Create a role that can bypass row-level security (RLS) + +To create a [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles) that can bypass [row-level security]({% link {{ page.version.version }}/row-level-security.md %}), execute the following statement to grant the [`BYPASSRLS`]({% link {{ page.version.version }}/security-reference/authorization.md %}#bypassrls) privilege: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE ROLE can_bypassrls WITH BYPASSRLS; +~~~ + +For instructions showing how to alter a role to add or remove the `BYPASSRLS` privilege, see [`ALTER ROLE`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). + +To see all of the roles that can bypass RLS, execute the following query as an [`admin` role]({% link {{ page.version.version }}/security-reference/authorization.md %}#admin-role): + +{% include_cached copy-clipboard.html %} +~~~ sql +SELECT rolname FROM pg_roles WHERE rolbypassrls = true +~~~ + ### Set the `SUBJECT` role option for certificate based authentication {% include {{page.version.version}}/sql/role-subject-option.md %} @@ -330,3 +349,23 @@ CREATE ROLE maxroach WITH SUBJECT 'CN=myName,OU=myOrgUnit,O=myOrg,L=myLocality,S - [`SHOW GRANTS`]({% link {{ page.version.version }}/show-grants.md %}) - [SQL Statements]({% link {{ page.version.version }}/sql-statements.md %}) - [Online Schema Changes]({% link {{ page.version.version }}/online-schema-changes.md %}) + + + + diff --git a/src/current/v25.2/drop-policy.md b/src/current/v25.2/drop-policy.md new file mode 100644 index 00000000000..bd8f0c13a4c --- /dev/null +++ b/src/current/v25.2/drop-policy.md @@ -0,0 +1,118 @@ +--- +title: DROP POLICY +summary: The DROP POLICY statement removes an existing row-level security (RLS) policy from a table. +toc: true +keywords: security, row level security, RLS +docs_area: reference.sql +--- + +The `DROP POLICY` statement removes an existing [row-level security (RLS)]({% link {{ page.version.version }}/enum.md %}) policy from a [table]({% link {{ page.version.version }}/schema-design-table.md %}). + +## Syntax + + + +{% include_cached copy-clipboard.html %} +~~~ +DROP POLICY [ IF EXISTS ] policy_name ON table_name [ CASCADE | RESTRICT ]; +~~~ + +## Parameters + +| Parameter | Description | +|---------------------|--------------------------------------------------------------------------------------------------------| +| `policy_name` | Unique identifier for the policy on the table. | +| `table_name` | The [table]({% link {{ page.version.version }}/schema-design-table.md %}) to which the policy applies. | +| `IF EXISTS` | Suppresses an error if the policy doesn't exist. | +| `CASCADE, RESTRICT` | Standard dependency handling (usually not relevant for policies themselves). | + +## Examples + +### Replace a Policy + +This example demonstrates dropping an existing policy before replacing it with a new one that has a different fundamental behavior (e.g., changing from `PERMISSIVE` to `RESTRICTIVE`), which cannot be done using [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}). + +Given an `orders` table that has [row-level security]({% link {{ page.version.version }}/row-level-security.md %}#enable-or-disable-row-level-security) enabled: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE TABLE orders ( + user_id TEXT PRIMARY KEY, + order_details TEXT, + is_archived BOOLEAN DEFAULT FALSE NOT NULL +); +~~~ + + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE orders ENABLE ROW LEVEL SECURITY; +~~~ + +And further given that an initial `PERMISSIVE` policy was created to grant access to non-archived orders for users in a `customer_service` role: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE ROLE customer_service; +~~~ + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE POLICY user_orders_policy ON orders + AS PERMISSIVE -- This is the key aspect we want to change + FOR ALL + TO customer_service + USING ( user_id = current_user AND is_archived = FALSE ) + WITH CHECK ( user_id = current_user AND is_archived = FALSE ); +~~~ + +Next, we learn that changing security requirements will mandate a stricter approach going forward. We want to change this policy to act as a fundamental restriction that **must** be met; this cannot be accomplished with a `PERMISSIVE` policy. Since [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) cannot change `AS PERMISSIVE` to `AS RESTRICTIVE`, we must drop the old policy and create a new one. + +Next, drop the existing policy: + +{% include_cached copy-clipboard.html %} +~~~ sql +DROP POLICY IF EXISTS user_orders_policy ON orders; +~~~ + +After dropping the old policy, you can create the new, stricter policy: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE POLICY user_orders_policy ON orders + AS RESTRICTIVE -- Changed from PERMISSIVE + FOR ALL + TO customer_service + USING ( user_id = current_user AND is_archived = FALSE ) + WITH CHECK ( user_id = current_user AND is_archived = FALSE ); +~~~ + +## See also + +- [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %}) +- [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) +- [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) +- [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) +- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) +- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) + + + + diff --git a/src/current/v25.2/row-level-security.md b/src/current/v25.2/row-level-security.md new file mode 100644 index 00000000000..ba7fb34f8a6 --- /dev/null +++ b/src/current/v25.2/row-level-security.md @@ -0,0 +1,581 @@ +--- +title: Row-Level Security (RLS) Overview +summary: Restrict access to specific rows of data based on user roles, permissions, or other criteria +toc: true +keywords: security, row level security, RLS +docs_area: develop +--- + +Row Level Security (_RLS_) is a security feature that allows organizations to restrict access to specific rows of data in a database based on user [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), [permissions]({% link {{ page.version.version }}/security-reference/authorization.md %}#authorization-models), or other criteria. + +Row-level security complements standard SQL privileges ([`GRANT`]({% link {{ page.version.version }}/grant.md %})/[`REVOKE`]({% link {{ page.version.version }}/revoke.md %})) by allowing administrators to define policies that determine precisely which rows users can view or modify within a specific table. + +## Use cases + +Use cases for row-level security include: + +- [Restricting access to sensitive data for compliance](#restricting-access-to-sensitive-data-for-compliance) +- [Designing multi-tenant applications](#designing-multi-tenant-applications) + +### Restricting access to sensitive data for compliance + +In industries like finance or healthcare, organizations are required to ensure that only authorized users access sensitive data. Row-level security (RLS) addresses this requirement directly within the database. + +For example, RLS allows a financial institution to restrict access to customer records based on roles or departments. In healthcare, RLS can be used to enforce policies ensuring patient records are visible only to the medical staff involved in their care. + +RLS embeds access control logic directly into the database and eliminates the need for manual filtering in application code. This centralized enforcement prevents inconsistencies, reduces security attack surface, and simplifies compliance with data access regulations. + +For an example, see [RLS for Data Security (Fine-Grained Access Control)](#rls-for-data-security-fine-grained-access-control). + +### Designing multi-tenant applications + +In multi-tenant applications such as typical Software-as-a-Service (SaaS) deployments, isolating data between tenants within shared tables is a requirement. Row-Level Security (RLS) provides a database-level mechanism for enforcing this isolation. SaaS providers can utilize RLS policies to ensure tenants can only access their own data, eliminating the need for complex and potentially insecure application-layer filtering logic based on tenant IDs. + +For an example, see [RLS for Multi-Tenant Isolation](#rls-for-multi-tenant-isolation). + +## How to use row-level security + +At a high level, the steps for using row-level security (RLS) are as follows: + +1. Create [schema objects]({% link {{ page.version.version }}/schema-design-overview.md %}) and [insert data]({% link {{ page.version.version }}/insert-data.md %}). ([`CREATE TABLE`]({% link {{ page.version.version }}/create-table.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %})) +2. [Create roles]({% link {{ page.version.version }}/create-role.md %}) & [grant access]({% link {{ page.version.version }}/grant.md %}) to schema objects by those roles. ([`CREATE ROLE`]({% link {{ page.version.version }}/create-role.md %}), [`GRANT`]({% link {{ page.version.version }}/grant.md %})) +3. Enable row-level security on the schema objects. ([`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security)) +4. Define row-level security policies on the schema objects which are assigned to specific roles. ([`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %})) + +For detailed examples showing how to use row-level security, see the [examples](#examples). + +## How row-level security policies are evaluated + +Policies function as filters or constraints applied automatically by CockroachDB during [query execution]({% link {{ page.version.version }}/architecture/sql-layer.md %}#query-execution). They are based on boolean expressions evaluated in the context of the current [user]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), [session properties]({% link {{ page.version.version }}/show-sessions.md %}), and the row data itself. + +When row-level security is enabled on a table: + +1. Existing [SQL privileges]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges) still determine **if** a user can access the table at all (e.g., `SELECT`, `INSERT`). +2. [Row-level security policies]({% link {{ page.version.version }}/show-policies.md %}) determine **which rows** within the table are accessible or modifiable for specific commands. + +Further details about RLS evaluation include: + +- All [policies]({% link {{ page.version.version }}/show-policies.md %}) apply to a specific set of [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles). For a policy to be applicable, it must match at least one of the roles assigned to it. If the policy is associated with the `PUBLIC` role, it applies to all roles. In order for reads or writes to succeed, there must be at least one permissive policy for the user's role. +- If RLS is enabled but no policies apply to a given combination of user and SQL statement, **access is denied by default**. +- Permissive policies are combined using `OR` logic, while restrictive policies are combined using `AND` logic. The overall policy enforcement is determined by evaluating a logical expression of the form: `(permissive policies) AND (restrictive policies)`. +- The `USING` clause of [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) filters rows during reads; the `WITH CHECK` clause validates writes, and defaults to `USING` if absent. + +## Considerations + +### Performance + +Complex [policy expressions]({% link {{ page.version.version }}/create-policy.md %}) evaluated per-row can impact query performance. To limit the performance impacts of row-level security, optimize your policy expressions and consider [indexing]({% link {{ page.version.version }}/indexes.md %}) relevant columns. + +According to internal testing, row-level security had the following performance impacts on a write-heavy [`sysbench`](https://github.com/akopytov/sysbench) workload: + +| Number of policies | Percentage slowdown of the workload (approx.) | +|--------------------|-----------------------------------------------| +| 1 | 110% | +| 10 | 140% | +| 50 | 200% | + +### Security privileges + +[Policy expressions]({% link {{ page.version.version }}/create-policy.md %}) execute with the [privileges]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges) of the user invoking the query, unless functions marked [`SECURITY DEFINER`]({% link {{ page.version.version }}/create-function.md %}#create-a-security-definer-function) are used. + +{{site.data.alerts.callout_danger}} +Functions marked `SECURITY DEFINER` should only be used with **extreme caution** to ensure expressions do not have unintended side effects. +{{site.data.alerts.end}} + +## Limitations + +### SQL language features that bypass row-level security + +The following SQL language features bypass row-level security: + +- [Foreign keys]({% link {{ page.version.version }}/foreign-key.md %}) (including cascades) +- [Primary key constraints]({% link {{ page.version.version }}/primary-key.md %}) +- [Unique constraints]({% link {{ page.version.version }}/unique.md %}) +- [`TRUNCATE`]({% link {{ page.version.version }}/truncate.md %}) + +### Change data capture (CDC) + +[CDC]({% link {{ page.version.version }}/change-data-capture-overview.md %}) messages that are emitted from a table will not be filtered using RLS policies. Furthermore, [CDC queries]({% link {{ page.version.version }}/cdc-queries.md %}) are not supported on tables using RLS, and will fail with the error message: `CDC queries are not supported on tables with row-level security enabled` + +### Backup and restore + +[Backup and restore]({% link {{ page.version.version }}/backup-and-restore-overview.md %}) functionality does not take RLS policies into account. + +### Logical data replication (LDR) and Physical cluster replication (PCR) + +[Logical Data Replication (LDR)]({% link {{ page.version.version }}/logical-data-replication-overview.md %}) and [Physical Cluster Replication (PCR)]({% link {{ page.version.version }}/physical-cluster-replication-overview.md %}) do not take RLS policies into account. + +LDR's [limitations with respect to schema changes]({% link {{ page.version.version }}/manage-logical-data-replication.md %}#schema-changes) also apply to RLS, since RLS policies amount to a schema change. + +If you use PCR, the target cluster will have all RLS policies applied to the data because PCR performs byte for byte replication. + +### Views + +When [views]({% link {{ page.version.version }}/views.md %}) are accessed, RLS policies on any underlying [tables]({% link {{ page.version.version }}/schema-design-table.md %}) are applied. [Policies]({% link {{ page.version.version }}/create-policy.md %}) can also be defined directly on views. + +Views use the [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) of the view owner to determine row-level security filters, **not** the role of the user executing the view. This can cause issues because the view owner may have entirely different policies than the user executing the view. + +The following security attributes for views are unimplemented: + +- `security_invoker`, which would allow using the role of the user executing the view. +- `security_barrier`, which instructs the [optimizer]({% link {{ page.version.version }}/cost-based-optimizer.md %}) to process policy filtering first, ensuring that [user-defined functions]({% link {{ page.version.version }}/user-defined-functions.md %}) (UDFs) never receive rows violating RLS policies. + +## Examples + +### Create a policy + +For an example, see [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}). + +### Alter a policy + +For an example, see [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}). + +### Drop a policy + +For an example, see [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}). + +### Enable or disable row-level security + +For examples, see: + +- [`ALTER TABLE ... (ENABLE, DISABLE) ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security). +- [`ALTER TABLE ... (FORCE, UNFORCE) ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security). + +### RLS for Data Security (Fine-Grained Access Control) + +In a fine-grained access control scenario, we want to restrict access to specific rows within a table based on user [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), attributes, or relationships defined within the data itself. This goes beyond table-level [`GRANT`]({% link {{ page.version.version }}/grant.md %}) permissions. Common examples include restricting access to salary information, personal data, or region-specific records. + +For example, imagine an `employees` table containing sensitive salary information. We want to enforce the following rules: + +- Employees can view their own record. +- Managers can view the records of their direct reports. +- Members of the `hr_department` role can view all records. + +#### Set up fine-grained access control schema + +First, define the `hr_department` role and `employees` table, add some data, and grant basic table access: + +{% include_cached copy-clipboard.html %} +~~~ sql +-- Create a role needed for the example policies. +-- Note: In a real scenario, manage roles appropriately. +-- This may require admin privileges not available to all users. +CREATE ROLE hr_department; +CREATE ROLE manager; +CREATE ROLE employee; + +-- Create roles for employees. +CREATE ROLE alice; +CREATE ROLE bob; +CREATE ROLE carol; +CREATE ROLE david; +CREATE ROLE edward; + +GRANT hr_department to edward; +GRANT manager to alice, carol; +GRANT employee to alice, bob, carol, david, edward; + +-- Assume roles 'hr_department' and potentially others exist. +-- Usernames are assumed to match the 'username' column for simplicity. +CREATE TABLE employees ( + id SERIAL PRIMARY KEY, + username TEXT UNIQUE NOT NULL, + full_name TEXT NOT NULL, + manager_username TEXT, + salary NUMERIC(10, 2) NOT NULL +); + +-- Sample Data +INSERT INTO employees (username, full_name, manager_username, salary) VALUES +('alice', 'Alice Smith', NULL, 120000), +('bob', 'Bob Jones', 'alice', 80000), +('carol', 'Carol White', 'alice', 85000), +('david', 'David Green', 'carol', 70000), +('edward', 'Edward Scissorhands', 'alice', 70000); + +-- Grant basic table access (RLS will refine row access) +GRANT SELECT, INSERT, UPDATE, DELETE ON employees TO hr_department; +GRANT SELECT ON employees TO manager; +GRANT SELECT ON employees TO employee; +~~~ + +#### Enable row-level security for fine-grained access control + +Next, enable row-level security using the [`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) statement. Optionally, you may want to ensure that the table owner is also subject to RLS using [`ALTER TABLE ... FORCE ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security). + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE employees ENABLE ROW LEVEL SECURITY; +-- Optional: Ensure owner is also subject to policies if needed +-- ALTER TABLE employees FORCE ROW LEVEL SECURITY; +~~~ + +#### Define row-level security policies for fine-grained access control + +Next, define RLS policies on the table. Policy 1 allows HR full access to the table: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE POLICY hr_access ON employees + FOR ALL -- Applies to SELECT, INSERT, UPDATE, DELETE + TO hr_department + USING (true) -- No row restriction for HR + WITH CHECK (true); -- No check restriction for HR +~~~ + +Policy 2 allows employees to view their own record. + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE POLICY self_access ON employees + AS PERMISSIVE -- Combine with other permissive policies (like manager access) + FOR SELECT + TO employee + USING (username = current_user); +~~~ + +Policy 3 allows managers to view their direct reports' records. This requires a way to look up the manager's username. In this example, we use the `current_user` special form of the [function with the same name]({% link {{ page.version.version }}/functions-and-operators.md %}#special-syntax-forms). + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE POLICY manager_access ON employees + AS PERMISSIVE + FOR SELECT -- Only for viewing + TO manager + USING (manager_username = current_user); + -- No WITH CHECK needed as it's SELECT-only +~~~ + +#### Verify fine-grained access control policies + +To verify that the RLS settings are working as expected, execute the statements in this section. + +The following statement is executed by user `alice` (the manager), and returns: Alice, Bob, Carol, and Edward, but **not** David, since he works for Carol. + +This is expected behavior due to Alice's `manager` role having `self_access` or `manager_access` policies. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET ROLE alice; +SELECT * FROM employees; +RESET ROLE; +~~~ + +~~~ + id | username | full_name | manager_username | salary +----------------------+----------+---------------------+------------------+------------ + 1068380269155778561 | alice | Alice Smith | NULL | 120000.00 + 1068380269155844097 | bob | Bob Jones | alice | 80000.00 + 1068380269155876865 | carol | Carol White | alice | 85000.00 + 1068380269155942401 | edward | Edward Scissorhands | alice | 70000.00 +~~~ + +The following statement is executed by user `bob` (an employee), and returns only Bob's information. + +This is expected behavior due to Bob's `employee` role only having the `self_access` policy. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET ROLE bob; +SELECT * FROM employees; +RESET ROLE; +~~~ + +~~~ + id | username | full_name | manager_username | salary +----------------------+----------+-----------+------------------+----------- + 1068380269155844097 | bob | Bob Jones | alice | 80000.00 +(1 row) +~~~ + +The following statement is executed by user `carol` (a manager), and returns: Carol, David. + +This is expected behavior due to Carol's `manager` role having `self_access` or `manager_access` policies. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET ROLE carol; +SELECT * FROM employees; +RESET ROLE; +~~~ + +~~~ + id | username | full_name | manager_username | salary +----------------------+----------+-------------+------------------+----------- + 1068380269155876865 | carol | Carol White | alice | 85000.00 + 1068380269155909633 | david | David Green | carol | 70000.00 +(2 rows) +~~~ + +The following statement is executed by a user `edward` belonging to `hr_department`, and returns all rows. + +This is expected behavior due to Edward's `hr_department` role having `hr_access` or `self_access` policies. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET ROLE edward; +SELECT * FROM employees; +RESET ROLE; +~~~ + +~~~ + id | username | full_name | manager_username | salary +----------------------+----------+---------------------+------------------+------------ + 1068380269155778561 | alice | Alice Smith | NULL | 120000.00 + 1068380269155844097 | bob | Bob Jones | alice | 80000.00 + 1068380269155876865 | carol | Carol White | alice | 85000.00 + 1068380269155909633 | david | David Green | carol | 70000.00 + 1068380269155942401 | edward | Edward Scissorhands | alice | 70000.00 +(5 rows) +~~~ + +The following statement is executed by the user `alice`, and fails because it violates the `self_access` policy's `WITH CHECK` clause since Alice tries to update Bob's salary, and `manager_access` doesn't grant `UPDATE`. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET ROLE alice; +UPDATE employees SET salary = 999999 WHERE username = 'bob'; +RESET ROLE; +~~~ + +~~~ +ERROR: user alice does not have UPDATE privilege on relation employees +SQLSTATE: 42501 +~~~ + +### RLS for Multi-Tenant Isolation + +Multi-tenant isolation is used to enforce strict data separation between different tenants (customers, organizations) sharing the same database infrastructure and schema. Each tenant must only be able to see and modify their own data. This is a critical requirement for Software-as-a-Service (SaaS) applications. + +For example, imagine a SaaS application serving multiple tenants, with all invoice data residing in a single `invoices` table. This table is distinguished by a `tenant_id` column. The application ensures that each user session is associated with a specific `tenant_id`. + +#### Create multi-tenant schema + +First, create the schema and index for the `tenants` and `invoices` tables. Next, add an index on `tenant_id` for increased lookup performance. + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE TABLE IF NOT EXISTS tenants ( + tenant_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + name TEXT NOT NULL UNIQUE +); + +CREATE TABLE IF NOT EXISTS invoices ( + invoice_id SERIAL PRIMARY KEY, + tenant_id UUID NOT NULL REFERENCES tenants(tenant_id), + customer_name TEXT NOT NULL, + amount NUMERIC(12, 2) NOT NULL, + created_at TIMESTAMPTZ DEFAULT now() +); + +CREATE INDEX idx_invoices_tenant_id ON invoices(tenant_id); +~~~ + +Populate the schema with data: + +{% include_cached copy-clipboard.html %} +~~~ sql +-- Insert the known tenants first to satisfy FK constraints +INSERT INTO tenants (tenant_id, name) VALUES + ('9607a12c-3c2f-407b-ae3c-af903542395b', 'Tenant A Inc.'), + ('8177c2fc-3b55-47b7-bf84-38bd3a3e9c0a', 'Tenant B Solutions'); + +-- Insert some additional dummy tenants +INSERT INTO tenants (name) VALUES + ('Example Corp'), + ('Global Widgets Ltd.'); + +-- Now, populate the invoices table +-- Use the known tenant UUIDs and some generated ones (assuming default gen_random_uuid works or select from tenants) + +-- Invoice for Tenant A +INSERT INTO invoices (tenant_id, customer_name, amount) VALUES + ('9607a12c-3c2f-407b-ae3c-af903542395b', 'Customer One', 1500.75); + +-- Invoice for Tenant B +INSERT INTO invoices (tenant_id, customer_name, amount) VALUES + ('8177c2fc-3b55-47b7-bf84-38bd3a3e9c0a', 'Customer Two', 899.00); + +-- Another invoice for Tenant A +INSERT INTO invoices (tenant_id, customer_name, amount) VALUES + ('9607a12c-3c2f-407b-ae3c-af903542395b', 'Customer Three', 210.50); + +-- Invoice for Example Corp (assuming its UUID was generated) +INSERT INTO invoices (tenant_id, customer_name, amount) + SELECT tenant_id, 'Customer Four', 5000.00 + FROM tenants WHERE name = 'Example Corp'; + +-- Invoice for Global Widgets Ltd. (assuming its UUID was generated) +INSERT INTO invoices (tenant_id, customer_name, amount) + SELECT tenant_id, 'Customer Five', 120.99 + FROM tenants WHERE name = 'Global Widgets Ltd.'; + +-- Yet another invoice for Tenant B +INSERT INTO invoices (tenant_id, customer_name, amount) VALUES + ('8177c2fc-3b55-47b7-bf84-38bd3a3e9c0a', 'Customer Six', 345.67); +~~~ + +#### Define user roles for app developer + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE ROLE app_dev; +GRANT SELECT ON tenants TO app_dev; +GRANT SELECT, INSERT, UPDATE, DELETE ON invoices TO app_dev; +~~~ + +#### Define how the application sets the tenant ID for the session + +Next, each application will need to set the tenant context for the session. In this example, we will use the `application_name` session variable to pass in a tenant ID which will later be extracted from the variable. + +Specifically, the UUID following the period in `application_name` is the tenant ID. We will use the `current_setting()` function in our RLS policies to extract the ID. + +{{site.data.alerts.callout_danger}} +For multi-tenancy to work correctly, this setting **must** be reliably managed by the application layer and passed in the connection string. +{{site.data.alerts.end}} + +{% include_cached copy-clipboard.html %} +~~~ sql +SET application_name = 'my_cool_app.9607a12c-3c2f-407b-ae3c-af903542395b'; +~~~ + +#### Enable row-level security for multi-tenant isolation + +To enable row-level security for the `invoices` table, issue the statements below. + +{{site.data.alerts.callout_danger}} +For multi-tenant isolation to work properly in this example, you **must** also `FORCE ROW LEVEL SECURITY` so that the policies also apply to the table owner. +{{site.data.alerts.end}} + +{% include_cached copy-clipboard.html %} +~~~ sql +ALTER TABLE invoices ENABLE ROW LEVEL SECURITY; +-- Consider applying to owner/admins too unless bypassed explicitly +ALTER TABLE invoices FORCE ROW LEVEL SECURITY; +~~~ + +#### Define tenant isolation policies + +The following policy enforces tenant isolation for all operations. + +{% include_cached copy-clipboard.html %} +~~~ sql +-- CREATE POLICY tenant_isolation ON invoices AS RESTRICTIVE FOR ALL TO public USING (tenant_id = split_part(current_setting('application_name', true), '.', 2)::UUID) WITH CHECK (tenant_id = split_part(current_setting('application_name', true), '.', 2)::UUID); + +CREATE POLICY tenant_isolation ON invoices + AS RESTRICTIVE + FOR ALL + TO app_dev + USING (tenant_id = split_part(current_setting('application_name', true),'.',2)::UUID) -- Filter rows on SELECT/UPDATE/DELETE + WITH CHECK (tenant_id = split_part(current_setting('application_name', true),'.',2)::UUID); -- Enforce tenant_id on INSERT/UPDATE +~~~ + +Explanation of policy: + +- `AS RESTRICTIVE`: Makes this policy mandatory. If other policies exist, they must *also* pass. For simple tenant isolation, this is often the safest default. +- `FOR ALL`: Covers all data modification and retrieval. +- `TO PUBLIC`: Applies the policy broadly. Roles should primarily manage table-level access using `GRANT`, while this policy handles row-level visibility. +- `USING`: Ensures queries only see rows matching the session's tenant ID, which is passed in using the `application_name` session variable and extracted using the `split_part` function. +- `WITH CHECK`: Prevents users from `INSERT`ing rows with a tenant ID column different from their session's calculated tenant ID, or `UPDATE`ing a row to change its `tenant_id` column across tenant boundaries. Without this, a user could potentially insert data into another tenant's space. + +#### Verify multi-tenant isolation policies + +To verify that the RLS settings are working as expected, execute the statements in this section. They use two tenants with the following IDs: + +- Tenant A, which has ID `9607a12c-3c2f-407b-ae3c-af903542395b`. +- Tenant B, which has ID `8177c2fc-3b55-47b7-bf84-38bd3a3e9c0a`. + +First, become the `app_dev` role which the policy applies to. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET ROLE app_dev; +~~~ + +Tenant A should see only those columns in `invoices` which have a `tenant_id` column matching its ID. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET application_name = 'my_cool_app.9607a12c-3c2f-407b-ae3c-af903542395b'; +SELECT * FROM invoices; +~~~ + +Tenant B should see only those columns in `invoices` which have a `tenant_id` column matching its ID. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET application_name = 'my_cool_app.8177c2fc-3b55-47b7-bf84-38bd3a3e9c0a'; +SELECT * FROM invoices; +~~~ + +Tenant A should not be able to make changes to the `invoice` table for rows which don't have a `tenant_id` column matching its ID. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET application_name = 'my_cool_app.9607a12c-3c2f-407b-ae3c-af903542395b'; +INSERT INTO invoices (tenant_id, customer_name, amount) VALUES ('8177c2fc-3b55-47b7-bf84-38bd3a3e9c0a'::UUID, 'Customer Three', 123.45); +~~~ + +The above statement fails because it violates the policy's `WITH CHECK` constraint, and the following error is signalled: + +~~~ +ERROR: new row violates row-level security policy for table "invoices" +~~~ + +Tenant A should be able to modify rows in the `invoice` table that have a `tenant_id` column matching its ID. + +{% include_cached copy-clipboard.html %} +~~~ sql +SET application_name = 'my_cool_app.9607a12c-3c2f-407b-ae3c-af903542395b'; +INSERT INTO invoices (tenant_id, customer_name, amount) VALUES ('9607a12c-3c2f-407b-ae3c-af903542395b'::UUID, 'Customer Three', 678.90); +~~~ + +The above statement succeeds. + +### Video demo: Row-level Security + +For a demo showing how to combine Row-level security with [Multi-region SQL]({% link {{ page.version.version }}/multiregion-overview.md %}) to constrain access to specific rows based on a user's geographic region, play the following video: + +{% include_cached youtube.html video_id="ZG8RsfwMaa8" %} + +## See also + ++ [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) +- [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) +- [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) +- [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) +- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER TABLE {FORCE, UNFORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security) +- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) +- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) + + + + diff --git a/src/current/v25.2/show-policies.md b/src/current/v25.2/show-policies.md new file mode 100644 index 00000000000..2b018506b4c --- /dev/null +++ b/src/current/v25.2/show-policies.md @@ -0,0 +1,139 @@ +--- +title: SHOW POLICIES +summary: The SHOW POLICIES statement lists the row-level security policies for a table +toc: true +keywords: security, row level security, RLS +docs_area: reference.sql +--- + +The `SHOW POLICIES` statement lists the [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies for a [table]({% link {{ page.version.version }}/schema-design-table.md %}). + +## Syntax + + + +{% include_cached copy-clipboard.html %} +~~~ +SHOW POLICIES FOR {table_name} +~~~ + +## Parameters + +| Parameter | Description | +|--------------|----------------------------------------------------| +| `table_name` | The name of the table to which the policy applies. | + +## Examples + +In this example, we will create a table, a role, and some policies to view: + +- The `user_orders_policy` is a permissive policy allowing any user to access their own orders. +- The `archived_orders_policy` is a restrictive policy ensuring that customer service roles can only view non-archived orders that are assigned to them. + +First, create the table, enable RLS, and add a role and policies: + +{% include_cached copy-clipboard.html %} +~~~ sql +CREATE TABLE orders ( + user_id TEXT PRIMARY KEY, + order_details TEXT, + is_archived BOOLEAN DEFAULT FALSE NOT NULL +); + +-- Enable RLS +ALTER TABLE orders ENABLE ROW LEVEL SECURITY; + +-- Add role +CREATE ROLE customer_service; + +-- Example policies +CREATE POLICY user_orders_policy ON orders + FOR ALL + TO PUBLIC + USING (user_id = current_user) + WITH CHECK (user_id = current_user); + +CREATE POLICY archived_orders_policy ON orders + AS RESTRICTIVE + FOR SELECT + TO customer_service + USING (user_id = current_user AND is_archived = FALSE); +~~~ + +To view the RLS policies applied to the `orders` table, use the `SHOW POLICIES` statement: + +{% include_cached copy-clipboard.html %} +~~~ sql +SHOW POLICIES FOR orders; +~~~ + +~~~ + name | cmd | type | roles | using_expr | with_check_expr +-------------------------+--------+-------------+--------------------+------------------------------------------------------+--------------------------- + user_orders_policy | ALL | permissive | {public} | user_id = current_user() | user_id = current_user() + archived_orders_policy | SELECT | restrictive | {customer_service} | (user_id = current_user()) AND (is_archived = false) | +(2 rows) +~~~ + +### Use `pg_policies` to view all row-level security policies in the system + +If you are the [`root` user]({% link {{ page.version.version }}/security-reference/authorization.md %}#root-user), you can view all RLS policies. This example uses the schema and policies from the [Row-level security overview]({% link {{ page.version.version }}/row-level-security.md %}). + +{% include_cached copy-clipboard.html %} +~~~ sql +SELECT current_user(); +~~~ + +~~~ + current_user +---------------- + root +(1 row) +~~~ + +{% include_cached copy-clipboard.html %} +~~~ sql +SELECT * FROM pg_policies; +~~~ + +~~~ + schemaname | tablename | policyname | permissive | roles | cmd | qual | with_check +-------------+-----------+--------------------+------------+-----------------+-----+-----------------------------------+--------------------------- + public | orders | user_orders_policy | permissive | {public} | ALL | user_id = current_user() | user_id = current_user() + public | employees | self_access | permissive | {public} | ALL | username = current_user() | NULL + public | employees | manager_access | permissive | {public} | ALL | manager_username = current_user() | NULL + public | invoices | tenant_isolation | permissive | {public} | ALL | NULL | NULL + public | employees | hr_access | permissive | {hr_department} | ALL | NULL | NULL +(5 rows) +~~~ + +## See also + +- [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %}) +- [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) +- [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) +- [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) +- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) +- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) + + + + From e3ef5249f032b94c516fed3505091848df7c7860 Mon Sep 17 00:00:00 2001 From: Rich Loveland Date: Fri, 9 May 2025 13:31:56 -0400 Subject: [PATCH 2/6] Update with spilchen feedback (1) --- src/current/_includes/v25.2/sql/privileges.md | 1 - .../_includes/v25.2/sql/role-options.md | 2 +- src/current/v25.2/alter-table.md | 8 +-- src/current/v25.2/create-policy.md | 31 ++++++-- src/current/v25.2/drop-policy.md | 71 ++----------------- src/current/v25.2/row-level-security.md | 54 +++++--------- src/current/v25.2/show-policies.md | 14 +--- 7 files changed, 53 insertions(+), 128 deletions(-) diff --git a/src/current/_includes/v25.2/sql/privileges.md b/src/current/_includes/v25.2/sql/privileges.md index f5f683f15ae..428e58091cb 100644 --- a/src/current/_includes/v25.2/sql/privileges.md +++ b/src/current/_includes/v25.2/sql/privileges.md @@ -2,7 +2,6 @@ Privilege | Levels | Description ----------|--------|------------ `ALL` | System, Database, Schema, Table, Sequence, Type | For the object to which `ALL` is applied, grants all privileges at the system, database, schema, table, sequence, or type level. `BACKUP` | System, Database, Table | Grants the ability to create [backups]({% link {{ page.version.version }}/backup-and-restore-overview.md %}) at the system, database, or table level. - `BYPASSRLS` | **New in v25.2** Grants the ability for a role to bypass [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies on a table using the `BYPASSRLS`/`NOBYPASSRLS` role options, granting unrestricted read and write access to all rows. `CANCELQUERY` | System | Grants the ability to cancel queries. `CHANGEFEED` | Table | Grants the ability to create [changefeeds]({% link {{ page.version.version }}/change-data-capture-overview.md %}) on a table. `CONNECT` | Database | Grants the ability to view a database's metadata, which consists of objects in a database's `information_schema` and `pg_catalog` system catalogs. This allows the role to view the database's table, schemas, user-defined types, and list the database when running `SHOW DATABASES`. The `CONNECT` privilege is also required to run backups of the database. diff --git a/src/current/_includes/v25.2/sql/role-options.md b/src/current/_includes/v25.2/sql/role-options.md index 199c19ea1e1..0fedc228277 100644 --- a/src/current/_includes/v25.2/sql/role-options.md +++ b/src/current/_includes/v25.2/sql/role-options.md @@ -1,6 +1,6 @@ Role option | Description ------------|------------- - `BYPASSRLS`/`NOBYPASSRLS` | **New in v25.2**: Grants the ability to bypass [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies on a table, granting unrestricted read and write access to all rows. + `BYPASSRLS`/`NOBYPASSRLS` | **New in v25.2**: Grants the ability to bypass [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies on a table, granting unrestricted read and write access to all rows. This option controls the access from an RLS perspective only; the user also needs sufficient [`GRANT`]({% link {{ page.version.version }}/grant.md %}) privileges to read or write to the table. `CANCELQUERY`/`NOCANCELQUERY` | **Deprecated in v22.2: Use the `CANCELQUERY` [system privilege]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges).** Allow or disallow a role to cancel [queries]({% link {{ page.version.version }}/cancel-query.md %}) and [sessions]({% link {{ page.version.version }}/cancel-session.md %}) of other roles. Without this role option, roles can only cancel their own queries and sessions. Even with the `CANCELQUERY` role option, non-`admin` roles cannot cancel `admin` queries or sessions. This option should usually be combined with `VIEWACTIVITY` so that the role can view other roles' query and session information.

By default, the role option is set to `NOCANCELQUERY` for all non-`admin` roles. `CONTROLCHANGEFEED`/`NOCONTROLCHANGEFEED` | **Deprecated in v23.1: Use the `CHANGEFEED` [privilege]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges).** Allow or disallow a role to run [`CREATE CHANGEFEED`]({% link {{ page.version.version }}/create-changefeed.md %}) on tables they have `SELECT` privileges on.

By default, the role option is set to `NOCONTROLCHANGEFEED` for all non-`admin` roles. `CONTROLJOB`/`NOCONTROLJOB` | Allow or disallow a role to [pause]({% link {{ page.version.version }}/pause-job.md %}), [resume]({% link {{ page.version.version }}/resume-job.md %}), and [cancel]({% link {{ page.version.version }}/cancel-job.md %}) jobs. Non-`admin` roles cannot control jobs created by `admin` roles.

By default, the role option is set to `NOCONTROLJOB` for all non-`admin` roles. diff --git a/src/current/v25.2/alter-table.md b/src/current/v25.2/alter-table.md index 67ff8a99e87..6d8041c60b4 100644 --- a/src/current/v25.2/alter-table.md +++ b/src/current/v25.2/alter-table.md @@ -60,7 +60,7 @@ Subcommand | Description | Can combine with other subcommands? [`RENAME TO`](#rename-to) | Change the names of tables. | No [`RESET {storage parameter}`](#reset-storage-parameter) | Reset a storage parameter on a table to its default value. | Yes [`(ENABLE, DISABLE) ROW LEVEL SECURITY`](#enable-disable-row-level-security) | Enable or disable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) for a table. | No -[`(FORCE, UNFORCE) ROW LEVEL SECURITY`](#force-unforce-row-level-security) | Force the table owner to be subject to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies defined on a table. | No +[`(FORCE, NO FORCE) ROW LEVEL SECURITY`](#force-unforce-row-level-security) | Force the table owner to be subject to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies defined on a table. | No [`SET {storage parameter}`](#set-storage-parameter) | Set a storage parameter on a table. | Yes [`SET LOCALITY`](#set-locality) | Set the table locality for a table in a [multi-region database]({% link {{ page.version.version }}/multiregion-overview.md %}). | No [`SET SCHEMA`](#set-schema) | Change the [schema]({% link {{ page.version.version }}/sql-name-resolution.md %}) of a table. | No @@ -491,7 +491,7 @@ The user must be a member of the [`admin`]({% link {{ page.version.version }}/se | `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | | `(ENABLE, DISABLE)` | Whether to enable or disable RLS. | -### `{FORCE, UNFORCE} ROW LEVEL SECURITY` +### `{FORCE, NO FORCE} ROW LEVEL SECURITY` `ALTER TABLE ... FORCE ROW LEVEL SECURITY` prevents table [owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) from bypassing [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) policies. @@ -512,7 +512,7 @@ The user must be a member of the [`admin`]({% link {{ page.version.version }}/se | Parameter | Description | |--------------------|------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| | `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | -| `(FORCE, UNFORCE)` | `FORCE` ensures that all access (even by the table owner) adheres to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies. `UNFORCE` removes that restriction. | +| `(FORCE, NO FORCE)` | `FORCE` ensures that all access (even by the table owner) adheres to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies. `NO FORCE` removes that restriction. | ### `SET {storage parameter}` @@ -3111,7 +3111,7 @@ To remove this restriction, and allow the table owner to bypass RLS policies, is {% include_cached copy-clipboard.html %} ~~~ sql -ALTER TABLE orders UNFORCE ROW LEVEL SECURITY; +ALTER TABLE orders NO FORCE ROW LEVEL SECURITY; ~~~ {{site.data.alerts.callout_danger}} diff --git a/src/current/v25.2/create-policy.md b/src/current/v25.2/create-policy.md index 4f6ac25cb0d..03f5e36359d 100644 --- a/src/current/v25.2/create-policy.md +++ b/src/current/v25.2/create-policy.md @@ -22,7 +22,7 @@ NB. This is commented out while we wait for a fix to DOC-12125 {% include_cached copy-clipboard.html %} ~~~ -CREATE POLICY policy_name ON table_name +CREATE POLICY [ IF NOT EXISTS ] policy_name ON table_name [ AS { PERMISSIVE | RESTRICTIVE } ] [ FOR { ALL | SELECT | INSERT | UPDATE | DELETE } ] [ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ] @@ -36,16 +36,37 @@ Parameter | Description ----------|------------ `policy_name` | Unique identifier for the policy on the table. `table_name` | The [table]({% link {{ page.version.version }}/schema-design-table.md %}) to which the policy applies. -`AS { PERMISSIVE, RESTRICTIVE }` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, policies are combined using `OR`. A row is accessible if *any* permissive policy grants access. For `RESTRICTIVE`, policies are combined using `AND`. The overall policy enforcement is determined by evaluating a logical expression of the form: `(permissive policies) AND (restrictive policies)`. This means that all restrictive policies must grant access for a row to be accessible, and restrictive policies are evaluated *after* permissive policies. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. -`FOR { ALL, SELECT, INSERT, UPDATE, DELETE } ` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). +`AS { PERMISSIVE, RESTRICTIVE }` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, policies are combined using `OR`. A row is accessible if *any* permissive policy grants access. For `RESTRICTIVE`, policies are combined using `AND`. The overall policy enforcement is determined by evaluating a logical expression of the form: `(permissive policies) AND (restrictive policies)`. This means that all restrictive policies must grant access for a row to be accessible, and restrictive policies are evaluated *after* permissive policies. This means that you need to have at least one `PERMISSIVE` policy in place before applying `RESTRICTIVE` policies. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. +`FOR { ALL, SELECT, INSERT, UPDATE, DELETE } ` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). For details, see [Policies by statement type](#policies-by-statement-type). `TO { role_name, ...}` | (**Default**: `PUBLIC`.) Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the policy applies. `USING ( using_expression )` | Defines the filter condition such that only rows for which the `using_expression` evaluates to `TRUE` are visible or available for modification. Rows evaluating to `FALSE` or `NULL` are silently excluded. Note this the expression is evaluated **before** any data modifications are attempted. The filter condition applies to [`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %}), and [`INSERT`]({% link {{ page.version.version }}/insert.md %}) (for `INSERT ... ON CONFLICT DO UPDATE`). `WITH CHECK ( check_expression )` | Defines a constraint condition such that rows being inserted or updated must satisfy `check_expression` (i.e., must evaluate to `TRUE`). This expression is evaluated **after** the row data is prepared but **before** it is written. If the expression evaluates to `FALSE` or `NULL`, the operation fails with an RLS policy violation error. Applies to [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}). {{site.data.alerts.callout_info}} -THe `USING` and `WITH CHECK` expressions can reference table columns and use session-specific [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) (e.g., `current_user()`, `session_user()`) and [variables]({% link {{ page.version.version }}/session-variables.md %}). +The `USING` and `WITH CHECK` expressions can reference table columns and use session-specific [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) (e.g., `current_user()`, `session_user()`) and [variables]({% link {{ page.version.version }}/session-variables.md %}). However, these expressions cannot contain a subexpression. {{site.data.alerts.end}} +### Policies by statement type + +The following table shows which policies are applied to which statement types, with additional considerations listed after the table. + +| Command / clause pattern | `SELECT` policy - `USING` (row that already exists) | `INSERT` policy - `WITH CHECK` (row being added) | `UPDATE` policy - `USING` (row before the change) | `UPDATE` policy - `WITH CHECK` (row after the change) | `DELETE` policy - `USING` (row to be removed) | +|-------------------------------------|-----------------------------------------------------|--------------------------------------------------|---------------------------------------------------|-------------------------------------------------------|-----------------------------------------------| +| `SELECT` | ✓ | — | — | — | — | +| `SELECT ... FOR UPDATE / FOR SHARE` | ✓ | — | ✓ | — | — | +| `INSERT / MERGE ... THEN INSERT` | — | ✓ | — | — | — | +| `INSERT ... RETURNING` | ✓ ‡ | ✓ | — | — | — | +| `UPDATE / MERGE ... THEN UPDATE` | ✓ ‡ | — | ✓ | ✓ | — | +| `DELETE` | ✓ ‡ | — | — | — | ✓ | +| `INSERT ... ON CONFLICT DO UPDATE` | ✓ | — | ✓ | ✓ | — | + +‡ The `SELECT` check is only evaluated when the statement actually needs to read from the relation, e.g., in a `WHERE`, `SET`, or `RETURNING` clause that references table columns. + +CockroachDB's behavior differs from that described in the table above in the following ways: + +- `SELECT` evaluation: CockroachDB always evaluates `SELECT` (`USING`) policies for `INSERT` and `UPDATE`, even when the statement doesn't reference table columns. This differs from PostgreSQL; this difference may be resolved in an upcoming release. +- `ON CONFLICT ... DO NOTHING`: CockroachDB still runs constraint and row-level policy checks on the `VALUES` clause even when the candidate row is discarded because of a conflict, so `INSERT ... ON CONFLICT DO NOTHING` may reject rows that PostgreSQL would silently ignore. This is a known limitation described in [cockroachdb/cockroach#35370](https://github.com/cockroachdb/cockroach/issues/35370). + ## Examples In this example, we only allow users to see or modify their own rows in an `orders` table. @@ -75,7 +96,7 @@ CREATE POLICY user_orders_policy ON orders - [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) - [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) - [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) -- [`ALTER TABLE {FORCE, UNFORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security) +- [`ALTER TABLE {FORCE, NO FORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security) - [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) - [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) diff --git a/src/current/v25.2/drop-policy.md b/src/current/v25.2/drop-policy.md index bd8f0c13a4c..a8f04c02ac2 100644 --- a/src/current/v25.2/drop-policy.md +++ b/src/current/v25.2/drop-policy.md @@ -31,67 +31,17 @@ DROP POLICY [ IF EXISTS ] policy_name ON table_name [ CASCADE | RESTRICT ]; | `policy_name` | Unique identifier for the policy on the table. | | `table_name` | The [table]({% link {{ page.version.version }}/schema-design-table.md %}) to which the policy applies. | | `IF EXISTS` | Suppresses an error if the policy doesn't exist. | -| `CASCADE, RESTRICT` | Standard dependency handling (usually not relevant for policies themselves). | +| `CASCADE, RESTRICT` | Standard dependency handling (not relevant for policies themselves). | ## Examples -### Replace a Policy +### Drop a policy -This example demonstrates dropping an existing policy before replacing it with a new one that has a different fundamental behavior (e.g., changing from `PERMISSIVE` to `RESTRICTIVE`), which cannot be done using [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}). - -Given an `orders` table that has [row-level security]({% link {{ page.version.version }}/row-level-security.md %}#enable-or-disable-row-level-security) enabled: - -{% include_cached copy-clipboard.html %} -~~~ sql -CREATE TABLE orders ( - user_id TEXT PRIMARY KEY, - order_details TEXT, - is_archived BOOLEAN DEFAULT FALSE NOT NULL -); -~~~ - - -{% include_cached copy-clipboard.html %} -~~~ sql -ALTER TABLE orders ENABLE ROW LEVEL SECURITY; -~~~ - -And further given that an initial `PERMISSIVE` policy was created to grant access to non-archived orders for users in a `customer_service` role: +To drop an existing policy, issue the following statement: {% include_cached copy-clipboard.html %} ~~~ sql -CREATE ROLE customer_service; -~~~ - -{% include_cached copy-clipboard.html %} -~~~ sql -CREATE POLICY user_orders_policy ON orders - AS PERMISSIVE -- This is the key aspect we want to change - FOR ALL - TO customer_service - USING ( user_id = current_user AND is_archived = FALSE ) - WITH CHECK ( user_id = current_user AND is_archived = FALSE ); -~~~ - -Next, we learn that changing security requirements will mandate a stricter approach going forward. We want to change this policy to act as a fundamental restriction that **must** be met; this cannot be accomplished with a `PERMISSIVE` policy. Since [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) cannot change `AS PERMISSIVE` to `AS RESTRICTIVE`, we must drop the old policy and create a new one. - -Next, drop the existing policy: - -{% include_cached copy-clipboard.html %} -~~~ sql -DROP POLICY IF EXISTS user_orders_policy ON orders; -~~~ - -After dropping the old policy, you can create the new, stricter policy: - -{% include_cached copy-clipboard.html %} -~~~ sql -CREATE POLICY user_orders_policy ON orders - AS RESTRICTIVE -- Changed from PERMISSIVE - FOR ALL - TO customer_service - USING ( user_id = current_user AND is_archived = FALSE ) - WITH CHECK ( user_id = current_user AND is_archived = FALSE ); +DROP POLICY IF EXISTS {your_policy} ON orders; ~~~ ## See also @@ -103,16 +53,3 @@ CREATE POLICY user_orders_policy ON orders - [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) - [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) - [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) - - - - diff --git a/src/current/v25.2/row-level-security.md b/src/current/v25.2/row-level-security.md index ba7fb34f8a6..b4427cec23e 100644 --- a/src/current/v25.2/row-level-security.md +++ b/src/current/v25.2/row-level-security.md @@ -66,14 +66,6 @@ Further details about RLS evaluation include: Complex [policy expressions]({% link {{ page.version.version }}/create-policy.md %}) evaluated per-row can impact query performance. To limit the performance impacts of row-level security, optimize your policy expressions and consider [indexing]({% link {{ page.version.version }}/indexes.md %}) relevant columns. -According to internal testing, row-level security had the following performance impacts on a write-heavy [`sysbench`](https://github.com/akopytov/sysbench) workload: - -| Number of policies | Percentage slowdown of the workload (approx.) | -|--------------------|-----------------------------------------------| -| 1 | 110% | -| 10 | 140% | -| 50 | 200% | - ### Security privileges [Policy expressions]({% link {{ page.version.version }}/create-policy.md %}) execute with the [privileges]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges) of the user invoking the query, unless functions marked [`SECURITY DEFINER`]({% link {{ page.version.version }}/create-function.md %}#create-a-security-definer-function) are used. @@ -111,15 +103,10 @@ If you use PCR, the target cluster will have all RLS policies applied to the dat ### Views -When [views]({% link {{ page.version.version }}/views.md %}) are accessed, RLS policies on any underlying [tables]({% link {{ page.version.version }}/schema-design-table.md %}) are applied. [Policies]({% link {{ page.version.version }}/create-policy.md %}) can also be defined directly on views. +When [views]({% link {{ page.version.version }}/views.md %}) are accessed, RLS policies on any underlying [tables]({% link {{ page.version.version }}/schema-design-table.md %}) are applied. [Policies]({% link {{ page.version.version }}/create-policy.md %}) can only be defined directly on tables, not views. Views use the [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) of the view owner to determine row-level security filters, **not** the role of the user executing the view. This can cause issues because the view owner may have entirely different policies than the user executing the view. -The following security attributes for views are unimplemented: - -- `security_invoker`, which would allow using the role of the user executing the view. -- `security_barrier`, which instructs the [optimizer]({% link {{ page.version.version }}/cost-based-optimizer.md %}) to process policy filtering first, ensuring that [user-defined functions]({% link {{ page.version.version }}/user-defined-functions.md %}) (UDFs) never receive rows violating RLS policies. - ## Examples ### Create a policy @@ -139,7 +126,7 @@ For an example, see [`DROP POLICY`]({% link {{ page.version.version }}/drop-poli For examples, see: - [`ALTER TABLE ... (ENABLE, DISABLE) ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security). -- [`ALTER TABLE ... (FORCE, UNFORCE) ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security). +- [`ALTER TABLE ... (FORCE, NO FORCE) ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security). ### RLS for Data Security (Fine-Grained Access Control) @@ -329,20 +316,6 @@ RESET ROLE; (5 rows) ~~~ -The following statement is executed by the user `alice`, and fails because it violates the `self_access` policy's `WITH CHECK` clause since Alice tries to update Bob's salary, and `manager_access` doesn't grant `UPDATE`. - -{% include_cached copy-clipboard.html %} -~~~ sql -SET ROLE alice; -UPDATE employees SET salary = 999999 WHERE username = 'bob'; -RESET ROLE; -~~~ - -~~~ -ERROR: user alice does not have UPDATE privilege on relation employees -SQLSTATE: 42501 -~~~ - ### RLS for Multi-Tenant Isolation Multi-tenant isolation is used to enforce strict data separation between different tenants (customers, organizations) sharing the same database infrastructure and schema. Each tenant must only be able to see and modify their own data. This is a critical requirement for Software-as-a-Service (SaaS) applications. @@ -449,9 +422,7 @@ For multi-tenant isolation to work properly in this example, you **must** also ` {% include_cached copy-clipboard.html %} ~~~ sql -ALTER TABLE invoices ENABLE ROW LEVEL SECURITY; --- Consider applying to owner/admins too unless bypassed explicitly -ALTER TABLE invoices FORCE ROW LEVEL SECURITY; +ALTER TABLE invoices ENABLE ROW LEVEL SECURITY, FORCE ROW LEVEL SECURITY; ~~~ #### Define tenant isolation policies @@ -460,7 +431,11 @@ The following policy enforces tenant isolation for all operations. {% include_cached copy-clipboard.html %} ~~~ sql --- CREATE POLICY tenant_isolation ON invoices AS RESTRICTIVE FOR ALL TO public USING (tenant_id = split_part(current_setting('application_name', true), '.', 2)::UUID) WITH CHECK (tenant_id = split_part(current_setting('application_name', true), '.', 2)::UUID); +CREATE POLICY tenant_isolation_permissive ON invoices + AS PERMISSIVE + FOR ALL + TO public + USING (tenant_id = split_part(current_setting('application_name', true), '.', 2)::UUID); CREATE POLICY tenant_isolation ON invoices AS RESTRICTIVE @@ -472,11 +447,12 @@ CREATE POLICY tenant_isolation ON invoices Explanation of policy: -- `AS RESTRICTIVE`: Makes this policy mandatory. If other policies exist, they must *also* pass. For simple tenant isolation, this is often the safest default. +- `AS PERMISSIVE`: Necessary because you need at least one permissive policy. +- `AS RESTRICTIVE`: Makes the policy mandatory. If other policies exist, they must *also* pass. For simple tenant isolation, this is often the safest default. - `FOR ALL`: Covers all data modification and retrieval. - `TO PUBLIC`: Applies the policy broadly. Roles should primarily manage table-level access using `GRANT`, while this policy handles row-level visibility. - `USING`: Ensures queries only see rows matching the session's tenant ID, which is passed in using the `application_name` session variable and extracted using the `split_part` function. -- `WITH CHECK`: Prevents users from `INSERT`ing rows with a tenant ID column different from their session's calculated tenant ID, or `UPDATE`ing a row to change its `tenant_id` column across tenant boundaries. Without this, a user could potentially insert data into another tenant's space. +- `WITH CHECK`: Prevents users from `INSERT`ing rows with a tenant ID column different from their session's calculated tenant ID, or `UPDATE`ing a row to change its `tenant_id` column across tenant boundaries. Without this, a user could potentially insert data into another tenant's space. In this case, the `WITH CHECK` expression could have been omitted; it is only necessary if it's different than the `USING` expression, or if it applies to a command that doesn't do reads (e.g., for `INSERT`). #### Verify multi-tenant isolation policies @@ -532,6 +508,10 @@ INSERT INTO invoices (tenant_id, customer_name, amount) VALUES ('9607a12c-3c2f-4 The above statement succeeds. +~~~ +INSERT 0 1 +~~~ + ### Video demo: Row-level Security For a demo showing how to combine Row-level security with [Multi-region SQL]({% link {{ page.version.version }}/multiregion-overview.md %}) to constrain access to specific rows based on a user's geographic region, play the following video: @@ -545,7 +525,7 @@ For a demo showing how to combine Row-level security with [Multi-region SQL]({% - [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) - [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) - [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) -- [`ALTER TABLE {FORCE, UNFORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security) +- [`ALTER TABLE {FORCE, NO FORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-unforce-row-level-security) - [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) - [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) @@ -554,7 +534,7 @@ For a demo showing how to combine Row-level security with [Multi-region SQL]({% @@ -47,14 +49,14 @@ Parameter | Description ----------|------------ `policy_name` | The identifier of the existing policy to be modified. Must be unique for the specified `table_name`. `ON table_name` | The name of the table on which the policy `policy_name` is defined. -`RENAME TO { new_policy_name }` | The new identifier for the policy. The `new_policy_name` must be a unique name on `table_name`. -`TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...]` | Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the altered policy applies. These role(s) replace the existing set of roles for the policy (`PUBLIC` refers to all roles). `CURRENT_USER` and `SESSION_USER` refer to the current execution context's user (also available via [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) `current_user()` and `session_user()`). -`USING ( using_expression )` | Replaces the previous value of this expression. For details about this expression, see [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}#parameters). -`WITH CHECK ( check_expression )` | Replaces the previous value of this expression. For details about this expression, see [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}#parameters). +`new_policy_name` | The new identifier for the policy. The `new_policy_name` must be a unique name on `table_name`. +`TO (role_name | PUBLIC | CURRENT_USER | SESSION_USER) [, ...]` | Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the altered policy applies. These role(s) replace the existing set of roles for the policy. `PUBLIC` refers to all roles. `CURRENT_USER` and `SESSION_USER` refer to the current execution context's user (also available via [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) `current_user()` and `session_user()`). +`USING ( using_expression )` | Replaces the previous value of this expression. For details about this expression, refer to [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}#parameters). +`WITH CHECK ( check_expression )` | Replaces the previous value of this expression. For details about this expression, refer to [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}#parameters). -## Examples +## Example -In this example, we start by only allowing users to see or modify their own rows in an `orders` table. Then, as the schema is updated due to business requirements, we must refine the policy to take into account the new requirements. +In this example, you will start by only allowing users to see or modify their own rows in an `orders` table. Then, as the schema is updated due to business requirements, you will refine the policy to take into account the new requirements. {% include_cached copy-clipboard.html %} ~~~ sql @@ -65,14 +67,14 @@ The original policy on the table was as follows: {% include_cached copy-clipboard.html %} ~~~ sql - CREATE POLICY user_orders_policy ON orders - FOR ALL - TO PUBLIC - USING ( user_id = current_user ) - WITH CHECK ( user_id = current_user ); +CREATE POLICY user_orders_policy ON orders + FOR ALL + TO PUBLIC + USING ( user_id = CURRENT_USER ) + WITH CHECK ( user_id = CURRENT_USER ); ~~~ -However, the `orders` table schema has been updated to include an `is_archived` flag, and the initial policy needs refinement. +However, the `orders` table schema will be updated to include an `is_archived` flag, and the initial policy will need refinement. {% include_cached copy-clipboard.html %} ~~~ sql @@ -84,7 +86,7 @@ CREATE INDEX idx_orders_user_id_is_archived ON orders(user_id, is_archived); -- The policy requirements have changed as follows: 1. The policy should now only apply to users belonging to the `customer_service` role, not `PUBLIC`. -1. Users (in `customer_service`) should only be able to view and modify orders that are **not** archived (`is_archived = FALSE`). Archived orders should be invisible/immutable via this policy. +1. Users in `customer_service` should only be able to view and modify orders that are **not** archived (`is_archived = FALSE`). Archived orders should be invisible/immutable via this policy. This assumes the `customer_service` role has been created: @@ -98,21 +100,18 @@ This leads to the following `ALTER POLICY` statement: {% include_cached copy-clipboard.html %} ~~~ sql ALTER POLICY user_orders_policy ON orders - -- 1. Change the applicable role(s) TO customer_service - -- 2. Update the USING clause to filter out archived orders - USING ( user_id = current_user AND is_archived = FALSE ) - -- 3. Update the WITH CHECK clause to prevent archiving/modifying archived orders via this policy - WITH CHECK ( user_id = current_user AND is_archived = FALSE ); + USING ( user_id = CURRENT_USER AND is_archived = FALSE ) + WITH CHECK ( user_id = CURRENT_USER AND is_archived = FALSE ); ~~~ The changes to the `ALTER POLICY` statement can be explained as follows: - `TO customer_service`: Restricts the policy's application from all users (`PUBLIC`) to only those who are members of the `customer_service` role. Other users will no longer be affected by this specific policy (they would need other applicable policies or RLS would deny access by default). -- `USING ( user_id = current_user AND is_archived = FALSE )`: Modifies the visibility rule. Now, `customer_service` users can only see rows matching their `user_id` *and* where `is_archived` is false. -- `WITH CHECK ( user_id = current_user AND is_archived = FALSE )`: Modifies the constraint for `INSERT`/`UPDATE`. Users attempting modifications must satisfy the `user_id` match, and the resulting row must have `is_archived = FALSE`. This prevents them from inserting archived orders or updating an order to set `is_archived = TRUE` via operations governed by this policy. +- `USING ( user_id = CURRENT_USER AND is_archived = FALSE )`: Modifies the visibility rule. Now, `customer_service` users can only see rows that match their `user_id` *and* are not archived. +- `WITH CHECK ( user_id = CURRENT_USER AND is_archived = FALSE )`: Modifies the constraint for `INSERT`/`UPDATE`. Users attempting modifications must match the `user_id`, and the resulting row must not be archived. This prevents the user from inserting archived orders or updating an order to set `is_archived = TRUE` via operations governed by this policy. -This `ALTER POLICY` statement reflects a typical evolution: refining role targeting and adapting the policy logic to accommodate schema changes and evolving access control requirements. +The preceding `ALTER POLICY` statement represents a typical use case: it refines role targeting and adapts the policy logic to accommodate schema changes and evolving access control requirements. ## See also @@ -120,19 +119,6 @@ This `ALTER POLICY` statement reflects a typical evolution: refining role target - [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) - [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) - [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) -- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-row-level-security) - [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) - [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) - - - - diff --git a/src/current/v25.2/alter-role.md b/src/current/v25.2/alter-role.md index 8b2381dd08a..17d3031929d 100644 --- a/src/current/v25.2/alter-role.md +++ b/src/current/v25.2/alter-role.md @@ -54,7 +54,6 @@ CREATE ROLE carl; ~~~ ~~~ sql --- sqlchecker: ignore ALTER ROLE carl WITH LOGIN PASSWORD 'An0ther$tr0nGpassW0rD' VALID UNTIL '2021-10-10'; ~~~ @@ -301,16 +300,3 @@ ALTER ROLE max WITH SUBJECT 'CN=myName2,OU=myOrgUnit2,O=myOrg2,L=myLocality2,ST= - [SQL Statements]({% link {{ page.version.version }}/sql-statements.md %}) - [Authorization Best Practices]({% link {{ page.version.version }}/security-reference/authorization.md %}#authorization-best-practices) - [`SHOW DEFAULT SESSION VARIABLES FOR ROLE`]({% link {{ page.version.version }}/show-default-session-variables-for-role.md %}) - - - - diff --git a/src/current/v25.2/alter-table.md b/src/current/v25.2/alter-table.md index baea309974e..b2dd4c6a65f 100644 --- a/src/current/v25.2/alter-table.md +++ b/src/current/v25.2/alter-table.md @@ -50,17 +50,18 @@ Subcommand | Description | Can combine with other subcommands? [`ALTER COLUMN`](#alter-column) | Change an existing column. | Yes [`ALTER PRIMARY KEY`](#alter-primary-key) | Change the [primary key]({% link {{ page.version.version }}/primary-key.md %}) of a table. | Yes [`CONFIGURE ZONE`](#configure-zone) | [Replication Controls]({% link {{ page.version.version }}/configure-replication-zones.md %}) for a table. | No +[`DISABLE ROW LEVEL SECURITY`](#disable-row-level-security) | Disable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) for a table. | Yes [`DROP COLUMN`](#drop-column) | Remove columns from tables. | Yes [`DROP CONSTRAINT`](#drop-constraint) | Remove constraints from columns. | Yes +[`ENABLE ROW LEVEL SECURITY`](#enable-row-level-security) | Enable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) for a table. | Yes [`EXPERIMENTAL_AUDIT`](#experimental_audit) | Enable per-table audit logs, for security purposes. | Yes +[`FORCE / NO FORCE ROW LEVEL SECURITY`](#force-row-level-security) | Force the table owner to be subject to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies defined on a table. | Yes [`OWNER TO`](#owner-to) | Change the owner of the table. | No [`PARTITION BY`](#partition-by) | Partition, re-partition, or un-partition a table. | Yes [`RENAME COLUMN`](#rename-column) | Change the names of columns. | Yes [`RENAME CONSTRAINT`](#rename-constraint) | Change constraints columns. | Yes [`RENAME TO`](#rename-to) | Change the names of tables. | No [`RESET {storage parameter}`](#reset-storage-parameter) | Reset a storage parameter on a table to its default value. | Yes -[`(ENABLE, DISABLE) ROW LEVEL SECURITY`](#enable-disable-row-level-security) | Enable or disable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) for a table. | Yes -[`(FORCE, NO FORCE) ROW LEVEL SECURITY`](#force-row-level-security) | Force the table owner to be subject to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies defined on a table. | Yes [`SET {storage parameter}`](#set-storage-parameter) | Set a storage parameter on a table. | Yes [`SET LOCALITY`](#set-locality) | Set the table locality for a table in a [multi-region database]({% link {{ page.version.version }}/multiregion-overview.md %}). | No [`SET SCHEMA`](#set-schema) | Change the [schema]({% link {{ page.version.version }}/sql-name-resolution.md %}) of a table. | No @@ -470,15 +471,13 @@ Parameter | Description | For usage, see [Synopsis](#synopsis). -### `(ENABLE, DISABLE) ROW LEVEL SECURITY` +### `ENABLE ROW LEVEL SECURITY` [Row-level security]({% link {{ page.version.version }}/row-level-security.md %}) must be explicitly enabled per [table]({% link {{ page.version.version }}/schema-design-table.md %}). Typically, this is controlled by the [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) that owns the table. -For examples, see [Enable and disable row-level security](#enable-and-disable-row-level-security). +For examples, see [Enable row-level security](#enable-row-level-security). -{{site.data.alerts.callout_info}} -RLS applies to a table **only when explicitly enabled** using `ALTER TABLE ... ENABLE ROW LEVEL SECURITY`. Roles exempt from RLS policies include [admins]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), [table owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) (unless the table is set to [`FORCE ROW LEVEL SECURITY`](#force-row-level-security)), and [roles with `BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). -{{site.data.alerts.end}} +{% include {{ page.version.version }}/sql/row-level-security-enabled.md %} #### Required privileges @@ -486,18 +485,35 @@ The user must be a member of the [`admin`]({% link {{ page.version.version }}/se #### Parameters -| Parameter | Description | -|---------------------|----------------------------------------------------------------------------------------------------------------------------------------------------| -| `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | -| `(ENABLE, DISABLE)` | Whether to enable or disable RLS. | +| Parameter | Description | +|--------------|----------------------------------------------------------------------------------------------------------------------------------------------------| +| `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | +| `ENABLE` | Whether to enable RLS. | + +### `DISABLE ROW LEVEL SECURITY` -### `{FORCE, NO FORCE} ROW LEVEL SECURITY` +This statement disables [Row-level security]({% link {{ page.version.version }}/row-level-security.md %}) per [table]({% link {{ page.version.version }}/schema-design-table.md %}). Typically, this is controlled by the [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) that owns the table. + +For examples, refer to [Disable row-level security](#disable-row-level-security). + +#### Required privileges + +The user must be a member of the [`admin`]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) or [owner]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) roles. + +#### Parameters + +| Parameter | Description | +|--------------|----------------------------------------------------------------------------------------------------------------------------------------------------| +| `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | +| `DISABLE` | Whether to disable RLS. | + +### `FORCE / NO FORCE ROW LEVEL SECURITY` `ALTER TABLE ... FORCE ROW LEVEL SECURITY` prevents table [owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) from bypassing [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) policies. -Use this statement when you need to ensure that all access, including by the table owner, adheres to the defined RLS policies. For example, in production or multi-tenant environments where all roles (including administrators) must operate under policy constraints. Note that this statement only has an affect if [`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`](#enable-disable-row-level-security) is also set. +Use this statement when you need to ensure that all access, including by the table owner, adheres to the defined RLS policies. Note that this statement only has an affect if [`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`](#enable-row-level-security) is also set. -For examples, see [Force row-level security](#force-row-level-security). +For examples, refer to [Force row-level security](#force-row-level-security). {{site.data.alerts.callout_danger}} Users with the `BYPASSRLS` [role option]({% link {{ page.version.version }}/security-reference/authorization.md %}#role-options) can still bypass RLS even when `ALTER TABLE ... FORCE ROW LEVEL SECURITY` is enabled. @@ -509,10 +525,11 @@ The user must be a member of the [`admin`]({% link {{ page.version.version }}/se #### Parameters -| Parameter | Description | -|--------------------|------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| -| `table_name` | The name of the table which is having [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) enabled or disabled. | -| `(FORCE, NO FORCE)` | `FORCE` ensures that all access (even by the table owner) adheres to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies. `NO FORCE` removes that restriction. | +| Parameter | Description | +|--------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| +| `table_name` | The name of the table on which [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) is enabled or disabled. | +| `FORCE` | `FORCE` ensures that all access (even by the table owner) adheres to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies. | +| `NO FORCE` | `NO FORCE` removes the restriction that all access (even by the table owner) adheres to [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies. | ### `SET {storage parameter}` @@ -3078,7 +3095,7 @@ To ensure that the data added to the `vehicles` table prior to the creation of t If present in a [`CREATE TABLE`]({% link {{ page.version.version }}/create-table.md %}) statement, the table is considered validated because an empty table trivially meets its constraints. {{site.data.alerts.end}} -### Enable and disable row-level security +### Enable row-level security To enable [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) (RLS) on a table, issue the following statement: @@ -3087,6 +3104,10 @@ To enable [row-level security]({% link {{ page.version.version }}/row-level-secu ALTER TABLE orders ENABLE ROW LEVEL SECURITY; ~~~ +{% include {{ page.version.version }}/sql/row-level-security-enabled.md %} + +### Disable row-level security + To disable row-level security, use the following statement: {% include_cached copy-clipboard.html %} @@ -3094,10 +3115,6 @@ To disable row-level security, use the following statement: ALTER TABLE orders DISABLE ROW LEVEL SECURITY; ~~~ -{{site.data.alerts.callout_info}} -RLS applies to a table **only when explicitly enabled** using `ALTER TABLE ... ENABLE ROW LEVEL SECURITY`. Roles exempt from RLS policies include [admins]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles), [table owners]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) (unless the table is set to [`FORCE ROW LEVEL SECURITY`](#force-row-level-security)), and [roles with `BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). -{{site.data.alerts.end}} - ### Force row-level security To ensure that all access, including by the table [owner]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership), adheres to the defined [row-level security]({% link {{ page.version.version }}/row-level-security.md %}) policies, issue the following statement: diff --git a/src/current/v25.2/create-policy.md b/src/current/v25.2/create-policy.md index c2efd25d9ff..b0199eb2ac2 100644 --- a/src/current/v25.2/create-policy.md +++ b/src/current/v25.2/create-policy.md @@ -12,10 +12,12 @@ The `CREATE POLICY` statement defines a new [row-level security (RLS)]({% link { @@ -23,9 +25,9 @@ NB. This is commented out while we wait for a fix to DOC-12125 {% include_cached copy-clipboard.html %} ~~~ CREATE POLICY [ IF NOT EXISTS ] policy_name ON table_name - [ AS { PERMISSIVE | RESTRICTIVE } ] + [ AS ( PERMISSIVE | RESTRICTIVE ) ] [ FOR { ALL | SELECT | INSERT | UPDATE | DELETE } ] - [ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ] + [ TO ( role_name | PUBLIC | CURRENT_USER | SESSION_USER ) [, ...] ] [ USING ( using_expression ) ] [ WITH CHECK ( check_expression ) ]; ~~~ @@ -37,11 +39,11 @@ Parameter | Description `IF NOT EXISTS` | Used to specify that the policy will only be created if one with the same `policy_name` does not already exist on `table_name`. If a policy with that name does already exist, the statement will not return an error if this parameter is used. `policy_name` | Unique identifier for the policy on the table. `table_name` | The [table]({% link {{ page.version.version }}/schema-design-table.md %}) to which the policy applies. -`AS { PERMISSIVE, RESTRICTIVE }` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, policies are combined using `OR`. A row is accessible if *any* permissive policy grants access. For `RESTRICTIVE`, policies are combined using `AND`. The overall policy enforcement is determined by evaluating a logical expression of the form: `(permissive policies) AND (restrictive policies)`. This means that all restrictive policies must grant access for a row to be accessible, and restrictive policies are evaluated *after* permissive policies. This means that you need to have at least one `PERMISSIVE` policy in place before applying `RESTRICTIVE` policies. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. -`FOR { ALL, SELECT, INSERT, UPDATE, DELETE } ` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). For details, see [Policies by statement type](#policies-by-statement-type). +`AS { PERMISSIVE, RESTRICTIVE }` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, combine policies using `OR`: a row is accessible if **any** permissive policy grants access. For `RESTRICTIVE`, combine policies using `AND`: a row is accessible if **all** restrictive policies grant access. The overall policy enforcement is determined logically as: `{permissive policies} AND {restrictive policies}`: restrictive policies are evaluated **after** permissive policies. This means that at least one `PERMISSIVE` policy must be in place before `RESTRICTIVE` policies are applied. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. +`FOR { ALL, SELECT, INSERT, UPDATE, DELETE } ` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to: ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). For details, refer to [Policies by statement type](#policies-by-statement-type). `TO { role_name, ...}` | (**Default**: `PUBLIC`, which means the policy applies to all roles.) Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the policy applies. `USING ( using_expression )` | Defines the filter condition such that only rows for which the `using_expression` evaluates to `TRUE` are visible or available for modification. Rows evaluating to `FALSE` or `NULL` are silently excluded. Note this the expression is evaluated **before** any data modifications are attempted. The filter condition applies to [`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %}), and [`INSERT`]({% link {{ page.version.version }}/insert.md %}) (for `INSERT ... ON CONFLICT DO UPDATE`). -`WITH CHECK ( check_expression )` | Defines a constraint condition such that rows being inserted or updated must satisfy `check_expression` (i.e., must evaluate to `TRUE`). This expression is evaluated **after** the row data is prepared but **before** it is written. If the expression evaluates to `FALSE` or `NULL`, the operation fails with an RLS policy violation error. Applies to [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}). If this expression is omitted, it will default to the `USING` expression for new rows in an `UPDATE` or `INSERT`. +`WITH CHECK ( check_expression )` | Defines a constraint condition such that rows being inserted or updated must satisfy `check_expression` (i.e., must evaluate to `TRUE`). This expression is evaluated **after** the row data is prepared but **before** it is written. If the expression evaluates to `FALSE` or `NULL`, the operation fails with an RLS policy violation error. Applies to [`INSERT`]({% link {{ page.version.version }}/insert.md %}) and [`UPDATE`]({% link {{ page.version.version }}/update.md %}). If this expression is omitted, it will default to the `USING` expression for new rows in an `UPDATE` or `INSERT`. {{site.data.alerts.callout_info}} The `USING` and `WITH CHECK` expressions can reference table columns and use session-specific [functions]({% link {{ page.version.version }}/functions-and-operators.md %}) (e.g., `current_user()`, `session_user()`) and [variables]({% link {{ page.version.version }}/session-variables.md %}). However, these expressions cannot contain a subexpression. @@ -65,15 +67,14 @@ The following table shows which policies are applied to which statement types, w Additional considerations include: - `SELECT` evaluation: CockroachDB always evaluates `SELECT` (`USING`) policies for `INSERT`, `UPDATE`, and `DELETE`, even when the statement doesn't reference table columns. -- `ON CONFLICT ... DO NOTHING`: CockroachDB does not run the constraint and row-level policy checks on the `VALUES` clause if the candidate row has a conflict. This is a known limitation described in [cockroachdb/cockroach#35370](https://github.com/cockroachdb/cockroach/issues/35370). +- {% include {{ page.version.version }}/known-limitations/rls-values-on-conflict-do-nothing.md %} This is a [known limitation](#known-limitations). ## Examples -In this example, we only allow users to see or modify their own rows in an `orders` table. +In this example, you will allow users to see or modify only their own rows in an `orders` table. {% include_cached copy-clipboard.html %} ~~~ sql --- Minimal schema for the 'orders' table example. CREATE TABLE orders (user_id TEXT PRIMARY KEY, order_details TEXT); ~~~ @@ -85,29 +86,21 @@ ALTER TABLE orders ENABLE ROW LEVEL SECURITY; CREATE POLICY user_orders_policy ON orders FOR ALL TO PUBLIC -- Applies to all roles - USING ( user_id = current_user ) - WITH CHECK ( user_id = current_user ); + USING ( user_id = CURRENT_USER ) + WITH CHECK ( user_id = CURRENT_USER ); ~~~ +## Known limitations + +- {% include {{ page.version.version }}/known-limitations/rls-values-on-conflict-do-nothing.md %} + ## See also - [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %}) - [`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) - [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) - [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) -- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security) +- [`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-row-level-security) - [`ALTER TABLE {FORCE, NO FORCE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#force-row-level-security) - [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls) - [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls) - - - - diff --git a/src/current/v25.2/create-role.md b/src/current/v25.2/create-role.md index c7d3bd0c9bf..b1acfd3e46a 100644 --- a/src/current/v25.2/create-role.md +++ b/src/current/v25.2/create-role.md @@ -105,7 +105,6 @@ After creating roles, you must [grant them privileges to databases]({% link {{ p ### Create a role that can log in to the database ~~~ sql --- sqlchecker: ignore CREATE ROLE can_login WITH LOGIN PASSWORD '$tr0nGpassW0rD' VALID UNTIL '2021-10-10'; ~~~ @@ -316,7 +315,7 @@ To create a [role]({% link {{ page.version.version }}/security-reference/authori CREATE ROLE can_bypassrls WITH BYPASSRLS; ~~~ -For instructions showing how to alter a role to add or remove the `BYPASSRLS` privilege, see [`ALTER ROLE`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). +For instructions showing how to alter a role to add or remove the `BYPASSRLS` privilege, refer to [`ALTER ROLE`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls). ### Set the `SUBJECT` role option for certificate based authentication @@ -342,23 +341,3 @@ CREATE ROLE maxroach WITH SUBJECT 'CN=myName,OU=myOrgUnit,O=myOrg,L=myLocality,S - [`SHOW GRANTS`]({% link {{ page.version.version }}/show-grants.md %}) - [SQL Statements]({% link {{ page.version.version }}/sql-statements.md %}) - [Online Schema Changes]({% link {{ page.version.version }}/online-schema-changes.md %}) - - - - diff --git a/src/current/v25.2/drop-policy.md b/src/current/v25.2/drop-policy.md index a8f04c02ac2..6f4a9de5b0d 100644 --- a/src/current/v25.2/drop-policy.md +++ b/src/current/v25.2/drop-policy.md @@ -12,7 +12,9 @@ The `DROP POLICY` statement removes an existing [row-level security (RLS)]({% li - - diff --git a/src/current/v25.2/show-policies.md b/src/current/v25.2/show-policies.md index 177e4a37324..f9d76bd2e08 100644 --- a/src/current/v25.2/show-policies.md +++ b/src/current/v25.2/show-policies.md @@ -12,7 +12,9 @@ The `SHOW POLICIES` statement lists the [row-level security (RLS)]({% link {{ pa - - diff --git a/src/current/v25.2/sql-statements.md b/src/current/v25.2/sql-statements.md index ae2d2dc7be6..b596bf6d08e 100644 --- a/src/current/v25.2/sql-statements.md +++ b/src/current/v25.2/sql-statements.md @@ -18,6 +18,7 @@ Statement | Usage [`ALTER FUNCTION`]({% link {{ page.version.version }}/alter-function.md %}) | Modify a [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}). [`ALTER INDEX`]({% link {{ page.version.version }}/alter-index.md %}) | Apply a schema change to an index. [`ALTER PARTITION`]({% link {{ page.version.version }}/alter-partition.md %}) | Configure the replication zone for a partition. +[`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) | Alter a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`ALTER PROCEDURE`]({% link {{ page.version.version }}/alter-procedure.md %}) | Modify a [stored procedure]({% link {{ page.version.version }}/stored-procedures.md %}). [`ALTER RANGE`]({% link {{ page.version.version }}/alter-range.md %}) | Configure the replication zone for a system range. [`ALTER SCHEMA`]({% link {{ page.version.version }}/alter-schema.md %}) | Alter a user-defined schema. @@ -31,6 +32,7 @@ Statement | Usage [`CREATE DATABASE`]({% link {{ page.version.version }}/create-database.md %}) | Create a new database. [`CREATE FUNCTION`]({% link {{ page.version.version }}/create-function.md %}) | Create a [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}). [`CREATE INDEX`]({% link {{ page.version.version }}/create-index.md %}) | Create an index for a table. +[`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) | Create a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`CREATE PROCEDURE`]({% link {{ page.version.version }}/create-procedure.md %}) | Create a [stored procedure]({% link {{ page.version.version }}/stored-procedures.md %}). [`CREATE SCHEMA`]({% link {{ page.version.version }}/create-schema.md %}) | Create a user-defined schema. [`CREATE SEQUENCE`]({% link {{ page.version.version }}/create-sequence.md %}) | Create a new sequence. @@ -43,6 +45,7 @@ Statement | Usage [`DROP FUNCTION`]({% link {{ page.version.version }}/drop-function.md %}) | Remove a [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}) from a database. [`DROP INDEX`]({% link {{ page.version.version }}/drop-index.md %}) | Remove an index for a table. [`DROP OWNED BY`]({% link {{ page.version.version }}/drop-owned-by.md %}) | Drop all objects owned by and any [grants]({% link {{ page.version.version }}/grant.md %}) on objects not owned by a [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles). +[`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) | Drop a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`DROP PROCEDURE`]({% link {{ page.version.version }}/drop-procedure.md %}) | Remove a [stored procedure]({% link {{ page.version.version }}/stored-procedures.md %}). [`DROP SCHEMA`]({% link {{ page.version.version }}/drop-schema.md %}) | Drop a user-defined schema. [`DROP SEQUENCE`]({% link {{ page.version.version }}/drop-sequence.md %}) | Remove a sequence. @@ -60,6 +63,7 @@ Statement | Usage [`SHOW FULL TABLE SCANS`]({% link {{ page.version.version }}/show-full-table-scans.md %}) | List recent queries that used a full table scan. [`SHOW INDEX`]({% link {{ page.version.version }}/show-index.md %}) | View index information for a table or database. [`SHOW LOCALITY`]({% link {{ page.version.version }}/show-locality.md %}) | View the locality of the current node. +[`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) | Show the [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies for a table. [`SHOW PARTITIONS`]({% link {{ page.version.version }}/show-partitions.md %}) | List partitions in a database. [`SHOW REGIONS`]({% link {{ page.version.version }}/show-regions.md %}) | List the [cluster regions]({% link {{ page.version.version }}/multiregion-overview.md %}#cluster-regions) or [database regions]({% link {{ page.version.version }}/multiregion-overview.md %}#database-regions) in a [multi-region cluster]({% link {{ page.version.version }}/multiregion-overview.md %}). [`SHOW SUPER REGIONS`]({% link {{ page.version.version }}/show-super-regions.md %}) | List the [super regions]({% link {{ page.version.version }}/multiregion-overview.md %}#super-regions) associated with a database in a [multi-region cluster]({% link {{ page.version.version }}/multiregion-overview.md %}). From c627ca61c51596a7c2bf9d51f4b559ac9d956430 Mon Sep 17 00:00:00 2001 From: Rich Loveland Date: Tue, 13 May 2025 11:04:46 -0400 Subject: [PATCH 6/6] Update with taroface feedback (2) --- src/current/v25.2/alter-policy.md | 4 ++-- src/current/v25.2/create-policy.md | 8 ++++---- src/current/v25.2/sql-statements.md | 8 ++++---- 3 files changed, 10 insertions(+), 10 deletions(-) diff --git a/src/current/v25.2/alter-policy.md b/src/current/v25.2/alter-policy.md index eb6a93a38ec..8c4fedf092a 100644 --- a/src/current/v25.2/alter-policy.md +++ b/src/current/v25.2/alter-policy.md @@ -16,7 +16,7 @@ Allowed changes to a policy using `ALTER POLICY` include: - Modify the [`WITH CHECK` expression](#parameters). {{site.data.alerts.callout_info}} -You cannot use `ALTER POLICY` to change the `PERMISSIVE`, `RESTRICTIVE`, or `FOR` clauses of a policy, as defined in `CREATE POLICY ... ON ... { PERMISSIVE | RESTRICTIVE } ... FOR { ALL | SELECT | ... }`. To make these changes, drop the policy with [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) and issue a new [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) statement. +You cannot use `ALTER POLICY` to change the `PERMISSIVE`, `RESTRICTIVE`, or `FOR` clauses of a policy, as defined in `CREATE POLICY ... ON ... ( PERMISSIVE | RESTRICTIVE ) ... FOR ( ALL | SELECT | ... )`. To make these changes, drop the policy with [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) and issue a new [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) statement. {{site.data.alerts.end}} ## Syntax @@ -38,7 +38,7 @@ to update the parameters and potentially the diagram. ALTER POLICY policy_name ON table_name RENAME TO new_policy_name; ALTER POLICY policy_name ON table_name - [ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ] + [ TO ( role_name | PUBLIC | CURRENT_USER | SESSION_USER ) [, ...] ] [ USING ( using_expression ) ] [ WITH CHECK ( check_expression ) ]; ~~~ diff --git a/src/current/v25.2/create-policy.md b/src/current/v25.2/create-policy.md index b0199eb2ac2..56201ae6799 100644 --- a/src/current/v25.2/create-policy.md +++ b/src/current/v25.2/create-policy.md @@ -26,7 +26,7 @@ to update the parameters and potentially the diagram. ~~~ CREATE POLICY [ IF NOT EXISTS ] policy_name ON table_name [ AS ( PERMISSIVE | RESTRICTIVE ) ] - [ FOR { ALL | SELECT | INSERT | UPDATE | DELETE } ] + [ FOR ( ALL | SELECT | INSERT | UPDATE | DELETE ) ] [ TO ( role_name | PUBLIC | CURRENT_USER | SESSION_USER ) [, ...] ] [ USING ( using_expression ) ] [ WITH CHECK ( check_expression ) ]; @@ -39,9 +39,9 @@ Parameter | Description `IF NOT EXISTS` | Used to specify that the policy will only be created if one with the same `policy_name` does not already exist on `table_name`. If a policy with that name does already exist, the statement will not return an error if this parameter is used. `policy_name` | Unique identifier for the policy on the table. `table_name` | The [table]({% link {{ page.version.version }}/schema-design-table.md %}) to which the policy applies. -`AS { PERMISSIVE, RESTRICTIVE }` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, combine policies using `OR`: a row is accessible if **any** permissive policy grants access. For `RESTRICTIVE`, combine policies using `AND`: a row is accessible if **all** restrictive policies grant access. The overall policy enforcement is determined logically as: `{permissive policies} AND {restrictive policies}`: restrictive policies are evaluated **after** permissive policies. This means that at least one `PERMISSIVE` policy must be in place before `RESTRICTIVE` policies are applied. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. -`FOR { ALL, SELECT, INSERT, UPDATE, DELETE } ` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to: ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). For details, refer to [Policies by statement type](#policies-by-statement-type). -`TO { role_name, ...}` | (**Default**: `PUBLIC`, which means the policy applies to all roles.) Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the policy applies. +`AS ( PERMISSIVE, RESTRICTIVE )` | (**Default**: `PERMISSIVE`.) For `PERMISSIVE`, combine policies using `OR`: a row is accessible if **any** permissive policy grants access. For `RESTRICTIVE`, combine policies using `AND`: a row is accessible if **all** restrictive policies grant access. The overall policy enforcement is determined logically as: `{permissive policies} AND {restrictive policies}`: restrictive policies are evaluated **after** permissive policies. This means that at least one `PERMISSIVE` policy must be in place before `RESTRICTIVE` policies are applied. If any restrictive policy denies access, the row is inaccessible, regardless of the permissive policies. +`FOR ( ALL, SELECT, INSERT, UPDATE, DELETE )` | (**Default**: `ALL`.) Specifies the SQL statement(s) the policy applies to: ([`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})). For details, refer to [Policies by statement type](#policies-by-statement-type). +`TO role_name, ...` | (**Default**: `PUBLIC`, which means the policy applies to all roles.) Specifies the database [role(s)]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) to which the policy applies. `USING ( using_expression )` | Defines the filter condition such that only rows for which the `using_expression` evaluates to `TRUE` are visible or available for modification. Rows evaluating to `FALSE` or `NULL` are silently excluded. Note this the expression is evaluated **before** any data modifications are attempted. The filter condition applies to [`SELECT`]({% link {{ page.version.version }}/select-clause.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %}), and [`INSERT`]({% link {{ page.version.version }}/insert.md %}) (for `INSERT ... ON CONFLICT DO UPDATE`). `WITH CHECK ( check_expression )` | Defines a constraint condition such that rows being inserted or updated must satisfy `check_expression` (i.e., must evaluate to `TRUE`). This expression is evaluated **after** the row data is prepared but **before** it is written. If the expression evaluates to `FALSE` or `NULL`, the operation fails with an RLS policy violation error. Applies to [`INSERT`]({% link {{ page.version.version }}/insert.md %}) and [`UPDATE`]({% link {{ page.version.version }}/update.md %}). If this expression is omitted, it will default to the `USING` expression for new rows in an `UPDATE` or `INSERT`. diff --git a/src/current/v25.2/sql-statements.md b/src/current/v25.2/sql-statements.md index b596bf6d08e..437039fdf4f 100644 --- a/src/current/v25.2/sql-statements.md +++ b/src/current/v25.2/sql-statements.md @@ -18,7 +18,6 @@ Statement | Usage [`ALTER FUNCTION`]({% link {{ page.version.version }}/alter-function.md %}) | Modify a [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}). [`ALTER INDEX`]({% link {{ page.version.version }}/alter-index.md %}) | Apply a schema change to an index. [`ALTER PARTITION`]({% link {{ page.version.version }}/alter-partition.md %}) | Configure the replication zone for a partition. -[`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) | Alter a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`ALTER PROCEDURE`]({% link {{ page.version.version }}/alter-procedure.md %}) | Modify a [stored procedure]({% link {{ page.version.version }}/stored-procedures.md %}). [`ALTER RANGE`]({% link {{ page.version.version }}/alter-range.md %}) | Configure the replication zone for a system range. [`ALTER SCHEMA`]({% link {{ page.version.version }}/alter-schema.md %}) | Alter a user-defined schema. @@ -32,7 +31,6 @@ Statement | Usage [`CREATE DATABASE`]({% link {{ page.version.version }}/create-database.md %}) | Create a new database. [`CREATE FUNCTION`]({% link {{ page.version.version }}/create-function.md %}) | Create a [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}). [`CREATE INDEX`]({% link {{ page.version.version }}/create-index.md %}) | Create an index for a table. -[`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) | Create a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`CREATE PROCEDURE`]({% link {{ page.version.version }}/create-procedure.md %}) | Create a [stored procedure]({% link {{ page.version.version }}/stored-procedures.md %}). [`CREATE SCHEMA`]({% link {{ page.version.version }}/create-schema.md %}) | Create a user-defined schema. [`CREATE SEQUENCE`]({% link {{ page.version.version }}/create-sequence.md %}) | Create a new sequence. @@ -45,7 +43,6 @@ Statement | Usage [`DROP FUNCTION`]({% link {{ page.version.version }}/drop-function.md %}) | Remove a [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}) from a database. [`DROP INDEX`]({% link {{ page.version.version }}/drop-index.md %}) | Remove an index for a table. [`DROP OWNED BY`]({% link {{ page.version.version }}/drop-owned-by.md %}) | Drop all objects owned by and any [grants]({% link {{ page.version.version }}/grant.md %}) on objects not owned by a [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles). -[`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) | Drop a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`DROP PROCEDURE`]({% link {{ page.version.version }}/drop-procedure.md %}) | Remove a [stored procedure]({% link {{ page.version.version }}/stored-procedures.md %}). [`DROP SCHEMA`]({% link {{ page.version.version }}/drop-schema.md %}) | Drop a user-defined schema. [`DROP SEQUENCE`]({% link {{ page.version.version }}/drop-sequence.md %}) | Remove a sequence. @@ -63,7 +60,6 @@ Statement | Usage [`SHOW FULL TABLE SCANS`]({% link {{ page.version.version }}/show-full-table-scans.md %}) | List recent queries that used a full table scan. [`SHOW INDEX`]({% link {{ page.version.version }}/show-index.md %}) | View index information for a table or database. [`SHOW LOCALITY`]({% link {{ page.version.version }}/show-locality.md %}) | View the locality of the current node. -[`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) | Show the [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies for a table. [`SHOW PARTITIONS`]({% link {{ page.version.version }}/show-partitions.md %}) | List partitions in a database. [`SHOW REGIONS`]({% link {{ page.version.version }}/show-regions.md %}) | List the [cluster regions]({% link {{ page.version.version }}/multiregion-overview.md %}#cluster-regions) or [database regions]({% link {{ page.version.version }}/multiregion-overview.md %}#database-regions) in a [multi-region cluster]({% link {{ page.version.version }}/multiregion-overview.md %}). [`SHOW SUPER REGIONS`]({% link {{ page.version.version }}/show-super-regions.md %}) | List the [super regions]({% link {{ page.version.version }}/multiregion-overview.md %}#super-regions) associated with a database in a [multi-region cluster]({% link {{ page.version.version }}/multiregion-overview.md %}). @@ -101,14 +97,18 @@ Statement | Usage Statement | Usage ----------|------------ +[`ALTER POLICY`]({% link {{ page.version.version }}/alter-policy.md %}) | Alter a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. +[`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %}) | Create a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`CREATE ROLE`]({% link {{ page.version.version }}/create-role.md %}) | Create SQL [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles), which are groups containing any number of roles and users as members. [`CREATE USER`]({% link {{ page.version.version }}/create-user.md %}) | Create SQL users, which lets you control [privileges]({% link {{ page.version.version }}/security-reference/authorization.md %}#managing-privileges) on your databases and tables. +[`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %}) | Drop a [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy. [`DROP ROLE`]({% link {{ page.version.version }}/drop-role.md %}) | Remove one or more SQL [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles). [`DROP USER`]({% link {{ page.version.version }}/drop-user.md %}) | Remove one or more SQL users. [`GRANT`]({% link {{ page.version.version }}/grant.md %}) | Grant privileges to [users and roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles), or add a [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles) or [user]({% link {{ page.version.version }}/security-reference/authorization.md %}#create-and-manage-users) as a member to a role. [`REASSIGN OWNED`]({% link {{ page.version.version }}/reassign-owned.md %}) | Change the [ownership]({% link {{ page.version.version }}/security-reference/authorization.md %}#object-ownership) of all database objects in the current database that are currently owned by a specific [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles) or [user]({% link {{ page.version.version }}/security-reference/authorization.md %}#sql-users). [`REVOKE`]({% link {{ page.version.version }}/revoke.md %}) | Revoke privileges from [users]({% link {{ page.version.version }}/security-reference/authorization.md %}#create-and-manage-users) or [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles), or revoke a [role]({% link {{ page.version.version }}/security-reference/authorization.md %}#users-and-roles) or [user's]({% link {{ page.version.version }}/security-reference/authorization.md %}#create-and-manage-users) membership to a role. [`SHOW GRANTS`]({% link {{ page.version.version }}/show-grants.md %}) | View privileges granted to users. +[`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %}) | Show the [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies for a table. [`SHOW ROLES`]({% link {{ page.version.version }}/show-roles.md %}) | Lists the roles for all databases. [`SHOW USERS`]({% link {{ page.version.version }}/show-users.md %}) | Lists the users for all databases. [`SHOW DEFAULT PRIVILEGES`]({% link {{ page.version.version }}/show-default-privileges.md %}) | Show the default privileges for objects created by specific roles/users in the current database.