344 lines
14 KiB
PL/PgSQL
344 lines
14 KiB
PL/PgSQL
-- CarrotSkin PostgreSQL 数据库初始化脚本
|
||
-- 创建数据库(可选,如果已经创建可跳过)
|
||
--CREATE DATABASE carrotskin WITH ENCODING 'UTF8' LC_COLLATE 'C.UTF-8' LC_CTYPE 'C.UTF-8';
|
||
|
||
-- 用户表,支持积分系统和权限管理
|
||
CREATE TABLE "user" (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
username VARCHAR(255) NOT NULL DEFAULT '' UNIQUE,
|
||
password VARCHAR(255) NOT NULL DEFAULT '',
|
||
email VARCHAR(255) NOT NULL DEFAULT '' UNIQUE,
|
||
avatar VARCHAR(255) NOT NULL DEFAULT '',
|
||
points INTEGER NOT NULL DEFAULT 0,
|
||
role VARCHAR(50) NOT NULL DEFAULT 'user',
|
||
status SMALLINT NOT NULL DEFAULT 1,
|
||
last_login_at TIMESTAMP,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_user_role ON "user"(role);
|
||
CREATE INDEX idx_user_status ON "user"(status);
|
||
CREATE INDEX idx_user_points ON "user"(points DESC);
|
||
|
||
-- 用户表注释
|
||
COMMENT ON TABLE "user" IS '用户表';
|
||
COMMENT ON COLUMN "user".id IS '用户ID';
|
||
COMMENT ON COLUMN "user".username IS '用户名';
|
||
COMMENT ON COLUMN "user".password IS '密码哈希';
|
||
COMMENT ON COLUMN "user".email IS '邮箱地址';
|
||
COMMENT ON COLUMN "user".avatar IS '头像URL(存储在MinIO中)';
|
||
COMMENT ON COLUMN "user".points IS '用户积分';
|
||
COMMENT ON COLUMN "user".role IS '用户角色(user, admin等)';
|
||
COMMENT ON COLUMN "user".status IS '用户状态(1:正常, 0:禁用, -1:删除)';
|
||
COMMENT ON COLUMN "user".last_login_at IS '最后登录时间';
|
||
COMMENT ON COLUMN "user".created_at IS '创建时间';
|
||
COMMENT ON COLUMN "user".updated_at IS '更新时间';
|
||
|
||
-- 创建材质类型枚举
|
||
CREATE TYPE texture_type AS ENUM ('SKIN', 'CAPE');
|
||
|
||
-- 材质表,存储皮肤和披风
|
||
CREATE TABLE textures (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
uploader_id BIGINT NOT NULL,
|
||
name VARCHAR(100) NOT NULL DEFAULT '',
|
||
description TEXT,
|
||
type texture_type NOT NULL,
|
||
url VARCHAR(255) NOT NULL,
|
||
hash VARCHAR(64) NOT NULL UNIQUE,
|
||
size INTEGER NOT NULL DEFAULT 0,
|
||
is_public BOOLEAN NOT NULL DEFAULT FALSE,
|
||
download_count INTEGER NOT NULL DEFAULT 0,
|
||
favorite_count INTEGER NOT NULL DEFAULT 0,
|
||
is_slim BOOLEAN NOT NULL DEFAULT FALSE,
|
||
status SMALLINT NOT NULL DEFAULT 1,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT fk_textures_uploader FOREIGN KEY (uploader_id) REFERENCES "user"(id) ON DELETE CASCADE
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_textures_uploader_id ON textures(uploader_id);
|
||
CREATE INDEX idx_textures_public_type_status ON textures(is_public, type, status);
|
||
CREATE INDEX idx_textures_download_count ON textures(download_count DESC);
|
||
CREATE INDEX idx_textures_favorite_count ON textures(favorite_count DESC);
|
||
|
||
-- 材质表注释
|
||
COMMENT ON TABLE textures IS '皮肤与披风材质表';
|
||
COMMENT ON COLUMN textures.id IS '材质的唯一ID';
|
||
COMMENT ON COLUMN textures.uploader_id IS '上传者的用户ID';
|
||
COMMENT ON COLUMN textures.name IS '材质名称';
|
||
COMMENT ON COLUMN textures.description IS '材质描述';
|
||
COMMENT ON COLUMN textures.type IS '材质类型(皮肤或披风)';
|
||
COMMENT ON COLUMN textures.url IS '材质在MinIO中的永久访问URL';
|
||
COMMENT ON COLUMN textures.hash IS '材质文件的SHA-256哈希值,用于快速去重和校验';
|
||
COMMENT ON COLUMN textures.size IS '文件大小(字节)';
|
||
COMMENT ON COLUMN textures.is_public IS '是否公开到皮肤广场';
|
||
COMMENT ON COLUMN textures.download_count IS '下载次数';
|
||
COMMENT ON COLUMN textures.favorite_count IS '收藏次数';
|
||
COMMENT ON COLUMN textures.is_slim IS '是否为细手臂模型(Alex),默认为粗手臂模型(Steve)';
|
||
COMMENT ON COLUMN textures.status IS '状态(1:正常, 0:审核中, -1:已删除)';
|
||
COMMENT ON COLUMN textures.created_at IS '创建时间';
|
||
COMMENT ON COLUMN textures.updated_at IS '更新时间';
|
||
|
||
-- 用户材质收藏表
|
||
CREATE TABLE user_texture_favorites (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
user_id BIGINT NOT NULL,
|
||
texture_id BIGINT NOT NULL,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT uk_user_texture UNIQUE (user_id, texture_id),
|
||
CONSTRAINT fk_favorites_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_favorites_texture FOREIGN KEY (texture_id) REFERENCES textures(id) ON DELETE CASCADE
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_favorites_user_id ON user_texture_favorites(user_id);
|
||
CREATE INDEX idx_favorites_texture_id ON user_texture_favorites(texture_id);
|
||
CREATE INDEX idx_favorites_created_at ON user_texture_favorites(created_at);
|
||
|
||
-- 收藏表注释
|
||
COMMENT ON TABLE user_texture_favorites IS '用户材质收藏表';
|
||
COMMENT ON COLUMN user_texture_favorites.id IS '收藏记录的唯一ID';
|
||
COMMENT ON COLUMN user_texture_favorites.user_id IS '用户ID';
|
||
COMMENT ON COLUMN user_texture_favorites.texture_id IS '收藏的材质ID';
|
||
COMMENT ON COLUMN user_texture_favorites.created_at IS '收藏时间';
|
||
|
||
-- 用户角色信息表(Minecraft档案)
|
||
CREATE TABLE profiles (
|
||
uuid VARCHAR(36) PRIMARY KEY,
|
||
user_id BIGINT NOT NULL,
|
||
name VARCHAR(16) NOT NULL UNIQUE,
|
||
skin_id BIGINT,
|
||
cape_id BIGINT,
|
||
rsa_private_key TEXT NOT NULL,
|
||
is_active BOOLEAN NOT NULL DEFAULT TRUE,
|
||
last_used_at TIMESTAMP,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT fk_profiles_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_profiles_skin FOREIGN KEY (skin_id) REFERENCES textures(id) ON DELETE SET NULL,
|
||
CONSTRAINT fk_profiles_cape FOREIGN KEY (cape_id) REFERENCES textures(id) ON DELETE SET NULL
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_profiles_user_id ON profiles(user_id);
|
||
CREATE INDEX idx_profiles_active ON profiles(is_active);
|
||
|
||
-- 档案表注释
|
||
COMMENT ON TABLE profiles IS '用户角色信息表(Minecraft档案)';
|
||
COMMENT ON COLUMN profiles.uuid IS '角色的UUID,通常为Minecraft玩家的UUID';
|
||
COMMENT ON COLUMN profiles.user_id IS '关联的用户ID';
|
||
COMMENT ON COLUMN profiles.name IS '角色名(Minecraft游戏内名称)';
|
||
COMMENT ON COLUMN profiles.skin_id IS '当前使用的皮肤ID';
|
||
COMMENT ON COLUMN profiles.cape_id IS '当前使用的披风ID';
|
||
COMMENT ON COLUMN profiles.rsa_private_key IS '用于签名的RSA-2048私钥(PEM格式)';
|
||
COMMENT ON COLUMN profiles.is_active IS '是否为活跃档案';
|
||
COMMENT ON COLUMN profiles.last_used_at IS '最后使用时间';
|
||
COMMENT ON COLUMN profiles.created_at IS '创建时间';
|
||
COMMENT ON COLUMN profiles.updated_at IS '更新时间';
|
||
|
||
-- Casbin权限管理相关表
|
||
CREATE TABLE casbin_rule (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
ptype VARCHAR(100) NOT NULL,
|
||
v0 VARCHAR(100) NOT NULL DEFAULT '',
|
||
v1 VARCHAR(100) NOT NULL DEFAULT '',
|
||
v2 VARCHAR(100) NOT NULL DEFAULT '',
|
||
v3 VARCHAR(100) NOT NULL DEFAULT '',
|
||
v4 VARCHAR(100) NOT NULL DEFAULT '',
|
||
v5 VARCHAR(100) NOT NULL DEFAULT '',
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT uk_casbin_rule UNIQUE (ptype, v0, v1, v2, v3, v4, v5)
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_casbin_ptype ON casbin_rule(ptype);
|
||
CREATE INDEX idx_casbin_v0 ON casbin_rule(v0);
|
||
CREATE INDEX idx_casbin_v1 ON casbin_rule(v1);
|
||
|
||
-- Casbin表注释
|
||
COMMENT ON TABLE casbin_rule IS 'Casbin权限规则表';
|
||
COMMENT ON COLUMN casbin_rule.ptype IS '策略类型(p, g等)';
|
||
COMMENT ON COLUMN casbin_rule.v0 IS '主体(用户或角色)';
|
||
COMMENT ON COLUMN casbin_rule.v1 IS '资源对象';
|
||
COMMENT ON COLUMN casbin_rule.v2 IS '操作动作';
|
||
|
||
-- 创建变更类型枚举
|
||
CREATE TYPE point_change_type AS ENUM ('EARN', 'SPEND', 'ADMIN_ADJUST');
|
||
|
||
-- 用户积分变更记录表
|
||
CREATE TABLE user_point_logs (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
user_id BIGINT NOT NULL,
|
||
change_type point_change_type NOT NULL,
|
||
amount INTEGER NOT NULL,
|
||
balance_before INTEGER NOT NULL,
|
||
balance_after INTEGER NOT NULL,
|
||
reason VARCHAR(255) NOT NULL,
|
||
reference_type VARCHAR(50),
|
||
reference_id BIGINT,
|
||
operator_id BIGINT,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT fk_point_logs_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_point_logs_operator FOREIGN KEY (operator_id) REFERENCES "user"(id) ON DELETE SET NULL
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_point_logs_user_id ON user_point_logs(user_id);
|
||
CREATE INDEX idx_point_logs_created_at ON user_point_logs(created_at DESC);
|
||
CREATE INDEX idx_point_logs_change_type ON user_point_logs(change_type);
|
||
|
||
-- 积分日志表注释
|
||
COMMENT ON TABLE user_point_logs IS '用户积分变更记录表';
|
||
|
||
-- 创建配置类型枚举
|
||
CREATE TYPE config_type AS ENUM ('STRING', 'INTEGER', 'BOOLEAN', 'JSON');
|
||
|
||
-- 系统配置表
|
||
CREATE TABLE system_config (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
key VARCHAR(100) NOT NULL UNIQUE,
|
||
value TEXT NOT NULL,
|
||
description VARCHAR(255) NOT NULL DEFAULT '',
|
||
type config_type NOT NULL DEFAULT 'STRING',
|
||
is_public BOOLEAN NOT NULL DEFAULT FALSE,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_system_config_public ON system_config(is_public);
|
||
|
||
-- 系统配置表注释
|
||
COMMENT ON TABLE system_config IS '系统配置表';
|
||
|
||
-- 用户登录日志表
|
||
CREATE TABLE user_login_logs (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
user_id BIGINT NOT NULL,
|
||
ip_address INET NOT NULL,
|
||
user_agent TEXT,
|
||
login_method VARCHAR(50) NOT NULL DEFAULT 'PASSWORD',
|
||
is_success BOOLEAN NOT NULL,
|
||
failure_reason VARCHAR(255),
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT fk_login_logs_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_login_logs_user_id ON user_login_logs(user_id);
|
||
CREATE INDEX idx_login_logs_created_at ON user_login_logs(created_at DESC);
|
||
CREATE INDEX idx_login_logs_ip_address ON user_login_logs(ip_address);
|
||
CREATE INDEX idx_login_logs_success ON user_login_logs(is_success);
|
||
|
||
-- 登录日志表注释
|
||
COMMENT ON TABLE user_login_logs IS '用户登录日志表';
|
||
|
||
-- 审计日志表
|
||
CREATE TABLE audit_logs (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
user_id BIGINT,
|
||
action VARCHAR(100) NOT NULL,
|
||
resource_type VARCHAR(50) NOT NULL,
|
||
resource_id VARCHAR(50),
|
||
old_values JSONB,
|
||
new_values JSONB,
|
||
ip_address INET NOT NULL,
|
||
user_agent TEXT,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT fk_audit_logs_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE SET NULL
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_audit_logs_user_id ON audit_logs(user_id);
|
||
CREATE INDEX idx_audit_logs_created_at ON audit_logs(created_at DESC);
|
||
CREATE INDEX idx_audit_logs_action ON audit_logs(action);
|
||
CREATE INDEX idx_audit_logs_resource ON audit_logs(resource_type, resource_id);
|
||
|
||
-- 审计日志表注释
|
||
COMMENT ON TABLE audit_logs IS '审计日志表';
|
||
|
||
-- 材质下载记录表(用于统计和防刷)
|
||
CREATE TABLE texture_download_logs (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
texture_id BIGINT NOT NULL,
|
||
user_id BIGINT,
|
||
ip_address INET NOT NULL,
|
||
user_agent TEXT,
|
||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT fk_download_logs_texture FOREIGN KEY (texture_id) REFERENCES textures(id) ON DELETE CASCADE,
|
||
CONSTRAINT fk_download_logs_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE SET NULL
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX idx_download_logs_texture_id ON texture_download_logs(texture_id);
|
||
CREATE INDEX idx_download_logs_user_id ON texture_download_logs(user_id);
|
||
CREATE INDEX idx_download_logs_created_at ON texture_download_logs(created_at DESC);
|
||
CREATE INDEX idx_download_logs_ip_address ON texture_download_logs(ip_address);
|
||
|
||
-- 下载记录表注释
|
||
COMMENT ON TABLE texture_download_logs IS '材质下载记录表';
|
||
|
||
-- 创建更新时间触发器函数
|
||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||
RETURNS TRIGGER AS $$
|
||
BEGIN
|
||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||
RETURN NEW;
|
||
END;
|
||
$$ language 'plpgsql';
|
||
|
||
-- 为需要的表添加更新时间触发器
|
||
CREATE TRIGGER update_user_updated_at BEFORE UPDATE ON "user"
|
||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||
|
||
CREATE TRIGGER update_textures_updated_at BEFORE UPDATE ON textures
|
||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||
|
||
CREATE TRIGGER update_profiles_updated_at BEFORE UPDATE ON profiles
|
||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||
|
||
CREATE TRIGGER update_system_config_updated_at BEFORE UPDATE ON system_config
|
||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||
|
||
-- 插入默认的系统配置
|
||
INSERT INTO system_config (key, value, description, type, is_public) VALUES
|
||
('site_name', 'CarrotSkin', '网站名称', 'STRING', TRUE),
|
||
('site_description', '一个优秀的Minecraft皮肤站', '网站描述', 'STRING', TRUE),
|
||
('registration_enabled', 'true', '是否允许用户注册', 'BOOLEAN', TRUE),
|
||
('checkin_reward', '10', '签到奖励积分', 'INTEGER', TRUE),
|
||
('texture_download_reward', '1', '材质被下载奖励积分', 'INTEGER', FALSE),
|
||
('max_textures_per_user', '50', '每个用户最大材质数量', 'INTEGER', FALSE),
|
||
('max_profiles_per_user', '5', '每个用户最大角色数量', 'INTEGER', FALSE),
|
||
('default_avatar', 'https://carrotskin.com/assets/images/default-avatar.png', '默认头像', 'STRING', TRUE);
|
||
|
||
-- 插入默认的Casbin权限规则
|
||
INSERT INTO casbin_rule (ptype, v0, v1, v2) VALUES
|
||
('p', 'admin', '*', '*'),
|
||
('p', 'user', 'texture', 'create'),
|
||
('p', 'user', 'texture', 'read'),
|
||
('p', 'user', 'texture', 'update_own'),
|
||
('p', 'user', 'texture', 'delete_own'),
|
||
('p', 'user', 'profile', 'create'),
|
||
('p', 'user', 'profile', 'read'),
|
||
('p', 'user', 'profile', 'update_own'),
|
||
('p', 'user', 'profile', 'delete_own'),
|
||
('p', 'user', 'user', 'update_own'),
|
||
('g', 'admin', 'user', '');
|
||
|
||
-- 插入默认的管理员
|
||
INSERT INTO "user" (username, password, email, is_admin, created_at, updated_at) VALUES
|
||
('admin', '$2a$10$...', 'admin@example.com', TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);
|
||
|