Initial commit: Material Texture API service
- Go + Gin + GORM + PostgreSQL backend - RESTful API for material management - Docker deployment support - Database partitioning for billion-scale data - API documentation 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
37
migrations/001_init.sql
Normal file
37
migrations/001_init.sql
Normal file
@@ -0,0 +1,37 @@
|
||||
-- 材质管理系统初始化脚本
|
||||
-- 此脚本由GORM AutoMigrate自动执行,仅作参考
|
||||
|
||||
-- 材质表
|
||||
CREATE TABLE IF NOT EXISTS materials (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
diffuse_r FLOAT NOT NULL DEFAULT 0,
|
||||
diffuse_g FLOAT NOT NULL DEFAULT 0,
|
||||
diffuse_b FLOAT NOT NULL DEFAULT 0,
|
||||
alpha FLOAT NOT NULL DEFAULT 1,
|
||||
shininess FLOAT NOT NULL DEFAULT 0,
|
||||
specular_r FLOAT NOT NULL DEFAULT 0,
|
||||
specular_g FLOAT NOT NULL DEFAULT 0,
|
||||
specular_b FLOAT NOT NULL DEFAULT 0,
|
||||
ambient_r FLOAT NOT NULL DEFAULT 0,
|
||||
ambient_g FLOAT NOT NULL DEFAULT 0,
|
||||
ambient_b FLOAT NOT NULL DEFAULT 0,
|
||||
metallic FLOAT NOT NULL DEFAULT 0,
|
||||
roughness FLOAT NOT NULL DEFAULT 0.5,
|
||||
reflectance FLOAT NOT NULL DEFAULT 0.5,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- 材质绑定表
|
||||
CREATE TABLE IF NOT EXISTS material_bindings (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
material_id BIGINT NOT NULL REFERENCES materials(id) ON DELETE CASCADE,
|
||||
group_id VARCHAR(255) NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- 索引
|
||||
CREATE INDEX IF NOT EXISTS idx_bindings_material_id ON material_bindings(material_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_bindings_group_id ON material_bindings(group_id);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS idx_unique_material_group ON material_bindings(material_id, group_id);
|
||||
113
migrations/002_partition_bindings.sql
Normal file
113
migrations/002_partition_bindings.sql
Normal file
@@ -0,0 +1,113 @@
|
||||
-- ============================================
|
||||
-- Migration: 002_partition_bindings.sql
|
||||
-- Purpose: 将 material_bindings 表改为 HASH 分区表
|
||||
-- 支持亿级数据规模
|
||||
-- ============================================
|
||||
|
||||
-- 注意: 此迁移需要在维护窗口执行,会有短暂锁表
|
||||
-- 预估执行时间: 取决于现有数据量
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- 1. 创建新的分区表
|
||||
CREATE TABLE material_bindings_new (
|
||||
id BIGSERIAL,
|
||||
material_id BIGINT NOT NULL,
|
||||
group_id VARCHAR(255) NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (material_id, id)
|
||||
) PARTITION BY HASH (material_id);
|
||||
|
||||
-- 2. 创建 16 个分区 (每个分区预计容纳 600-1000 万行)
|
||||
CREATE TABLE material_bindings_p0 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 0);
|
||||
CREATE TABLE material_bindings_p1 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 1);
|
||||
CREATE TABLE material_bindings_p2 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 2);
|
||||
CREATE TABLE material_bindings_p3 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 3);
|
||||
CREATE TABLE material_bindings_p4 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 4);
|
||||
CREATE TABLE material_bindings_p5 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 5);
|
||||
CREATE TABLE material_bindings_p6 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 6);
|
||||
CREATE TABLE material_bindings_p7 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 7);
|
||||
CREATE TABLE material_bindings_p8 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 8);
|
||||
CREATE TABLE material_bindings_p9 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 9);
|
||||
CREATE TABLE material_bindings_p10 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 10);
|
||||
CREATE TABLE material_bindings_p11 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 11);
|
||||
CREATE TABLE material_bindings_p12 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 12);
|
||||
CREATE TABLE material_bindings_p13 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 13);
|
||||
CREATE TABLE material_bindings_p14 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 14);
|
||||
CREATE TABLE material_bindings_p15 PARTITION OF material_bindings_new
|
||||
FOR VALUES WITH (MODULUS 16, REMAINDER 15);
|
||||
|
||||
-- 3. 为每个分区创建 group_id 索引 (用于按 group 查询)
|
||||
CREATE INDEX idx_bindings_p0_group ON material_bindings_p0(group_id);
|
||||
CREATE INDEX idx_bindings_p1_group ON material_bindings_p1(group_id);
|
||||
CREATE INDEX idx_bindings_p2_group ON material_bindings_p2(group_id);
|
||||
CREATE INDEX idx_bindings_p3_group ON material_bindings_p3(group_id);
|
||||
CREATE INDEX idx_bindings_p4_group ON material_bindings_p4(group_id);
|
||||
CREATE INDEX idx_bindings_p5_group ON material_bindings_p5(group_id);
|
||||
CREATE INDEX idx_bindings_p6_group ON material_bindings_p6(group_id);
|
||||
CREATE INDEX idx_bindings_p7_group ON material_bindings_p7(group_id);
|
||||
CREATE INDEX idx_bindings_p8_group ON material_bindings_p8(group_id);
|
||||
CREATE INDEX idx_bindings_p9_group ON material_bindings_p9(group_id);
|
||||
CREATE INDEX idx_bindings_p10_group ON material_bindings_p10(group_id);
|
||||
CREATE INDEX idx_bindings_p11_group ON material_bindings_p11(group_id);
|
||||
CREATE INDEX idx_bindings_p12_group ON material_bindings_p12(group_id);
|
||||
CREATE INDEX idx_bindings_p13_group ON material_bindings_p13(group_id);
|
||||
CREATE INDEX idx_bindings_p14_group ON material_bindings_p14(group_id);
|
||||
CREATE INDEX idx_bindings_p15_group ON material_bindings_p15(group_id);
|
||||
|
||||
-- 4. 为每个分区创建唯一约束 (防止重复绑定)
|
||||
CREATE UNIQUE INDEX idx_bindings_p0_unique ON material_bindings_p0(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p1_unique ON material_bindings_p1(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p2_unique ON material_bindings_p2(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p3_unique ON material_bindings_p3(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p4_unique ON material_bindings_p4(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p5_unique ON material_bindings_p5(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p6_unique ON material_bindings_p6(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p7_unique ON material_bindings_p7(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p8_unique ON material_bindings_p8(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p9_unique ON material_bindings_p9(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p10_unique ON material_bindings_p10(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p11_unique ON material_bindings_p11(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p12_unique ON material_bindings_p12(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p13_unique ON material_bindings_p13(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p14_unique ON material_bindings_p14(material_id, group_id);
|
||||
CREATE UNIQUE INDEX idx_bindings_p15_unique ON material_bindings_p15(material_id, group_id);
|
||||
|
||||
-- 5. 迁移现有数据 (如果表已存在)
|
||||
-- 注意: 如果数据量大,建议分批迁移
|
||||
INSERT INTO material_bindings_new (id, material_id, group_id, created_at)
|
||||
SELECT id, material_id, group_id, created_at
|
||||
FROM material_bindings
|
||||
ON CONFLICT DO NOTHING;
|
||||
|
||||
-- 6. 切换表名
|
||||
ALTER TABLE material_bindings RENAME TO material_bindings_old;
|
||||
ALTER TABLE material_bindings_new RENAME TO material_bindings;
|
||||
|
||||
-- 7. 重置序列 (确保新插入的 ID 不冲突)
|
||||
SELECT setval('material_bindings_new_id_seq', COALESCE((SELECT MAX(id) FROM material_bindings), 0) + 1, false);
|
||||
|
||||
COMMIT;
|
||||
|
||||
-- ============================================
|
||||
-- 回滚脚本 (如需回滚,手动执行)
|
||||
-- ============================================
|
||||
-- BEGIN;
|
||||
-- DROP TABLE IF EXISTS material_bindings CASCADE;
|
||||
-- ALTER TABLE material_bindings_old RENAME TO material_bindings;
|
||||
-- COMMIT;
|
||||
26
migrations/003_add_indexes.sql
Normal file
26
migrations/003_add_indexes.sql
Normal file
@@ -0,0 +1,26 @@
|
||||
-- ============================================
|
||||
-- Migration: 003_add_indexes.sql
|
||||
-- Purpose: 添加性能优化索引
|
||||
-- ============================================
|
||||
|
||||
-- 1. 启用 pg_trgm 扩展 (支持模糊搜索索引)
|
||||
CREATE EXTENSION IF NOT EXISTS pg_trgm;
|
||||
|
||||
-- 2. 材质名称模糊搜索索引 (GIN 索引,支持 ILIKE '%keyword%')
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_materials_name_trgm
|
||||
ON materials USING gin (name gin_trgm_ops);
|
||||
|
||||
-- 3. 材质创建时间索引 (用于排序)
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_materials_created_at
|
||||
ON materials(created_at DESC);
|
||||
|
||||
-- 4. 材质更新时间索引
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_materials_updated_at
|
||||
ON materials(updated_at DESC);
|
||||
|
||||
-- 注意: 如果使用了分区表 (002_partition_bindings.sql),
|
||||
-- 以下索引已在分区迁移中创建,可跳过
|
||||
|
||||
-- 5. binding 表 group_id + material_id 复合索引 (优化批量查询)
|
||||
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_bindings_group_material
|
||||
-- ON material_bindings(group_id, material_id);
|
||||
11
migrations/004_add_version_column.sql
Normal file
11
migrations/004_add_version_column.sql
Normal file
@@ -0,0 +1,11 @@
|
||||
-- ============================================
|
||||
-- Migration: 004_add_version_column.sql
|
||||
-- Purpose: 添加乐观锁版本字段
|
||||
-- ============================================
|
||||
|
||||
-- 添加 version 字段到 materials 表 (用于乐观锁)
|
||||
ALTER TABLE materials
|
||||
ADD COLUMN IF NOT EXISTS version BIGINT NOT NULL DEFAULT 0;
|
||||
|
||||
-- 注释
|
||||
COMMENT ON COLUMN materials.version IS '乐观锁版本号,用于防止并发更新覆盖';
|
||||
Reference in New Issue
Block a user