-- +migrate Up CREATE TABLE categories ( id SERIAL PRIMARY KEY, name VARCHAR(100) NOT NULL, description TEXT, slug VARCHAR(255) UNIQUE, parent_id INTEGER REFERENCES categories(id) ON DELETE CASCADE, user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE, cover_photo_id INTEGER REFERENCES photos(id) ON DELETE SET NULL, color VARCHAR(7) DEFAULT '#3B82F6', is_public BOOLEAN DEFAULT true, photo_count INTEGER DEFAULT 0, album_count INTEGER DEFAULT 0, sort_order INTEGER DEFAULT 0, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, deleted_at TIMESTAMP ); -- 创建索引 CREATE INDEX idx_categories_user_id ON categories(user_id); CREATE INDEX idx_categories_parent_id ON categories(parent_id); CREATE INDEX idx_categories_cover_photo_id ON categories(cover_photo_id); CREATE INDEX idx_categories_slug ON categories(slug); CREATE INDEX idx_categories_is_public ON categories(is_public); CREATE INDEX idx_categories_created_at ON categories(created_at); CREATE INDEX idx_categories_photo_count ON categories(photo_count); CREATE INDEX idx_categories_album_count ON categories(album_count); CREATE INDEX idx_categories_sort_order ON categories(sort_order); CREATE INDEX idx_categories_deleted_at ON categories(deleted_at) WHERE deleted_at IS NOT NULL; -- 树形结构查询优化 CREATE INDEX idx_categories_parent_sort ON categories(parent_id, sort_order); -- 添加更新时间触发器 CREATE TRIGGER update_categories_updated_at BEFORE UPDATE ON categories FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- 添加 slug 自动生成触发器 CREATE OR REPLACE FUNCTION generate_category_slug() RETURNS TRIGGER AS $$ BEGIN IF NEW.slug IS NULL OR NEW.slug = '' THEN NEW.slug = lower(regexp_replace(NEW.name, '[^a-zA-Z0-9]+', '-', 'g')); NEW.slug = trim(both '-' from NEW.slug); -- 确保 slug 唯一 DECLARE counter INTEGER := 0; base_slug VARCHAR(255); BEGIN base_slug := NEW.slug; WHILE EXISTS (SELECT 1 FROM categories WHERE slug = NEW.slug AND id != COALESCE(NEW.id, 0)) LOOP counter := counter + 1; NEW.slug := base_slug || '-' || counter; END LOOP; END; END IF; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER generate_categories_slug BEFORE INSERT OR UPDATE ON categories FOR EACH ROW EXECUTE FUNCTION generate_category_slug(); -- 插入默认分类 INSERT INTO categories (name, description, slug, user_id, color, is_public) SELECT '风景摄影' as name, '自然风光、城市景观等风景类摄影作品' as description, 'landscape' as slug, 1 as user_id, '#10B981' as color, true as is_public WHERE EXISTS (SELECT 1 FROM users WHERE id = 1); INSERT INTO categories (name, description, slug, user_id, color, is_public) SELECT '人像摄影' as name, '肖像、写真、人物摄影作品' as description, 'portrait' as slug, 1 as user_id, '#F59E0B' as color, true as is_public WHERE EXISTS (SELECT 1 FROM users WHERE id = 1); INSERT INTO categories (name, description, slug, user_id, color, is_public) SELECT '街拍摄影' as name, '街头摄影、日常生活记录' as description, 'street' as slug, 1 as user_id, '#EF4444' as color, true as is_public WHERE EXISTS (SELECT 1 FROM users WHERE id = 1); INSERT INTO categories (name, description, slug, user_id, color, is_public) SELECT '建筑摄影' as name, '建筑、室内设计等建筑类摄影作品' as description, 'architecture' as slug, 1 as user_id, '#8B5CF6' as color, true as is_public WHERE EXISTS (SELECT 1 FROM users WHERE id = 1); -- +migrate Down DROP TRIGGER IF EXISTS generate_categories_slug ON categories; DROP FUNCTION IF EXISTS generate_category_slug(); DROP TRIGGER IF EXISTS update_categories_updated_at ON categories; DROP TABLE IF EXISTS categories;