89 lines
3.3 KiB
PL/PgSQL
89 lines
3.3 KiB
PL/PgSQL
-- ViGent 用户认证系统数据库表
|
||
-- 在 Supabase SQL Editor 中执行
|
||
|
||
-- 1. 创建 users 表
|
||
CREATE TABLE IF NOT EXISTS users (
|
||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
phone TEXT UNIQUE NOT NULL,
|
||
password_hash TEXT NOT NULL,
|
||
username TEXT,
|
||
role TEXT DEFAULT 'pending' CHECK (role IN ('pending', 'user', 'admin')),
|
||
is_active BOOLEAN DEFAULT FALSE,
|
||
expires_at TIMESTAMP WITH TIME ZONE,
|
||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||
);
|
||
|
||
-- 2. 创建 user_sessions 表 (单设备登录)
|
||
CREATE TABLE IF NOT EXISTS user_sessions (
|
||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
user_id UUID REFERENCES users(id) ON DELETE CASCADE UNIQUE,
|
||
session_token TEXT UNIQUE NOT NULL,
|
||
device_info TEXT,
|
||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||
);
|
||
|
||
-- 3. 创建 social_accounts 表 (社交账号绑定)
|
||
CREATE TABLE IF NOT EXISTS social_accounts (
|
||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
|
||
platform TEXT NOT NULL CHECK (platform IN ('bilibili', 'douyin', 'xiaohongshu')),
|
||
logged_in BOOLEAN DEFAULT FALSE,
|
||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
UNIQUE(user_id, platform)
|
||
);
|
||
|
||
-- 4. 创建索引
|
||
CREATE INDEX IF NOT EXISTS idx_users_phone ON users(phone);
|
||
CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON user_sessions(user_id);
|
||
CREATE INDEX IF NOT EXISTS idx_social_user_platform ON social_accounts(user_id, platform);
|
||
|
||
-- 5. 启用 RLS (行级安全)
|
||
ALTER TABLE users ENABLE ROW LEVEL SECURITY;
|
||
ALTER TABLE user_sessions ENABLE ROW LEVEL SECURITY;
|
||
ALTER TABLE social_accounts ENABLE ROW LEVEL SECURITY;
|
||
|
||
-- 6. RLS 策略 (Service Role 可以绑过 RLS,所以后端使用 service_role key 时不受限)
|
||
-- 以下策略仅对 anon key 生效
|
||
|
||
-- users: 仅管理员可查看所有用户,普通用户只能查看自己
|
||
CREATE POLICY "Users can view own profile" ON users
|
||
FOR SELECT USING (auth.uid()::text = id::text);
|
||
|
||
-- user_sessions: 用户只能访问自己的 session
|
||
CREATE POLICY "Users can access own sessions" ON user_sessions
|
||
FOR ALL USING (user_id::text = auth.uid()::text);
|
||
|
||
-- social_accounts: 用户只能访问自己的社交账号
|
||
CREATE POLICY "Users can access own social accounts" ON social_accounts
|
||
FOR ALL USING (user_id::text = auth.uid()::text);
|
||
|
||
-- 7. 更新时间自动更新触发器
|
||
CREATE OR REPLACE FUNCTION update_updated_at()
|
||
RETURNS TRIGGER AS $$
|
||
BEGIN
|
||
NEW.updated_at = NOW();
|
||
RETURN NEW;
|
||
END;
|
||
$$ LANGUAGE plpgsql;
|
||
|
||
CREATE TRIGGER users_updated_at
|
||
BEFORE UPDATE ON users
|
||
FOR EACH ROW
|
||
EXECUTE FUNCTION update_updated_at();
|
||
|
||
-- 8. 订单表(支付宝付费)
|
||
CREATE TABLE IF NOT EXISTS orders (
|
||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
|
||
out_trade_no TEXT UNIQUE NOT NULL,
|
||
amount DECIMAL(10, 2) NOT NULL DEFAULT 999.00,
|
||
status TEXT DEFAULT 'pending' CHECK (status IN ('pending', 'paid', 'failed')),
|
||
trade_no TEXT,
|
||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
paid_at TIMESTAMP WITH TIME ZONE
|
||
);
|
||
|
||
CREATE INDEX IF NOT EXISTS idx_orders_user_id ON orders(user_id);
|
||
CREATE INDEX IF NOT EXISTS idx_orders_out_trade_no ON orders(out_trade_no);
|