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