From 5473457c0c08fee4b4e26edce0b89b4bca43cfba Mon Sep 17 00:00:00 2001 From: Akkadius Date: Sun, 7 Jul 2019 05:26:10 -0500 Subject: [PATCH] Migrate database schema --- loginserver/database.cpp | 64 ++++++++----------- .../login_util/EQEmuLoginServerDBInstall.sql | 57 ----------------- loginserver/login_util/login_schema.sql | 59 +++++++++++++++++ .../login_util/tblLoginServerAccounts.sql | 11 ---- .../login_util/tblServerAdminRegistration.sql | 12 ---- loginserver/login_util/tblServerListType.sql | 10 --- .../login_util/tblWorldServerRegistration.sql | 14 ---- 7 files changed, 86 insertions(+), 141 deletions(-) delete mode 100644 loginserver/login_util/EQEmuLoginServerDBInstall.sql create mode 100644 loginserver/login_util/login_schema.sql delete mode 100644 loginserver/login_util/tblLoginServerAccounts.sql delete mode 100644 loginserver/login_util/tblServerAdminRegistration.sql delete mode 100644 loginserver/login_util/tblServerListType.sql delete mode 100644 loginserver/login_util/tblWorldServerRegistration.sql diff --git a/loginserver/database.cpp b/loginserver/database.cpp index 7db8ddad5..8c5eb5dce 100644 --- a/loginserver/database.cpp +++ b/loginserver/database.cpp @@ -95,8 +95,7 @@ bool Database::GetLoginDataFromAccountInfo( ) { auto query = fmt::format( - "SELECT LoginServerID, AccountPassword FROM {0} WHERE AccountName = '{1}' AND AccountLoginserver = '{2}' LIMIT 1", - server.options.GetAccountTable(), + "SELECT id, account_password FROM login_accounts WHERE account_name = '{0}' AND source_loginserver = '{1}' LIMIT 1", EscapeString(name), EscapeString(loginserver) ); @@ -193,8 +192,7 @@ bool Database::GetLoginTokenDataFromToken( unsigned int Database::GetFreeID(const std::string &loginserver) { auto query = fmt::format( - "SELECT IFNULL(MAX(LoginServerID), 0) + 1 FROM {0} WHERE AccountLoginServer='{1}'", - server.options.GetAccountTable(), + "SELECT IFNULL(MAX(id), 0) + 1 FROM login_accounts WHERE source_loginserver = '{0}'", EscapeString(loginserver) ); @@ -222,7 +220,10 @@ bool Database::CreateLoginData( unsigned int &id ) { - return CreateLoginDataWithID(name, password, loginserver, GetFreeID(loginserver)); + uint32 free_id = GetFreeID(loginserver); + id = free_id; + + return CreateLoginDataWithID(name, password, loginserver, free_id); } /** @@ -244,9 +245,8 @@ bool Database::CreateLoginDataWithID( } auto query = fmt::format( - "INSERT INTO {0} (LoginServerID, AccountLoginserver, AccountName, AccountPassword, AccountEmail, LastLoginDate, LastIPAddress) " - "VALUES ({1}, '{2}', '{3}', '{4}', 'local_creation', NOW(), '127.0.0.1')", - server.options.GetAccountTable(), + "INSERT INTO login_accounts (id, source_loginserver, account_name, account_password, account_email, last_login_date, last_ip_address, created_at) " + "VALUES ({0}, '{1}', '{2}', '{3}', 'local_creation', NOW(), '127.0.0.1', NOW())", id, EscapeString(loginserver), EscapeString(in_account_name), @@ -277,8 +277,7 @@ bool Database::DoesLoginServerAccountExist( } auto query = fmt::format( - "SELECT AccountName FROM {0} WHERE AccountName = '{1}' AND AccountLoginserver = '{2}'", - server.options.GetAccountTable(), + "SELECT AccountName FROM login_accounts WHERE account_name = '{0}' AND source_loginserver = '{1}'", EscapeString(name), EscapeString(loginserver) ); @@ -310,8 +309,7 @@ void Database::UpdateLoginHash( ); auto query = fmt::format( - "UPDATE {0} SET AccountPassword='{1}' WHERE AccountName='{2}' AND AccountLoginserver='{3}'", - server.options.GetAccountTable(), + "UPDATE login_accounts SET account_password = '{0}' WHERE account_name = '{1}' AND source_loginserver = '{2}'", hash, EscapeString(name), EscapeString(loginserver) @@ -346,19 +344,17 @@ bool Database::GetWorldRegistration( { auto query = fmt::format( "SELECT\n" - " ifnull(WSR.ServerID, 999999) AS ServerID,\n" - " WSR.ServerTagDescription,\n" - " ifnull(WSR.ServerTrusted, 0) AS ServerTrusted,\n" - " ifnull(SLT.ServerListTypeID, 3) AS ServerListTypeID,\n" - " SLT.ServerListTypeDescription,\n" - " ifnull(WSR.ServerAdminID, 0) AS ServerAdminID\n" + " ifnull(WSR.id, 999999) AS server_id,\n" + " WSR.tag_description,\n" + " ifnull(WSR.is_server_trusted, 0) AS is_server_trusted,\n" + " ifnull(SLT.id, 3) AS login_server_list_type_id,\n" + " SLT.description,\n" + " ifnull(WSR.login_server_admin_id, 0) AS login_server_admin_id\n" "FROM\n" - " {0} AS WSR\n" - " JOIN {1} AS SLT ON WSR.ServerListTypeID = SLT.ServerListTypeID\n" + " login_world_servers AS WSR\n" + " JOIN login_server_list_types AS SLT ON WSR.login_server_list_type_id = SLT.id\n" "WHERE\n" - " WSR.ServerShortName = '{2}' LIMIT 1", - server.options.GetWorldRegistrationTable(), - server.options.GetWorldServerTypeTable(), + " WSR.short_name = '{0}' LIMIT 1", EscapeString(short_name) ); @@ -379,8 +375,7 @@ bool Database::GetWorldRegistration( if (db_account_id > 0) { auto world_registration_query = fmt::format( - "SELECT AccountName, AccountPassword FROM {0} WHERE ServerAdminID = {1} LIMIT 1", - server.options.GetWorldAdminRegistrationTable(), + "SELECT account_name, account_password FROM login_server_admins WHERE id = {0} LIMIT 1", db_account_id ); @@ -405,8 +400,7 @@ bool Database::GetWorldRegistration( void Database::UpdateLSAccountData(unsigned int id, std::string ip_address) { auto query = fmt::format( - "UPDATE {0} SET LastIPAddress = '{1}', LastLoginDate = NOW() where LoginServerId = {2}", - server.options.GetAccountTable(), + "UPDATE login_accounts SET last_ip_address = '{0}', last_login_date = NOW() where id = {1}", ip_address, id ); @@ -428,9 +422,8 @@ void Database::UpdateLSAccountInfo( ) { auto query = fmt::format( - "REPLACE {0} SET LoginServerID = {1}, AccountName = '{2}', AccountPassword = sha('{3}'), AccountCreateDate = now(), " - "AccountEmail = '{4}', LastIPAddress = '0.0.0.0', LastLoginDate = now()", - server.options.GetAccountTable(), + "REPLACE login_accounts SET id = {0}, account_name = '{1}', account_password = sha('{2}'), " + "account_email = '{3}', last_ip_address = '0.0.0.0', last_login_date = now()", id, EscapeString(name), EscapeString(password), @@ -448,8 +441,7 @@ void Database::UpdateLSAccountInfo( void Database::UpdateWorldRegistration(unsigned int id, std::string long_name, std::string ip_address) { auto query = fmt::format( - "UPDATE {0} SET ServerLastLoginDate = NOW(), ServerLastIPAddr = '{1}', ServerLongName = '{2}' WHERE ServerID = {3}", - server.options.GetWorldRegistrationTable(), + "UPDATE login_world_servers SET last_login_date = NOW(), last_ip_address = '{0}', long_name = '{1}' WHERE id = {2}", ip_address, EscapeString(long_name), id @@ -471,8 +463,7 @@ bool Database::CreateWorldRegistration( ) { auto query = fmt::format( - "SELECT ifnull(max(ServerID),0) + 1 FROM {0}", - server.options.GetWorldRegistrationTable() + "SELECT ifnull(max(id),0) + 1 FROM login_world_servers" ); auto results = QueryDatabase(query); @@ -485,9 +476,8 @@ bool Database::CreateWorldRegistration( id = atoi(row[0]); auto insert_query = fmt::format( - "INSERT INTO {0} SET ServerID = {1}, ServerLongName = '{2}', ServerShortName = '{3}', \n" - "ServerListTypeID = 3, ServerAdminID = 0, ServerTrusted = 0, ServerTagDescription = ''", - server.options.GetWorldRegistrationTable(), + "INSERT INTO login_world_servers SET id = {0}, long_name = '{1}', short_name = '{2}', \n" + "login_server_list_type_id = 3, login_server_admin_id = 0, is_server_trusted = 0, tag_description = ''", id, long_name, short_name diff --git a/loginserver/login_util/EQEmuLoginServerDBInstall.sql b/loginserver/login_util/EQEmuLoginServerDBInstall.sql deleted file mode 100644 index ae8f6e5e8..000000000 --- a/loginserver/login_util/EQEmuLoginServerDBInstall.sql +++ /dev/null @@ -1,57 +0,0 @@ -DROP TABLE IF EXISTS tblLoginServerAccounts; -CREATE TABLE IF NOT EXISTS tblLoginServerAccounts ( - LoginServerID integer unsigned NOT NULL auto_increment, - AccountName varchar(30) NOT NULL, - AccountPassword varchar(50) NOT NULL, - AccountCreateDate timestamp default CURRENT_TIMESTAMP NOT NULL, - AccountEmail varchar(100) NOT NULL, - LastLoginDate datetime NOT NULL, - LastIPAddress varchar(15) NOT NULL, - PRIMARY KEY (LoginServerID, AccountName) -) ENGINE=InnoDB; - -insert into tblLoginServerAccounts (AccountName, AccountPassword, AccountEmail, LastLoginDate, LastIPAddress) values('Admin', sha('password'), 'admin@somewhere.com', now(), '127.0.0.1'); - -DROP TABLE IF EXISTS tblServerListType; -CREATE TABLE IF NOT EXISTS tblServerListType ( - ServerListTypeID integer unsigned NOT NULL, - ServerListTypeDescription varchar(20) NOT NULL, - PRIMARY KEY (ServerListTypeID) -) ENGINE=MyISAM; - -INSERT INTO tblServerListType (ServerListTypeID, ServerListTypeDescription) VALUES (1, 'Legends'); -INSERT INTO tblServerListType (ServerListTypeID, ServerListTypeDescription) VALUES (2, 'Preferred'); -INSERT INTO tblServerListType (ServerListTypeID, ServerListTypeDescription) VALUES (3, 'Standard'); - -DROP TABLE IF EXISTS tblServerAdminRegistration; -CREATE TABLE IF NOT EXISTS tblServerAdminRegistration ( - ServerAdminID integer unsigned NOT NULL auto_increment, - AccountName varchar(30) NOT NULL, - AccountPassword varchar(30) NOT NULL, - FirstName varchar(40) NOT NULL, - LastName varchar(50) NOT NULL, - Email varchar(100) NULL, - RegistrationDate datetime NOT NULL, - RegistrationIPAddr varchar(15) NOT NULL, - PRIMARY KEY (ServerAdminID, Email) -) ENGINE=MyISAM; - -INSERT INTO tblServerAdminRegistration (AccountName, AccountPassword, FirstName, LastName, Email, RegistrationDate, RegistrationIPAddr) VALUES ('Admin', 'Password', 'Tom', 'Wilson', 'Tom.Wilson@gmail.com', now(), '0.0.0.0'); - -DROP TABLE IF EXISTS tblWorldServerRegistration; -CREATE TABLE IF NOT EXISTS tblWorldServerRegistration ( - ServerID integer unsigned NOT NULL auto_increment, - ServerLongName varchar(100) NOT NULL, - ServerTagDescription varchar(50) NOT NULL DEFAULT '', - ServerShortName varchar(25) NOT NULL, - ServerListTypeID integer NOT NULL, - ServerLastLoginDate datetime NULL, - ServerLastIPAddr varchar(15) NULL, - ServerAdminID integer NOT NULL, - ServerTrusted integer NOT NULL, - Note varchar(300) NULL, - PRIMARY KEY (ServerID, ServerLongName) -) ENGINE=InnoDB; - - -INSERT INTO tblWorldServerRegistration (ServerLongName, ServerTagDescription, ServerShortName, ServerListTypeID, ServerLastLoginDate, ServerLastIPAddr, ServerAdminID, ServerTrusted, Note) VALUES ('My Test Server', 'A test server', 'MTST', 1, now(), '0.0.0.0', 1, 0, 'This is a note for the test server'); diff --git a/loginserver/login_util/login_schema.sql b/loginserver/login_util/login_schema.sql new file mode 100644 index 000000000..b96f08e0e --- /dev/null +++ b/loginserver/login_util/login_schema.sql @@ -0,0 +1,59 @@ +CREATE TABLE `login_accounts` ( + `id` int(11) unsigned NOT NULL, + `account_name` varchar(50) NOT NULL, + `account_password` text NOT NULL, + `account_email` varchar(100) NOT NULL, + `source_loginserver` varchar(64) DEFAULT NULL, + `last_ip_address` varchar(15) NOT NULL, + `last_login_date` datetime NOT NULL, + `created_at` datetime DEFAULT NULL, + `updated_at` datetime DEFAULT current_timestamp(), + PRIMARY KEY (`id`,`account_name`), + UNIQUE KEY `source_loginserver_account_name` (`source_loginserver`,`account_name`) +) ENGINE=InnoDB DEFAULT CHARSET=latin1; + +CREATE TABLE `login_server_admins` ( + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `account_name` varchar(30) NOT NULL, + `account_password` varchar(100) NOT NULL, + `first_name` varchar(50) NOT NULL, + `last_name` varchar(50) NOT NULL, + `email` varchar(100) NOT NULL, + `registration_date` datetime NOT NULL, + `registration_ip_address` varchar(15) NOT NULL, + PRIMARY KEY (`id`,`account_name`) +) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=latin1; + +CREATE TABLE `login_server_list_types` ( + `id` int(10) unsigned NOT NULL, + `description` varchar(60) NOT NULL, + PRIMARY KEY (`id`) +) ENGINE=InnoDB DEFAULT CHARSET=latin1; + +INSERT INTO `login_server_list_types` (`id`, `description`) VALUES ('1', 'Legends'), +('2', 'Preferred'), +('3', 'Standard'); + +CREATE TABLE `login_world_servers` ( + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `long_name` varchar(100) NOT NULL, + `short_name` varchar(100) NOT NULL, + `tag_description` varchar(50) NOT NULL DEFAULT '', + `login_server_list_type_id` int(11) NOT NULL, + `last_login_date` datetime DEFAULT NULL, + `last_ip_address` varchar(15) DEFAULT NULL, + `login_server_admin_id` int(11) NOT NULL, + `is_server_trusted` int(11) NOT NULL, + `note` varchar(300) DEFAULT NULL, + PRIMARY KEY (`id`,`long_name`) +) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=latin1; + +CREATE TABLE `login_api_tokens` ( + `id` int(11) NOT NULL AUTO_INCREMENT, + `token` varchar(200) DEFAULT NULL, + `can_write` int(11) DEFAULT 0, + `can_read` int(11) DEFAULT 0, + `created_at` datetime DEFAULT NULL, + `updated_at` datetime DEFAULT current_timestamp(), + PRIMARY KEY (`id`) +) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=latin1; \ No newline at end of file diff --git a/loginserver/login_util/tblLoginServerAccounts.sql b/loginserver/login_util/tblLoginServerAccounts.sql deleted file mode 100644 index 65143b38b..000000000 --- a/loginserver/login_util/tblLoginServerAccounts.sql +++ /dev/null @@ -1,11 +0,0 @@ -DROP TABLE IF EXISTS tblLoginServerAccounts; -CREATE TABLE IF NOT EXISTS tblLoginServerAccounts ( - LoginServerID integer unsigned NOT NULL auto_increment, - AccountName varchar(30) NOT NULL, - AccountPassword varchar(50) NOT NULL, - AccountCreateDate timestamp default CURRENT_TIMESTAMP NOT NULL, - AccountEmail varchar(100) NOT NULL, - LastLoginDate datetime NOT NULL, - LastIPAddress varchar(15) NOT NULL, - PRIMARY KEY (LoginServerID, AccountName) -) ENGINE=InnoDB; diff --git a/loginserver/login_util/tblServerAdminRegistration.sql b/loginserver/login_util/tblServerAdminRegistration.sql deleted file mode 100644 index 8e91a5a77..000000000 --- a/loginserver/login_util/tblServerAdminRegistration.sql +++ /dev/null @@ -1,12 +0,0 @@ -DROP TABLE IF EXISTS tblServerAdminRegistration; -CREATE TABLE IF NOT EXISTS tblServerAdminRegistration ( - ServerAdminID integer unsigned NOT NULL auto_increment, - AccountName varchar(30) NOT NULL, - AccountPassword varchar(30) NOT NULL, - FirstName varchar(40) NOT NULL, - LastName varchar(50) NOT NULL, - Email varchar(100) NULL, - RegistrationDate datetime NOT NULL, - RegistrationIPAddr varchar(15) NOT NULL, - PRIMARY KEY (ServerAdminID, Email) -) ENGINE=MyISAM; \ No newline at end of file diff --git a/loginserver/login_util/tblServerListType.sql b/loginserver/login_util/tblServerListType.sql deleted file mode 100644 index fafaffe45..000000000 --- a/loginserver/login_util/tblServerListType.sql +++ /dev/null @@ -1,10 +0,0 @@ -DROP TABLE IF EXISTS tblServerListType; -CREATE TABLE IF NOT EXISTS tblServerListType ( - ServerListTypeID integer unsigned NOT NULL, - ServerListTypeDescription varchar(20) NOT NULL, - PRIMARY KEY (ServerListTypeID) -) ENGINE=MyISAM; - -INSERT INTO tblServerListType (ServerListTypeID, ServerListTypeDescription) VALUES (1, 'Legends'); -INSERT INTO tblServerListType (ServerListTypeID, ServerListTypeDescription) VALUES (2, 'Preferred'); -INSERT INTO tblServerListType (ServerListTypeID, ServerListTypeDescription) VALUES (3, 'Standard'); \ No newline at end of file diff --git a/loginserver/login_util/tblWorldServerRegistration.sql b/loginserver/login_util/tblWorldServerRegistration.sql deleted file mode 100644 index e0ee4dc9f..000000000 --- a/loginserver/login_util/tblWorldServerRegistration.sql +++ /dev/null @@ -1,14 +0,0 @@ -DROP TABLE IF EXISTS tblWorldServerRegistration; -CREATE TABLE IF NOT EXISTS tblWorldServerRegistration ( - ServerID integer unsigned NOT NULL auto_increment, - ServerLongName varchar(100) NOT NULL, - ServerTagDescription varchar(50) NOT NULL DEFAULT '', - ServerShortName varchar(25) NOT NULL, - ServerListTypeID integer NOT NULL, - ServerLastLoginDate datetime NULL, - ServerLastIPAddr varchar(15) NULL, - ServerAdminID integer NOT NULL, - Note varchar(300) NULL, - ServerTrusted int(11), - PRIMARY KEY (ServerID, ServerLongName) -) ENGINE=InnoDB;