Skip to content
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.

Commit 279b824

Browse files
committedMar 21, 2025·
Make initial migrations idempotent
1 parent 10912b9 commit 279b824

File tree

4 files changed

+162
-37
lines changed

4 files changed

+162
-37
lines changed
 

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

+89-9
Original file line numberDiff line numberDiff line change
@@ -1,17 +1,51 @@
11
-- migrate:up
22

33
-- Set up realtime
4-
-- defaults to empty publication
5-
create publication supabase_realtime;
4+
-- 1. Create publication supabase_realtime if it doesn't already exist
5+
do $$
6+
begin
7+
if not exists (
8+
select 1 from pg_catalog.pg_publication
9+
where pubname = 'supabase_realtime'
10+
)
11+
then
12+
create publication supabase_realtime;
13+
end if;
14+
end
15+
$$;
616

717
-- Supabase super admin
8-
alter user supabase_admin with superuser createdb createrole replication bypassrls;
18+
alter user supabase_admin with superuser createdb createrole replication bypassrls;
919

1020
-- Supabase replication user
11-
create user supabase_replication_admin with login replication;
21+
do $$
22+
begin
23+
if not exists (
24+
select 1 from pg_roles
25+
where rolname = 'supabase_replication_admin'
26+
)
27+
then
28+
create user supabase_replication_admin with
29+
login
30+
replication;
31+
end if;
32+
end
33+
$$;
1234

1335
-- Supabase read-only user
14-
create role supabase_read_only_user with login bypassrls;
36+
do $$
37+
begin
38+
if not exists (
39+
select 1 from pg_roles
40+
where rolname = 'supabase_read_only_user'
41+
)
42+
then
43+
create role supabase_read_only_user with
44+
login
45+
bypassrls;
46+
end if;
47+
end
48+
$$;
1549
grant pg_read_all_data to supabase_read_only_user;
1650

1751
-- Extension namespacing
@@ -21,11 +55,57 @@ create extension if not exists pgcrypto with schema extensions;
2155
create extension if not exists pgjwt with schema extensions;
2256

2357
-- Set up auth roles for the developer
24-
create role anon nologin noinherit;
25-
create role authenticated nologin noinherit; -- "logged in" user: web_user, app_user, etc
26-
create role service_role nologin noinherit bypassrls; -- allow developers to create JWT's that bypass their policies
58+
do $$
59+
begin
60+
if not exists (
61+
select 1 from pg_roles
62+
where rolname = 'anon'
63+
)
64+
then
65+
create role anon nologin noinherit;
66+
end if;
67+
end
68+
$$;
69+
70+
-- "logged in" user: web_user, app_user, etc
71+
do $$
72+
begin
73+
if not exists (
74+
select 1 from pg_roles
75+
where rolname = 'authenticated'
76+
)
77+
then
78+
create role authenticated nologin noinherit;
79+
end if;
80+
end
81+
$$;
82+
83+
-- allow developers to create JWT's that bypass their policies
84+
do $$
85+
begin
86+
if not exists (
87+
select 1 from pg_roles
88+
where rolname = 'service_role'
89+
)
90+
then
91+
create role service_role nologin noinherit bypassrls;
92+
end if;
93+
end
94+
$$;
95+
96+
do $$
97+
begin
98+
if not exists (
99+
select 1 from pg_roles
100+
where rolname = 'authenticator'
101+
)
102+
then
103+
create role authenticator login noinherit;
104+
end if;
105+
end
106+
$$;
107+
27108

28-
create user authenticator noinherit;
29109
grant anon to authenticator;
30110
grant authenticated to authenticator;
31111
grant service_role to authenticator;

Diff for: ‎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";

Diff for: ‎migrations/db/migrations/00000000000002-storage-schema.sql

+20-10
Original file line numberDiff line numberDiff line change
@@ -7,7 +7,7 @@ alter default privileges in schema storage grant all on tables to postgres, anon
77
alter default privileges in schema storage grant all on functions to postgres, anon, authenticated, service_role;
88
alter default privileges in schema storage grant all on sequences to postgres, anon, authenticated, service_role;
99

