-- ============================================ -- 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;