Skip to content

Commit 56780c5

Browse files
committed
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 0809b4d commit 56780c5

12 files changed

+1164
-40
lines changed

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

+6
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

+24
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

+1
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` | **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.
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

+1
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**: 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.
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.

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

+138
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,138 @@
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` 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).
20+
{{site.data.alerts.end}}
21+
22+
## Syntax
23+
24+
<!--
25+
26+
NB. This is commented out while we wait for a fix to DOC-12125
27+
28+
<div>
29+
{% remote_include https://raw.githubusercontent.com/cockroachdb/generated-diagrams/{{ page.release_info.crdb_branch_name }}/grammar_svg/alter_policy_stmt.html %}
30+
</div>
31+
32+
-->
33+
34+
{% include_cached copy-clipboard.html %}
35+
~~~
36+
ALTER POLICY policy_name ON table_name RENAME TO new_policy_name;
37+
38+
ALTER POLICY policy_name ON table_name
39+
[ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ]
40+
[ USING ( using_expression ) ]
41+
[ WITH CHECK ( check_expression ) ];
42+
~~~
43+
44+
## Parameters
45+
46+
Parameter | Description
47+
----------|------------
48+
`policy_name` | The identifier of the existing policy to be modified. Must be unique for the specified `table_name`.
49+
`ON table_name` | The name of the table on which the policy `policy_name` is defined.
50+
`RENAME TO { new_policy_name }` | The new identifier for the policy. The `new_policy_name` must be a unique name on `table_name`.
51+
`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()`).
52+
`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).
53+
`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).
54+
55+
## Examples
56+
57+
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.
58+
59+
{% include_cached copy-clipboard.html %}
60+
~~~ sql
61+
CREATE TABLE orders (user_id TEXT PRIMARY KEY, order_details TEXT);
62+
~~~
63+
64+
The original policy on the table was as follows:
65+
66+
{% include_cached copy-clipboard.html %}
67+
~~~ sql
68+
CREATE POLICY user_orders_policy ON orders
69+
FOR ALL
70+
TO PUBLIC
71+
USING ( user_id = current_user )
72+
WITH CHECK ( user_id = current_user );
73+
~~~
74+
75+
However, the `orders` table schema has been updated to include an `is_archived` flag, and the initial policy needs refinement.
76+
77+
{% include_cached copy-clipboard.html %}
78+
~~~ sql
79+
-- Assume this change was made after the initial policy was created
80+
ALTER TABLE orders ADD COLUMN is_archived BOOLEAN DEFAULT FALSE NOT NULL;
81+
CREATE INDEX idx_orders_user_id_is_archived ON orders(user_id, is_archived); -- For performance
82+
~~~
83+
84+
The policy requirements have changed as follows:
85+
86+
1. The policy should now only apply to users belonging to the `customer_service` role, not `PUBLIC`.
87+
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.
88+
89+
This assumes the `customer_service` role has been created:
90+
91+
{% include_cached copy-clipboard.html %}
92+
~~~ sql
93+
CREATE ROLE customer_service;
94+
~~~
95+
96+
This leads to the following `ALTER POLICY` statement:
97+
98+
{% include_cached copy-clipboard.html %}
99+
~~~ sql
100+
ALTER POLICY user_orders_policy ON orders
101+
-- 1. Change the applicable role(s)
102+
TO customer_service
103+
-- 2. Update the USING clause to filter out archived orders
104+
USING ( user_id = current_user AND is_archived = FALSE )
105+
-- 3. Update the WITH CHECK clause to prevent archiving/modifying archived orders via this policy
106+
WITH CHECK ( user_id = current_user AND is_archived = FALSE );
107+
~~~
108+
109+
The changes to the `ALTER POLICY` statement can be explained as follows:
110+
111+
- `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).
112+
- `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.
113+
- `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.
114+
115+
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.
116+
117+
## See also
118+
119+
- [Row-level security (RLS) overview]({% link {{ page.version.version }}/row-level-security.md %})
120+
- [`CREATE POLICY`]({% link {{ page.version.version }}/create-policy.md %})
121+
- [`DROP POLICY`]({% link {{ page.version.version }}/drop-policy.md %})
122+
- [`SHOW POLICIES`]({% link {{ page.version.version }}/show-policies.md %})
123+
- [`ALTER TABLE {ENABLE, DISABLE} ROW LEVEL SECURITY`]({% link {{ page.version.version }}/alter-table.md %}#enable-disable-row-level-security)
124+
- [`ALTER ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/alter-role.md %}#allow-a-role-to-bypass-row-level-security-rls)
125+
- [`CREATE ROLE ... WITH BYPASSRLS`]({% link {{ page.version.version }}/create-role.md %}#create-a-role-that-can-bypass-row-level-security-rls)
126+
127+
<!-- Sqlchecker test cleanup block. NB. This must always come last. Be sure to comment this out when finished writing the doc. -->
128+
129+
<!--
130+
131+
{% include_cached copy-clipboard.html %}
132+
~~~ sql
133+
DROP POLICY IF EXISTS user_orders_policy ON orders CASCADE;
134+
DROP TABLE IF EXISTS orders CASCADE;
135+
DROP USER customer_service;
136+
~~~
137+
138+
-->

0 commit comments

Comments
 (0)