This commit is contained in:
parent
343350e302
commit
488a3dfe05
|
|
@ -1,12 +1,15 @@
|
||||||
|
-- ✅ 创建 schema (幂等)
|
||||||
DO $$
|
DO $$
|
||||||
BEGIN
|
BEGIN
|
||||||
IF NOT EXISTS (
|
IF NOT EXISTS (
|
||||||
SELECT schema_name FROM information_schema.schemata WHERE schema_name = 'storage'
|
SELECT schema_name FROM information_schema.schemata
|
||||||
|
WHERE schema_name = 'storage'
|
||||||
) THEN
|
) THEN
|
||||||
CREATE SCHEMA storage;
|
CREATE SCHEMA storage;
|
||||||
END IF;
|
END IF;
|
||||||
END$$;
|
END$$;
|
||||||
|
|
||||||
|
-- ✅ 创建角色和默认权限(幂等)
|
||||||
DO $$
|
DO $$
|
||||||
DECLARE
|
DECLARE
|
||||||
install_roles text := COALESCE(current_setting('storage.install_roles', true), 'true');
|
install_roles text := COALESCE(current_setting('storage.install_roles', true), 'true');
|
||||||
|
|
@ -16,31 +19,23 @@ DECLARE
|
||||||
BEGIN
|
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 = anon_role) THEN
|
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = anon_role) THEN
|
||||||
EXECUTE 'CREATE ROLE ' || quote_ident(anon_role) || ' NOLOGIN NOINHERIT';
|
EXECUTE 'CREATE ROLE ' || quote_ident(anon_role) || ' NOLOGIN NOINHERIT';
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = authenticated_role) THEN
|
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = authenticated_role) THEN
|
||||||
EXECUTE 'CREATE ROLE ' || quote_ident(authenticated_role) || ' NOLOGIN NOINHERIT';
|
EXECUTE 'CREATE ROLE ' || quote_ident(authenticated_role) || ' NOLOGIN NOINHERIT';
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = service_role) THEN
|
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = service_role) THEN
|
||||||
EXECUTE 'CREATE ROLE ' || quote_ident(service_role) || ' NOLOGIN NOINHERIT BYPASSRLS';
|
EXECUTE 'CREATE ROLE ' || quote_ident(service_role) || ' NOLOGIN NOINHERIT BYPASSRLS';
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'authenticator') THEN
|
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'authenticator') THEN
|
||||||
CREATE USER authenticator NOINHERIT;
|
CREATE USER authenticator NOINHERIT;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- 授权角色
|
EXECUTE 'GRANT ' || quote_ident(anon_role) || ',' ||
|
||||||
EXECUTE 'GRANT ' || quote_ident(anon_role) || ' TO authenticator';
|
quote_ident(authenticated_role) || ',' ||
|
||||||
EXECUTE 'GRANT ' || quote_ident(authenticated_role) || ' TO authenticator';
|
quote_ident(service_role) || ' TO authenticator';
|
||||||
EXECUTE 'GRANT ' || quote_ident(service_role) || ' TO authenticator';
|
|
||||||
|
|
||||||
-- 不再尝试 GRANT postgres TO authenticator(禁止行为)
|
|
||||||
|
|
||||||
-- schema usage 与默认权限
|
|
||||||
EXECUTE 'GRANT USAGE ON SCHEMA storage TO ' ||
|
EXECUTE 'GRANT USAGE ON SCHEMA storage TO ' ||
|
||||||
quote_ident(anon_role) || ',' ||
|
quote_ident(anon_role) || ',' ||
|
||||||
quote_ident(authenticated_role) || ',' ||
|
quote_ident(authenticated_role) || ',' ||
|
||||||
|
|
@ -48,14 +43,13 @@ BEGIN
|
||||||
|
|
||||||
EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON TABLES TO ' ||
|
EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON TABLES TO ' ||
|
||||||
quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role);
|
quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role);
|
||||||
|
|
||||||
EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON FUNCTIONS TO ' ||
|
EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON FUNCTIONS TO ' ||
|
||||||
quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role);
|
quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role);
|
||||||
|
|
||||||
EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON SEQUENCES TO ' ||
|
EXECUTE 'ALTER DEFAULT PRIVILEGES IN SCHEMA storage GRANT ALL ON SEQUENCES TO ' ||
|
||||||
quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role);
|
quote_ident(anon_role) || ',' || quote_ident(authenticated_role) || ',' || quote_ident(service_role);
|
||||||
END$$;
|
END$$;
|
||||||
|
|
||||||
|
-- ✅ 创建 migrations 表(幂等)
|
||||||
CREATE TABLE IF NOT EXISTS storage.migrations (
|
CREATE TABLE IF NOT EXISTS storage.migrations (
|
||||||
id integer PRIMARY KEY,
|
id integer PRIMARY KEY,
|
||||||
name varchar(100) UNIQUE NOT NULL,
|
name varchar(100) UNIQUE NOT NULL,
|
||||||
|
|
@ -63,17 +57,32 @@ CREATE TABLE IF NOT EXISTS storage.migrations (
|
||||||
executed_at timestamp DEFAULT current_timestamp
|
executed_at timestamp DEFAULT current_timestamp
|
||||||
);
|
);
|
||||||
|
|
||||||
|
-- ✅ 创建 buckets 表(不含 public 字段)
|
||||||
CREATE TABLE IF NOT EXISTS storage.buckets (
|
CREATE TABLE IF NOT EXISTS storage.buckets (
|
||||||
id text NOT NULL,
|
id text NOT NULL,
|
||||||
name text NOT NULL,
|
name text NOT NULL,
|
||||||
owner uuid,
|
owner uuid,
|
||||||
public boolean NOT NULL DEFAULT false,
|
|
||||||
created_at timestamptz DEFAULT now(),
|
created_at timestamptz DEFAULT now(),
|
||||||
updated_at timestamptz DEFAULT now(),
|
updated_at timestamptz DEFAULT now(),
|
||||||
PRIMARY KEY (id)
|
PRIMARY KEY (id)
|
||||||
);
|
);
|
||||||
CREATE UNIQUE INDEX IF NOT EXISTS bname ON storage.buckets (name);
|
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 (
|
CREATE TABLE IF NOT EXISTS storage.objects (
|
||||||
id uuid NOT NULL DEFAULT gen_random_uuid(),
|
id uuid NOT NULL DEFAULT gen_random_uuid(),
|
||||||
bucket_id text,
|
bucket_id text,
|
||||||
|
|
@ -89,43 +98,36 @@ CREATE TABLE IF NOT EXISTS storage.objects (
|
||||||
CREATE UNIQUE INDEX IF NOT EXISTS bucketid_objname ON storage.objects (bucket_id, name);
|
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);
|
CREATE INDEX IF NOT EXISTS name_prefix_search ON storage.objects (name text_pattern_ops);
|
||||||
|
|
||||||
|
-- ✅ 启用 RLS
|
||||||
ALTER TABLE storage.objects ENABLE ROW LEVEL SECURITY;
|
ALTER TABLE storage.objects ENABLE ROW LEVEL SECURITY;
|
||||||
|
|
||||||
-- 安全函数定义
|
-- ✅ 内置函数(可重用)
|
||||||
CREATE OR REPLACE FUNCTION storage.foldername(name text)
|
CREATE OR REPLACE FUNCTION storage.foldername(name text)
|
||||||
RETURNS text[]
|
RETURNS text[] LANGUAGE plpgsql AS $$
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE _parts text[];
|
DECLARE _parts text[];
|
||||||
BEGIN
|
BEGIN
|
||||||
SELECT string_to_array(name, '/') INTO _parts;
|
SELECT string_to_array(name, '/') INTO _parts;
|
||||||
RETURN _parts[1:array_length(_parts,1)-1];
|
RETURN _parts[1:array_length(_parts,1)-1];
|
||||||
END
|
END$$;
|
||||||
$$;
|
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION storage.filename(name text)
|
CREATE OR REPLACE FUNCTION storage.filename(name text)
|
||||||
RETURNS text
|
RETURNS text LANGUAGE plpgsql AS $$
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE _parts text[];
|
DECLARE _parts text[];
|
||||||
BEGIN
|
BEGIN
|
||||||
SELECT string_to_array(name, '/') INTO _parts;
|
SELECT string_to_array(name, '/') INTO _parts;
|
||||||
RETURN _parts[array_length(_parts,1)];
|
RETURN _parts[array_length(_parts,1)];
|
||||||
END
|
END$$;
|
||||||
$$;
|
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION storage.extension(name text)
|
CREATE OR REPLACE FUNCTION storage.extension(name text)
|
||||||
RETURNS text
|
RETURNS text LANGUAGE plpgsql AS $$
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE _parts text[]; _filename text;
|
DECLARE _parts text[]; _filename text;
|
||||||
BEGIN
|
BEGIN
|
||||||
SELECT string_to_array(name, '/') INTO _parts;
|
SELECT string_to_array(name, '/') INTO _parts;
|
||||||
SELECT _parts[array_length(_parts,1)] INTO _filename;
|
SELECT _parts[array_length(_parts,1)] INTO _filename;
|
||||||
RETURN reverse(split_part(reverse(_filename), '.', 1));
|
RETURN reverse(split_part(reverse(_filename), '.', 1));
|
||||||
END
|
END$$;
|
||||||
$$;
|
|
||||||
|
|
||||||
|
-- ✅ 文件夹搜索函数(用于前端分层目录浏览)
|
||||||
CREATE OR REPLACE FUNCTION storage.search(
|
CREATE OR REPLACE FUNCTION storage.search(
|
||||||
prefix text, bucketname text, limits int DEFAULT 100, levels int DEFAULT 1, offsets int DEFAULT 0
|
prefix text, bucketname text, limits int DEFAULT 100, levels int DEFAULT 1, offsets int DEFAULT 0
|
||||||
)
|
)
|
||||||
|
|
@ -137,8 +139,7 @@ CREATE OR REPLACE FUNCTION storage.search(
|
||||||
last_accessed_at timestamptz,
|
last_accessed_at timestamptz,
|
||||||
metadata jsonb
|
metadata jsonb
|
||||||
)
|
)
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql AS $$
|
||||||
AS $$
|
|
||||||
BEGIN
|
BEGIN
|
||||||
RETURN QUERY
|
RETURN QUERY
|
||||||
WITH files_folders AS (
|
WITH files_folders AS (
|
||||||
|
|
@ -160,9 +161,9 @@ BEGIN
|
||||||
LEFT JOIN storage.objects
|
LEFT JOIN storage.objects
|
||||||
ON prefix || files_folders.folder = objects.name
|
ON prefix || files_folders.folder = objects.name
|
||||||
AND objects.bucket_id = bucketname;
|
AND objects.bucket_id = bucketname;
|
||||||
END
|
END$$;
|
||||||
$$;
|
|
||||||
|
|
||||||
|
-- ✅ 管理员角色创建(幂等)
|
||||||
DO $$
|
DO $$
|
||||||
DECLARE
|
DECLARE
|
||||||
install_roles text := COALESCE(current_setting('storage.install_roles', true), 'true');
|
install_roles text := COALESCE(current_setting('storage.install_roles', true), 'true');
|
||||||
|
|
@ -190,18 +191,14 @@ BEGIN
|
||||||
EXECUTE 'ALTER FUNCTION storage.filename(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.extension(text) OWNER TO ' || quote_ident(super_user);
|
||||||
EXECUTE 'ALTER FUNCTION storage.search(text,text,int,int,int) OWNER TO ' || quote_ident(super_user);
|
EXECUTE 'ALTER FUNCTION storage.search(text,text,int,int,int) OWNER TO ' || quote_ident(super_user);
|
||||||
|
|
||||||
END$$;
|
END$$;
|
||||||
|
|
||||||
|
-- ✅ 插入默认 bucket(公开访问,用于头像)
|
||||||
-- ✅ 单独插入 bucket(允许重复执行)
|
|
||||||
INSERT INTO storage.buckets (id, name, owner, public)
|
INSERT INTO storage.buckets (id, name, owner, public)
|
||||||
VALUES ('profile_images', 'profile_images', NULL, true)
|
VALUES ('profile_images', 'profile_images', NULL, true)
|
||||||
ON CONFLICT (id) DO UPDATE SET public = true;
|
ON CONFLICT (id) DO UPDATE SET public = true;
|
||||||
|
|
||||||
|
-- ✅ RLS 策略定义(幂等)
|
||||||
|
|
||||||
-- ✅ 单独定义权限策略(重复执行不会报错)
|
|
||||||
DO $$
|
DO $$
|
||||||
BEGIN
|
BEGIN
|
||||||
IF NOT EXISTS (
|
IF NOT EXISTS (
|
||||||
|
|
@ -223,4 +220,4 @@ BEGIN
|
||||||
TO anon
|
TO anon
|
||||||
USING (bucket_id = ''profile_images'')';
|
USING (bucket_id = ''profile_images'')';
|
||||||
END IF;
|
END IF;
|
||||||
END$$;
|
END$$;
|
||||||
|
|
|
||||||
Loading…
Reference in New Issue