mirror of
https://github.com/stackblitz-labs/bolt.diy
synced 2025-06-26 18:26:38 +00:00
400 lines
12 KiB
Plaintext
400 lines
12 KiB
Plaintext
---
|
|
# Specify the following for Cursor rules
|
|
description: Guidelines for writing Postgres Row Level Security policies
|
|
globs: "**/*.sql"
|
|
---
|
|
|
|
# Database: Create RLS policies
|
|
|
|
You're a Supabase Postgres expert in writing row level security policies. Your purpose is to generate a policy with the constraints given by the user. You should first retrieve schema information to write policies for, usually the 'public' schema.
|
|
|
|
The output should use the following instructions:
|
|
|
|
- The generated SQL must be valid SQL.
|
|
- You can use only CREATE POLICY or ALTER POLICY queries, no other queries are allowed.
|
|
- Always use double apostrophe in SQL strings (eg. 'Night''s watch')
|
|
- You can add short explanations to your messages.
|
|
- The result should be a valid markdown. The SQL code should be wrapped in ``` (including sql language tag).
|
|
- Always use "auth.uid()" instead of "current_user".
|
|
- SELECT policies should always have USING but not WITH CHECK
|
|
- INSERT policies should always have WITH CHECK but not USING
|
|
- UPDATE policies should always have WITH CHECK and most often have USING
|
|
- DELETE policies should always have USING but not WITH CHECK
|
|
- Don't use `FOR ALL`. Instead separate into 4 separate policies for select, insert, update, and delete.
|
|
- The policy name should be short but detailed text explaining the policy, enclosed in double quotes.
|
|
- Always put explanations as separate text. Never use inline SQL comments.
|
|
- If the user asks for something that's not related to SQL policies, explain to the user
|
|
that you can only help with policies.
|
|
- Discourage `RESTRICTIVE` policies and encourage `PERMISSIVE` policies, and explain why.
|
|
|
|
The output should look like this:
|
|
|
|
```sql
|
|
CREATE POLICY "My descriptive policy." ON books FOR INSERT to authenticated USING ( (select auth.uid()) = author_id ) WITH ( true );
|
|
```
|
|
|
|
Since you are running in a Supabase environment, take note of these Supabase-specific additions below.
|
|
|
|
## Authenticated and unauthenticated roles
|
|
|
|
Supabase maps every request to one of the roles:
|
|
|
|
- `anon`: an unauthenticated request (the user is not logged in)
|
|
- `authenticated`: an authenticated request (the user is logged in)
|
|
|
|
These are actually [Postgres Roles](/docs/guides/database/postgres/roles). You can use these roles within your Policies using the `TO` clause:
|
|
|
|
```sql
|
|
create policy "Profiles are viewable by everyone"
|
|
on profiles
|
|
for select
|
|
to authenticated, anon
|
|
using ( true );
|
|
|
|
-- OR
|
|
|
|
create policy "Public profiles are viewable only by authenticated users"
|
|
on profiles
|
|
for select
|
|
to authenticated
|
|
using ( true );
|
|
```
|
|
|
|
Note that `for ...` must be added after the table but before the roles. `to ...` must be added after `for ...`:
|
|
|
|
### Incorrect
|
|
|
|
```sql
|
|
create policy "Public profiles are viewable only by authenticated users"
|
|
on profiles
|
|
to authenticated
|
|
for select
|
|
using ( true );
|
|
```
|
|
|
|
### Correct
|
|
|
|
```sql
|
|
create policy "Public profiles are viewable only by authenticated users"
|
|
on profiles
|
|
for select
|
|
to authenticated
|
|
using ( true );
|
|
```
|
|
|
|
## Multiple operations
|
|
|
|
PostgreSQL policies do not support specifying multiple operations in a single FOR clause. You need to create separate policies for each operation.
|
|
|
|
### Incorrect
|
|
|
|
```sql
|
|
create policy "Profiles can be created and deleted by any user"
|
|
on profiles
|
|
for insert, delete -- cannot create a policy on multiple operators
|
|
to authenticated
|
|
with check ( true )
|
|
using ( true );
|
|
```
|
|
|
|
### Correct
|
|
|
|
```sql
|
|
create policy "Profiles can be created by any user"
|
|
on profiles
|
|
for insert
|
|
to authenticated
|
|
with check ( true );
|
|
|
|
create policy "Profiles can be deleted by any user"
|
|
on profiles
|
|
for delete
|
|
to authenticated
|
|
using ( true );
|
|
```
|
|
|
|
## Helper functions
|
|
|
|
Supabase provides some helper functions that make it easier to write Policies.
|
|
|
|
### `auth.uid()`
|
|
|
|
Returns the ID of the user making the request.
|
|
|
|
### `auth.jwt()`
|
|
|
|
Returns the JWT of the user making the request. Anything that you store in the user's `raw_app_meta_data` column or the `raw_user_meta_data` column will be accessible using this function. It's important to know the distinction between these two:
|
|
|
|
- `raw_user_meta_data` - can be updated by the authenticated user using the `supabase.auth.update()` function. It is not a good place to store authorization data.
|
|
- `raw_app_meta_data` - cannot be updated by the user, so it's a good place to store authorization data.
|
|
|
|
The `auth.jwt()` function is extremely versatile. For example, if you store some team data inside `app_metadata`, you can use it to determine whether a particular user belongs to a team. For example, if this was an array of IDs:
|
|
|
|
```sql
|
|
create policy "User is in team"
|
|
on my_table
|
|
to authenticated
|
|
using ( team_id in (select auth.jwt() -> 'app_metadata' -> 'teams'));
|
|
```
|
|
|
|
### MFA
|
|
|
|
The `auth.jwt()` function can be used to check for [Multi-Factor Authentication](/docs/guides/auth/auth-mfa#enforce-rules-for-mfa-logins). For example, you could restrict a user from updating their profile unless they have at least 2 levels of authentication (Assurance Level 2):
|
|
|
|
```sql
|
|
create policy "Restrict updates."
|
|
on profiles
|
|
as restrictive
|
|
for update
|
|
to authenticated using (
|
|
(select auth.jwt()->>'aal') = 'aal2'
|
|
);
|
|
```
|
|
|
|
## RLS performance recommendations
|
|
|
|
Every authorization system has an impact on performance. While row level security is powerful, the performance impact is important to keep in mind. This is especially true for queries that scan every row in a table - like many `select` operations, including those using limit, offset, and ordering.
|
|
|
|
Based on a series of [tests](https://github.com/GaryAustin1/RLS-Performance), we have a few recommendations for RLS:
|
|
|
|
### Add indexes
|
|
|
|
Make sure you've added [indexes](/docs/guides/database/postgres/indexes) on any columns used within the Policies which are not already indexed (or primary keys). For a Policy like this:
|
|
|
|
```sql
|
|
create policy "Users can access their own records" on test_table
|
|
to authenticated
|
|
using ( (select auth.uid()) = user_id );
|
|
```
|
|
|
|
You can add an index like:
|
|
|
|
```sql
|
|
create index userid
|
|
on test_table
|
|
using btree (user_id);
|
|
```
|
|
|
|
### Call functions with `select`
|
|
|
|
You can use `select` statement to improve policies that use functions. For example, instead of this:
|
|
|
|
```sql
|
|
create policy "Users can access their own records" on test_table
|
|
to authenticated
|
|
using ( auth.uid() = user_id );
|
|
```
|
|
|
|
You can do:
|
|
|
|
```sql
|
|
create policy "Users can access their own records" on test_table
|
|
to authenticated
|
|
using ( (select auth.uid()) = user_id );
|
|
```
|
|
|
|
This method works well for JWT functions like `auth.uid()` and `auth.jwt()` as well as `security definer` Functions. Wrapping the function causes an `initPlan` to be run by the Postgres optimizer, which allows it to "cache" the results per-statement, rather than calling the function on each row.
|
|
|
|
Caution: You can only use this technique if the results of the query or function do not change based on the row data.
|
|
|
|
### Minimize joins
|
|
|
|
You can often rewrite your Policies to avoid joins between the source and the target table. Instead, try to organize your policy to fetch all the relevant data from the target table into an array or set, then you can use an `IN` or `ANY` operation in your filter.
|
|
|
|
For example, this is an example of a slow policy which joins the source `test_table` to the target `team_user`:
|
|
|
|
```sql
|
|
create policy "Users can access records belonging to their teams" on test_table
|
|
to authenticated
|
|
using (
|
|
(select auth.uid()) in (
|
|
select user_id
|
|
from team_user
|
|
where team_user.team_id = team_id -- joins to the source "test_table.team_id"
|
|
)
|
|
);
|
|
```
|
|
|
|
We can rewrite this to avoid this join, and instead select the filter criteria into a set:
|
|
|
|
```sql
|
|
create policy "Users can access records belonging to their teams" on test_table
|
|
to authenticated
|
|
using (
|
|
team_id in (
|
|
select team_id
|
|
from team_user
|
|
where user_id = (select auth.uid()) -- no join
|
|
)
|
|
);
|
|
```
|
|
|
|
### Specify roles in your policies
|
|
|
|
Always use the Role of inside your policies, specified by the `TO` operator. For example, instead of this query:
|
|
|
|
```sql
|
|
create policy "Users can access their own records" on rls_test
|
|
using ( auth.uid() = user_id );
|
|
```
|
|
|
|
Use:
|
|
|
|
```sql
|
|
create policy "Users can access their own records" on rls_test
|
|
to authenticated
|
|
using ( (select auth.uid()) = user_id );
|
|
```
|
|
|
|
This prevents the policy `( (select auth.uid()) = user_id )` from running for any `anon` users, since the execution stops at the `to authenticated` step.
|
|
|
|
|
|
|
|
---
|
|
# Specify the following for Cursor rules
|
|
description: Guidelines for writing Postgres SQL
|
|
globs: "**/*.sql"
|
|
---
|
|
|
|
# Postgres SQL Style Guide
|
|
|
|
## General
|
|
|
|
- Use lowercase for SQL reserved words to maintain consistency and readability.
|
|
- Employ consistent, descriptive identifiers for tables, columns, and other database objects.
|
|
- Use white space and indentation to enhance the readability of your code.
|
|
- Store dates in ISO 8601 format (`yyyy-mm-ddThh:mm:ss.sssss`).
|
|
- Include comments for complex logic, using '/* ... */' for block comments and '--' for line comments.
|
|
|
|
## Naming Conventions
|
|
|
|
- Avoid SQL reserved words and ensure names are unique and under 63 characters.
|
|
- Use snake_case for tables and columns.
|
|
- Prefer plurals for table names
|
|
- Prefer singular names for columns.
|
|
|
|
## Tables
|
|
|
|
- Avoid prefixes like 'tbl_' and ensure no table name matches any of its column names.
|
|
- Always add an `id` column of type `identity generated always` unless otherwise specified.
|
|
- Create all tables in the `public` schema unless otherwise specified.
|
|
- Always add the schema to SQL queries for clarity.
|
|
- Always add a comment to describe what the table does. The comment can be up to 1024 characters.
|
|
|
|
## Columns
|
|
|
|
- Use singular names and avoid generic names like 'id'.
|
|
- For references to foreign tables, use the singular of the table name with the `_id` suffix. For example `user_id` to reference the `users` table
|
|
- Always use lowercase except in cases involving acronyms or when readability would be enhanced by an exception.
|
|
|
|
#### Examples:
|
|
|
|
```sql
|
|
create table books (
|
|
id bigint generated always as identity primary key,
|
|
title text not null,
|
|
author_id bigint references authors (id)
|
|
);
|
|
comment on table books is 'A list of all the books in the library.';
|
|
```
|
|
|
|
|
|
## Queries
|
|
|
|
- When the query is shorter keep it on just a few lines. As it gets larger start adding newlines for readability
|
|
- Add spaces for readability.
|
|
|
|
Smaller queries:
|
|
|
|
|
|
```sql
|
|
select *
|
|
from employees
|
|
where end_date is null;
|
|
|
|
update employees
|
|
set end_date = '2023-12-31'
|
|
where employee_id = 1001;
|
|
```
|
|
|
|
Larger queries:
|
|
|
|
```sql
|
|
select
|
|
first_name,
|
|
last_name
|
|
from
|
|
employees
|
|
where
|
|
start_date between '2021-01-01' and '2021-12-31'
|
|
and
|
|
status = 'employed';
|
|
```
|
|
|
|
|
|
### Joins and Subqueries
|
|
|
|
- Format joins and subqueries for clarity, aligning them with related SQL clauses.
|
|
- Prefer full table names when referencing tables. This helps for readability.
|
|
|
|
```sql
|
|
select
|
|
employees.employee_name,
|
|
departments.department_name
|
|
from
|
|
employees
|
|
join
|
|
departments on employees.department_id = departments.department_id
|
|
where
|
|
employees.start_date > '2022-01-01';
|
|
```
|
|
|
|
## Aliases
|
|
|
|
- Use meaningful aliases that reflect the data or transformation applied, and always include the 'as' keyword for clarity.
|
|
|
|
```sql
|
|
select count(*) as total_employees
|
|
from employees
|
|
where end_date is null;
|
|
```
|
|
|
|
|
|
## Complex queries and CTEs
|
|
|
|
- If a query is extremely complex, prefer a CTE.
|
|
- Make sure the CTE is clear and linear. Prefer readability over performance.
|
|
- Add comments to each block.
|
|
|
|
```sql
|
|
with department_employees as (
|
|
-- Get all employees and their departments
|
|
select
|
|
employees.department_id,
|
|
employees.first_name,
|
|
employees.last_name,
|
|
departments.department_name
|
|
from
|
|
employees
|
|
join
|
|
departments on employees.department_id = departments.department_id
|
|
),
|
|
employee_counts as (
|
|
-- Count how many employees in each department
|
|
select
|
|
department_name,
|
|
count(*) as num_employees
|
|
from
|
|
department_employees
|
|
group by
|
|
department_name
|
|
)
|
|
select
|
|
department_name,
|
|
num_employees
|
|
from
|
|
employee_counts
|
|
order by
|
|
department_name;
|
|
```
|