From 30e1cde3b270c13f7b44499fcf0c23a73e1c055a Mon Sep 17 00:00:00 2001 From: hailin Date: Mon, 26 May 2025 16:50:39 +0800 Subject: [PATCH] . --- .../migrations/tenant/0002-storage-schema.sql | 274 ++++++++++-------- 1 file changed, 157 insertions(+), 117 deletions(-) diff --git a/storage_v1.19.1/migrations/tenant/0002-storage-schema.sql b/storage_v1.19.1/migrations/tenant/0002-storage-schema.sql index 91fa033..9a82885 100644 --- a/storage_v1.19.1/migrations/tenant/0002-storage-schema.sql +++ b/storage_v1.19.1/migrations/tenant/0002-storage-schema.sql @@ -1,183 +1,223 @@ - DO $$ BEGIN - IF NOT EXISTS(SELECT schema_name FROM information_schema.schemata WHERE schema_name = 'storage') THEN + IF NOT EXISTS ( + SELECT schema_name FROM information_schema.schemata WHERE schema_name = 'storage' + ) THEN CREATE SCHEMA storage; END IF; END$$; 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'); + 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; + IF install_roles != 'true' THEN RETURN; END IF; + + -- 角色存在判断后再建 + IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = anon_role) THEN + EXECUTE 'CREATE ROLE ' || quote_ident(anon_role) || ' NOLOGIN NOINHERIT'; END IF; - -- Install ROLES - EXECUTE 'CREATE ROLE IF NOT EXISTS ' || anon_role || ' NOLOGIN NOINHERIT'; - EXECUTE 'CREATE ROLE IF NOT EXISTS ' || authenticated_role || ' NOLOGIN NOINHERIT'; - EXECUTE 'CREATE ROLE IF NOT EXISTS ' || service_role || ' NOLOGIN NOINHERIT bypassrls'; + IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = authenticated_role) THEN + EXECUTE 'CREATE ROLE ' || quote_ident(authenticated_role) || ' NOLOGIN NOINHERIT'; + END IF; - -- create user authenticator noinherit; - IF NOT EXISTS ( - SELECT 1 - FROM pg_roles - WHERE rolname = 'authenticator' - ) THEN - EXECUTE 'create user authenticator noinherit;'; - END IF; + IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = service_role) THEN + EXECUTE 'CREATE ROLE ' || quote_ident(service_role) || ' NOLOGIN NOINHERIT BYPASSRLS'; + END IF; - EXECUTE 'grant ' || anon_role || ' to authenticator'; - EXECUTE 'grant ' || authenticated_role || ' to authenticator'; - EXECUTE 'grant ' || service_role || ' to authenticator'; - grant postgres to authenticator; + IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'authenticator') THEN + CREATE USER authenticator NOINHERIT; + END IF; - EXECUTE 'grant usage on schema storage to postgres,' || anon_role || ',' || authenticated_role || ',' || service_role; + -- 授权角色 + EXECUTE 'GRANT ' || quote_ident(anon_role) || ' TO authenticator'; + EXECUTE 'GRANT ' || quote_ident(authenticated_role) || ' TO authenticator'; + EXECUTE 'GRANT ' || quote_ident(service_role) || ' TO authenticator'; - 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; + -- 不再尝试 GRANT postgres TO authenticator(禁止行为) + + -- schema usage 与默认权限 + EXECUTE 'GRANT USAGE ON SCHEMA storage TO ' || + quote_ident(anon_role) || ',' || + quote_ident(authenticated_role) || ',' || + quote_ident(service_role); + + EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON TABLES TO ' || + quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role); + + EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON FUNCTIONS TO ' || + quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role); + + EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON SEQUENCES TO ' || + quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role); END$$; - -CREATE TABLE IF NOT EXISTS "storage"."migrations" ( +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 + hash varchar(40) NOT NULL, 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 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 UNIQUE INDEX IF NOT EXISTS bname ON storage.buckets (name); -CREATE TABLE IF NOT EXISTS "storage"."objects" ( - "id" uuid NOT NULL DEFAULT gen_random_uuid(), - "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 TABLE IF NOT EXISTS storage.objects ( + id uuid NOT NULL DEFAULT gen_random_uuid(), + 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); +CREATE UNIQUE INDEX IF NOT EXISTS bucketid_objname ON storage.objects (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; -drop function if exists storage.foldername; +-- 安全函数定义 CREATE OR REPLACE FUNCTION storage.foldername(name text) RETURNS text[] LANGUAGE plpgsql -AS $function$ -DECLARE -_parts text[]; +AS $$ +DECLARE _parts text[]; BEGIN - select string_to_array(name, '/') into _parts; - return _parts[1:array_length(_parts,1)-1]; + SELECT string_to_array(name, '/') INTO _parts; + RETURN _parts[1:array_length(_parts,1)-1]; END -$function$; +$$; -drop function if exists storage.filename; CREATE OR REPLACE FUNCTION storage.filename(name text) RETURNS text LANGUAGE plpgsql -AS $function$ -DECLARE -_parts text[]; +AS $$ +DECLARE _parts text[]; BEGIN - select string_to_array(name, '/') into _parts; - return _parts[array_length(_parts,1)]; + SELECT string_to_array(name, '/') INTO _parts; + RETURN _parts[array_length(_parts,1)]; END -$function$; +$$; -drop function if exists storage.extension; CREATE OR REPLACE FUNCTION storage.extension(name text) RETURNS text LANGUAGE plpgsql -AS $function$ -DECLARE -_parts text[]; -_filename text; +AS $$ +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)); + SELECT string_to_array(name, '/') INTO _parts; + SELECT _parts[array_length(_parts,1)] INTO _filename; + RETURN reverse(split_part(reverse(_filename), '.', 1)); END -$function$; +$$; --- @todo can this query be optimised further? -drop function if exists storage.search; -CREATE OR REPLACE FUNCTION storage.search(prefix text, bucketname text, limits int DEFAULT 100, levels int DEFAULT 1, offsets int DEFAULT 0) +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, + updated_at timestamptz, + created_at timestamptz, + last_accessed_at timestamptz, metadata jsonb - ) + ) LANGUAGE plpgsql -AS $function$ +AS $$ 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; + RETURN QUERY + WITH files_folders AS ( + SELECT (string_to_array(objects.name, '/'))[levels] AS folder + FROM storage.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 storage.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'); + 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 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'; + EXECUTE 'CREATE ROLE ' || quote_ident(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; + EXECUTE 'GRANT ALL PRIVILEGES ON SCHEMA storage TO ' || quote_ident(super_user); + EXECUTE 'GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA storage TO ' || quote_ident(super_user); + EXECUTE 'GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA storage TO ' || quote_ident(super_user); IF super_user != 'postgres' THEN - EXECUTE 'ALTER USER ' || super_user || ' SET search_path = "storage"'; + EXECUTE 'ALTER ROLE ' || quote_ident(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; + EXECUTE 'ALTER TABLE storage.objects OWNER TO ' || quote_ident(super_user); + EXECUTE 'ALTER TABLE storage.buckets OWNER TO ' || quote_ident(super_user); + EXECUTE 'ALTER TABLE storage.migrations OWNER TO ' || quote_ident(super_user); + + EXECUTE 'ALTER FUNCTION storage.foldername(text) OWNER TO ' || quote_ident(super_user); + EXECUTE 'ALTER FUNCTION storage.filename(text) OWNER TO ' || quote_ident(super_user); + EXECUTE 'ALTER FUNCTION storage.extension(text) OWNER TO ' || quote_ident(super_user); + EXECUTE 'ALTER FUNCTION storage.search(text,text,int,int,int) OWNER TO ' || quote_ident(super_user); + END$$; + + +-- ✅ 单独插入 bucket(允许重复执行) +INSERT INTO storage.buckets (id, name, owner) +VALUES ('profile_images', 'profile_images', NULL) +ON CONFLICT (id) DO NOTHING; + +-- ✅ 单独定义权限策略(重复执行不会报错) +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_policies WHERE policyname = 'anon upload profile_images' + ) THEN + EXECUTE $$CREATE POLICY "anon upload profile_images" + ON storage.objects + FOR INSERT + TO anon + WITH CHECK (bucket_id = 'profile_images')$$; + END IF; + + IF NOT EXISTS ( + SELECT 1 FROM pg_policies WHERE policyname = 'anon read profile_images' + ) THEN + EXECUTE $$CREATE POLICY "anon read profile_images" + ON storage.objects + FOR SELECT + TO anon + USING (bucket_id = 'profile_images')$$; + END IF; +END$$; \ No newline at end of file