Skip to content

Commit dcc3acb

Browse files
committed
fix: evtrigs ownership
Fixes #1437. Now that the effects of the `migrations/db/init-scripts` are fully tested on the following files: - [nix/tests/sql/auth.out](https://github.com/supabase/postgres/blob/develop/nix/tests/expected/auth.out) - [nix/tests/sql/storage.out](https://github.com/supabase/postgres/blob/develop/nix/tests/expected/storage.out) - [nix/tests/sql/roles.out](https://github.com/supabase/postgres/blob/develop/nix/tests/expected/roles.out) - [nix/tests/sql/evtrigs.out](https://github.com/supabase/postgres/blob/develop/nix/tests/expected/evtrigs.out) - [nix/tests/sql/extensions_schema.out](https://github.com/supabase/postgres/blob/develop/nix/tests/expected/extensions_schema.out) - [nix/tests/sql/realtime.out](https://github.com/supabase/postgres/blob/develop/nix/tests/expected/realtime.out) This reattempts to move `migrations/db/init-scripts` to `migrations/db/migrations` and have a single directory for migrations. Of the above tests, the only change pertains to the event triggers owners which is the problem on #1437. This requires modifying migrations, but the changes are more about following best practices: + Makes migrations idempotent. + [alter default privileges](https://www.postgresql.org/docs/current/sql-alterdefaultprivileges.html) explicitly list postgres as the target role. + Also: - adds a conditional for pgjwt which is not available on the 17 version - Realtime publication maintains the same postgres owner
1 parent 7d57e19 commit dcc3acb

13 files changed

+228
-126
lines changed

Diff for: migrations/README.md

+2-5
Original file line numberDiff line numberDiff line change
@@ -42,8 +42,6 @@ nix run github:supabase/postgres/mybranch#dbmate-tool -- --version 15
4242

