feat: CREATE INDEX CONCURRENTLY for "userId" "id" composite note index if admin wish. (#15915)

* chore: CREATE INDEX CONCURRENTLY for "userId" "id" composite note index

* chore: remove { concurrent: true } and comment why

* update comment

* feat: add MISSKEY_MIGRATION_CREATE_INDEX_CONCURRENTLY option

* fix: spdx license header

* alter comment

* chore: improve behavior when migration failure

* docs(changelog): 2025.4.1 で追加されたインデックスの再生成をノートの追加しながら行えるようになりました

* ちょっと表現を変更

---------

Co-authored-by: 饺子w (Yumechi) <35571479+eternal-flame-ad@users.noreply.github.com>
This commit is contained in:
anatawa12 2025-05-03 12:57:50 +09:00 committed by GitHub
parent d25af911cf
commit 1af98b690b
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
6 changed files with 49 additions and 4 deletions

View File

@ -11,6 +11,11 @@
### Server
- Enhance: 凍結されたユーザのノートが各種タイムラインで表示されないように `#15775`
- Enhance: 連合先のソフトウェア及びバージョン名により配信停止を行えるように `#15727`
- Enhance: 2025.4.1 で追加されたインデックスの再生成をノートの追加しながら行えるようになりました。 `#15915`
- `MISSKEY_MIGRATION_CREATE_INDEX_CONCURRENTLY` 環境変数を `1` にセットしていると、巨大なテーブルの既存のカラムに関するインデックス再生成が`CREATE INDEX CONCURRENTLY`を使用するようになりました。
- 複数のサーバープロセスをクラスタリングしているサーバーにおいて、一部のプロセスが起動している状態でこのオプションを有効にしてマイグレーションすることにより、ダウンタイムを削減することができます。
- ただし、このオプションを有効にする場合、インデックスの作成にかかる時間が倍~3倍以上になることがあります。
- また、大きなインスタンスである場合にはインデックスの作成に失敗し、複数回再試行する必要がある可能性があります。
## 2025.4.1

View File

@ -3,11 +3,25 @@
* SPDX-License-Identifier: AGPL-3.0-only
*/
import { isConcurrentIndexMigrationEnabled } from "./js/migration-config.js";
export class CompositeNoteIndex1745378064470 {
name = 'CompositeNoteIndex1745378064470';
transaction = isConcurrentIndexMigrationEnabled() ? false : undefined;
async up(queryRunner) {
await queryRunner.query(`CREATE INDEX "IDX_724b311e6f883751f261ebe378" ON "note" ("userId", "id" DESC)`);
const concurrently = isConcurrentIndexMigrationEnabled();
if (concurrently) {
const hasValidIndex = await queryRunner.query(`SELECT indisvalid FROM pg_index INNER JOIN pg_class ON pg_index.indexrelid = pg_class.oid WHERE pg_class.relname = 'IDX_724b311e6f883751f261ebe378'`);
if (!hasValidIndex || hasValidIndex[0].indisvalid !== true) {
await queryRunner.query(`DROP INDEX IF EXISTS "IDX_724b311e6f883751f261ebe378"`);
await queryRunner.query(`CREATE INDEX CONCURRENTLY "IDX_724b311e6f883751f261ebe378" ON "note" ("userId", "id" DESC)`);
}
} else {
await queryRunner.query(`CREATE INDEX IF NOT EXISTS "IDX_724b311e6f883751f261ebe378" ON "note" ("userId", "id" DESC)`);
}
await queryRunner.query(`DROP INDEX IF EXISTS "IDX_5b87d9d19127bd5d92026017a7"`);
// Flush all cached Linear Scan Plans and redo statistics for composite index
// this is important for Postgres to learn that even in highly complex queries, using this index first can reduce the result set significantly
@ -15,7 +29,8 @@ export class CompositeNoteIndex1745378064470 {
}
async down(queryRunner) {
const mayConcurrently = isConcurrentIndexMigrationEnabled() ? 'CONCURRENTLY' : '';
await queryRunner.query(`DROP INDEX IF EXISTS "IDX_724b311e6f883751f261ebe378"`);
await queryRunner.query(`CREATE INDEX "IDX_5b87d9d19127bd5d92026017a7" ON "note" ("userId")`);
await queryRunner.query(`CREATE INDEX ${mayConcurrently} "IDX_5b87d9d19127bd5d92026017a7" ON "note" ("userId")`);
}
}

View File

@ -0,0 +1,8 @@
/*
* SPDX-FileCopyrightText: syuilo and misskey-project
* SPDX-License-Identifier: AGPL-3.0-only
*/
export function isConcurrentIndexMigrationEnabled() {
return process.env.MISSKEY_MIGRATION_CREATE_INDEX_CONCURRENTLY === '1';
}

View File

@ -1,6 +1,7 @@
import { DataSource } from 'typeorm';
import { loadConfig } from './built/config.js';
import { entities } from './built/postgres.js';
import { isConcurrentIndexMigrationEnabled } from "./migration/js/migration-config.js";
const config = loadConfig();
@ -14,4 +15,5 @@ export default new DataSource({
extra: config.db.extra,
entities: entities,
migrations: ['migration/*.js'],
migrationsTransactionMode: isConcurrentIndexMigrationEnabled() ? 'each' : 'all',
});

View File

@ -24,8 +24,13 @@ const $config: Provider = {
const $db: Provider = {
provide: DI.db,
useFactory: async (config) => {
const db = createPostgresDataSource(config);
return await db.initialize();
try {
const db = createPostgresDataSource(config);
return await db.initialize();
} catch (e) {
console.log(e);
throw e;
}
},
inject: [DI.config],
};

View File

@ -10,6 +10,16 @@ import { MiUser } from './User.js';
import { MiChannel } from './Channel.js';
import type { MiDriveFile } from './DriveFile.js';
// Note: When you create a new index for existing column of this table,
// it might be better to index concurrently under isConcurrentIndexMigrationEnabled flag
// by editing generated migration file since this table is very large,
// and it will make a long lock to create index in most cases.
// Please note that `CREATE INDEX CONCURRENTLY` is not supported in transaction,
// so you need to set `transaction = false` in migration if isConcurrentIndexMigrationEnabled() is true.
// Please refer 1745378064470-composite-note-index.js for example.
// You should not use `@Index({ concurrent: true })` decorator because database initialization for test will fail
// because it will always run CREATE INDEX in transaction based on decorators.
// Not appending `{ concurrent: true }` to `@Index` will not cause any problem in production,
@Index(['userId', 'id'])
@Entity('note')
export class MiNote {