Using Row-Level Security in GORM
Row-level security (RLS) in PostgreSQL enables tables to implement policies that limit access or modification of rows
according to the user's role, enhancing the basic SQL-standard privileges provided by GRANT
.
Once activated, all standard access to the table has to adhere to these policies. If no policies are defined on the table, it defaults to a deny-all rule, meaning no rows can be seen or mutated. These policies can be tailored to specific commands, roles, or both, allowing for detailed management of who can access or change data.
This guide explains how to attach RLS Policies to your GORM types (objects) and configure the schema migration to manage both the RLS and the GORM models as a single migration unit using Atlas.
Atlas support for Row-Level Security Policies used in this guide is available exclusively to Pro users. To use this feature, run:
atlas login
Getting started with Atlas and GORM
Before we continue, ensure you have installed the Atlas GORM Provider on your GORM project.
To set up, follow along the getting started guide for GORM and Atlas.
Composite Schema
The GORM package is mostly used for defining tables (our Go types) and interacting with the database. Table policies or any other database native objects do not have representation in GORM models.
In order to extend our PostgreSQL schema to include both our GORM types and their policies, we configure Atlas to read the state of the schema from a Composite Schema data source. Follow the steps below to configure this for your project:
1. Let's define a simple schema with two types (tables): users
and tenants
:
type Tenant struct {
gorm.Model
ID uint
Name string
}
type User struct {
gorm.Model
ID uint
TenantID uint
}
2. Now, suppose we want to limit access to the users
table based on the tenant_id
field. We can achieve this by defining
a Row-Level Security (RLS) policy on the users
table. Below is the SQL code that defines the RLS policy:
--- Enable row-level security on the users table.
ALTER TABLE "users" ENABLE ROW LEVEL SECURITY;
-- Create a policy that restricts access to rows in the users table based on the current tenant.
CREATE POLICY tenant_isolation ON "users"
USING ("tenant_id" = current_setting('app.current_tenant')::integer);
3. Lastly, In your atlas.hcl
config file, add a composite_schema
that includes both your
custom security policies defined in schema.sql
and your GORM model:
data "composite_schema" "app" {
# Load the GORM model first
schema "public" {
url = data.external_schema.gorm.url
}
# Next, load the RLS schema.
schema "public" {
url = "file://schema.sql"
}
}
env "local" {
src = data.composite_schema.app.url
dev = "docker://postgres/15/dev?search_path=public""
}
Usage
After setting up our composite schema, we can get its representation using the atlas schema inspect
command, generate
schema migrations for it, apply them to a database, and more. Below are a few commands to get you started with Atlas:
Inspect the Schema
The atlas schema inspect
command is commonly used to inspect databases. However, we can also use it to inspect our
composite_schema
and print the SQL representation of it:
atlas schema inspect \
--env local \
--url env://src \
--format '{{ sql . }}'
The command above prints the following SQL. Note, the tenant_isolation
policy is defined in the schema after the users
table:
-- Create "users" table
CREATE TABLE "users" ("id" bigserial NOT NULL, "created_at" timestamptz NULL, "updated_at" timestamptz NULL, "deleted_at" timestamptz NULL, "tenant_id" bigint NULL, PRIMARY KEY ("id"));
-- Create index "idx_users_deleted_at" to table: "users"
CREATE INDEX "idx_users_deleted_at" ON "users" ("deleted_at");
-- Enable row-level security for "users" table
ALTER TABLE "users" ENABLE ROW LEVEL SECURITY;
-- Create policy "tenant_isolation"
CREATE POLICY "tenant_isolation" ON "users" AS PERMISSIVE FOR ALL TO PUBLIC USING (tenant_id = (current_setting('app.current_tenant'::text))::integer);
-- Create "tenants" table
CREATE TABLE "tenants" ("id" bigserial NOT NULL, "created_at" timestamptz NULL, "updated_at" timestamptz NULL, "deleted_at" timestamptz NULL, "name" text NULL, "user_id" bigint NULL, PRIMARY KEY ("id"));
-- Create index "idx_tenants_deleted_at" to table: "tenants"
CREATE INDEX "idx_tenants_deleted_at" ON "tenants" ("deleted_at");
Generate Migrations For the Schema
To generate a migration for the schema, run the following command:
atlas migrate diff \
--env local
Note that a new migration file is created with the following content:
-- Create "users" table
CREATE TABLE "users" ("id" bigserial NOT NULL, "created_at" timestamptz NULL, "updated_at" timestamptz NULL, "deleted_at" timestamptz NULL, "tenant_id" bigint NULL, PRIMARY KEY ("id"));
-- Create index "idx_users_deleted_at" to table: "users"
CREATE INDEX "idx_users_deleted_at" ON "users" ("deleted_at");
-- Enable row-level security for "users" table
ALTER TABLE "users" ENABLE ROW LEVEL SECURITY;
-- Create policy "tenant_isolation"
CREATE POLICY "tenant_isolation" ON "users" AS PERMISSIVE FOR ALL TO PUBLIC USING (tenant_id = (current_setting('app.current_tenant'::text))::integer);
-- Create "tenants" table
CREATE TABLE "tenants" ("id" bigserial NOT NULL, "created_at" timestamptz NULL, "updated_at" timestamptz NULL, "deleted_at" timestamptz NULL, "name" text NULL, "user_id" bigint NULL, PRIMARY KEY ("id"));
-- Create index "idx_tenants_deleted_at" to table: "tenants"
CREATE INDEX "idx_tenants_deleted_at" ON "tenants" ("deleted_at");
Apply the Migrations
To apply the migration generated above to a database, run the following command:
atlas migrate apply \
--env local \
--url "postgres://postgres:pass@localhost:5432/database?search_path=public&sslmode=disable"
Sometimes, there is a need to apply the schema directly to the database without generating a migration file. For example, when experimenting with schema changes, spinning up a database for testing, etc. In such cases, you can use the command below to apply the schema directly to the database:
atlas schema apply \
--env local \
--url "postgres://postgres:pass@localhost:5432/database?search_path=public&sslmode=disable"
Or, using the Atlas Go SDK:
ac, err := atlasexec.NewClient(".", "atlas")
if err != nil {
log.Fatalf("failed to initialize client: %w", err)
}
// Automatically update the database with the desired schema.
// Another option, is to use 'migrate apply' or 'schema apply' manually.
if _, err := ac.SchemaApply(ctx, &atlasexec.SchemaApplyParams{
Env: "local",
URL: "postgres://postgres:pass@localhost:5432/database?search_path=public&sslmode=disable",
}); err != nil {
log.Fatalf("failed to apply schema changes: %w", err)
}
After setting up our GORM model and the RLS policies, we can open a GORM client and pass the different mutations and queries the relevant tenant ID we work on. This ensures that the database upholds our RLS policy.