interpreter-admin/database/create-admin.sql
Mars Developer 51f8d95bf9 first commit
2025-06-26 11:24:11 +08:00

132 lines
4.5 KiB
PL/PgSQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- 创建管理员账户初始化脚本
-- 在Supabase SQL编辑器中运行此脚本来创建管理员账户
-- 1. 创建admin_users表如果不存在
CREATE TABLE IF NOT EXISTS admin_users (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
username TEXT UNIQUE NOT NULL,
password_hash TEXT NOT NULL,
role TEXT NOT NULL DEFAULT 'admin',
full_name TEXT,
email TEXT,
is_active BOOLEAN DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
last_login TIMESTAMP WITH TIME ZONE
);
-- 2. 创建profiles表的管理员记录如果不存在
CREATE TABLE IF NOT EXISTS profiles (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
email TEXT UNIQUE NOT NULL,
full_name TEXT,
avatar_url TEXT,
role TEXT NOT NULL DEFAULT 'customer' CHECK (role IN ('customer', 'interpreter', 'admin')),
languages TEXT[] DEFAULT '{}',
credits INTEGER DEFAULT 0,
phone TEXT,
company TEXT,
department TEXT,
specializations TEXT[] DEFAULT '{}',
hourly_rate DECIMAL(10,2),
timezone TEXT DEFAULT 'UTC',
is_active BOOLEAN DEFAULT true,
is_enterprise BOOLEAN DEFAULT false,
enterprise_id UUID,
subscription_id TEXT,
contract_pricing JSONB,
verification_status TEXT DEFAULT 'pending' CHECK (verification_status IN ('pending', 'verified', 'rejected')),
status TEXT DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
last_login TIMESTAMP WITH TIME ZONE
);
-- 3. 插入默认管理员账户到admin_users表
-- 密码: admin123 (使用bcrypt加密)
INSERT INTO admin_users (username, password_hash, role, full_name, email) VALUES
('admin@example.com', '$2a$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi', 'admin', '系统管理员', 'admin@example.com')
ON CONFLICT (username) DO UPDATE SET
password_hash = EXCLUDED.password_hash,
updated_at = NOW();
-- 4. 插入管理员到profiles表
INSERT INTO profiles (email, full_name, role, is_active, verification_status) VALUES
('admin@example.com', '系统管理员', 'admin', true, 'verified')
ON CONFLICT (email) DO UPDATE SET
full_name = EXCLUDED.full_name,
role = EXCLUDED.role,
is_active = EXCLUDED.is_active,
verification_status = EXCLUDED.verification_status,
updated_at = NOW();
-- 5. 创建更新时间戳的触发器函数(如果不存在)
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ language 'plpgsql';
-- 6. 为admin_users表创建更新时间戳触发器
DROP TRIGGER IF EXISTS update_admin_users_updated_at ON admin_users;
CREATE TRIGGER update_admin_users_updated_at
BEFORE UPDATE ON admin_users
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- 7. 为profiles表创建更新时间戳触发器
DROP TRIGGER IF EXISTS update_profiles_updated_at ON profiles;
CREATE TRIGGER update_profiles_updated_at
BEFORE UPDATE ON profiles
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- 8. 启用行级安全策略RLS
ALTER TABLE admin_users ENABLE ROW LEVEL SECURITY;
ALTER TABLE profiles ENABLE ROW LEVEL SECURITY;
-- 9. 创建RLS策略允许所有操作实际使用时需要根据需求调整
DROP POLICY IF EXISTS "Allow all operations on admin_users" ON admin_users;
CREATE POLICY "Allow all operations on admin_users" ON admin_users FOR ALL USING (true);
DROP POLICY IF EXISTS "Allow all operations on profiles" ON profiles;
CREATE POLICY "Allow all operations on profiles" ON profiles FOR ALL USING (true);
-- 10. 创建索引以提高查询性能
CREATE INDEX IF NOT EXISTS idx_admin_users_username ON admin_users(username);
CREATE INDEX IF NOT EXISTS idx_admin_users_email ON admin_users(email);
CREATE INDEX IF NOT EXISTS idx_profiles_email ON profiles(email);
CREATE INDEX IF NOT EXISTS idx_profiles_role ON profiles(role);
-- 11. 验证管理员账户创建
SELECT
'admin_users' as table_name,
username,
role,
full_name,
email,
is_active,
created_at
FROM admin_users
WHERE username = 'admin@example.com'
UNION ALL
SELECT
'profiles' as table_name,
email as username,
role,
full_name,
email,
is_active::text,
created_at
FROM profiles
WHERE email = 'admin@example.com' AND role = 'admin';
-- 显示结果
SELECT '管理员账户创建完成!' as message;
SELECT '登录信息:' as info;
SELECT '用户名: admin@example.com' as username;
SELECT '密码: admin123' as password;