Skip to content

Commit

Permalink
fix: add base migrations to storage service
Browse files Browse the repository at this point in the history
  • Loading branch information
fenos committed Jan 5, 2024
1 parent 01c8a7e commit 2c21686
Show file tree
Hide file tree
Showing 33 changed files with 544 additions and 249 deletions.
7 changes: 5 additions & 2 deletions src/test/db/docker-compose.yml → docker-compose.yml
Original file line number Diff line number Diff line change
Expand Up @@ -6,8 +6,11 @@ services:
image: postgres:13
ports:
- '5432:5432'
volumes:
- ./src/test/db:/docker-entrypoint-initdb.d/
healthcheck:
test: [ "CMD-SHELL", "pg_isready", "-d", "postgres" ]
interval: 50s
timeout: 60s
retries: 5
environment:
POSTGRES_DB: postgres
POSTGRES_USER: postgres
Expand Down
168 changes: 168 additions & 0 deletions migrations/tenant/0002-storage-schema.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,168 @@
CREATE SCHEMA IF NOT EXISTS storage;

create extension if not exists "uuid-ossp";
create extension if not exists pgcrypto;

DO $$
DECLARE
install_roles text = COALESCE(current_setting('storage.install_roles', true), 'true');
anon_role text = COALESCE(current_setting('storage.anon_role', true), 'anon');
authenticated_role text = COALESCE(current_setting('storage.authenticated_role', true), 'authenticated');
service_role text = COALESCE(current_setting('storage.service_role', true), 'service_role');
BEGIN
IF install_roles != 'true' THEN
RETURN;
END IF;

-- Install ROLES
EXECUTE 'CREATE ROLE ' || anon_role || ' NOLOGIN NOINHERIT';
EXECUTE 'CREATE ROLE ' || authenticated_role || ' NOLOGIN NOINHERIT';
EXECUTE 'CREATE ROLE ' || service_role || ' NOLOGIN NOINHERIT bypassrls';

create user authenticator noinherit;
EXECUTE 'grant ' || anon_role || ' to authenticator';
EXECUTE 'grant ' || authenticated_role || ' to authenticator';
EXECUTE 'grant ' || service_role || ' to authenticator';
grant postgres to authenticator;

EXECUTE 'grant usage on schema storage to postgres,' || anon_role || ',' || authenticated_role || ',' || service_role;

EXECUTE 'alter default privileges in schema storage grant all on tables to postgres,' || anon_role || ',' || authenticated_role || ',' || service_role;
EXECUTE 'alter default privileges in schema storage grant all on functions to postgres,' || anon_role || ',' || authenticated_role || ',' || service_role;
EXECUTE 'alter default privileges in schema storage grant all on sequences to postgres,' || anon_role || ',' || authenticated_role || ',' || service_role;
END$$;


CREATE TABLE IF NOT EXISTS "storage"."migrations" (
id integer PRIMARY KEY,
name varchar(100) UNIQUE NOT NULL,
hash varchar(40) NOT NULL, -- sha1 hex encoded hash of the file name and contents, to ensure it hasn't been altered since applying the migration
executed_at timestamp DEFAULT current_timestamp
);

