Files
ystp/docs/database.md

20 KiB
Raw Blame History

数据库设计PostgreSQL + Redis- ImageForge

目标:支撑“网站 + 对外 API + 计费”的核心数据闭环,并为后续实现提供可迁移的表结构参考。

相关口径:

  • 产品范围:docs/prd.md
  • 计费与用量:docs/billing.md
  • 安全:docs/security.md

1. 概述

1.1 技术选型

  • PostgreSQL:系统真相来源(用户/任务/用量账本/订阅/发票/审计)。
  • Redis缓存会话、API Key 缓存、限流计数、队列Streams与进度推送PubSub 可选)。

1.2 设计原则

  • 用量可追溯:以 usage_events(明细账本)作为最终真相,可对账/可追责。
  • 幂等可落地idempotency_keys 保障重试不重复扣费/不重复建任务。
  • 多租户可扩展:后续可加 team/org不影响现有表的主键与关系。
  • 安全默认:不存明文 API Key审计日志不写入敏感明文。

2. PostgreSQL 扩展与类型

2.1 UUID 生成

本设计默认使用 gen_random_uuid(),需要启用 pgcrypto

CREATE EXTENSION IF NOT EXISTS pgcrypto;

注意:如果改用 uuid-ossp,则应统一改为 uuid_generate_v4(),避免文档与实现不一致。

2.2 枚举类型(建议)

CREATE TYPE user_role AS ENUM ('user', 'admin');
CREATE TYPE task_status AS ENUM ('pending', 'processing', 'completed', 'failed', 'cancelled');
CREATE TYPE file_status AS ENUM ('pending', 'processing', 'completed', 'failed');
CREATE TYPE compression_level AS ENUM ('high', 'medium', 'low');
CREATE TYPE task_source AS ENUM ('web', 'api');

CREATE TYPE subscription_status AS ENUM ('trialing', 'active', 'past_due', 'paused', 'canceled', 'incomplete');
CREATE TYPE invoice_status AS ENUM ('draft', 'open', 'paid', 'void', 'uncollectible');
CREATE TYPE payment_status AS ENUM ('pending', 'succeeded', 'failed', 'refunded');

3. ER 图(核心关系)

   ┌──────────────┐        ┌──────────────┐
   │    plans     │◄───────│ subscriptions│
   └──────┬───────┘        └──────┬───────┘
          │                        │
          │                        ▼
          │                ┌──────────────┐
          │                │   invoices   │◄────┐
          │                └──────┬───────┘     │
          │                        │             │
          │                        ▼             │
          │                ┌──────────────┐      │
          │                │   payments   │      │
          │                └──────────────┘      │
          │                                      │
          ▼                                      │
   ┌──────────────┐       ┌──────────────┐       │
   │    users     │──────►│   api_keys   │       │
   └──────┬───────┘       └──────────────┘       │
          │                                      │
          ▼                                      │
   ┌──────────────┐       ┌──────────────┐       │
   │    tasks     │──────►│  task_files  │       │
   └──────┬───────┘       └──────┬───────┘       │
          │                      │               │
          ▼                      ▼               │
   ┌──────────────┐       ┌──────────────┐       │
   │ usage_events │◄──────│ idempotency  │       │
   └──────┬───────┘       └──────────────┘       │
          │                                      │
          ▼                                      │
   ┌──────────────┐                              │
   │ usage_periods│                              │
   └──────────────┘                              │
                                                  │
                 ┌───────────────────────────────▼┐
                 │         webhook_events         │
                 └────────────────────────────────┘

4. 表结构(建议)

以下 SQL 用于“设计说明”真正落地时建议拆分迁移文件core/billing/metering

4.1 users - 用户

CREATE TABLE users (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  email VARCHAR(255) NOT NULL UNIQUE,
  username VARCHAR(50) NOT NULL UNIQUE,
  password_hash VARCHAR(255) NOT NULL,
  role user_role NOT NULL DEFAULT 'user',
  is_active BOOLEAN NOT NULL DEFAULT true,

  -- 邮箱验证
  email_verified_at TIMESTAMPTZ,

  -- 计费侧映射(可选,取决于支付渠道)
  billing_customer_id VARCHAR(200),

  -- 覆盖限制运营用NULL 表示用套餐默认)
  rate_limit_override INTEGER,
  storage_limit_mb INTEGER,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_users_role ON users(role);
