|
| 1 | +--- |
| 2 | +meta: |
| 3 | + title: How to use Row Level Security with Serverless SQL Database |
| 4 | + description: This page explains how to use Row Level Security with Serverless SQL Databases |
| 5 | +content: |
| 6 | + h1: How to use Row Level Security with Serverless SQL Database |
| 7 | + paragraph: This page explains how to use Row Level Security with Serverless SQL Databases |
| 8 | +tags: sql-databases serverless database row-level-security postgresql postgrest |
| 9 | +dates: |
| 10 | + validation: 2024-09-24 |
| 11 | + posted: 2024-09-24 |
| 12 | +categories: |
| 13 | + - serverless |
| 14 | +--- |
| 15 | + |
| 16 | +Row Level Security can be actived with Serverless SQL Database for a maximum 2 different roles having both read and write permissions. This can be useful to restrict access to subset of users with frameworks or tools such as [PostgREST](https://docs.postgrest.org/en/v12/). |
| 17 | +This requires setting up different [IAM permissions sets](https://www.scaleway.com/en/docs/identity-and-access-management/iam/reference-content/permission-sets/) for each role (**ServerlessSQLDatabaseFullAccess** or **ServerlessSQLDatabaseReadWrite** for one role, and **ServerlessSQLDatabaseDataReadWrite** for the other). |
| 18 | + |
| 19 | +<Macro id="requirements" /> |
| 20 | + |
| 21 | +- A Scaleway account logged into the [console](https://console.scaleway.com) |
| 22 | +- [Owner](/identity-and-access-management/iam/concepts/#owner) status or [IAM permissions](/identity-and-access-management/iam/concepts/#permission) allowing you to perform actions in the intended Organization |
| 23 | +- [Created a Serverless SQL Database](/serverless/sql-databases/how-to/create-a-database/) |
| 24 | +- [Created two applications](/identity-and-access-management/iam/how-to/create-application/) in IAM |
| 25 | + |
| 26 | +## Add sample data and create PostgreSQL Row Level Security |
| 27 | + |
| 28 | +1. [Connect to your Serverless SQL Database](https://www.scaleway.com/en/docs/serverless/sql-databases/quickstart/#how-to-connect-to-a-database) with a PostgreSQL client. For instance with psql: |
| 29 | + ```bash |
| 30 | + psql "postgres://[user-or-application-id]:[api-secret-key]@[database-hostname]:5432/[database-name]?sslmode=require" |
| 31 | + ``` |
| 32 | + |
| 33 | +2. Add sample data using the following command: |
| 34 | + ```sql |
| 35 | + CREATE TABLE pets (name varchar, keeper varchar, id int); |
| 36 | + INSERT INTO pets VALUES ('Stuart','role_admin',1),('Nemo','role_admin',2),('Alfie','role_readwrite',3),('Peanut','role_readwrite',4); |
| 37 | + ``` |
| 38 | + |
| 39 | +3. Enable **Row Level Security**: |
| 40 | + ```sql |
| 41 | + ALTER TABLE pets ENABLE row level security; |
| 42 | + ``` |
| 43 | + |
| 44 | +4. Create a PostgreSQL policy so that users or applications connecting with `role_readwrite` can access a `pet` row only if its `keeper` column value is `role_readwrite`: |
| 45 | + ```sql |
| 46 | + CREATE POLICY pets_keeper ON pets TO role_readwrite USING (keeper = current_user); |
| 47 | + ``` |
| 48 | + |
| 49 | +5. (Optional) You can check that you can still see all data with your current connection: |
| 50 | + ```sql |
| 51 | + SELECT * FROM pets; |
| 52 | + ``` |
| 53 | + This is expected as you are connected with `role_admin`. You can verify the current role your are connected with using the following command: |
| 54 | + ```sql |
| 55 | + SELECT current_user; |
| 56 | + ``` |
| 57 | + |
| 58 | + |
| 59 | +## Create an IAM application with Row Level Security enabled |
| 60 | + |
| 61 | +1. Create a new [IAM application](https://www.scaleway.com/en/docs/identity-and-access-management/iam/how-to/create-application/) or use an existing one. |
| 62 | + |
| 63 | +2. Add **ServerlessSQLDatabaseDataReadWrite** permission set to this application by creating a new [IAM policy](https://www.scaleway.com/en/docs/identity-and-access-management/iam/how-to/create-policy/) |
| 64 | + |
| 65 | + <Message type="tip"> |
| 66 | + You need to provide **ServerlessSQLDatabaseDataReadWrite** permission set and not **ServerlessSQLDatabaseReadWrite** permission set. Indeed, all connections to your database performed with **ServerlessSQLDatabaseDataReadWrite** permissions will use `role_readwrite` in PostgreSQL, whereas all connections performed with **ServerlessSQLDatabaseReadWrite** or **ServerlessSQLDatabaseFullAccess** will use `role_admin` in PostgreSQL. |
| 67 | + </Message> |
| 68 | + |
| 69 | +3. Create an [API Key](https://www.scaleway.com/en/docs/identity-and-access-management/iam/how-to/create-api-keys/) for this application and connect to your Serverless SQL Database with this application. |
| 70 | + ```bash |
| 71 | + psql "postgres://[new-application-id]:[new-api-secret-key]@[database-hostname]:5432/[database-name]?sslmode=require" |
| 72 | + ``` |
| 73 | + |
| 74 | +4. List the `pets` this application has access to with: |
| 75 | + ```sql |
| 76 | + SELECT * FROM pets; |
| 77 | + ``` |
| 78 | + You should only see pets with a `keeper` column value of `role_readwrite`. |
| 79 | + |
| 80 | + Your new application can now only access a specific subset of rows based on its permissions. |
| 81 | + |
| 82 | + <Message type="tip"> |
| 83 | + Note that row level security and policies can be created or deleted by a table owner. In this example, you can check table owner with the following command `select * from pg_tables where tablename = 'pets';`. |
| 84 | + </Message> |
0 commit comments