CREATE TABLE IF NOT EXISTS "storage"."buckets" (
"id" text not NULL,
"name" text NOT NULL,
"owner" uuid,
"created_at" timestamptz DEFAULT now(),
"updated_at" timestamptz DEFAULT now(),
PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX IF NOT EXISTS "bname" ON "storage"."buckets" USING BTREE ("name");

CREATE TABLE IF NOT EXISTS "storage"."objects" (
"id" uuid NOT NULL DEFAULT uuid_generate_v4(),
"bucket_id" text,
"name" text,
"owner" uuid,
"created_at" timestamptz DEFAULT now(),
"updated_at" timestamptz DEFAULT now(),
"last_accessed_at" timestamptz DEFAULT now(),
"metadata" jsonb,
CONSTRAINT "objects_bucketId_fkey" FOREIGN KEY ("bucket_id") REFERENCES "storage"."buckets"("id"),
PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX IF NOT EXISTS "bucketid_objname" ON "storage"."objects" USING BTREE ("bucket_id","name");
CREATE INDEX IF NOT EXISTS name_prefix_search ON storage.objects(name text_pattern_ops);

ALTER TABLE storage.objects ENABLE ROW LEVEL SECURITY;

CREATE OR REPLACE FUNCTION storage.foldername(name text)
RETURNS text[]
LANGUAGE plpgsql
AS $function$
DECLARE
_parts text[];
BEGIN
select string_to_array(name, '/') into _parts;
return _parts[1:array_length(_parts,1)-1];
END
$function$;

CREATE OR REPLACE FUNCTION storage.filename(name text)
RETURNS text
LANGUAGE plpgsql
AS $function$
DECLARE
_parts text[];
BEGIN
select string_to_array(name, '/') into _parts;
return _parts[array_length(_parts,1)];
END
$function$;

CREATE OR REPLACE FUNCTION storage.extension(name text)
RETURNS text
LANGUAGE plpgsql
AS $function$
DECLARE
_parts text[];
_filename text;
BEGIN
select string_to_array(name, '/') into _parts;
select _parts[array_length(_parts,1)] into _filename;
-- @todo return the last part instead of 2
return reverse(split_part(reverse(_filename), '.', 1));
END
$function$;

-- @todo can this query be optimised further?
CREATE OR REPLACE FUNCTION storage.search(prefix text, bucketname text, limits int DEFAULT 100, levels int DEFAULT 1, offsets int DEFAULT 0)
RETURNS TABLE (
name text,
id uuid,
updated_at TIMESTAMPTZ,
created_at TIMESTAMPTZ,
last_accessed_at TIMESTAMPTZ,
metadata jsonb
)
LANGUAGE plpgsql
AS $function$
BEGIN
return query
with files_folders as (
select ((string_to_array(objects.name, '/'))[levels]) as folder
from objects
where objects.name ilike prefix || '%'
and bucket_id = bucketname
GROUP by folder
limit limits
offset offsets
)
select files_folders.folder as name, objects.id, objects.updated_at, objects.created_at, objects.last_accessed_at, objects.metadata from files_folders
left join objects
on prefix || files_folders.folder = objects.name and objects.bucket_id=bucketname;
END
$function$;


DO $$
DECLARE
install_roles text = COALESCE(current_setting('storage.install_roles', true), 'true');
super_user text = COALESCE(current_setting('storage.super_user', true), 'supabase_storage_admin');
BEGIN
IF install_roles != 'true' THEN
RETURN;
END IF;

IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = super_user) THEN
EXECUTE 'CREATE USER ' || super_user || ' NOINHERIT CREATEROLE LOGIN NOREPLICATION';
END IF;

-- Grant privileges to Super User
EXECUTE 'GRANT ALL PRIVILEGES ON SCHEMA storage TO ' || super_user;
EXECUTE 'GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA storage TO ' || super_user;
EXECUTE 'GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA storage TO ' || super_user;

IF super_user != 'postgres' THEN
EXECUTE 'ALTER USER ' || super_user || ' SET search_path = "storage"';
END IF;

EXECUTE 'ALTER table "storage".objects owner to ' || super_user;
EXECUTE 'ALTER table "storage".buckets owner to ' || super_user;
EXECUTE 'ALTER table "storage".migrations OWNER TO ' || super_user;
EXECUTE 'ALTER function "storage".foldername(text) owner to ' || super_user;
EXECUTE 'ALTER function "storage".filename(text) owner to ' || super_user;
EXECUTE 'ALTER function "storage".extension(text) owner to ' || super_user;
EXECUTE 'ALTER function "storage".search(text,text,int,int,int) owner to ' || super_user;
END$$;
File renamed without changes.
File renamed without changes.
4 changes: 2 additions & 2 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -15,8 +15,8 @@
"prettier:check": "prettier -v && prettier -c src/**",
"format": "prettier -c --write src/**",
"eslint:check": "eslint 'src/**'",
"infra:stop": "docker-compose --project-directory . -f src/test/db/docker-compose.yml down --remove-orphans",
"infra:start": "docker-compose --project-directory . -f src/test/db/docker-compose.yml up -d && sleep 5 && npm run migration:run",
"infra:stop": "docker-compose --project-directory . -f docker-compose.yml down --remove-orphans",
"infra:start": "docker-compose --project-directory . -f docker-compose.yml up -d && sleep 5 && npm run migration:run",
"infra:restart": "npm run infra:stop && npm run infra:start"
},
"author": "Supabase",
Expand Down
12 changes: 12 additions & 0 deletions src/config.ts
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,12 @@ type StorageConfigType = {
jwtSecret: string
jwtAlgorithm: string
multitenantDatabaseUrl?: string
dbAnonRole: string
dbAuthenticatedRole: string
dbServiceRole: string
dbInstallRoles: boolean
dbSuperUser: string
dbSearchPath: string
databaseURL: string
databaseSSLRootCert?: string
databasePoolURL?: string
Expand Down Expand Up @@ -124,6 +130,12 @@ export function getConfig(): StorageConfigType {
isMultitenant: getOptionalConfigFromEnv('IS_MULTITENANT') === 'true',
jwtSecret: getOptionalIfMultitenantConfigFromEnv('PGRST_JWT_SECRET') || '',
jwtAlgorithm: getOptionalConfigFromEnv('PGRST_JWT_ALGORITHM') || 'HS256',
dbAnonRole: getOptionalConfigFromEnv('DB_ANON_ROLE') || 'anon',
dbServiceRole: getOptionalConfigFromEnv('DB_SERVICE_ROLE') || 'service_role',
dbAuthenticatedRole: getOptionalConfigFromEnv('DB_AUTHENTICATED_ROLE') || 'authenticated',
dbInstallRoles: !(getOptionalConfigFromEnv('DB_INSTALL_ROLES') === 'false'),
dbSuperUser: getOptionalConfigFromEnv('DB_SUPER_USER') || 'postgres',
dbSearchPath: getOptionalConfigFromEnv('DB_SEARCH_PATH') || '',
multitenantDatabaseUrl: getOptionalConfigFromEnv('MULTITENANT_DATABASE_URL'),
databaseSSLRootCert: getOptionalConfigFromEnv('DATABASE_SSL_ROOT_CERT'),
databaseURL: getOptionalIfMultitenantConfigFromEnv('DATABASE_URL') || '',
Expand Down
3 changes: 2 additions & 1 deletion src/database/connection.ts
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@ const {
databaseMaxConnections,
databaseFreePoolAfterInactivity,
databaseConnectionTimeout,
dbSearchPath,
} = getConfig()

interface TenantConnectionOptions {
Expand Down Expand Up @@ -50,7 +51,7 @@ export const connections = new TTLCache<string, Knex>({
pool.client.removeAllListeners()
},
})
const searchPath = ['storage', 'public', 'extensions']
const searchPath = ['storage', 'public', 'extensions', ...dbSearchPath.split(',')].filter(Boolean)

export class TenantConnection {
public readonly role: string
Expand Down
Loading

0 comments on commit 2c21686

Please sign in to comment.