4343
aiming to provide a single source of truth for migrations on the platform that can be depended upon by those components. For more information on goals see [the RFC](https://www.notion.so/supabase/Centralize-SQL-Migrations-cd3847ae027d4f2bba9defb2cc82f69a)
4444

45-
46-
4745
## How it was Created
4846

4947
Migrations were pulled (in order) from:
@@ -53,9 +51,8 @@ Migrations were pulled (in order) from:
5351

5452
For compatibility with hosted projects, we include [migrate.sh](migrate.sh) that executes migrations in the same order as ami build:
5553

56-
1. Run all `db/init-scripts` with `postgres` superuser role.
57-
2. Run all `db/migrations` with `supabase_admin` superuser role.
58-
3. Finalize role passwords with `/etc/postgresql.schema.sql` if present.
54+
1. Run all `db/migrations` with `supabase_admin` superuser role.
55+
2. Finalize role passwords with `/etc/postgresql.schema.sql` if present.
5956

6057
Additionally, [supabase/postgres](https://github.com/supabase/postgres/blob/develop/ansible/playbook-docker.yml#L9) image contains several migration scripts to configure default extensions. These are run first by docker entrypoint and included in ami by ansible.
6158

Diff for: migrations/db/init-scripts/00000000000000-initial-schema.sql

-65
This file was deleted.

Diff for: migrations/db/migrate.sh

-7
Original file line numberDiff line numberDiff line change
@@ -38,11 +38,6 @@ begin
3838
end if;
3939
end \$\$
4040
EOSQL
41-
# run init scripts as postgres user
42-
for sql in "$db"/init-scripts/*.sql; do
43-
echo "$0: running $sql"
44-
psql -v ON_ERROR_STOP=1 --no-password --no-psqlrc -U postgres -f "$sql"
45-
done
4641
psql -v ON_ERROR_STOP=1 --no-password --no-psqlrc -U postgres -c "ALTER USER supabase_admin WITH PASSWORD '$PGPASSWORD'"
4742
# run migrations as super user - postgres user demoted in post-setup
4843
for sql in "$db"/migrations/*.sql; do
@@ -54,8 +49,6 @@ else
5449
create role postgres superuser login password '$PGPASSWORD';
5550
alter database postgres owner to postgres;
5651
EOSQL
57-
# run init scripts as postgres user
58-
DBMATE_MIGRATIONS_DIR="$db/init-scripts" DATABASE_URL="postgres://postgres:$connect" dbmate --no-dump-schema migrate
5952
psql -v ON_ERROR_STOP=1 --no-password --no-psqlrc -U postgres -c "ALTER USER supabase_admin WITH PASSWORD '$PGPASSWORD'"
6053
# run migrations as super user - postgres user demoted in post-setup
6154
DBMATE_MIGRATIONS_DIR="$db/migrations" DATABASE_URL="postgres://supabase_admin:$connect" dbmate --no-dump-schema migrate
+147
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,147 @@
1+
-- migrate:up
2+
3+
-- Set up realtime
4+
do $$
5+
begin
6+
if not exists (
7+
select 1 from pg_catalog.pg_publication
8+
where pubname = 'supabase_realtime'
9+
)
10+
then
11+
set role postgres;
12+
create publication supabase_realtime;
13+
reset role;
14+
end if;
15+
end
16+
$$;
17+
18+
-- Supabase super admin
19+
alter user supabase_admin with superuser createdb createrole replication bypassrls;
20+
21+
-- Supabase replication user
22+
do $$
23+
begin
24+
if not exists (
25+
select 1 from pg_roles
26+
where rolname = 'supabase_replication_admin'
27+
)
28+
then
29+
create user supabase_replication_admin with
30+
login
31+
replication;
32+
end if;
33+
end
34+
$$;
35+
36+
-- Supabase read-only user
37+
do $$
38+
begin
39+
if not exists (
40+
select 1 from pg_roles
41+
where rolname = 'supabase_read_only_user'
42+
)
43+
then
44+
create role supabase_read_only_user with
45+
login
46+
bypassrls;
47+
end if;
48+
end
49+
$$;
50+
grant pg_read_all_data to supabase_read_only_user;
51+
52+
-- Extension namespacing
53+
create schema if not exists extensions;
54+
create extension if not exists "uuid-ossp" with schema extensions;
55+
create extension if not exists pgcrypto with schema extensions;
56+
-- newer versions don't have pgjwt available
57+
do $$
58+
begin
59+
if exists (
60+
select 1 from pg_available_extensions where name = 'pgjwt'
61+
) then
62+
create extension if not exists pgjwt with schema extensions;
63+
end if;
64+
end $$;
65+
66+
-- Set up auth roles for the developer
67+
do $$
68+
begin
69+
if not exists (
70+
select 1 from pg_roles
71+
where rolname = 'anon'
72+
)
73+
then
74+
create role anon nologin noinherit;
75+
end if;
76+
end
77+
$$;
78+
79+
-- "logged in" user: web_user, app_user, etc
80+
do $$
81+
begin
82+
if not exists (
83+
select 1 from pg_roles
84+
where rolname = 'authenticated'
85+
)
86+
then
87+
create role authenticated nologin noinherit;
88+
end if;
89+
end
90+
$$;
91+
92+
-- allow developers to create JWT's that bypass their policies
93+
do $$
94+
begin
95+
if not exists (
96+
select 1 from pg_roles
97+
where rolname = 'service_role'
98+
)
99+
then
100+
create role service_role nologin noinherit bypassrls;
101+
end if;
102+
end
103+
$$;
104+
105+
do $$
106+
begin
107+
if not exists (
108+
select 1 from pg_roles
109+
where rolname = 'authenticator'
110+
)
111+
then
112+
create role authenticator login noinherit;
113+
end if;
114+
end
115+
$$;
116+
117+
118+
grant anon to authenticator;
119+
grant authenticated to authenticator;
120+
grant service_role to authenticator;
121+
grant supabase_admin to authenticator;
122+
123+
-- These are required so that the users receive grants whenever "postgres" creates tables/function
124+
grant usage on schema public to postgres, anon, authenticated, service_role;
125+
alter default privileges for role postgres in schema public grant all on tables to postgres, anon, authenticated, service_role;
126+
alter default privileges for role postgres in schema public grant all on functions to postgres, anon, authenticated, service_role;
127+
alter default privileges for role postgres in schema public grant all on sequences to postgres, anon, authenticated, service_role;
128+
129+
-- Allow Extensions to be used in the API
130+
grant usage on schema extensions to postgres, anon, authenticated, service_role;
131+
132+
-- Set up namespacing
133+
alter user supabase_admin SET search_path TO public, extensions; -- don't include the "auth" schema
134+
135+
-- These are required so that the users receive grants whenever "supabase_admin" creates tables/function
136+
alter default privileges for user supabase_admin in schema public grant all
137+
on sequences to postgres, anon, authenticated, service_role;
138+
alter default privileges for user supabase_admin in schema public grant all
139+
on tables to postgres, anon, authenticated, service_role;
140+
alter default privileges for user supabase_admin in schema public grant all
141+
on functions to postgres, anon, authenticated, service_role;
142+
143+
-- Set short statement/query timeouts for API roles
144+
alter role anon set statement_timeout = '3s';
145+
alter role authenticated set statement_timeout = '8s';
146+
147+
-- migrate:down

Diff for: migrations/db/init-scripts/00000000000001-auth-schema.sql renamed to migrations/db/migrations/00000000000001-auth-schema.sql

+26-14
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,7 @@ CREATE SCHEMA IF NOT EXISTS auth AUTHORIZATION supabase_admin;
44

55
-- auth.users definition
66

7-
CREATE TABLE auth.users (
7+
CREATE TABLE IF NOT EXISTS auth.users (
88
instance_id uuid NULL,
99
id uuid NOT NULL UNIQUE,
1010
aud varchar(255) NULL,
@@ -28,13 +28,13 @@ CREATE TABLE auth.users (
2828
updated_at timestamptz NULL,
2929
CONSTRAINT users_pkey PRIMARY KEY (id)
3030
);
31-
CREATE INDEX users_instance_id_email_idx ON auth.users USING btree (instance_id, email);
32-
CREATE INDEX users_instance_id_idx ON auth.users USING btree (instance_id);
31+
CREATE INDEX IF NOT EXISTS users_instance_id_email_idx ON auth.users USING btree (instance_id, email);
32+
CREATE INDEX IF NOT EXISTS users_instance_id_idx ON auth.users USING btree (instance_id);
3333
comment on table auth.users is 'Auth: Stores user login data within a secure schema.';
3434

3535
-- auth.refresh_tokens definition
3636

37-
CREATE TABLE auth.refresh_tokens (
37+
CREATE TABLE IF NOT EXISTS auth.refresh_tokens (
3838
instance_id uuid NULL,
3939
id bigserial NOT NULL,
4040
"token" varchar(255) NULL,
@@ -44,14 +44,14 @@ CREATE TABLE auth.refresh_tokens (
4444
updated_at timestamptz NULL,
4545
CONSTRAINT refresh_tokens_pkey PRIMARY KEY (id)
4646
);
47-
CREATE INDEX refresh_tokens_instance_id_idx ON auth.refresh_tokens USING btree (instance_id);
48-
CREATE INDEX refresh_tokens_instance_id_user_id_idx ON auth.refresh_tokens USING btree (instance_id, user_id);
49-
CREATE INDEX refresh_tokens_token_idx ON auth.refresh_tokens USING btree (token);
47+
CREATE INDEX IF NOT EXISTS refresh_tokens_instance_id_idx ON auth.refresh_tokens USING btree (instance_id);
48+
CREATE INDEX IF NOT EXISTS refresh_tokens_instance_id_user_id_idx ON auth.refresh_tokens USING btree (instance_id, user_id);
49+
CREATE INDEX IF NOT EXISTS refresh_tokens_token_idx ON auth.refresh_tokens USING btree (token);
5050
comment on table auth.refresh_tokens is 'Auth: Store of tokens used to refresh JWT tokens once they expire.';
5151

5252
-- auth.instances definition
5353

54-
CREATE TABLE auth.instances (
54+
CREATE TABLE IF NOT EXISTS auth.instances (
5555
id uuid NOT NULL,
5656
uuid uuid NULL,
5757
raw_base_config text NULL,
@@ -63,32 +63,34 @@ comment on table auth.instances is 'Auth: Manages users across multiple sites.';
6363

6464
-- auth.audit_log_entries definition
6565

66-
CREATE TABLE auth.audit_log_entries (
66+
CREATE TABLE IF NOT EXISTS auth.audit_log_entries (
6767
instance_id uuid NULL,
6868
id uuid NOT NULL,
6969
payload json NULL,
7070
created_at timestamptz NULL,
7171
CONSTRAINT audit_log_entries_pkey PRIMARY KEY (id)
7272
);
73-
CREATE INDEX audit_logs_instance_id_idx ON auth.audit_log_entries USING btree (instance_id);
73+
CREATE INDEX IF NOT EXISTS audit_logs_instance_id_idx ON auth.audit_log_entries USING btree (instance_id);
7474
comment on table auth.audit_log_entries is 'Auth: Audit trail for user actions.';
7575

7676
-- auth.schema_migrations definition
7777

78-
CREATE TABLE auth.schema_migrations (
78+
CREATE TABLE IF NOT EXISTS auth.schema_migrations (
7979
"version" varchar(255) NOT NULL,
8080
CONSTRAINT schema_migrations_pkey PRIMARY KEY ("version")
8181
);
8282
comment on table auth.schema_migrations is 'Auth: Manages updates to the auth system.';
8383

84+
-- insert migrations if they do not yet exist
8485
INSERT INTO auth.schema_migrations (version)
8586
VALUES ('20171026211738'),
8687
('20171026211808'),
8788
('20171026211834'),
8889
('20180103212743'),
8990
('20180108183307'),
9091
('20180119214651'),
91-
('20180125194653');
92+
('20180125194653')
93+
ON CONFLICT DO NOTHING;
9294

9395
-- Gets the User ID from the request cookie
9496
create or replace function auth.uid() returns uuid as $$
@@ -109,8 +111,18 @@ $$ language sql stable;
109111
GRANT USAGE ON SCHEMA auth TO anon, authenticated, service_role;
110112

111113
-- Supabase super admin
112-
CREATE USER supabase_auth_admin NOINHERIT CREATEROLE LOGIN NOREPLICATION;
113-
GRANT ALL PRIVILEGES ON SCHEMA auth TO supabase_auth_admin;
114+
do $$
115+
begin
116+
if not exists (
117+
select 1 from pg_roles
118+
where rolname = 'supabase_auth_admin'
119+
)
120+
then
121+
CREATE USER supabase_auth_admin NOINHERIT CREATEROLE LOGIN NOREPLICATION;
122+
end if;
123+
end
124+
$$;
125+
114126
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA auth TO supabase_auth_admin;
115127
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA auth TO supabase_auth_admin;
116128
ALTER USER supabase_auth_admin SET search_path = "auth";

0 commit comments

Comments
 (0)