Add foreign keys to tables linked to messages

This commit is contained in:
chylex 2025-02-02 13:55:44 +01:00
parent 60761d80ab
commit 7a6dd23912
No known key found for this signature in database
4 changed files with 127 additions and 53 deletions

View File

@ -0,0 +1,67 @@
using System.Threading.Tasks;
using DHT.Server.Database.Sqlite.Utils;
namespace DHT.Server.Database.Sqlite.Schema;
sealed class SqliteSchemaUpgradeTo10 : ISchemaUpgrade {
async Task ISchemaUpgrade.Run(ISqliteConnection conn, ISchemaUpgradeCallbacks.IProgressReporter reporter) {
await reporter.MainWork("Migrating message embeds...", 0, 5);
await conn.ExecuteAsync("""
CREATE TABLE message_embeds_new (
message_id INTEGER NOT NULL,
json TEXT NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await conn.ExecuteAsync("INSERT INTO message_embeds_new (message_id, json) SELECT message_id, json FROM message_embeds WHERE message_id IN (SELECT DISTINCT message_id FROM messages)");
await reporter.MainWork("Migrating message reactions...", 1, 5);
await conn.ExecuteAsync("""
CREATE TABLE message_reactions_new (
message_id INTEGER NOT NULL,
emoji_id INTEGER,
emoji_name TEXT,
emoji_flags INTEGER NOT NULL,
count INTEGER NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await conn.ExecuteAsync("INSERT INTO message_reactions_new (message_id, emoji_id, emoji_name, emoji_flags, count) SELECT message_id, emoji_id, emoji_name, emoji_flags, count FROM message_reactions WHERE message_id IN (SELECT DISTINCT message_id FROM messages)");
await reporter.MainWork("Migrating message edit timestamps...", 2, 5);
await conn.ExecuteAsync("""
CREATE TABLE message_edit_timestamps_new (
message_id INTEGER PRIMARY KEY NOT NULL,
edit_timestamp INTEGER NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await conn.ExecuteAsync("INSERT INTO message_edit_timestamps_new (message_id, edit_timestamp) SELECT message_id, edit_timestamp FROM message_edit_timestamps WHERE message_id IN (SELECT DISTINCT message_id FROM messages)");
await reporter.MainWork("Migrating message replies...", 3, 5);
await conn.ExecuteAsync("""
CREATE TABLE message_replied_to_new (
message_id INTEGER PRIMARY KEY NOT NULL,
replied_to_id INTEGER NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await conn.ExecuteAsync("INSERT INTO message_replied_to_new (message_id, replied_to_id) SELECT message_id, replied_to_id FROM message_replied_to WHERE message_id IN (SELECT DISTINCT message_id FROM messages)");
await reporter.MainWork("Applying schema changes...", 4, 5);
await conn.ExecuteAsync("DROP TABLE message_embeds");
await conn.ExecuteAsync("ALTER TABLE message_embeds_new RENAME TO message_embeds");
await conn.ExecuteAsync("CREATE INDEX embeds_message_ix ON message_embeds(message_id)");
await conn.ExecuteAsync("DROP TABLE message_reactions");
await conn.ExecuteAsync("ALTER TABLE message_reactions_new RENAME TO message_reactions");
await conn.ExecuteAsync("CREATE INDEX reactions_message_ix ON message_reactions(message_id)");
await conn.ExecuteAsync("DROP TABLE message_edit_timestamps");
await conn.ExecuteAsync("ALTER TABLE message_edit_timestamps_new RENAME TO message_edit_timestamps");
await conn.ExecuteAsync("DROP TABLE message_replied_to");
await conn.ExecuteAsync("ALTER TABLE message_replied_to_new RENAME TO message_replied_to");
}
}

View File

@ -6,30 +6,38 @@ namespace DHT.Server.Database.Sqlite.Schema;
sealed class SqliteSchemaUpgradeTo3 : ISchemaUpgrade {
async Task ISchemaUpgrade.Run(ISqliteConnection conn, ISchemaUpgradeCallbacks.IProgressReporter reporter) {
await reporter.MainWork("Applying schema changes...", 0, 1);
await SqliteSchema.CreateMessageEditTimestampTable(conn);
await conn.ExecuteAsync("ALTER TABLE message_edit_timestamps RENAME TO edit_timestamps");
await SqliteSchema.CreateMessageRepliedToTable(conn);
await conn.ExecuteAsync("ALTER TABLE message_replied_to RENAME TO replied_to");
await conn.ExecuteAsync("""
CREATE TABLE edit_timestamps (
message_id INTEGER PRIMARY KEY NOT NULL,
edit_timestamp INTEGER NOT NULL
)
""");
await conn.ExecuteAsync("""
CREATE TABLE replied_to (
message_id INTEGER PRIMARY KEY NOT NULL,
replied_to_id INTEGER NOT NULL
)
""");
await conn.ExecuteAsync("""
INSERT INTO edit_timestamps (message_id, edit_timestamp)
SELECT message_id, edit_timestamp
FROM messages
WHERE edit_timestamp IS NOT NULL
""");
await conn.ExecuteAsync("""
INSERT INTO replied_to (message_id, replied_to_id)
SELECT message_id, replied_to_id
FROM messages
WHERE replied_to_id IS NOT NULL
""");
await conn.ExecuteAsync("ALTER TABLE messages DROP COLUMN replied_to_id");
await conn.ExecuteAsync("ALTER TABLE messages DROP COLUMN edit_timestamp");
await reporter.MainWork("Vacuuming the database...", 1, 1);
await conn.ExecuteAsync("VACUUM");
}

View File

@ -8,19 +8,19 @@ using DHT.Utils.Logging;
namespace DHT.Server.Database.Sqlite;
sealed class SqliteSchema {
internal const int Version = 9;
internal const int Version = 10;
private static readonly Log Log = Log.ForType<SqliteSchema>();
private readonly ISqliteConnection conn;
public SqliteSchema(ISqliteConnection conn) {
this.conn = conn;
}
public async Task<bool> Setup(ISchemaUpgradeCallbacks callbacks) {
await conn.ExecuteAsync("CREATE TABLE IF NOT EXISTS metadata (key TEXT PRIMARY KEY, value TEXT)");
var dbVersionStr = await conn.ExecuteReaderAsync("SELECT value FROM metadata WHERE key = 'version'", static reader => reader?.GetString(0));
if (dbVersionStr == null) {
await InitializeSchemas();
@ -36,13 +36,13 @@ sealed class SqliteSchema {
if (!proceed) {
return false;
}
await callbacks.Start(Version - dbVersion, async reporter => await UpgradeSchemas(dbVersion, reporter));
}
return true;
}
private async Task InitializeSchemas() {
await conn.ExecuteAsync("""
CREATE TABLE users (
@ -53,7 +53,7 @@ sealed class SqliteSchema {
discriminator TEXT
)
""");
await conn.ExecuteAsync("""
CREATE TABLE servers (
id INTEGER PRIMARY KEY NOT NULL,
@ -61,7 +61,7 @@ sealed class SqliteSchema {
type TEXT NOT NULL
)
""");
await conn.ExecuteAsync("""
CREATE TABLE channels (
id INTEGER PRIMARY KEY NOT NULL,
@ -73,7 +73,7 @@ sealed class SqliteSchema {
nsfw INTEGER
)
""");
await conn.ExecuteAsync("""
CREATE TABLE messages (
message_id INTEGER PRIMARY KEY NOT NULL,
@ -83,7 +83,7 @@ sealed class SqliteSchema {
timestamp INTEGER NOT NULL
)
""");
await conn.ExecuteAsync("""
CREATE TABLE attachments (
attachment_id INTEGER NOT NULL PRIMARY KEY NOT NULL,
@ -96,53 +96,51 @@ sealed class SqliteSchema {
height INTEGER
)
""");
await conn.ExecuteAsync("""
CREATE TABLE message_embeds (
message_id INTEGER NOT NULL,
json TEXT NOT NULL
json TEXT NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await conn.ExecuteAsync("""
CREATE TABLE message_reactions (
message_id INTEGER NOT NULL,
emoji_id INTEGER,
emoji_name TEXT,
emoji_flags INTEGER NOT NULL,
count INTEGER NOT NULL
count INTEGER NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await CreateMessageEditTimestampTable(conn);
await CreateMessageRepliedToTable(conn);
await CreateDownloadTables(conn);
await CreateMessageAttachmentsTable(conn);
await conn.ExecuteAsync("CREATE INDEX embeds_message_ix ON message_embeds(message_id)");
await conn.ExecuteAsync("CREATE INDEX reactions_message_ix ON message_reactions(message_id)");
await conn.ExecuteAsync("INSERT INTO metadata (key, value) VALUES ('version', " + Version + ")");
}
internal static async Task CreateMessageEditTimestampTable(ISqliteConnection conn) {
await conn.ExecuteAsync("""
CREATE TABLE message_edit_timestamps (
message_id INTEGER PRIMARY KEY NOT NULL,
edit_timestamp INTEGER NOT NULL
edit_timestamp INTEGER NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
}
internal static async Task CreateMessageRepliedToTable(ISqliteConnection conn) {
await conn.ExecuteAsync("""
CREATE TABLE message_replied_to (
message_id INTEGER PRIMARY KEY NOT NULL,
replied_to_id INTEGER NOT NULL
replied_to_id INTEGER NOT NULL,
FOREIGN KEY (message_id) REFERENCES messages (message_id) ON UPDATE CASCADE ON DELETE CASCADE
)
""");
await CreateDownloadTables(conn);
await CreateMessageAttachmentsTable(conn);
await conn.ExecuteAsync("CREATE INDEX embeds_message_ix ON message_embeds(message_id)");
await conn.ExecuteAsync("CREATE INDEX reactions_message_ix ON message_reactions(message_id)");
await conn.ExecuteAsync("INSERT INTO metadata (key, value) VALUES ('version', " + Version + ")");
}
internal static async Task CreateDownloadTables(ISqliteConnection conn) {
await conn.ExecuteAsync("""
CREATE TABLE download_metadata (
@ -153,7 +151,7 @@ sealed class SqliteSchema {
size INTEGER
)
""");
await conn.ExecuteAsync("""
CREATE TABLE download_blobs (
normalized_url TEXT NOT NULL PRIMARY KEY,
@ -174,7 +172,7 @@ sealed class SqliteSchema {
)
""");
}
private async Task UpgradeSchemas(int dbVersion, ISchemaUpgradeCallbacks.IProgressReporter reporter) {
var upgrades = new Dictionary<int, ISchemaUpgrade> {
{ 1, new SqliteSchemaUpgradeTo2() },
@ -185,23 +183,24 @@ sealed class SqliteSchema {
{ 6, new SqliteSchemaUpgradeTo7() },
{ 7, new SqliteSchemaUpgradeTo8() },
{ 8, new SqliteSchemaUpgradeTo9() },
{ 9, new SqliteSchemaUpgradeTo10() },
};
var perf = Log.Start("from version " + dbVersion);
for (int fromVersion = dbVersion; fromVersion < Version; fromVersion++) {
var toVersion = fromVersion + 1;
if (upgrades.TryGetValue(fromVersion, out var upgrade)) {
await upgrade.Run(conn, reporter);
}
await conn.ExecuteAsync("UPDATE metadata SET value = " + toVersion + " WHERE key = 'version'");
perf.Step("Upgrade to version " + toVersion);
await reporter.NextVersion();
}
perf.End();
}
}

Binary file not shown.