CREATE INDEX idx_users_created_at ON users(created_at);
CREATE INDEX idx_users_email_verified ON users(email_verified_at) WHERE email_verified_at IS NULL;

4.2 api_keys - API Key

CREATE TABLE api_keys (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,

  name VARCHAR(100) NOT NULL,
  key_prefix VARCHAR(20) NOT NULL,  -- 展示/索引用(如 "if_live_abcd"
  key_hash VARCHAR(255) NOT NULL,   -- 推荐HMAC-SHA256(full_key, API_KEY_PEPPER)

  permissions JSONB NOT NULL DEFAULT '["compress"]',
  rate_limit INTEGER NOT NULL DEFAULT 100,
  is_active BOOLEAN NOT NULL DEFAULT true,

  last_used_at TIMESTAMPTZ,
  last_used_ip INET,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_api_keys_user_id ON api_keys(user_id);
CREATE UNIQUE INDEX idx_api_keys_prefix ON api_keys(key_prefix);
CREATE INDEX idx_api_keys_is_active ON api_keys(is_active);

4.3 email_verifications - 邮箱验证

CREATE TABLE email_verifications (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  token_hash VARCHAR(64) NOT NULL,  -- SHA256(token),不存明文
  expires_at TIMESTAMPTZ NOT NULL,
  verified_at TIMESTAMPTZ,
  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE UNIQUE INDEX idx_email_verifications_token ON email_verifications(token_hash);
CREATE INDEX idx_email_verifications_user_id ON email_verifications(user_id);
CREATE INDEX idx_email_verifications_expires ON email_verifications(expires_at) WHERE verified_at IS NULL;

4.4 password_resets - 密码重置

CREATE TABLE password_resets (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  token_hash VARCHAR(64) NOT NULL,  -- SHA256(token),不存明文
  expires_at TIMESTAMPTZ NOT NULL,
  used_at TIMESTAMPTZ,
  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE UNIQUE INDEX idx_password_resets_token ON password_resets(token_hash);
CREATE INDEX idx_password_resets_user_id ON password_resets(user_id);
CREATE INDEX idx_password_resets_expires ON password_resets(expires_at) WHERE used_at IS NULL;

4.5 plans - 套餐

CREATE TABLE plans (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  code VARCHAR(50) NOT NULL UNIQUE, -- 展示/运营用(如 "free", "pro_monthly"
  name VARCHAR(100) NOT NULL,
  description TEXT,

  -- Stripe 映射(对接 Checkout 时使用)
  stripe_product_id VARCHAR(200),
  stripe_price_id VARCHAR(200),

  currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
  amount_cents INTEGER NOT NULL DEFAULT 0,
  interval VARCHAR(20) NOT NULL DEFAULT 'monthly', -- 可后续改 ENUM

  included_units_per_period INTEGER NOT NULL,
  max_file_size_mb INTEGER NOT NULL,
  max_files_per_batch INTEGER NOT NULL,
  concurrency_limit INTEGER NOT NULL,
  retention_days INTEGER NOT NULL,

  features JSONB NOT NULL DEFAULT '{}'::jsonb,
  is_active BOOLEAN NOT NULL DEFAULT true,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_plans_is_active ON plans(is_active);

4.4 subscriptions - 订阅

CREATE TABLE subscriptions (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  plan_id UUID NOT NULL REFERENCES plans(id),

  status subscription_status NOT NULL DEFAULT 'incomplete',
  current_period_start TIMESTAMPTZ NOT NULL,
  current_period_end TIMESTAMPTZ NOT NULL,

  cancel_at_period_end BOOLEAN NOT NULL DEFAULT false,
  canceled_at TIMESTAMPTZ,

  provider VARCHAR(20) NOT NULL DEFAULT 'none', -- none/stripe
  provider_customer_id VARCHAR(200),
  provider_subscription_id VARCHAR(200),

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_subscriptions_user_id ON subscriptions(user_id);
CREATE INDEX idx_subscriptions_status ON subscriptions(status);

4.5 invoices - 发票/账单

CREATE TABLE invoices (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  subscription_id UUID REFERENCES subscriptions(id) ON DELETE SET NULL,

  invoice_number VARCHAR(50) NOT NULL UNIQUE,
  status invoice_status NOT NULL DEFAULT 'open',
  currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
  total_amount_cents INTEGER NOT NULL DEFAULT 0,

  period_start TIMESTAMPTZ,
  period_end TIMESTAMPTZ,

  provider VARCHAR(20) NOT NULL DEFAULT 'none',
  provider_invoice_id VARCHAR(200),
  hosted_invoice_url TEXT,
  pdf_url TEXT,

  due_at TIMESTAMPTZ,
  paid_at TIMESTAMPTZ,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_invoices_user_id ON invoices(user_id);
CREATE INDEX idx_invoices_status ON invoices(status);

4.6 payments - 支付记录

CREATE TABLE payments (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  invoice_id UUID REFERENCES invoices(id) ON DELETE SET NULL,

  provider VARCHAR(20) NOT NULL DEFAULT 'none',
  provider_payment_id VARCHAR(200),

  status payment_status NOT NULL DEFAULT 'pending',
  currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
  amount_cents INTEGER NOT NULL DEFAULT 0,
  paid_at TIMESTAMPTZ,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_payments_user_id ON payments(user_id);
CREATE INDEX idx_payments_status ON payments(status);

4.7 webhook_events - Webhook 事件(支付回调)

CREATE TABLE webhook_events (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  provider VARCHAR(20) NOT NULL,
  provider_event_id VARCHAR(200) NOT NULL,
  event_type VARCHAR(200) NOT NULL,
  payload JSONB NOT NULL,
  received_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  processed_at TIMESTAMPTZ,
  status VARCHAR(20) NOT NULL DEFAULT 'received', -- received/processed/failed
  error_message TEXT
);

CREATE UNIQUE INDEX idx_webhook_events_unique ON webhook_events(provider, provider_event_id);
CREATE INDEX idx_webhook_events_status ON webhook_events(status);

4.8 tasks - 压缩任务

CREATE TABLE tasks (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),

  user_id UUID REFERENCES users(id) ON DELETE SET NULL, -- 游客为空
  session_id VARCHAR(100),                              -- 游客会话
  api_key_id UUID REFERENCES api_keys(id) ON DELETE SET NULL, -- API 调用可记录

  source task_source NOT NULL DEFAULT 'web',
  status task_status NOT NULL DEFAULT 'pending',

  compression_level compression_level NOT NULL DEFAULT 'medium',
  output_format VARCHAR(10),         -- NULL 表示保持原格式
  max_width INTEGER,
  max_height INTEGER,
  preserve_metadata BOOLEAN NOT NULL DEFAULT false,

  total_files INTEGER NOT NULL DEFAULT 0,
  completed_files INTEGER NOT NULL DEFAULT 0,
  failed_files INTEGER NOT NULL DEFAULT 0,
  total_original_size BIGINT NOT NULL DEFAULT 0,
  total_compressed_size BIGINT NOT NULL DEFAULT 0,

  error_message TEXT,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  started_at TIMESTAMPTZ,
  completed_at TIMESTAMPTZ,

  -- 到期清理:匿名可默认 24h登录用户应由应用按套餐写入更长 retention
  expires_at TIMESTAMPTZ NOT NULL DEFAULT (NOW() + INTERVAL '24 hours')
);

CREATE INDEX idx_tasks_user_id ON tasks(user_id);
CREATE INDEX idx_tasks_session_id ON tasks(session_id);
CREATE INDEX idx_tasks_status ON tasks(status);
CREATE INDEX idx_tasks_created_at ON tasks(created_at);
CREATE INDEX idx_tasks_expires_at ON tasks(expires_at);

4.9 task_files - 任务文件

CREATE TABLE task_files (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  task_id UUID NOT NULL REFERENCES tasks(id) ON DELETE CASCADE,

  original_name VARCHAR(255) NOT NULL,
  original_format VARCHAR(10) NOT NULL,
  output_format VARCHAR(10) NOT NULL,

  original_size BIGINT NOT NULL,
  compressed_size BIGINT,
  saved_percent DECIMAL(6, 2),

  storage_path VARCHAR(500), -- S3 key 或本地路径
  status file_status NOT NULL DEFAULT 'pending',
  error_message TEXT,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  completed_at TIMESTAMPTZ
);

CREATE INDEX idx_task_files_task_id ON task_files(task_id);
CREATE INDEX idx_task_files_status ON task_files(status);

4.10 idempotency_keys - 幂等记录

CREATE TABLE idempotency_keys (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),

  user_id UUID REFERENCES users(id) ON DELETE CASCADE,
  api_key_id UUID REFERENCES api_keys(id) ON DELETE CASCADE,

  idempotency_key VARCHAR(128) NOT NULL,
  request_hash VARCHAR(64) NOT NULL,

  response_status INTEGER NOT NULL,
  response_body JSONB, -- JSON 接口可存;二进制接口建议存“元信息 + 对象指针”

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  expires_at TIMESTAMPTZ NOT NULL
);

CREATE UNIQUE INDEX idx_idempotency_user_key ON idempotency_keys(user_id, idempotency_key) WHERE user_id IS NOT NULL;
CREATE UNIQUE INDEX idx_idempotency_api_key_key ON idempotency_keys(api_key_id, idempotency_key) WHERE api_key_id IS NOT NULL;
CREATE INDEX idx_idempotency_expires_at ON idempotency_keys(expires_at);

4.11 usage_events - 用量账本(明细)

CREATE TABLE usage_events (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),

  user_id UUID REFERENCES users(id) ON DELETE SET NULL,
  api_key_id UUID REFERENCES api_keys(id) ON DELETE SET NULL,
  source task_source NOT NULL,

  task_id UUID REFERENCES tasks(id) ON DELETE SET NULL,
  task_file_id UUID REFERENCES task_files(id) ON DELETE SET NULL,

  units INTEGER NOT NULL DEFAULT 1,
  bytes_in BIGINT NOT NULL DEFAULT 0,
  bytes_out BIGINT NOT NULL DEFAULT 0,
  format_in VARCHAR(10),
  format_out VARCHAR(10),

  occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE UNIQUE INDEX idx_usage_events_task_file_unique ON usage_events(task_file_id) WHERE task_file_id IS NOT NULL;
CREATE INDEX idx_usage_events_user_time ON usage_events(user_id, occurred_at);
CREATE INDEX idx_usage_events_api_key_time ON usage_events(api_key_id, occurred_at);

4.12 usage_periods - 用量聚合(按订阅周期)

CREATE TABLE usage_periods (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  subscription_id UUID REFERENCES subscriptions(id) ON DELETE SET NULL,

  period_start TIMESTAMPTZ NOT NULL,
  period_end TIMESTAMPTZ NOT NULL,

  used_units INTEGER NOT NULL DEFAULT 0,
  bytes_in BIGINT NOT NULL DEFAULT 0,
  bytes_out BIGINT NOT NULL DEFAULT 0,

  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),

  UNIQUE(user_id, period_start, period_end)
);

CREATE INDEX idx_usage_periods_user_period ON usage_periods(user_id, period_start);

4.13 system_config - 系统配置

CREATE TABLE system_config (
  key VARCHAR(100) PRIMARY KEY,
  value JSONB NOT NULL,
  description TEXT,
  updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
  updated_by UUID REFERENCES users(id)
);

4.14 audit_logs - 审计日志

CREATE TABLE audit_logs (
  id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  user_id UUID REFERENCES users(id) ON DELETE SET NULL,
  action VARCHAR(50) NOT NULL,   -- login/compress/config_change/billing/...
  resource_type VARCHAR(50),
  resource_id UUID,
  details JSONB,
  ip_address INET,
  user_agent TEXT,
  created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);

CREATE INDEX idx_audit_logs_user_id ON audit_logs(user_id);
CREATE INDEX idx_audit_logs_action ON audit_logs(action);
CREATE INDEX idx_audit_logs_created_at ON audit_logs(created_at);

5. Redis 数据结构(建议)

5.1 会话(匿名/网站)

Key: session:{session_id}
Value: JSON { user_id, role, created_at, expires_at }
TTL: 7 days

5.2 限流计数

Key: rate_limit:{scope}:{id}:{minute}
Value: request_count
TTL: 60 seconds

5.2.1 匿名试用每日额度(硬限制)

Key: anon_quota:{session_id}:{yyyy-mm-dd}
Value: used_units
TTL: 48 hours

# yyyy-mm-dd自然日UTC+8次日 00:00 重置

# 必须:叠加 IP 维度,降低刷 session 的风险(两者任一超出都拒绝)
Key: anon_quota_ip:{ip}:{yyyy-mm-dd}
Value: used_units
TTL: 48 hours

5.3 队列Redis Streams

Stream: stream:compress_jobs
Group:  compress_workers
Message fields: { task_id, priority, created_at }

5.4 任务进度(可选)

PubSub:  pubsub:task:{task_id}
Message: JSON { progress, completed_files, current_file }

5.5 API Key 缓存(可选)

Key: api_key:{key_prefix}
Value: JSON { api_key_id, user_id, permissions, rate_limit, ... }
TTL: 5 minutes

6. 数据清理策略(必须)

  • 过期任务:按 tasks.expires_at 清理任务/文件/对象存储。
  • 幂等记录:按 idempotency_keys.expires_at 清理。
  • 邮箱验证 Token:按 email_verifications.expires_at 清理已过期且未验证的记录。
  • 密码重置 Token:按 password_resets.expires_at 清理已过期或已使用的记录。
  • Webhook 事件:保留 30~90 天(便于排查),过期清理或归档。
  • 用量账本usage_events 建议长期保留(对账),必要时做分区(按月/按季度)。

示例:

-- 清理过期任务
DELETE FROM tasks WHERE expires_at < NOW();

-- 清理幂等记录
DELETE FROM idempotency_keys WHERE expires_at < NOW();

-- 清理邮箱验证 Token保留已验证的清理过期未验证的
DELETE FROM email_verifications WHERE expires_at < NOW() AND verified_at IS NULL;

-- 清理密码重置 Token保留 7 天内的记录用于审计)
DELETE FROM password_resets WHERE expires_at < NOW() - INTERVAL '7 days';

-- 清理 Webhook 事件
DELETE FROM webhook_events WHERE received_at < NOW() - INTERVAL '90 days';

7. 初始化数据(建议)

7.1 默认套餐

INSERT INTO plans (code, name, stripe_price_id, currency, amount_cents, interval, included_units_per_period, max_file_size_mb, max_files_per_batch, concurrency_limit, retention_days, features)
VALUES
  ('free', 'Free', NULL, 'CNY', 0, 'monthly', 500, 5, 10, 2, 1, '{"api": false, "webhook": false}'),
  ('pro_monthly', 'Pro月付', 'price_xxx_pro_monthly', 'CNY', 1999, 'monthly', 10000, 20, 50, 8, 7, '{"api": true, "webhook": true}'),
  ('business_monthly', 'Business月付', 'price_xxx_business_monthly', 'CNY', 9999, 'monthly', 100000, 50, 200, 32, 30, '{"api": true, "webhook": true, "ip_allowlist": true}');

7.2 默认系统配置

INSERT INTO system_config (key, value, description) VALUES
('features', '{"registration_enabled": true, "api_key_enabled": true, "anonymous_upload_enabled": true, "email_verification_required": true}', '功能开关'),
('rate_limits', '{"anonymous_per_minute": 10, "anonymous_units_per_day": 10, "user_per_minute": 60, "api_key_per_minute": 100}', '速率限制默认值'),
('file_limits', '{"max_image_pixels": 40000000}', '图片安全限制(像素上限等)'),
('mail', '{"enabled": true, "provider": "custom", "from": "noreply@example.com", "from_name": "ImageForge"}', '邮件服务配置(密码加密存储)');