|
| 1 | +--- |
| 2 | +title: Row-Level Security |
| 3 | +description: Configure fine-grained access control policies to determine which rows in a table a user can access. |
| 4 | +category: platform |
| 5 | +status: publish |
| 6 | +slug: rls |
| 7 | +--- |
| 8 | + |
| 9 | +import Callout from "@commons-components/Information/Callout.astro"; |
| 10 | + |
| 11 | +Row-Level Security (RLS) allows you to define fine-grained access control policies that determine which rows in a table a user can access. This ensures that users can only view or modify data they are authorized to see, enhancing data security and privacy. |
| 12 | + |
| 13 | +<Callout type="note" title="RLS Scope"> |
| 14 | +RLS rules only affect users who are authenticated using tokens. Admins, APIKEYs, or other non-token users are not restricted by RLS. |
| 15 | +</Callout> |
| 16 | + |
| 17 | +RLS is a powerful feature for building secure, multi-tenant applications. When combined with [SQLite Sync](https://github.com/sqliteai/sqlite-sync), it enables you to create robust **local-first apps** where user data is stored on the device for offline availability and superior performance. |
| 18 | + |
| 19 | +This architecture simplifies development by allowing your application to interact with a local database while SQLite Cloud transparently handles the synchronization with a central database. RLS ensures that each user's data is securely isolated during this process. The centralized database can then be used for powerful business analytics and reporting across all tenants, without compromising individual data privacy. |
| 20 | + |
| 21 | +## Policy Enforcement |
| 22 | + |
| 23 | +RLS in SQLite Cloud operates based on the following principles: |
| 24 | + |
| 25 | +Access is denied by default. |
| 26 | + |
| 27 | +Unless explicitly allowed by RLS rules, access is blocked. Specifically: |
| 28 | + |
| 29 | +- If RLS is enabled and rules are defined, only permitted operations will succeed. |
| 30 | +- If RLS is enabled but a rule is missing for an operation (e.g., `SELECT`), that operation will be denied. |
| 31 | +- If RLS is not enabled or not configured for a table, token-authenticated users won't see any rows at all. |
| 32 | + |
| 33 | +To make data accessible to token-authenticated users, you must both enable RLS for the table and define rules for the desired operations (like `SELECT`, `INSERT`, etc.). |
| 34 | + |
| 35 | +Otherwise, they will be blocked from accessing any rows. |
| 36 | + |
| 37 | +## Configuring RLS |
| 38 | + |
| 39 | +You can configure RLS policies for your databases through the SQLite Cloud dashboard. |
| 40 | + |
| 41 | +1. **Navigate to the Databases Page**: From the main dashboard, go to the "Databases" page. |
| 42 | +2. **Select the RLS Column**: In the list of your databases, click on the button in the "RLS" column for the desired database. |
| 43 | + |
| 44 | +  |
| 45 | + |
| 46 | +3. **Configure RLS Settings**: On the RLS settings page, you can define the policies for each table. |
| 47 | + |
| 48 | +  |
| 49 | + |
| 50 | + For each table, you can specify the following RLS policies: |
| 51 | + |
| 52 | + - **SELECT**: A SQL expression that determines which rows a user can `SELECT`. |
| 53 | + - **INSERT**: A SQL expression that determines if a user can `INSERT` a new row. |
| 54 | + - **UPDATE**: A SQL expression that determines which rows a user can `UPDATE`. |
| 55 | + - **DELETE**: A SQL expression that determines which rows a user can `DELETE`. |
| 56 | + |
| 57 | + <Callout type="note" title="RLS Expressions"> |
| 58 | + The SQL expressions can be any valid SQLite expression that returns a boolean value. You can use built-in SQLite functions, and even custom functions to define your policies. |
| 59 | + </Callout> |
| 60 | + |
| 61 | +### User Information Functions |
| 62 | + |
| 63 | +To help you create dynamic RLS policies, SQLite Cloud provides two functions to retrieve information about the current authenticated user: |
| 64 | + |
| 65 | +- `auth_userid()`: Returns the `userid` of the current token-authenticated user. |
| 66 | +- `auth_json()`: Returns a JSON object with all the details of the current token-authenticated user, including `user_id`, `name`, `attributes`, `created_at`, and `expires_at`. |
| 67 | + |
| 68 | +These functions are particularly useful for creating policies that are based on user attributes. |
| 69 | + |
| 70 | +For more information on Access Tokens, see the [Access Tokens documentation](/docs/access-tokens). The API Documentation for the Access Tokens API can be found in the Weblite section in the [Dashboard](https://dashboard.sqlitecloud.io/). |
| 71 | + |
| 72 | +### OLD and NEW References |
| 73 | + |
| 74 | +Your RLS policies for `INSERT`, `UPDATE`, and `DELETE` operations can reference column values as they are being changed. This is done using the special `OLD.column` and `NEW.column` identifiers. Their availability and meaning depend on the operation being performed: |
| 75 | + |
| 76 | +| Operation | `OLD.column` Reference | `NEW.column` Reference | |
| 77 | +| :--- | :--- | :--- | |
| 78 | +| `INSERT` | Not available | The value for the new row. | |
| 79 | +| `UPDATE` | The value of the row *before* the update. | The value of the row *after* the update. | |
| 80 | +| `DELETE` | The value of the row being deleted. | Not available | |
| 81 | + |
| 82 | +## Example |
| 83 | + |
| 84 | +Suppose you have a `tasks` table with the following schema: |
| 85 | + |
| 86 | +```sql |
| 87 | +CREATE TABLE tasks ( |
| 88 | + id INTEGER PRIMARY KEY, |
| 89 | + title TEXT, |
| 90 | + owner_id INTEGER, |
| 91 | + status TEXT |
| 92 | +); |
| 93 | +``` |
| 94 | + |
| 95 | +Here are a few examples of RLS policies you can create: |
| 96 | + |
| 97 | +**1. Users can only see their own tasks.** |
| 98 | + |
| 99 | +```sql |
| 100 | +-- SELECT policy |
| 101 | +owner_id = auth_userid() |
| 102 | +``` |
| 103 | + |
| 104 | +**2. Users can only insert tasks for themselves.** |
| 105 | + |
| 106 | +```sql |
| 107 | +-- INSERT policy |
| 108 | +NEW.owner_id = auth_userid() |
| 109 | +``` |
| 110 | + |
| 111 | +**3. Users can only update the status of their own tasks.** |
| 112 | + |
| 113 | +```sql |
| 114 | +-- UPDATE policy |
| 115 | +OLD.owner_id = auth_userid() |
| 116 | +``` |
| 117 | + |
| 118 | +**4. Users with the 'admin' group can see all tasks.** |
| 119 | + |
| 120 | +```sql |
| 121 | +-- SELECT policy |
| 122 | +json_extract(auth_json(), '$.attributes.group') = 'admin' |
| 123 | +``` |
| 124 | + |
| 125 | +**5. Role-Based Access within a Tenancy** |
| 126 | + |
| 127 | +```sql |
| 128 | +-- SELECT policy |
| 129 | +org_id = json_extract(auth_json(), '$.attributes.org_id') AND |
| 130 | +(json_extract(auth_json(), '$.attributes.role') = 'admin' OR owner_id = auth_userid()) |
| 131 | +``` |
| 132 | + |
| 133 | +**6. Access via a Membership Linking Table** |
| 134 | + |
| 135 | +```sql |
| 136 | +-- SELECT policy |
| 137 | +EXISTS ( |
| 138 | + SELECT 1 FROM project_members |
| 139 | + WHERE project_members.project_id = tasks.project_id |
| 140 | + AND project_members.user_id = auth_userid() |
| 141 | +) |
| 142 | +``` |
| 143 | + |
| 144 | +**7. Public vs. Private Record Visibility** |
| 145 | + |
| 146 | +```sql |
| 147 | +-- SELECT policy |
| 148 | +visibility = 'public' OR owner_id = auth_userid() |
| 149 | +``` |
| 150 | + |
| 151 | +With these policies, when a user executes a query, SQLite Cloud will automatically enforce the defined RLS rules, ensuring data security and compliance. |
| 152 | + |
| 153 | +### Additional Real-World Examples |
| 154 | + |
| 155 | +Here are a few more examples to illustrate how you can use RLS policies to solve common security challenges. |
| 156 | + |
| 157 | +#### 1. Team-Based Access (Multi-Tenancy) |
| 158 | + |
| 159 | +**Use Case:** A user should only be able to see documents that belong to their organization or team. This is a classic multi-tenancy scenario. |
| 160 | + |
| 161 | +**Assumptions:** |
| 162 | +* Your `documents` table has an `org_id` column. |
| 163 | +* The user's access token contains their organization ID in the JSON attributes (e.g., `{"org_id": "acme_corp"}`). |
| 164 | + |
| 165 | +**RLS Policy (`SELECT`):** |
| 166 | +```sql |
| 167 | +-- On the 'documents' table |
| 168 | +org_id = json_extract(auth_json(), '$.attributes.org_id') |
| 169 | +``` |
| 170 | + |
| 171 | +**Explanation:** |
| 172 | +This policy ensures that the `org_id` in the document row must match the `org_id` stored in the authenticated user's token. This effectively isolates data between different organizations. |
| 173 | + |
| 174 | +--- |
| 175 | + |
| 176 | +#### 2. Content Publishing Workflow |
| 177 | + |
| 178 | +**Use Case:** In a simple CMS or blog, any user (even anonymous ones, if applicable) can see articles with a `published` status. However, only the original author can see their own articles when they are in the `draft` status. |
| 179 | + |
| 180 | +**Assumptions:** |
| 181 | +* Your `articles` table has a `status` column (`'draft'` or `'published'`) and an `author_id` column. |
| 182 | + |
| 183 | +**RLS Policy (`SELECT`):** |
| 184 | +```sql |
| 185 | +-- On the 'articles' table |
| 186 | +status = 'published' OR (status = 'draft' AND author_id = auth_userid()) |
| 187 | +``` |
| 188 | + |
| 189 | +**Explanation:** |
| 190 | +This policy uses a boolean `OR` to combine two conditions. A user can see a row if: |
| 191 | +1. The article's status is `published`, OR |
| 192 | +2. The article's status is `draft` AND the user is the author. |
| 193 | + |
| 194 | +--- |
| 195 | + |
| 196 | +#### 3. Making Records Read-Only |
| 197 | + |
| 198 | +**Use Case:** Once an invoice has been marked as `paid`, it should become immutable. No user should be able to update it. |
| 199 | + |
| 200 | +**Assumptions:** |
| 201 | +* Your `invoices` table has a `status` column (`'pending'`, `'paid'`, etc.). |
| 202 | + |
| 203 | +**RLS Policy (`UPDATE`):** |
| 204 | +```sql |
| 205 | +-- On the 'invoices' table |
| 206 | +OLD.status <> 'paid' |
| 207 | +``` |
| 208 | + |
| 209 | +**Explanation:** |
| 210 | +This policy uses the `OLD` reference to check the value of the `status` column *before* the update is applied. If the status is already `'paid'`, the condition `OLD.status <> 'paid'` will be false, and the `UPDATE` operation will be denied. This effectively makes paid invoices read-only. |
| 211 | + |
| 212 | +### Advanced: RLS and SQLite Sync |
| 213 | + |
| 214 | +When using RLS in conjunction with [SQLite Sync](https://github.com/sqliteai/sqlite-sync), it's important to understand how they interact. The Sync protocol applies changes on a column-by-column basis, which can affect how `INSERT` and `UPDATE` policies are evaluated. |
| 215 | + |
| 216 | +To accommodate this, SQLite Cloud offers two modes for handling RLS during sync operations, configurable via the `rls_mode` server setting. |
| 217 | + |
| 218 | +#### Default Mode (`rls_mode = 1`) |
| 219 | + |
| 220 | +To simplify policy creation for the most common use cases, the default mode does **not** enforce `INSERT` and `UPDATE` policies while applying changes from SQLite Sync. |
| 221 | + |
| 222 | +Instead, after the sync operation is complete, the `SELECT` policy is used to validate the final state of the row. If the user does not have permission to view the resulting row, the entire transaction is rolled back. This ensures that users cannot introduce changes that they are not allowed to see. |
| 223 | + |
| 224 | +#### Manual Policy Mode (`rls_mode = 0`) |
| 225 | + |
| 226 | +For more complex scenarios, such as implementing separate read/write permissions or restricting write access to specific columns, you can set `rls_mode` to `0`. |
| 227 | + |
| 228 | +In this mode, your `INSERT` and `UPDATE` policies are enforced for every incremental change applied by SQLite Sync. Because of Sync's column-by-column operation, your policies must be written to permit intermediate states. This means the policies must allow `NEW` values for non-primary key columns to be temporarily set to their default values during the sync process. |
0 commit comments