fix: Optimize heartbeat indexes containing `important` on sqlite using SQLite partial indexes (#6511)
Co-authored-by: copilot-swe-agent[bot] <198982749+Copilot@users.noreply.github.com> Co-authored-by: louislam <1336778+louislam@users.noreply.github.com> Co-authored-by: CommanderStorm <26258709+CommanderStorm@users.noreply.github.com>pull/5248/head^2
parent
d23ff8c486
commit
af5fd5488d
@ -0,0 +1,37 @@
|
||||
exports.up = async function (knex) {
|
||||
const isSQLite = knex.client.dialect === "sqlite3";
|
||||
|
||||
if (isSQLite) {
|
||||
// For SQLite: Use partial indexes with WHERE important = 1
|
||||
// Drop existing indexes using IF EXISTS
|
||||
await knex.raw("DROP INDEX IF EXISTS monitor_important_time_index");
|
||||
await knex.raw("DROP INDEX IF EXISTS heartbeat_important_index");
|
||||
|
||||
// Create partial indexes with predicate
|
||||
await knex.schema.alterTable("heartbeat", function (table) {
|
||||
table.index([ "monitor_id", "time" ], "monitor_important_time_index", {
|
||||
predicate: knex.whereRaw("important = 1")
|
||||
});
|
||||
table.index([ "important" ], "heartbeat_important_index", {
|
||||
predicate: knex.whereRaw("important = 1")
|
||||
});
|
||||
});
|
||||
}
|
||||
// For MariaDB/MySQL: No changes (partial indexes not supported)
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
const isSQLite = knex.client.dialect === "sqlite3";
|
||||
|
||||
if (isSQLite) {
|
||||
// Restore original indexes
|
||||
await knex.raw("DROP INDEX IF EXISTS monitor_important_time_index");
|
||||
await knex.raw("DROP INDEX IF EXISTS heartbeat_important_index");
|
||||
|
||||
await knex.schema.alterTable("heartbeat", function (table) {
|
||||
table.index([ "monitor_id", "important", "time" ], "monitor_important_time_index");
|
||||
table.index([ "important" ]);
|
||||
});
|
||||
}
|
||||
// For MariaDB/MySQL: No changes
|
||||
};
|
||||
@ -0,0 +1,133 @@
|
||||
const { describe, test } = require("node:test");
|
||||
const fs = require("fs");
|
||||
const path = require("path");
|
||||
const { GenericContainer, Wait } = require("testcontainers");
|
||||
|
||||
describe("Database Migration - Optimize Important Indexes", () => {
|
||||
test("SQLite: All migrations run successfully", async () => {
|
||||
const testDbPath = path.join(__dirname, "../../data/test-migration.db");
|
||||
const testDbDir = path.dirname(testDbPath);
|
||||
|
||||
// Ensure data directory exists
|
||||
if (!fs.existsSync(testDbDir)) {
|
||||
fs.mkdirSync(testDbDir, { recursive: true });
|
||||
}
|
||||
|
||||
// Clean up any existing test database
|
||||
if (fs.existsSync(testDbPath)) {
|
||||
fs.unlinkSync(testDbPath);
|
||||
}
|
||||
|
||||
// Use the same SQLite driver as the project
|
||||
const Dialect = require("knex/lib/dialects/sqlite3/index.js");
|
||||
Dialect.prototype._driver = () => require("@louislam/sqlite3");
|
||||
|
||||
const knex = require("knex");
|
||||
const db = knex({
|
||||
client: Dialect,
|
||||
connection: {
|
||||
filename: testDbPath
|
||||
},
|
||||
useNullAsDefault: true,
|
||||
});
|
||||
|
||||
// Setup R (redbean) with knex instance like production code does
|
||||
const { R } = require("redbean-node");
|
||||
R.setup(db);
|
||||
|
||||
try {
|
||||
// Use production code to initialize SQLite tables (like first run)
|
||||
const { createTables } = require("../../db/knex_init_db.js");
|
||||
await createTables();
|
||||
|
||||
// Run all migrations like production code does
|
||||
await R.knex.migrate.latest({
|
||||
directory: path.join(__dirname, "../../db/knex_migrations")
|
||||
});
|
||||
|
||||
// Test passes if migrations complete successfully without errors
|
||||
|
||||
} finally {
|
||||
// Clean up
|
||||
await R.knex.destroy();
|
||||
if (fs.existsSync(testDbPath)) {
|
||||
fs.unlinkSync(testDbPath);
|
||||
}
|
||||
}
|
||||
});
|
||||
|
||||
test(
|
||||
"MariaDB: All migrations run successfully",
|
||||
{
|
||||
skip:
|
||||
!!process.env.CI &&
|
||||
(process.platform !== "linux" || process.arch !== "x64"),
|
||||
},
|
||||
async () => {
|
||||
// Start MariaDB container (using MariaDB 12 to match current production)
|
||||
const mariadbContainer = await new GenericContainer("mariadb:12")
|
||||
.withEnvironment({
|
||||
"MYSQL_ROOT_PASSWORD": "root",
|
||||
"MYSQL_DATABASE": "kuma_test",
|
||||
"MYSQL_USER": "kuma",
|
||||
"MYSQL_PASSWORD": "kuma"
|
||||
})
|
||||
.withExposedPorts(3306)
|
||||
.withWaitStrategy(Wait.forLogMessage("ready for connections", 2))
|
||||
.withStartupTimeout(120000)
|
||||
.start();
|
||||
|
||||
// Wait a bit more to ensure MariaDB is fully ready
|
||||
await new Promise(resolve => setTimeout(resolve, 2000));
|
||||
|
||||
const knex = require("knex");
|
||||
const knexInstance = knex({
|
||||
client: "mysql2",
|
||||
connection: {
|
||||
host: mariadbContainer.getHost(),
|
||||
port: mariadbContainer.getMappedPort(3306),
|
||||
user: "kuma",
|
||||
password: "kuma",
|
||||
database: "kuma_test",
|
||||
connectTimeout: 60000,
|
||||
},
|
||||
pool: {
|
||||
min: 0,
|
||||
max: 10,
|
||||
acquireTimeoutMillis: 60000,
|
||||
idleTimeoutMillis: 60000,
|
||||
},
|
||||
});
|
||||
|
||||
// Setup R (redbean) with knex instance like production code does
|
||||
const { R } = require("redbean-node");
|
||||
R.setup(knexInstance);
|
||||
|
||||
try {
|
||||
// Use production code to initialize MariaDB tables
|
||||
const { createTables } = require("../../db/knex_init_db.js");
|
||||
await createTables();
|
||||
|
||||
// Run all migrations like production code does
|
||||
await R.knex.migrate.latest({
|
||||
directory: path.join(__dirname, "../../db/knex_migrations")
|
||||
});
|
||||
|
||||
// Test passes if migrations complete successfully without errors
|
||||
|
||||
} finally {
|
||||
// Clean up
|
||||
try {
|
||||
await R.knex.destroy();
|
||||
} catch (e) {
|
||||
// Ignore cleanup errors
|
||||
}
|
||||
try {
|
||||
await mariadbContainer.stop();
|
||||
} catch (e) {
|
||||
// Ignore cleanup errors
|
||||
}
|
||||
}
|
||||
}
|
||||
);
|
||||
});
|
||||
Loading…
Reference in new issue