## 🧪 API测试系统完善 - 创建完整的单元测试套件 (tests/unit_test.go) - 认证流程、CRUD操作、文件上传测试 - 中间件、错误处理、性能测试 - 创建集成测试套件 (tests/integration_test.go) - 业务流程、数据一致性、并发测试 - 创建综合API测试 (test_api_comprehensive.http) - 92个测试场景,覆盖所有API端点 - 更新Makefile添加测试命令 - test-unit, test-integration, test-api, test-cover, test-bench ## 🗄️ 生产环境数据库配置 - Docker Compose生产环境配置 (configs/docker/docker-compose.prod.yml) - PostgreSQL 16 + Redis 7 + Nginx + 监控栈 - 数据库初始化脚本 (configs/docker/init-db.sql) - 完整表结构、索引优化、触发器、视图 - 生产环境配置脚本 (scripts/production-db-setup.sh) - 自动化配置、连接池、备份策略、监控 ## 📚 API文档完善 - 完整的API文档 (docs/API_DOCUMENTATION.md) - 详细接口说明、请求响应示例 - 认证流程、错误处理、性能优化 - SDK支持、部署指南、安全考虑 - 包含cURL示例和Postman Collection支持 ## 📊 项目进度 - 总进度: 50.0% → 57.5% - 中优先级任务: 55% → 70% - 并行完成3个重要任务,显著提升项目完成度 ## 🎯 技术成果 - 测试覆盖率大幅提升,支持自动化测试 - 生产环境就绪,支持Docker部署 - 完整的API文档,便于前后端协作 - 性能优化和监控配置,确保生产稳定性
377 lines
13 KiB
PL/PgSQL
377 lines
13 KiB
PL/PgSQL
-- 生产环境数据库初始化脚本
|
|
-- 创建数据库和用户
|
|
|
|
-- 创建应用用户
|
|
CREATE USER IF NOT EXISTS photography_user WITH PASSWORD 'photography_user_2024';
|
|
|
|
-- 授予权限
|
|
GRANT ALL PRIVILEGES ON DATABASE photography TO photography_user;
|
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO photography_user;
|
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO photography_user;
|
|
|
|
-- 创建扩展
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
CREATE EXTENSION IF NOT EXISTS "pg_trgm";
|
|
CREATE EXTENSION IF NOT EXISTS "btree_gin";
|
|
|
|
-- 设置时区
|
|
SET timezone = 'Asia/Shanghai';
|
|
|
|
-- 创建基础表结构
|
|
-- 用户表
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
username VARCHAR(50) UNIQUE NOT NULL,
|
|
email VARCHAR(100) UNIQUE NOT NULL,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
avatar VARCHAR(255),
|
|
status INTEGER DEFAULT 1 CHECK (status IN (0, 1)),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 分类表
|
|
CREATE TABLE IF NOT EXISTS categories (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(100) NOT NULL,
|
|
description TEXT,
|
|
parent_id BIGINT REFERENCES categories(id) ON DELETE SET NULL,
|
|
sort_order INTEGER DEFAULT 0,
|
|
is_active INTEGER DEFAULT 1 CHECK (is_active IN (0, 1)),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 照片表
|
|
CREATE TABLE IF NOT EXISTS photos (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
title VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
file_path VARCHAR(500) NOT NULL,
|
|
thumbnail_path VARCHAR(500),
|
|
file_size BIGINT,
|
|
mime_type VARCHAR(100),
|
|
width INTEGER,
|
|
height INTEGER,
|
|
category_id BIGINT REFERENCES categories(id) ON DELETE SET NULL,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
status INTEGER DEFAULT 1 CHECK (status IN (0, 1)),
|
|
view_count INTEGER DEFAULT 0,
|
|
like_count INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 标签表
|
|
CREATE TABLE IF NOT EXISTS tags (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(50) UNIQUE NOT NULL,
|
|
color VARCHAR(7) DEFAULT '#000000',
|
|
description TEXT,
|
|
is_active INTEGER DEFAULT 1 CHECK (is_active IN (0, 1)),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 照片标签关联表
|
|
CREATE TABLE IF NOT EXISTS photo_tags (
|
|
photo_id BIGINT NOT NULL REFERENCES photos(id) ON DELETE CASCADE,
|
|
tag_id BIGINT NOT NULL REFERENCES tags(id) ON DELETE CASCADE,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (photo_id, tag_id)
|
|
);
|
|
|
|
-- 相册表
|
|
CREATE TABLE IF NOT EXISTS albums (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(100) NOT NULL,
|
|
description TEXT,
|
|
cover_photo_id BIGINT REFERENCES photos(id) ON DELETE SET NULL,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
is_public INTEGER DEFAULT 0 CHECK (is_public IN (0, 1)),
|
|
sort_order INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 相册照片关联表
|
|
CREATE TABLE IF NOT EXISTS album_photos (
|
|
album_id BIGINT NOT NULL REFERENCES albums(id) ON DELETE CASCADE,
|
|
photo_id BIGINT NOT NULL REFERENCES photos(id) ON DELETE CASCADE,
|
|
sort_order INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (album_id, photo_id)
|
|
);
|
|
|
|
-- 创建索引
|
|
-- 用户表索引
|
|
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
|
|
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
|
CREATE INDEX IF NOT EXISTS idx_users_status ON users(status);
|
|
CREATE INDEX IF NOT EXISTS idx_users_created_at ON users(created_at);
|
|
|
|
-- 分类表索引
|
|
CREATE INDEX IF NOT EXISTS idx_categories_name ON categories(name);
|
|
CREATE INDEX IF NOT EXISTS idx_categories_parent_id ON categories(parent_id);
|
|
CREATE INDEX IF NOT EXISTS idx_categories_is_active ON categories(is_active);
|
|
CREATE INDEX IF NOT EXISTS idx_categories_sort_order ON categories(sort_order);
|
|
|
|
-- 照片表索引
|
|
CREATE INDEX IF NOT EXISTS idx_photos_title ON photos(title);
|
|
CREATE INDEX IF NOT EXISTS idx_photos_category_id ON photos(category_id);
|
|
CREATE INDEX IF NOT EXISTS idx_photos_user_id ON photos(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_photos_status ON photos(status);
|
|
CREATE INDEX IF NOT EXISTS idx_photos_created_at ON photos(created_at);
|
|
CREATE INDEX IF NOT EXISTS idx_photos_view_count ON photos(view_count);
|
|
CREATE INDEX IF NOT EXISTS idx_photos_like_count ON photos(like_count);
|
|
|
|
-- 标签表索引
|
|
CREATE INDEX IF NOT EXISTS idx_tags_name ON tags(name);
|
|
CREATE INDEX IF NOT EXISTS idx_tags_is_active ON tags(is_active);
|
|
|
|
-- 照片标签关联表索引
|
|
CREATE INDEX IF NOT EXISTS idx_photo_tags_photo_id ON photo_tags(photo_id);
|
|
CREATE INDEX IF NOT EXISTS idx_photo_tags_tag_id ON photo_tags(tag_id);
|
|
|
|
-- 相册表索引
|
|
CREATE INDEX IF NOT EXISTS idx_albums_name ON albums(name);
|
|
CREATE INDEX IF NOT EXISTS idx_albums_user_id ON albums(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_albums_is_public ON albums(is_public);
|
|
CREATE INDEX IF NOT EXISTS idx_albums_created_at ON albums(created_at);
|
|
|
|
-- 相册照片关联表索引
|
|
CREATE INDEX IF NOT EXISTS idx_album_photos_album_id ON album_photos(album_id);
|
|
CREATE INDEX IF NOT EXISTS idx_album_photos_photo_id ON album_photos(photo_id);
|
|
CREATE INDEX IF NOT EXISTS idx_album_photos_sort_order ON album_photos(sort_order);
|
|
|
|
-- 全文搜索索引
|
|
CREATE INDEX IF NOT EXISTS idx_photos_title_gin ON photos USING gin(to_tsvector('simple', title));
|
|
CREATE INDEX IF NOT EXISTS idx_photos_description_gin ON photos USING gin(to_tsvector('simple', description));
|
|
CREATE INDEX IF NOT EXISTS idx_categories_name_gin ON categories USING gin(to_tsvector('simple', name));
|
|
|
|
-- 创建更新时间触发器函数
|
|
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_users_updated_at BEFORE UPDATE ON users
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_categories_updated_at BEFORE UPDATE ON categories
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_photos_updated_at BEFORE UPDATE ON photos
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_tags_updated_at BEFORE UPDATE ON tags
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_albums_updated_at BEFORE UPDATE ON albums
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- 插入默认数据
|
|
-- 管理员用户
|
|
INSERT INTO users (username, email, password_hash, status) VALUES
|
|
('admin', 'admin@photography.com', '$2a$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi', 1)
|
|
ON CONFLICT (username) DO NOTHING;
|
|
|
|
-- 默认分类
|
|
INSERT INTO categories (name, description, sort_order, is_active) VALUES
|
|
('风景', '自然风光和城市景观', 1, 1),
|
|
('人像', '人物摄影作品', 2, 1),
|
|
('建筑', '建筑物和结构摄影', 3, 1),
|
|
('街拍', '街头摄影和纪实', 4, 1),
|
|
('艺术', '艺术创作和抽象', 5, 1),
|
|
('宠物', '动物和宠物摄影', 6, 1),
|
|
('美食', '食物和饮品摄影', 7, 1),
|
|
('旅行', '旅行和文化记录', 8, 1),
|
|
('黑白', '黑白摄影作品', 9, 1)
|
|
ON CONFLICT (name) DO NOTHING;
|
|
|
|
-- 默认标签
|
|
INSERT INTO tags (name, color, description, is_active) VALUES
|
|
('精选', '#ff4444', '精选优质作品', 1),
|
|
('热门', '#ff8800', '热门推荐作品', 1),
|
|
('新作', '#00aa00', '最新发布作品', 1),
|
|
('经典', '#4444ff', '经典收藏作品', 1),
|
|
('创意', '#aa00aa', '创意独特作品', 1),
|
|
('唯美', '#ff6699', '唯美艺术作品', 1),
|
|
('纪实', '#666666', '纪实摄影作品', 1),
|
|
('商业', '#ffaa00', '商业摄影作品', 1)
|
|
ON CONFLICT (name) DO NOTHING;
|
|
|
|
-- 创建视图
|
|
-- 照片详情视图
|
|
CREATE OR REPLACE VIEW photo_details AS
|
|
SELECT
|
|
p.id,
|
|
p.title,
|
|
p.description,
|
|
p.file_path,
|
|
p.thumbnail_path,
|
|
p.file_size,
|
|
p.mime_type,
|
|
p.width,
|
|
p.height,
|
|
p.status,
|
|
p.view_count,
|
|
p.like_count,
|
|
p.created_at,
|
|
p.updated_at,
|
|
u.username as photographer,
|
|
c.name as category_name,
|
|
COALESCE(
|
|
json_agg(
|
|
json_build_object(
|
|
'id', t.id,
|
|
'name', t.name,
|
|
'color', t.color
|
|
)
|
|
) FILTER (WHERE t.id IS NOT NULL),
|
|
'[]'
|
|
) as tags
|
|
FROM photos p
|
|
LEFT JOIN users u ON p.user_id = u.id
|
|
LEFT JOIN categories c ON p.category_id = c.id
|
|
LEFT JOIN photo_tags pt ON p.id = pt.photo_id
|
|
LEFT JOIN tags t ON pt.tag_id = t.id
|
|
WHERE p.status = 1
|
|
GROUP BY p.id, u.username, c.name;
|
|
|
|
-- 分类统计视图
|
|
CREATE OR REPLACE VIEW category_stats AS
|
|
SELECT
|
|
c.id,
|
|
c.name,
|
|
c.description,
|
|
c.parent_id,
|
|
c.sort_order,
|
|
c.is_active,
|
|
c.created_at,
|
|
c.updated_at,
|
|
COUNT(p.id) as photo_count,
|
|
COALESCE(MAX(p.created_at), c.created_at) as last_photo_date
|
|
FROM categories c
|
|
LEFT JOIN photos p ON c.id = p.category_id AND p.status = 1
|
|
WHERE c.is_active = 1
|
|
GROUP BY c.id, c.name, c.description, c.parent_id, c.sort_order, c.is_active, c.created_at, c.updated_at;
|
|
|
|
-- 用户统计视图
|
|
CREATE OR REPLACE VIEW user_stats AS
|
|
SELECT
|
|
u.id,
|
|
u.username,
|
|
u.email,
|
|
u.avatar,
|
|
u.status,
|
|
u.created_at,
|
|
u.updated_at,
|
|
COUNT(p.id) as photo_count,
|
|
COALESCE(SUM(p.view_count), 0) as total_views,
|
|
COALESCE(SUM(p.like_count), 0) as total_likes,
|
|
COALESCE(MAX(p.created_at), u.created_at) as last_upload_date
|
|
FROM users u
|
|
LEFT JOIN photos p ON u.id = p.user_id AND p.status = 1
|
|
WHERE u.status = 1
|
|
GROUP BY u.id, u.username, u.email, u.avatar, u.status, u.created_at, u.updated_at;
|
|
|
|
-- 创建函数
|
|
-- 更新照片查看次数
|
|
CREATE OR REPLACE FUNCTION increment_photo_view_count(photo_id_param BIGINT)
|
|
RETURNS VOID AS $$
|
|
BEGIN
|
|
UPDATE photos
|
|
SET view_count = view_count + 1
|
|
WHERE id = photo_id_param AND status = 1;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 更新照片点赞次数
|
|
CREATE OR REPLACE FUNCTION increment_photo_like_count(photo_id_param BIGINT)
|
|
RETURNS VOID AS $$
|
|
BEGIN
|
|
UPDATE photos
|
|
SET like_count = like_count + 1
|
|
WHERE id = photo_id_param AND status = 1;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 获取分类树
|
|
CREATE OR REPLACE FUNCTION get_category_tree()
|
|
RETURNS TABLE (
|
|
id BIGINT,
|
|
name VARCHAR(100),
|
|
description TEXT,
|
|
parent_id BIGINT,
|
|
level INTEGER,
|
|
path TEXT,
|
|
photo_count BIGINT
|
|
) AS $$
|
|
WITH RECURSIVE category_tree AS (
|
|
-- 根节点
|
|
SELECT
|
|
c.id,
|
|
c.name,
|
|
c.description,
|
|
c.parent_id,
|
|
0 as level,
|
|
c.name::TEXT as path,
|
|
COUNT(p.id) as photo_count
|
|
FROM categories c
|
|
LEFT JOIN photos p ON c.id = p.category_id AND p.status = 1
|
|
WHERE c.parent_id IS NULL AND c.is_active = 1
|
|
GROUP BY c.id, c.name, c.description, c.parent_id
|
|
|
|
UNION ALL
|
|
|
|
-- 子节点
|
|
SELECT
|
|
c.id,
|
|
c.name,
|
|
c.description,
|
|
c.parent_id,
|
|
ct.level + 1,
|
|
ct.path || ' > ' || c.name,
|
|
COUNT(p.id) as photo_count
|
|
FROM categories c
|
|
JOIN category_tree ct ON c.parent_id = ct.id
|
|
LEFT JOIN photos p ON c.id = p.category_id AND p.status = 1
|
|
WHERE c.is_active = 1
|
|
GROUP BY c.id, c.name, c.description, c.parent_id, ct.level, ct.path
|
|
)
|
|
SELECT * FROM category_tree ORDER BY path;
|
|
$$ LANGUAGE sql;
|
|
|
|
-- 数据库优化设置
|
|
-- 设置连接池参数
|
|
ALTER SYSTEM SET max_connections = 100;
|
|
ALTER SYSTEM SET shared_buffers = '256MB';
|
|
ALTER SYSTEM SET effective_cache_size = '1GB';
|
|
ALTER SYSTEM SET maintenance_work_mem = '64MB';
|
|
ALTER SYSTEM SET checkpoint_completion_target = 0.9;
|
|
ALTER SYSTEM SET wal_buffers = '16MB';
|
|
ALTER SYSTEM SET default_statistics_target = 100;
|
|
ALTER SYSTEM SET random_page_cost = 1.1;
|
|
ALTER SYSTEM SET effective_io_concurrency = 200;
|
|
|
|
-- 重新加载配置
|
|
SELECT pg_reload_conf();
|
|
|
|
-- 输出初始化完成信息
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE '生产环境数据库初始化完成';
|
|
RAISE NOTICE '数据库名称: photography';
|
|
RAISE NOTICE '应用用户: photography_user';
|
|
RAISE NOTICE '表创建完成: users, categories, photos, tags, photo_tags, albums, album_photos';
|
|
RAISE NOTICE '索引创建完成: 性能优化索引已建立';
|
|
RAISE NOTICE '触发器创建完成: 自动更新时间戳';
|
|
RAISE NOTICE '视图创建完成: photo_details, category_stats, user_stats';
|
|
RAISE NOTICE '函数创建完成: 工具函数已部署';
|
|
RAISE NOTICE '默认数据插入完成: 管理员用户、基础分类、默认标签';
|
|
END $$; |