Skip to content

Commit 5337dd9

Browse files
authored
Add docs for Row-level security (RLS) (#19527)
* 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`
1 parent 79a68c9 commit 5337dd9

16 files changed

+1162
-40
lines changed
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
`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. [#35370](https://github.com/cockroachdb/cockroach/issues/35370).

src/current/_includes/v25.2/sidebar-data/reference.json

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -382,6 +382,12 @@
382382
"/${VERSION}/column-level-encryption.html"
383383
]
384384
},
385+
{
386+
"title": "Row-level Security",
387+
"urls": [
388+
"/${VERSION}/row-level-security.html"
389+
]
390+
},
385391
{
386392
"title": "PKI and TLS",
387393
"urls": [

src/current/_includes/v25.2/sidebar-data/sql.json

Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -64,6 +64,12 @@
6464
"/${VERSION}/alter-partition.html"
6565
]
6666
},
67+
{
68+
"title": "<code>ALTER POLICY</code>",
69+
"urls": [
70+
"/${VERSION}/alter-policy.html"
71+
]
72+
},
6773
{
6874
"title": "<code>ALTER PROCEDURE</code>",
6975
"urls": [
@@ -220,6 +226,12 @@
220226
"/${VERSION}/create-logical-replication-stream.html"
221227
]
222228
},
229+
{
230+
"title": "<code>CREATE POLICY</code>",
231+
"urls": [
232+
"/${VERSION}/create-policy.html"
233+
]
234+
},
223235
{
224236
"title": "<code>CREATE PROCEDURE</code>",
225237
"urls": [
@@ -340,6 +352,12 @@
340352
"/${VERSION}/drop-owned-by.html"
341353
]
342354
},
355+
{
356+
"title": "<code>DROP POLICY</code>",
357+
"urls": [
358+
"/${VERSION}/drop-policy.html"
359+
]
360+
},
343361
{
344362
"title": "<code>DROP TRIGGER</code>",
345363
"urls": [
@@ -694,6 +712,12 @@
694712
"/${VERSION}/show-partitions.html"
695713
]
696714
},
715+
{
716+
"title": "<code>SHOW POLICIES</code>",
717+
"urls": [
718+
"/${VERSION}/show-policies.html"
719+
]
720+
},
697721
{
698722
"title": "<code>SHOW RANGES</code>",
699723
"urls": [

src/current/_includes/v25.2/sql/privileges.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2,6 +2,7 @@ Privilege | Levels | Description
22
----------|--------|------------
33
`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.
44
`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.
5+
<a name="bypassrls"></a> `BYPASSRLS` | Table | **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. This privilege 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.
56
`CANCELQUERY` | System | Grants the ability to cancel queries.
67
`CHANGEFEED` | Table | Grants the ability to create [changefeeds]({% link {{ page.version.version }}/change-data-capture-overview.md %}) on a table.
78
<a id="connect"></a>`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.

src/current/_includes/v25.2/sql/role-options.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
11
Role option | Description
22
------------|-------------
3+
<a name="bypassrls"></a> `BYPASSRLS`/`NOBYPASSRLS` | **New in v25.2**: Allow or disallow a role to bypass [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policies on a table. 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.
34
`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. <br><br>By default, the role option is set to `NOCANCELQUERY` for all non-`admin` roles.
45
`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. <br><br>By default, the role option is set to `NOCONTROLCHANGEFEED` for all non-`admin` roles.
56
`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. <br><br>By default, the role option is set to `NOCONTROLJOB` for all non-`admin` roles.
Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
{{site.data.alerts.callout_info}}
2+
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).
3+
{{site.data.alerts.end}}

src/current/v25.2/alter-policy.md

Lines changed: 124 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,124 @@
1+
---
2+
title: ALTER POLICY
3+
summary: The ALTER POLICY statement changes an existing row-level security (RLS) policy on a table.
4+
toc: true
5+
keywords: security, row level security, RLS
6+
docs_area: reference.sql
7+
---
8+
9+
The `ALTER POLICY` statement changes an existing [row-level security (RLS)]({% link {{ page.version.version }}/row-level-security.md %}) policy on a table.
10+
11+
Allowed changes to a policy using `ALTER POLICY` include:
12+
13+
- Rename the policy.
14+
- Change the applicable [roles]({% link {{ page.version.version }}/security-reference/authorization.md %}#roles).
15+
- Modify the [`USING` expression](#parameters).
16+
- Modify the [`WITH CHECK` expression](#parameters).
17+
18+
{{site.data.alerts.callout_info}}
19+
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.
20+
{{site.data.alerts.end}}
21+
22+
## Syntax
23+
24+
<!--
25+
26+
NB. This was waiting on a fix to DOC-12125 when this doc was being
27+
written. Now there is additional followup work (tracked in DOC-13653)
28+
to update the parameters and potentially the diagram.
29+
30+
<div>
31+
{% remote_include https://github.com/raw/cockroachdb/generated-diagrams/{{ page.release_info.crdb_branch_name }}/grammar_svg/alter_policy.html %}
32+
</div>
33+
34+
-->
35+
36+
{% include_cached copy-clipboard.html %}
37+
~~~
38+
ALTER POLICY policy_name ON table_name RENAME TO new_policy_name;
39+
40+
ALTER POLICY policy_name ON table_name
41+
[ TO ( role_name | PUBLIC | CURRENT_USER | SESSION_USER ) [, ...] ]
42+
[ USING ( using_expression ) ]
43+
[ WITH CHECK ( check_expression ) ];
44+
~~~
45+
46+
## Parameters
47+
48+
Parameter | Description
49+
----------|------------
50+
`policy_name` | The identifier of the existing policy to be modified. Must be unique for the specified `table_name`.
51+
`ON table_name` | The name of the table on which the policy `policy_name` is defined.
52+
`new_policy_name` | The new identifier for the policy. The `new_policy_name` must be a unique name on `table_name`.
53+
`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()`).
54+
`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).
55+
`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).
56+
57+
## Example
58+
59+
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.
60+
61+
{% include_cached copy-clipboard.html %}
62+
~~~ sql
63+
CREATE TABLE orders (user_id TEXT PRIMARY KEY, order_details TEXT);
64+
~~~
65+
66+
The original policy on the table was as follows:
67+
68+
{% include_cached copy-clipboard.html %}
69+
~~~ sql
70+
CREATE POLICY user_orders_policy ON orders
71+
FOR ALL
72+
TO PUBLIC
73+
USING ( user_id = CURRENT_USER )
74+
WITH CHECK ( user_id = CURRENT_USER );
75+
~~~
76+
77+
However, the `orders` table schema will be updated to include an `is_archived` flag, and the initial policy will need refinement.
78+
79+
{% include_cached copy-clipboard.html %}
80+
~~~ sql
81+
-- Assume this change was made after the initial policy was created
82+
ALTER TABLE orders ADD COLUMN is_archived BOOLEAN DEFAULT FALSE NOT NULL;
83+
CREATE INDEX idx_orders_user_id_is_archived ON orders(user_id, is_archived); -- For performance
84+
~~~
85+
86+
The policy requirements have changed as follows:
87+
88+
1. The policy should now only apply to users belonging to the `customer_service` role, not `PUBLIC`.
89+
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.
90+
91+
This assumes the `customer_service` role has been created:
92+
93+
{% include_cached copy-clipboard.html %}
94+
~~~ sql
95+
CREATE ROLE customer_service;
96+
~~~
97+
98+
This leads to the following `ALTER POLICY` statement:
99+
100+
{% include_cached copy-clipboard.html %}
101+
~~~ sql
102+
ALTER POLICY user_orders_policy ON orders
103+
TO customer_service
104+
USING ( user_id = CURRENT_USER AND is_archived = FALSE )
105+
WITH CHECK ( user_id = CURRENT_USER AND is_archived = FALSE );
106+
~~~
107+
108+
The changes to the `ALTER POLICY` statement can be explained as follows:
109+
110+
- `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).
111+
- `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.
112+
- `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.
113+
114+
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.
115+
116+
## See also
117+
118+
- [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %})
119+
- [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %})
120+
- [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %})
121+
- [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %})
122+
- [`ALTER TABLE ... ENABLE ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-row-level-security)
123+
- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls)
124+
- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls)

0 commit comments

Comments
 (0)