10-
CREATE TABLE "storage"."buckets" (
10+
CREATE TABLE IF NOT EXISTS "storage"."buckets" (
1111
"id" text not NULL,
1212
"name" text NOT NULL,
1313
"owner" uuid,
@@ -16,9 +16,9 @@ CREATE TABLE "storage"."buckets" (
1616
CONSTRAINT "buckets_owner_fkey" FOREIGN KEY ("owner") REFERENCES "auth"."users"("id"),
1717
PRIMARY KEY ("id")
1818
);
19-
CREATE UNIQUE INDEX "bname" ON "storage"."buckets" USING BTREE ("name");
19+
CREATE UNIQUE INDEX IF NOT EXISTS "bname" ON "storage"."buckets" USING BTREE ("name");
2020

21-
CREATE TABLE "storage"."objects" (
21+
CREATE TABLE IF NOT EXISTS "storage"."objects" (
2222
"id" uuid NOT NULL DEFAULT extensions.uuid_generate_v4(),
2323
"bucket_id" text,
2424
"name" text,
@@ -31,12 +31,12 @@ CREATE TABLE "storage"."objects" (
3131
CONSTRAINT "objects_owner_fkey" FOREIGN KEY ("owner") REFERENCES "auth"."users"("id"),
3232
PRIMARY KEY ("id")
3333
);
34-
CREATE UNIQUE INDEX "bucketid_objname" ON "storage"."objects" USING BTREE ("bucket_id","name");
35-
CREATE INDEX name_prefix_search ON storage.objects(name text_pattern_ops);
34+
CREATE UNIQUE INDEX IF NOT EXISTS "bucketid_objname" ON "storage"."objects" USING BTREE ("bucket_id","name");
35+
CREATE INDEX IF NOT EXISTS name_prefix_search ON storage.objects(name text_pattern_ops);
3636

3737
ALTER TABLE storage.objects ENABLE ROW LEVEL SECURITY;
3838

39-
CREATE FUNCTION storage.foldername(name text)
39+
CREATE OR REPLACE FUNCTION storage.foldername(name text)
4040
RETURNS text[]
4141
LANGUAGE plpgsql
4242
AS $function$
@@ -48,7 +48,7 @@ BEGIN
4848
END
4949
$function$;
5050

51-
CREATE FUNCTION storage.filename(name text)
51+
CREATE OR REPLACE FUNCTION storage.filename(name text)
5252
RETURNS text
5353
LANGUAGE plpgsql
5454
AS $function$
@@ -60,7 +60,7 @@ BEGIN
6060
END
6161
$function$;
6262

63-
CREATE FUNCTION storage.extension(name text)
63+
CREATE OR REPLACE FUNCTION storage.extension(name text)
6464
RETURNS text
6565
LANGUAGE plpgsql
6666
AS $function$
@@ -75,7 +75,7 @@ BEGIN
7575
END
7676
$function$;
7777

78-
CREATE FUNCTION storage.search(prefix text, bucketname text, limits int DEFAULT 100, levels int DEFAULT 1, offsets int DEFAULT 0)
78+
CREATE OR REPLACE FUNCTION storage.search(prefix text, bucketname text, limits int DEFAULT 100, levels int DEFAULT 1, offsets int DEFAULT 0)
7979
RETURNS TABLE (
8080
name text,
8181
id uuid,
@@ -104,7 +104,17 @@ CREATE TABLE IF NOT EXISTS storage.migrations (
104104
executed_at timestamp DEFAULT current_timestamp
105105
);
106106

107-
CREATE USER supabase_storage_admin NOINHERIT CREATEROLE LOGIN NOREPLICATION;
107+
do $$
108+
begin
109+
if not exists (
110+
select 1 from pg_roles
111+
where rolname = 'supabase_storage_admin'
112+
)
113+
then
114+
CREATE USER supabase_storage_admin NOINHERIT CREATEROLE LOGIN NOREPLICATION;
115+
end if;
116+
end
117+
$$;
108118
GRANT ALL PRIVILEGES ON SCHEMA storage TO supabase_storage_admin;
109119
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA storage TO supabase_storage_admin;
110120
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA storage TO supabase_storage_admin;

Diff for: ‎migrations/db/migrations/00000000000003-post-setup.sql

+27-4
Original file line numberDiff line numberDiff line change
@@ -39,8 +39,20 @@ BEGIN
3939

4040
END;
4141
$$;
42-
CREATE EVENT TRIGGER issue_pg_cron_access ON ddl_command_end WHEN TAG in ('CREATE SCHEMA')
43-
EXECUTE PROCEDURE extensions.grant_pg_cron_access();
42+
DO $$
43+
44+
BEGIN
45+
IF NOT EXISTS (
46+
SELECT 1
47+
FROM pg_catalog.pg_event_trigger
48+
WHERE evtname = 'issue_pg_cron_access'
49+
)
50+
THEN
51+
CREATE EVENT TRIGGER issue_pg_cron_access ON ddl_command_end WHEN TAG in ('CREATE SCHEMA')
52+
EXECUTE PROCEDURE extensions.grant_pg_cron_access();
53+
END IF;
54+
END
55+
$$;
4456
COMMENT ON FUNCTION extensions.grant_pg_cron_access IS 'Grants access to pg_cron';
4557

4658
-- Event trigger for pg_net
@@ -82,7 +94,6 @@ BEGIN
8294
END IF;
8395
END;
8496
$$;
85-
COMMENT ON FUNCTION extensions.grant_pg_net_access IS 'Grants access to pg_net';
8697

8798
DO
8899
$$
@@ -99,9 +110,21 @@ BEGIN
99110
END IF;
100111
END
101112
$$;
113+
COMMENT ON FUNCTION extensions.grant_pg_net_access IS 'Grants access to pg_net';
102114

103115
-- Supabase dashboard user
104-
CREATE ROLE dashboard_user NOSUPERUSER CREATEDB CREATEROLE REPLICATION;
116+
do $$
117+
begin
118+
if not exists (
119+
select 1 from pg_roles
120+
where rolname = 'dashboard_user'
121+
)
122+
then
123+
CREATE ROLE dashboard_user NOSUPERUSER CREATEDB CREATEROLE REPLICATION;
124+
end if;
125+
end
126+
$$;
127+
105128
GRANT ALL ON DATABASE postgres TO dashboard_user;
106129
GRANT ALL ON SCHEMA auth TO dashboard_user;
107130
GRANT ALL ON SCHEMA extensions TO dashboard_user;

0 commit comments

Comments
 (0)
Please sign in to comment.