Files
CollabVMAuthServer/CollabVMAuthServer/Database.cs
2024-04-05 08:25:18 -04:00

242 lines
10 KiB
C#

using System.Net;
using Isopoh.Cryptography.Argon2;
using MySqlConnector;
namespace Computernewb.CollabVMAuthServer;
public class Database
{
private readonly string connectionString;
public Database(MySQLConfig config)
{
connectionString = new MySqlConnectionStringBuilder
{
Server = config.Host,
UserID = config.Username,
Password = config.Password,
Database = config.Database
}.ToString();
}
public async Task Init()
{
await using var conn = new MySqlConnection(connectionString);
await conn.OpenAsync();
await using var cmd = conn.CreateCommand();
cmd.CommandText = """
CREATE TABLE IF NOT EXISTS users (
id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
username VARCHAR(20) NOT NULL UNIQUE KEY,
password TEXT NOT NULL,
email TEXT NOT NULL UNIQUE KEY,
email_verified BOOLEAN NOT NULL DEFAULT 0,
email_verification_code CHAR(8) DEFAULT NULL,
cvm_rank INT UNSIGNED NOT NULL DEFAULT 1,
banned BOOLEAN NOT NULL DEFAULT 0,
registration_ip VARBINARY(16) NOT NULL
);
""";
await cmd.ExecuteNonQueryAsync();
cmd.CommandText = """
CREATE TABLE IF NOT EXISTS sessions (
token CHAR(32) NOT NULL PRIMARY KEY,
username VARCHAR(20) NOT NULL,
created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
last_used TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
last_ip VARBINARY(16) NOT NULL,
FOREIGN KEY (username) REFERENCES users(username) ON UPDATE CASCADE ON DELETE CASCADE
)
""";
await cmd.ExecuteNonQueryAsync();
}
public async Task<User?> GetUser(string? username = null, string? email = null)
{
if (username == null && email == null)
throw new ArgumentException("username or email must be provided");
await using var conn = new MySqlConnection(connectionString);
await conn.OpenAsync();
await using var cmd = conn.CreateCommand();
if (username != null)
{
cmd.CommandText = "SELECT * FROM users WHERE username = @username";
cmd.Parameters.AddWithValue("@username", username);
}
else if (email != null)
{
cmd.CommandText = "SELECT * FROM users WHERE email = @email";
cmd.Parameters.AddWithValue("@email", email);
}
await using var reader = await cmd.ExecuteReaderAsync();
if (!await reader.ReadAsync())
return null;
return new User
{
Id = reader.GetUInt32("id"),
Username = reader.GetString("username"),
Password = reader.GetString("password"),
Email = reader.GetString("email"),
EmailVerified = reader.GetBoolean("email_verified"),
EmailVerificationCode = reader.GetString("email_verification_code"),
Rank = (Rank)reader.GetUInt32("cvm_rank"),
Banned = reader.GetBoolean("banned"),
RegistrationIP = new IPAddress(await reader.GetFieldValueAsync<byte[]>(8))
};
}
public async Task RegisterAccount(string username, string email, string password, bool verified, IPAddress ip,
string? verificationcode = null)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = """
INSERT INTO users
(username, password, email, email_verified, email_verification_code, registration_ip)
VALUES
(@username, @password, @email, @email_verified, @email_verification_code, @registration_ip)
""";
cmd.Parameters.AddWithValue("@username", username);
cmd.Parameters.AddWithValue("@password", Argon2.Hash(password));
cmd.Parameters.AddWithValue("@email", email);
cmd.Parameters.AddWithValue("@email_verified", verified);
cmd.Parameters.AddWithValue("@email_verification_code", verificationcode);
cmd.Parameters.AddWithValue("@registration_ip", ip.GetAddressBytes());
await cmd.ExecuteNonQueryAsync();
}
public async Task SetUserVerified(string username, bool verified)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "UPDATE users SET email_verified = @verified WHERE username = @username";
cmd.Parameters.AddWithValue("@verified", verified);
cmd.Parameters.AddWithValue("@username", username);
await cmd.ExecuteNonQueryAsync();
}
public async Task SetVerificationCode(string username, string code)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "UPDATE users SET email_verification_code = @code WHERE username = @username";
cmd.Parameters.AddWithValue("@code", code);
cmd.Parameters.AddWithValue("@username", username);
await cmd.ExecuteNonQueryAsync();
}
public async Task CreateSession(string username, string token, IPAddress ip)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "INSERT INTO sessions (token, username, last_ip) VALUES (@token, @username, @ip)";
cmd.Parameters.AddWithValue("@token", token);
cmd.Parameters.AddWithValue("@username", username);
cmd.Parameters.AddWithValue("@ip", ip.GetAddressBytes());
await cmd.ExecuteNonQueryAsync();
}
public async Task<Session[]> GetSessions(string username)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "SELECT * FROM sessions WHERE username = @username";
cmd.Parameters.AddWithValue("@username", username);
await using var reader = await cmd.ExecuteReaderAsync();
var sessions = new List<Session>();
while (await reader.ReadAsync())
{
sessions.Add(new Session
{
Token = reader.GetString("token"),
Username = reader.GetString("username"),
Created = reader.GetDateTime("created"),
LastUsed = reader.GetDateTime("last_used"),
LastIP = new IPAddress(await reader.GetFieldValueAsync<byte[]>(4))
});
}
return sessions.ToArray();
}
public async Task<Session?> GetSession(string token)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "SELECT * FROM sessions WHERE token = @token";
cmd.Parameters.AddWithValue("@token", token);
await using var reader = await cmd.ExecuteReaderAsync();
if (!await reader.ReadAsync())
return null;
return new Session
{
Token = reader.GetString("token"),
Username = reader.GetString("username"),
Created = reader.GetDateTime("created"),
LastUsed = reader.GetDateTime("last_used"),
LastIP = new IPAddress(await reader.GetFieldValueAsync<byte[]>(4))
};
}
public async Task RevokeSession(string token)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "DELETE FROM sessions WHERE token = @token";
cmd.Parameters.AddWithValue("@token", token);
await cmd.ExecuteNonQueryAsync();
}
public async Task RevokeAllSessions(string username)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "DELETE FROM sessions WHERE username = @username";
cmd.Parameters.AddWithValue("@username", username);
await cmd.ExecuteNonQueryAsync();
}
public async Task UpdateSessionLastUsed(string token, IPAddress ip)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
cmd.CommandText = "UPDATE sessions SET last_used = CURRENT_TIMESTAMP, last_ip = @ip WHERE token = @token";
cmd.Parameters.AddWithValue("@token", token);
cmd.Parameters.AddWithValue("@ip", ip.GetAddressBytes());
await cmd.ExecuteNonQueryAsync();
}
public async Task UpdateUser(string username, string? newUsername, string? newPassword, string? newEmail)
{
await using var db = new MySqlConnection(connectionString);
await db.OpenAsync();
await using var cmd = db.CreateCommand();
var updates = new List<string>();
if (newUsername != null)
{
updates.Add("username = @newUsername");
cmd.Parameters.AddWithValue("@newUsername", newUsername);
}
if (newPassword != null)
{
updates.Add("password = @newPassword");
cmd.Parameters.AddWithValue("@newPassword", Argon2.Hash(newPassword));
}
if (newEmail != null)
{
updates.Add("email = @newEmail");
cmd.Parameters.AddWithValue("@newEmail", newEmail);
}
cmd.CommandText = $"UPDATE users SET {string.Join(", ", updates)} WHERE username = @username";
cmd.Parameters.AddWithValue("@username", username);
await cmd.ExecuteNonQueryAsync();
}
}