249 lines
8.5 KiB
PL/PgSQL
249 lines
8.5 KiB
PL/PgSQL
-- ✅ 创建 schema (幂等)
|
||
DO $$
|
||
BEGIN
|
||
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');
|
||
BEGIN
|
||
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;
|
||
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = authenticated_role) THEN
|
||
EXECUTE 'CREATE ROLE ' || quote_ident(authenticated_role) || ' NOLOGIN 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;
|
||
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'authenticator') THEN
|
||
CREATE USER authenticator NOINHERIT;
|
||
END IF;
|
||
|
||
EXECUTE 'GRANT ' || quote_ident(anon_role) || ',' ||
|
||
quote_ident(authenticated_role) || ',' ||
|
||
quote_ident(service_role) || ' TO authenticator';
|
||
|
||
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$$;
|
||
|
||
-- ✅ 创建 migrations 表(幂等)
|
||
CREATE TABLE IF NOT EXISTS storage.migrations (
|
||
id integer PRIMARY KEY,
|
||
name varchar(100) UNIQUE NOT NULL,
|
||
hash varchar(40) NOT NULL,
|
||
executed_at timestamp DEFAULT current_timestamp
|
||
);
|
||
|
||
-- ✅ 创建 buckets 表(不含 public 字段)
|
||
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 (name);
|
||
|
||
-- ✅ 补 public 字段(兼容升级)
|
||
DO $$
|
||
BEGIN
|
||
IF NOT EXISTS (
|
||
SELECT 1 FROM information_schema.columns
|
||
WHERE table_schema = 'storage'
|
||
AND table_name = 'buckets'
|
||
AND column_name = 'public'
|
||
) THEN
|
||
ALTER TABLE storage.buckets
|
||
ADD COLUMN public boolean NOT NULL DEFAULT false;
|
||
END IF;
|
||
END$$;
|
||
|
||
-- ✅ 创建 objects 表
|
||
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 (bucket_id, name);
|
||
CREATE INDEX IF NOT EXISTS name_prefix_search ON storage.objects (name text_pattern_ops);
|
||
|
||
-- ✅ 启用 RLS
|
||
ALTER TABLE storage.objects ENABLE ROW LEVEL SECURITY;
|
||
|
||
-- ✅ 内置函数(可重用)
|
||
CREATE OR REPLACE FUNCTION storage.foldername(name text)
|
||
RETURNS text[] LANGUAGE plpgsql AS $$
|
||
DECLARE _parts text[];
|
||
BEGIN
|
||
SELECT string_to_array(name, '/') INTO _parts;
|
||
RETURN _parts[1:array_length(_parts,1)-1];
|
||
END$$;
|
||
|
||
CREATE OR REPLACE FUNCTION storage.filename(name text)
|
||
RETURNS text LANGUAGE plpgsql AS $$
|
||
DECLARE _parts text[];
|
||
BEGIN
|
||
SELECT string_to_array(name, '/') INTO _parts;
|
||
RETURN _parts[array_length(_parts,1)];
|
||
END$$;
|
||
|
||
CREATE OR REPLACE FUNCTION storage.extension(name text)
|
||
RETURNS text LANGUAGE plpgsql AS $$
|
||
DECLARE _parts text[]; _filename text;
|
||
BEGIN
|
||
SELECT string_to_array(name, '/') INTO _parts;
|
||
SELECT _parts[array_length(_parts,1)] INTO _filename;
|
||
RETURN reverse(split_part(reverse(_filename), '.', 1));
|
||
END$$;
|
||
|
||
-- ✅ 文件夹搜索函数(用于前端分层目录浏览)
|
||
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 $$
|
||
BEGIN
|
||
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$$;
|
||
|
||
-- ✅ 管理员角色创建(幂等)
|
||
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 ROLE ' || quote_ident(super_user) || ' NOINHERIT CREATEROLE LOGIN NOREPLICATION';
|
||
END IF;
|
||
|
||
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 ROLE ' || quote_ident(super_user) || ' SET search_path = "storage"';
|
||
END IF;
|
||
|
||
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, public)
|
||
VALUES ('profile_images', 'profile_images', NULL, true)
|
||
ON CONFLICT (id) DO UPDATE SET public = true;
|
||
|
||
-- ✅ RLS 策略定义(幂等)
|
||
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$$;
|
||
|
||
|
||
-- ✅ RLS 策略定义(files bucket,幂等)
|
||
DO $$
|
||
BEGIN
|
||
IF NOT EXISTS (
|
||
SELECT 1 FROM pg_policies WHERE policyname = 'anon upload files'
|
||
) THEN
|
||
EXECUTE 'CREATE POLICY "anon upload files"
|
||
ON storage.objects
|
||
FOR INSERT
|
||
TO anon
|
||
WITH CHECK (bucket_id = ''files'')';
|
||
END IF;
|
||
|
||
IF NOT EXISTS (
|
||
SELECT 1 FROM pg_policies WHERE policyname = 'anon read files'
|
||
) THEN
|
||
EXECUTE 'CREATE POLICY "anon read files"
|
||
ON storage.objects
|
||
FOR SELECT
|
||
TO anon
|
||
USING (bucket_id = ''files'')';
|
||
END IF;
|
||
END$$;
|