Updated table layout.

This commit is contained in:
flash 2025-04-27 19:38:00 +00:00
parent dde349601d
commit 999ce86a27
Signed by: flash
GPG key ID: 2C9C2C574D47FE3E
2 changed files with 64 additions and 46 deletions

View file

@ -1,6 +1,5 @@
using MySqlConnector; using MySqlConnector;
using SharpChat.Messages; using SharpChat.Messages;
using System.Text;
using System.Text.Json; using System.Text.Json;
namespace SharpChat.MariaDB; namespace SharpChat.MariaDB;
@ -21,13 +20,13 @@ public partial class MariaDBMessageStorage(string connString) : MessageStorage {
object? data = null object? data = null
) { ) {
await RunCommand( await RunCommand(
"INSERT INTO sqc_events (event_id, event_created, event_type, event_target, event_data" "INSERT INTO sqc_events (event_id, event_created, event_type, event_channel, event_data"
+ ", event_sender, event_sender_name, event_sender_colour, event_sender_rank, event_sender_nick, event_sender_perms)" + ", event_sender, event_sender_name, event_sender_colour, event_sender_rank, event_sender_nick, event_sender_perms)"
+ " VALUES (@id, NOW(), @type, @target, @data" + " VALUES (@id, NOW(), @type, @channel, @data"
+ ", @sender, @sender_name, @sender_colour, @sender_rank, @sender_nick, @sender_perms)", + ", @sender, @sender_name, @sender_colour, @sender_rank, @sender_nick, @sender_perms)",
new MySqlParameter("id", id), new MySqlParameter("id", id),
new MySqlParameter("type", type), new MySqlParameter("type", type),
new MySqlParameter("target", string.IsNullOrWhiteSpace(channelName) ? null : channelName), new MySqlParameter("channel", string.IsNullOrWhiteSpace(channelName) ? null : channelName),
new MySqlParameter("data", data == null ? "{}" : JsonSerializer.SerializeToUtf8Bytes(data)), new MySqlParameter("data", data == null ? "{}" : JsonSerializer.SerializeToUtf8Bytes(data)),
new MySqlParameter("sender", long.TryParse(senderId, out long senderId64) && senderId64 > 0 ? senderId64 : null), new MySqlParameter("sender", long.TryParse(senderId, out long senderId64) && senderId64 > 0 ? senderId64 : null),
new MySqlParameter("sender_name", senderName), new MySqlParameter("sender_name", senderName),
@ -41,7 +40,7 @@ public partial class MariaDBMessageStorage(string connString) : MessageStorage {
public async Task<Message?> GetMessage(long seqId) { public async Task<Message?> GetMessage(long seqId) {
try { try {
using MySqlDataReader? reader = await RunQuery( using MySqlDataReader? reader = await RunQuery(
"SELECT event_id, event_type, event_data, event_target" "SELECT event_id, event_type, event_data, event_channel"
+ ", event_sender, event_sender_name, event_sender_colour, event_sender_rank, event_sender_nick, event_sender_perms" + ", event_sender, event_sender_name, event_sender_colour, event_sender_rank, event_sender_nick, event_sender_perms"
+ ", UNIX_TIMESTAMP(event_created) AS event_created" + ", UNIX_TIMESTAMP(event_created) AS event_created"
+ ", UNIX_TIMESTAMP(event_deleted) AS event_deleted" + ", UNIX_TIMESTAMP(event_deleted) AS event_deleted"
@ -66,10 +65,11 @@ public partial class MariaDBMessageStorage(string connString) : MessageStorage {
} }
private static Message ReadEvent(MySqlDataReader reader) { private static Message ReadEvent(MySqlDataReader reader) {
using Stream data = reader.GetStream("event_data");
return new Message( return new Message(
reader.GetInt64("event_id"), reader.GetInt64("event_id"),
Encoding.ASCII.GetString((byte[])reader["event_type"]), reader.GetString("event_type"),
reader.IsDBNull(reader.GetOrdinal("event_sender")) ? null : reader.GetInt64("event_sender").ToString(), reader.IsDBNull(reader.GetOrdinal("event_sender")) ? null : reader.GetString("event_sender"),
reader.IsDBNull(reader.GetOrdinal("event_sender_name")) ? string.Empty : reader.GetString("event_sender_name"), reader.IsDBNull(reader.GetOrdinal("event_sender_name")) ? string.Empty : reader.GetString("event_sender_name"),
ColourInheritable.FromMisuzu(reader.GetInt32("event_sender_colour")), ColourInheritable.FromMisuzu(reader.GetInt32("event_sender_colour")),
reader.GetInt32("event_sender_rank"), reader.GetInt32("event_sender_rank"),
@ -77,8 +77,8 @@ public partial class MariaDBMessageStorage(string connString) : MessageStorage {
reader.IsDBNull(reader.GetOrdinal("event_sender_nick")) ? string.Empty : reader.GetString("event_sender_nick"), reader.IsDBNull(reader.GetOrdinal("event_sender_nick")) ? string.Empty : reader.GetString("event_sender_nick"),
DateTimeOffset.FromUnixTimeSeconds(reader.GetInt32("event_created")), DateTimeOffset.FromUnixTimeSeconds(reader.GetInt32("event_created")),
reader.IsDBNull(reader.GetOrdinal("event_deleted")) ? null : DateTimeOffset.FromUnixTimeSeconds(reader.GetInt32("event_deleted")), reader.IsDBNull(reader.GetOrdinal("event_deleted")) ? null : DateTimeOffset.FromUnixTimeSeconds(reader.GetInt32("event_deleted")),
reader.IsDBNull(reader.GetOrdinal("event_target")) ? null : Encoding.ASCII.GetString((byte[])reader["event_target"]), reader.IsDBNull(reader.GetOrdinal("event_channel")) ? null : reader.GetString("event_channel"),
JsonDocument.Parse(Encoding.ASCII.GetString((byte[])reader["event_data"])) JsonDocument.Parse(data)
); );
} }
@ -87,16 +87,16 @@ public partial class MariaDBMessageStorage(string connString) : MessageStorage {
try { try {
using MySqlDataReader? reader = await RunQuery( using MySqlDataReader? reader = await RunQuery(
"SELECT event_id, event_type, event_data, event_target" "SELECT event_id, event_type, event_data, event_channel"
+ ", event_sender, event_sender_name, event_sender_colour, event_sender_rank, event_sender_nick, event_sender_perms" + ", event_sender, event_sender_name, event_sender_colour, event_sender_rank, event_sender_nick, event_sender_perms"
+ ", UNIX_TIMESTAMP(event_created) AS event_created" + ", UNIX_TIMESTAMP(event_created) AS event_created"
+ ", UNIX_TIMESTAMP(event_deleted) AS event_deleted" + ", UNIX_TIMESTAMP(event_deleted) AS event_deleted"
+ " FROM sqc_events" + " FROM sqc_events"
+ " WHERE event_deleted IS NULL AND (event_target = @target OR event_target IS NULL)" + " WHERE event_deleted IS NULL AND (event_channel = @channel OR event_channel IS NULL)"
+ " AND event_id > @offset" + " AND event_id > @offset"
+ " ORDER BY event_id DESC" + " ORDER BY event_id DESC"
+ " LIMIT @amount", + " LIMIT @amount",
new MySqlParameter("target", channelName), new MySqlParameter("channel", channelName),
new MySqlParameter("amount", amount), new MySqlParameter("amount", amount),
new MySqlParameter("offset", offset) new MySqlParameter("offset", offset)
); );

View file

@ -5,14 +5,14 @@ namespace SharpChat.MariaDB;
public partial class MariaDBMessageStorage { public partial class MariaDBMessageStorage {
private async Task DoMigration(string name, Func<Task> action) { private async Task DoMigration(string name, Func<Task> action) {
bool done = await RunQueryValue<long>( bool done = await RunQueryValue<long>(
"SELECT COUNT(*) FROM `sqc_migrations` WHERE `migration_name` = @name", "SELECT COUNT(*) FROM sqc_migrations WHERE migration_name = @name",
new MySqlParameter("name", name) new MySqlParameter("name", name)
) > 0; ) > 0;
if(!done) { if(!done) {
Logger.Write($"Running migration '{name}'..."); Logger.Write($"Running migration '{name}'...");
await action(); await action();
await RunCommand( await RunCommand(
"INSERT INTO `sqc_migrations` (`migration_name`) VALUES (@name)", "INSERT INTO sqc_migrations (migration_name) VALUES (@name)",
new MySqlParameter("name", name) new MySqlParameter("name", name)
); );
} }
@ -20,11 +20,11 @@ public partial class MariaDBMessageStorage {
public async Task RunMigrations() { public async Task RunMigrations() {
await RunCommand( await RunCommand(
"CREATE TABLE IF NOT EXISTS `sqc_migrations` (" "CREATE TABLE IF NOT EXISTS sqc_migrations ("
+ "`migration_name` VARCHAR(255) NOT NULL," + "migration_name VARCHAR(255) NOT NULL,"
+ "`migration_completed` TIMESTAMP NOT NULL DEFAULT current_timestamp()," + "migration_completed TIMESTAMP NOT NULL DEFAULT current_timestamp(),"
+ "UNIQUE INDEX `migration_name` (`migration_name`)," + "UNIQUE INDEX migration_name (migration_name),"
+ "INDEX `migration_completed` (`migration_completed`)" + "INDEX migration_completed (migration_completed)"
+ ") COLLATE='utf8mb4_unicode_ci' ENGINE=InnoDB;" + ") COLLATE='utf8mb4_unicode_ci' ENGINE=InnoDB;"
); );
@ -34,6 +34,24 @@ public partial class MariaDBMessageStorage {
await DoMigration("event_user_and_nick_name_to_1000", EventUserAndNickNameTo1000); await DoMigration("event_user_and_nick_name_to_1000", EventUserAndNickNameTo1000);
await DoMigration("no_more_flags_field", NoMoreFlagsField); await DoMigration("no_more_flags_field", NoMoreFlagsField);
await DoMigration("update_event_type_names", UpdateEventTypeNames); await DoMigration("update_event_type_names", UpdateEventTypeNames);
await DoMigration("update_collations_and_use_json_type", UpdateCollationsAndUseJsonType);
}
private async Task UpdateCollationsAndUseJsonType() {
await RunCommand("UPDATE sqc_events SET event_target = LOWER(CONVERT(event_target USING ascii))");
await RunCommand("UPDATE sqc_events SET event_sender_nick = NULL WHERE event_sender_nick = ''");
await RunCommand(
"ALTER TABLE sqc_events COLLATE='utf8mb4_unicode_520_ci',"
+ " CHANGE COLUMN event_type event_type VARCHAR(255) NOT NULL COLLATE 'ascii_general_ci' AFTER event_id,"
+ " CHANGE COLUMN event_created event_created TIMESTAMP NOT NULL DEFAULT current_timestamp() AFTER event_type,"
+ " CHANGE COLUMN event_deleted event_deleted TIMESTAMP NULL DEFAULT NULL AFTER event_created,"
+ " CHANGE COLUMN event_target event_channel VARCHAR(255) NULL DEFAULT NULL COLLATE 'ascii_general_ci' AFTER event_deleted,"
+ " CHANGE COLUMN event_sender event_sender VARCHAR(255) NULL DEFAULT NULL COLLATE 'ascii_bin' AFTER event_channel,"
+ " CHANGE COLUMN event_sender_name event_sender_name VARCHAR(1000) NULL DEFAULT NULL COLLATE 'utf8mb4_unicode_520_ci' AFTER event_sender,"
+ " CHANGE COLUMN event_sender_nick event_sender_nick VARCHAR(1000) NULL DEFAULT NULL COLLATE 'utf8mb4_unicode_520_ci' AFTER event_sender_rank,"
+ " CHANGE COLUMN event_data event_data JSON NOT NULL DEFAULT '{}' AFTER event_sender_perms,"
+ " DROP INDEX event_target, ADD INDEX event_channel (event_channel)"
);
} }
private async Task UpdateEventTypeNames() { private async Task UpdateEventTypeNames() {
@ -58,48 +76,48 @@ public partial class MariaDBMessageStorage {
private async Task EventUserAndNickNameTo1000() { private async Task EventUserAndNickNameTo1000() {
await RunCommand( await RunCommand(
"ALTER TABLE `sqc_events`" "ALTER TABLE sqc_events"
+ " CHANGE COLUMN `event_sender_name` `event_sender_name` VARCHAR(1000) NULL DEFAULT NULL COLLATE 'utf8mb4_unicode_520_ci' AFTER `event_sender`," + " CHANGE COLUMN event_sender_name event_sender_name VARCHAR(1000) NULL DEFAULT NULL COLLATE 'utf8mb4_unicode_520_ci' AFTER event_sender,"
+ " CHANGE COLUMN `event_sender_nick` `event_sender_nick` VARCHAR(1000) NULL DEFAULT NULL COLLATE 'utf8mb4_unicode_520_ci' AFTER `event_sender_rank`;" + " CHANGE COLUMN event_sender_nick event_sender_nick VARCHAR(1000) NULL DEFAULT NULL COLLATE 'utf8mb4_unicode_520_ci' AFTER event_sender_rank;"
); );
} }
private async Task EventDataAsMediumBlob() { private async Task EventDataAsMediumBlob() {
await RunCommand( await RunCommand(
"ALTER TABLE `sqc_events`" "ALTER TABLE sqc_events"
+ " CHANGE COLUMN `event_data` `event_data` MEDIUMBLOB NULL DEFAULT NULL AFTER `event_flags`;" + " CHANGE COLUMN event_data event_data MEDIUMBLOB NULL DEFAULT NULL AFTER event_flags;"
); );
} }
private async Task AllowNullTarget() { private async Task AllowNullTarget() {
await RunCommand( await RunCommand(
"ALTER TABLE `sqc_events`" "ALTER TABLE sqc_events"
+ " CHANGE COLUMN `event_target` `event_target` VARBINARY(255) NULL AFTER `event_type`;" + " CHANGE COLUMN event_target event_target VARBINARY(255) NULL AFTER event_type;"
); );
} }
private async Task CreateEventsTable() { private async Task CreateEventsTable() {
await RunCommand( await RunCommand(
"CREATE TABLE `sqc_events` (" "CREATE TABLE sqc_events ("
+ "`event_id` BIGINT(20) NOT NULL," + "event_id BIGINT(20) NOT NULL,"
+ "`event_sender` BIGINT(20) UNSIGNED NULL DEFAULT NULL," + "event_sender BIGINT(20) UNSIGNED NULL DEFAULT NULL,"
+ "`event_sender_name` VARCHAR(255) NULL DEFAULT NULL," + "event_sender_name VARCHAR(255) NULL DEFAULT NULL,"
+ "`event_sender_colour` INT(11) NULL DEFAULT NULL," + "event_sender_colour INT(11) NULL DEFAULT NULL,"
+ "`event_sender_rank` INT(11) NULL DEFAULT NULL," + "event_sender_rank INT(11) NULL DEFAULT NULL,"
+ "`event_sender_nick` VARCHAR(255) NULL DEFAULT NULL," + "event_sender_nick VARCHAR(255) NULL DEFAULT NULL,"
+ "`event_sender_perms` INT(11) NULL DEFAULT NULL," + "event_sender_perms INT(11) NULL DEFAULT NULL,"
+ "`event_created` TIMESTAMP NOT NULL DEFAULT current_timestamp()," + "event_created TIMESTAMP NOT NULL DEFAULT current_timestamp(),"
+ "`event_deleted` TIMESTAMP NULL DEFAULT NULL," + "event_deleted TIMESTAMP NULL DEFAULT NULL,"
+ "`event_type` VARBINARY(255) NOT NULL," + "event_type VARBINARY(255) NOT NULL,"
+ "`event_target` VARBINARY(255) NOT NULL," + "event_target VARBINARY(255) NOT NULL,"
+ "`event_flags` TINYINT(3) UNSIGNED NOT NULL," + "event_flags TINYINT(3) UNSIGNED NOT NULL,"
+ "`event_data` BLOB NULL DEFAULT NULL," + "event_data BLOB NULL DEFAULT NULL,"
+ "PRIMARY KEY (`event_id`)," + "PRIMARY KEY (event_id),"
+ "INDEX `event_target` (`event_target`)," + "INDEX event_target (event_target),"
+ "INDEX `event_type` (`event_type`)," + "INDEX event_type (event_type),"
+ "INDEX `event_sender` (`event_sender`)," + "INDEX event_sender (event_sender),"
+ "INDEX `event_datetime` (`event_created`)," + "INDEX event_datetime (event_created),"
+ "INDEX `event_deleted` (`event_deleted`)" + "INDEX event_deleted (event_deleted)"
+ ") COLLATE='utf8mb4_unicode_ci' ENGINE=InnoDB;" + ") COLLATE='utf8mb4_unicode_ci' ENGINE=InnoDB;"
); );
} }