AWS-Panel/db_schema.md
2025-12-10 12:02:17 +08:00

359 lines
15 KiB
Markdown
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.

# aws-ec2-panel 数据库设计
本文档描述了 **aws_ec2_panel** 项目的完整 MySQL 数据库结构包含多租户、用户管理、AWS 凭证、EC2 实例、任务中心与审计日志等表结构。
---
## 1. 创建数据库
```sql
CREATE DATABASE IF NOT EXISTS aws_ec2_panel
DEFAULT CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
USE aws_ec2_panel;
2. 角色表roles
CREATE TABLE roles (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '角色主键',
name VARCHAR(64) NOT NULL COMMENT '角色名,如 ADMIN / CUSTOMER_ADMIN / CUSTOMER_USER',
description VARCHAR(255) DEFAULT NULL COMMENT '角色说明',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
UNIQUE KEY uniq_role_name (name)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='角色表';
3. 客户 / 租户表customers
CREATE TABLE customers (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '客户主键',
name VARCHAR(128) NOT NULL COMMENT '客户/租户名称,展示用',
contact_email VARCHAR(128) DEFAULT NULL COMMENT '联系邮箱',
is_active TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否启用 1=启用 0=禁用',
quota_instances INT UNSIGNED DEFAULT NULL COMMENT '实例数量配额NULL 表示不限制',
notes VARCHAR(255) DEFAULT NULL COMMENT '备注',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
UNIQUE KEY uniq_customer_name (name)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='客户/租户表';
4. 用户表users
CREATE TABLE users (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '用户主键',
username VARCHAR(64) NOT NULL COMMENT '登录用户名',
email VARCHAR(128) DEFAULT NULL COMMENT '邮箱',
password_hash VARCHAR(255) NOT NULL COMMENT '密码哈希',
role_id BIGINT UNSIGNED NOT NULL COMMENT '角色IDFK到roles',
customer_id BIGINT UNSIGNED DEFAULT NULL COMMENT '归属客户ID平台管理员可为空',
is_active TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否启用 1=启用 0=禁用',
last_login_at DATETIME DEFAULT NULL COMMENT '最近登录时间',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
CONSTRAINT fk_users_roles FOREIGN KEY (role_id)
REFERENCES roles(id)
ON DELETE RESTRICT
ON UPDATE CASCADE,
CONSTRAINT fk_users_customers FOREIGN KEY (customer_id)
REFERENCES customers(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
UNIQUE KEY uniq_username (username),
UNIQUE KEY uniq_email (email),
KEY idx_users_role (role_id),
KEY idx_users_customer (customer_id)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='用户表';
5. AWS 凭证表aws_credentials
CREATE TABLE aws_credentials (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT 'AWS 凭证主键',
name VARCHAR(128) NOT NULL COMMENT '凭证名称,控制台展示用',
account_id VARCHAR(32) NOT NULL COMMENT 'AWS Account ID (12位)',
credential_type ENUM('ACCESS_KEY', 'ASSUME_ROLE') NOT NULL DEFAULT 'ACCESS_KEY' COMMENT '凭证类型',
access_key_id VARCHAR(128) DEFAULT NULL COMMENT 'ACCESS_KEY_IDACCESS_KEY 时必填',
secret_access_key VARCHAR(256) DEFAULT NULL COMMENT 'SECRET_ACCESS_KEYACCESS_KEY 时必填',
role_arn VARCHAR(256) DEFAULT NULL COMMENT 'ASSUME_ROLE 模式下的 RoleArn',
external_id VARCHAR(128) DEFAULT NULL COMMENT 'ASSUME_ROLE 模式下使用的 ExternalId',
default_region VARCHAR(32) NOT NULL DEFAULT 'ap-northeast-1' COMMENT '默认 Region',
is_active TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否启用',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
UNIQUE KEY uniq_credential_account_name (account_id, name),
KEY idx_credential_account (account_id),
KEY idx_credential_active (is_active)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='AWS 凭证表';
6. 客户 ↔ 凭证映射表customer_credentials
CREATE TABLE customer_credentials (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '映射主键',
customer_id BIGINT UNSIGNED NOT NULL COMMENT '客户ID',
credential_id BIGINT UNSIGNED NOT NULL COMMENT 'AWS 凭证ID',
is_allowed TINYINT(1) NOT NULL DEFAULT 1 COMMENT '是否允许该客户使用此凭证',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
CONSTRAINT fk_cc_customer FOREIGN KEY (customer_id)
REFERENCES customers(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT fk_cc_credential FOREIGN KEY (credential_id)
REFERENCES aws_credentials(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
UNIQUE KEY uniq_customer_credential (customer_id, credential_id),
KEY idx_cc_customer (customer_id),
KEY idx_cc_credential (credential_id)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='客户与AWS凭证授权映射表';
7. 实例表instances
CREATE TABLE instances (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '实例主键',
customer_id BIGINT UNSIGNED NOT NULL COMMENT '归属客户ID',
credential_id BIGINT UNSIGNED DEFAULT NULL COMMENT '来自哪条AWS凭证可为空',
account_id VARCHAR(32) NOT NULL COMMENT 'AWS Account ID',
region VARCHAR(32) NOT NULL COMMENT '区域,如 ap-northeast-1',
az VARCHAR(32) DEFAULT NULL COMMENT '可用区,如 ap-northeast-1a',
instance_id VARCHAR(32) NOT NULL COMMENT 'AWS EC2 InstanceId如 i-xxxx',
name_tag VARCHAR(255) DEFAULT NULL COMMENT 'Name 标签',
instance_type VARCHAR(64) NOT NULL COMMENT '实例规格,如 t3.micro',
ami_id VARCHAR(64) DEFAULT NULL COMMENT 'AMI ID如 ami-xxxx',
key_name VARCHAR(128) DEFAULT NULL COMMENT '密钥对名称',
public_ip VARCHAR(45) DEFAULT NULL COMMENT '公网IP',
private_ip VARCHAR(45) DEFAULT NULL COMMENT '私网IP',
status ENUM(
'PENDING',
'RUNNING',
'STOPPING',
'STOPPED',
'SHUTTING_DOWN',
'TERMINATED',
'UNKNOWN'
) NOT NULL DEFAULT 'UNKNOWN' COMMENT '当前观测状态',
desired_status ENUM('RUNNING','STOPPED','TERMINATED') DEFAULT NULL COMMENT '用户期望状态',
security_groups JSON DEFAULT NULL COMMENT '安全组列表sg-xxx 数组',
subnet_id VARCHAR(64) DEFAULT NULL COMMENT '子网ID',
vpc_id VARCHAR(64) DEFAULT NULL COMMENT 'VPC ID',
launched_at DATETIME DEFAULT NULL COMMENT '实例启动时间',
terminated_at DATETIME DEFAULT NULL COMMENT '实例终止时间',
last_sync DATETIME DEFAULT NULL COMMENT '最近同步时间',
last_cloud_state JSON DEFAULT NULL COMMENT '上次同步时的云端原始信息(部分)',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
CONSTRAINT fk_instances_customer FOREIGN KEY (customer_id)
REFERENCES customers(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT fk_instances_credential FOREIGN KEY (credential_id)
REFERENCES aws_credentials(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
UNIQUE KEY uniq_instance_cloud (account_id, region, instance_id),
KEY idx_instances_customer (customer_id),
KEY idx_instances_status (status),
KEY idx_instances_region (region),
KEY idx_instances_last_sync (last_sync)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='AWS EC2 实例表';
8. 任务主表jobs
CREATE TABLE jobs (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '任务主键',
job_uuid CHAR(32) NOT NULL COMMENT '任务UUID对外查询用',
job_type ENUM(
'SYNC_INSTANCES',
'START_INSTANCES',
'STOP_INSTANCES',
'REBOOT_INSTANCES',
'TERMINATE_INSTANCES',
'CREATE_INSTANCES'
) NOT NULL COMMENT '任务类型',
status ENUM('PENDING','RUNNING','SUCCESS','FAILED') NOT NULL DEFAULT 'PENDING' COMMENT '任务状态',
progress TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT '进度 0~100',
total_count INT UNSIGNED DEFAULT 0 COMMENT '总数量',
success_count INT UNSIGNED DEFAULT 0 COMMENT '成功数量',
fail_count INT UNSIGNED DEFAULT 0 COMMENT '失败数量',
skipped_count INT UNSIGNED DEFAULT 0 COMMENT '跳过数量',
payload JSON DEFAULT NULL COMMENT '任务参数,如实例列表、过滤条件',
error_message VARCHAR(512) DEFAULT NULL COMMENT '任务层面错误信息摘要',
created_by_user_id BIGINT UNSIGNED DEFAULT NULL COMMENT '创建该任务的用户ID',
created_for_customer BIGINT UNSIGNED DEFAULT NULL COMMENT '面向的客户ID通常等于用户 customer_id',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
started_at DATETIME DEFAULT NULL COMMENT '开始时间',
finished_at DATETIME DEFAULT NULL COMMENT '结束时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
CONSTRAINT fk_jobs_user FOREIGN KEY (created_by_user_id)
REFERENCES users(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
CONSTRAINT fk_jobs_customer FOREIGN KEY (created_for_customer)
REFERENCES customers(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
UNIQUE KEY uniq_job_uuid (job_uuid),
KEY idx_jobs_type (job_type),
KEY idx_jobs_status (status),
KEY idx_jobs_created_at (created_at)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='批量任务主表';
9. 任务子表job_items
CREATE TABLE job_items (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '任务子项主键',
job_id BIGINT UNSIGNED NOT NULL COMMENT '任务ID',
resource_type ENUM('INSTANCE','OTHER') NOT NULL DEFAULT 'INSTANCE' COMMENT '资源类型',
resource_id BIGINT UNSIGNED DEFAULT NULL COMMENT '资源主键ID如实例ID',
account_id VARCHAR(32) DEFAULT NULL COMMENT 'AWS Account ID冗余便于查询',
region VARCHAR(32) DEFAULT NULL COMMENT 'Region冗余便于查询',
instance_id VARCHAR(32) DEFAULT NULL COMMENT 'InstanceId冗余便于查询',
action ENUM('CREATE','START','STOP','REBOOT','TERMINATE','SYNC') NOT NULL COMMENT '对子资源的动作',
status ENUM('PENDING','RUNNING','SUCCESS','FAILED','SKIPPED') NOT NULL DEFAULT 'PENDING' COMMENT '子项状态',
error_message VARCHAR(512) DEFAULT NULL COMMENT '错误信息',
extra JSON DEFAULT NULL COMMENT '额外信息如AWS原始返回',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
CONSTRAINT fk_job_items_job FOREIGN KEY (job_id)
REFERENCES jobs(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT fk_job_items_instance FOREIGN KEY (resource_id)
REFERENCES instances(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
KEY idx_job_items_job (job_id),
KEY idx_job_items_instance (resource_id),
KEY idx_job_items_status (status)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='批量任务子项表';
10. 审计日志表audit_logs
CREATE TABLE audit_logs (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '审计日志主键',
user_id BIGINT UNSIGNED DEFAULT NULL COMMENT '操作用户ID',
customer_id BIGINT UNSIGNED DEFAULT NULL COMMENT '客户ID若有',
action ENUM(
'LOGIN',
'LOGOUT',
'INSTANCE_CREATE',
'INSTANCE_START',
'INSTANCE_STOP',
'INSTANCE_REBOOT',
'INSTANCE_TERMINATE',
'INSTANCE_SYNC',
'CREDENTIAL_CREATE',
'CREDENTIAL_UPDATE',
'CREDENTIAL_DELETE',
'CUSTOMER_CREATE',
'CUSTOMER_UPDATE',
'CUSTOMER_DELETE',
'USER_CREATE',
'USER_UPDATE',
'USER_DELETE',
'OTHER'
) NOT NULL COMMENT '动作类型',
resource_type ENUM('USER','CUSTOMER','AWS_CREDENTIAL','INSTANCE','JOB','OTHER') NOT NULL COMMENT '资源类型',
resource_id BIGINT UNSIGNED DEFAULT NULL COMMENT '资源ID可空如登录无具体资源',
description VARCHAR(512) DEFAULT NULL COMMENT '简要描述,便于阅读',
payload JSON DEFAULT NULL COMMENT '附加信息,如请求参数、旧值/新值等',
ip_address VARCHAR(45) DEFAULT NULL COMMENT '操作来源 IP',
user_agent VARCHAR(255) DEFAULT NULL COMMENT 'User-Agent',
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
CONSTRAINT fk_audit_user FOREIGN KEY (user_id)
REFERENCES users(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
CONSTRAINT fk_audit_customer FOREIGN KEY (customer_id)
REFERENCES customers(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
KEY idx_audit_customer (customer_id),
KEY idx_audit_action (action),
KEY idx_audit_created_at (created_at),
KEY idx_audit_resource (resource_type, resource_id)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='审计日志表';
11. 全局设置表settings
CREATE TABLE settings (
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT COMMENT '主键',
k VARCHAR(128) NOT NULL COMMENT '配置键',
v TEXT DEFAULT NULL COMMENT '配置值建议存JSON或简单字符串',
description VARCHAR(255) DEFAULT NULL COMMENT '配置说明',
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
UNIQUE KEY uniq_settings_key (k)
) ENGINE=InnoDB
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_unicode_ci
COMMENT='全局配置KV表';
ALTER TABLE instances ADD COLUMN os_name VARCHAR(128);