// // Created by wolverindev on 24.03.18. // #include #include #include #include #include #include #include "SqlDataManager.h" using namespace std; using namespace std::chrono; using namespace ts; using namespace ts::server; SqlDataManager::SqlDataManager() {} SqlDataManager::~SqlDataManager() {} #define EXECUTE(msg, cmd) \ result = sql::command(this->manager, cmd).execute(); \ if(!result){ \ error = string(msg) + " Command '" + std::string(cmd) + "' returns " + result.fmtStr(); \ return false; \ } #define EXECUTE_(error_message, cmd, ignore) \ result = sql::command(this->manager, cmd).execute(); \ if(!result && result.msg().find(ignore) == string::npos){ \ error = string(error_message) + " Command '" + std::string(cmd) + "' returns " + result.fmtStr(); \ return false; \ } #define BUILD_CREATE_TABLE(tblName, types) "CREATE TABLE IF NOT EXISTS `" tblName "` (" types ")" #define CREATE_TABLE(table, types, append) EXECUTE("Could not setup SQL tables! ", BUILD_CREATE_TABLE(table, types) + append); #define DROP_INDEX(tblName, rowName) EXECUTE_("Failed to drop old indexes", "DROP INDEX IF EXISTS `idx_" tblName "_" rowName "`", ""); #define BUILD_CREATE_INDEX(tblName, rowName) "CREATE INDEX `idx_" tblName "_" rowName "` ON `" tblName "` (`" rowName "`);" #define CREATE_INDEX(tblName, rowName) EXECUTE_("Could not setup SQL table indexes! ", BUILD_CREATE_INDEX(tblName, rowName), "Duplicate"); #define DROP_INDEX2R(tblName, rowName1, rowName2) EXECUTE_("Failed to drop old indexes", "DROP INDEX IF EXISTS `idx_" tblName "_" rowName1 "_" rowName2 "`;", ""); #define BUILD_CREATE_INDEX2R(tblName, rowName1, rowName2) "CREATE INDEX `idx_" tblName "_" rowName1 "_" rowName2 "` ON `" tblName "` (`" rowName1 "`, `" rowName2 "`);" #define CREATE_INDEX2R(tblName, rowName1, rowName2) EXECUTE_("Could not setup SQL table indexes! ", BUILD_CREATE_INDEX2R(tblName, rowName1, rowName2), "Duplicate"); #define RESIZE_COLUMN(tblName, rowName, size) up vote EXECUTE("Could not change column size", "ALTER TABLE " tblName " ALTER COLUMN " rowName " varchar(" size ")"); #define CURRENT_VERSION 11 #define CLIENT_UID_LENGTH "64" #define CLIENT_NAME_LENGTH "128" #define UNKNOWN_KEY_LENGTH "256" template struct alive_watch { bool do_notify; T notify; alive_watch(T&& function) : notify(std::forward(function)), do_notify(true) { } ~alive_watch() { if(do_notify) notify(); } }; bool SqlDataManager::initialize(std::string& error) { if(ts::config::database::url.find("sqlite://") == 0) this->manager = new sql::sqlite::SqliteManager(); else if(ts::config::database::url.find("mysql://") == 0) this->manager = new sql::mysql::MySQLManager(); else { error = "Invalid database type!"; return false; } auto result = manager->connect(ts::config::database::url); if(!result) { error = "Could not connect to " + ts::config::database::url + " (" + result.fmtStr() + ")."; return false; } string command_append_utf8; if(manager->getType() == sql::TYPE_MYSQL) { sql::command(this->manager, "SET NAMES utf8").execute(); //sql::command(this->manager, "DEFAULT CHARSET=utf8").execute(); command_append_utf8 = " CHARACTER SET=utf8"; } else if(manager->getType() == sql::TYPE_SQLITE) { if(!config::database::sqlite::journal_mode.empty()) sql::command(this->manager, "PRAGMA journal_mode=" + config::database::sqlite::journal_mode + ";").execute(); if(!config::database::sqlite::sync_mode.empty()) sql::command(this->manager, "PRAGMA synchronous=" + config::database::sqlite::sync_mode + ";").execute(); if(!config::database::sqlite::locking_mode.empty()) sql::command(this->manager, "PRAGMA locking_mode=" + config::database::sqlite::locking_mode + ";").execute(); sql::command(this->manager, "PRAGMA encoding = \"UTF-8\";").execute(); } this->detectVersion(); //general stuff if(this->version != CURRENT_VERSION) { auto timestamp_start = system_clock::now(); logMessage(LOG_GENERAL, "Upgrading database from version " + to_string(this->version) + " to " + to_string(CURRENT_VERSION) + ". This could take a moment!"); if(manager->getType() == sql::TYPE_SQLITE) { result = sql::command(this->sql(),"BEGIN TRANSACTION;").execute(); if(!result) { error = "failed to begin transaction (" + result.fmtStr() + ")"; return false; } } alive_watch rollback_watch([&]{ if(manager->getType() == sql::TYPE_SQLITE) { auto result = sql::command(this->sql(), "ROLLBACK;").execute(); if (!result) { logCritical(LOG_GENERAL, "Failed to rollback database after transaction."); return; } debugMessage(LOG_GENERAL, "Rollbacked database successfully."); } }); switch (this->version) { case -1: CREATE_TABLE("general", "`key` VARCHAR(" UNKNOWN_KEY_LENGTH "), `value` TEXT", command_append_utf8); CREATE_TABLE("servers", "`serverId` INT NOT NULL, `host` TEXT NOT NULL, `port` INT", command_append_utf8); CREATE_TABLE("assignedGroups", "`serverId` INT NOT NULL, `cldbid` INT NOT NULL, `groupId` INT, `channelId` INT DEFAULT -1, `until` BIGINT DEFAULT -1", command_append_utf8); CREATE_TABLE("groups", "`serverId` INT NOT NULL, `groupId` INTEGER, `target` INT, `type` INT, `displayName` VARCHAR(" CLIENT_NAME_LENGTH ")", command_append_utf8); CREATE_TABLE("queries", "`username` VARCHAR(" CLIENT_NAME_LENGTH "), `password` TEXT, `uniqueId` VARCHAR(" CLIENT_UID_LENGTH ")", command_append_utf8); CREATE_TABLE("clients", "`serverId` INT NOT NULL, `cldbid` INTEGER, `clientUid` VARCHAR(" CLIENT_UID_LENGTH "), `firstConnect` BIGINT, `lastConnect` BIGINT, `connections` INT, `lastName` VARCHAR(" CLIENT_NAME_LENGTH ")", command_append_utf8); CREATE_TABLE("channels", "`serverId` INT NOT NULL, `channelId` INT, `type` INT, `parentId` INT", command_append_utf8); CREATE_TABLE("properties", "`serverId` INTEGER DEFAULT -1, `type` INTEGER, `id` INTEGER, `key` VARCHAR(" UNKNOWN_KEY_LENGTH "), `value` TEXT", command_append_utf8); CREATE_TABLE("permissions", "`serverId` INT NOT NULL, `type` INT, `id` INT, `channelId` INT, `permId` VARCHAR(" UNKNOWN_KEY_LENGTH "), `value` INT, `grant` INT", command_append_utf8); CREATE_TABLE("bannedClients", "`banId` INTEGER NOT NULL PRIMARY KEY, `serverId` INT NOT NULL, `invokerDbId` INT NOT NULL, `reason` TEXT, `hwid` VARCHAR(" CLIENT_UID_LENGTH "), `uid` VARCHAR(" CLIENT_UID_LENGTH "), `name` VARCHAR(" CLIENT_NAME_LENGTH "), `ip` VARCHAR(128), `strType` VARCHAR(32), `created` BIGINT DEFAULT -1, `until` BIGINT DEFAULT -1", command_append_utf8); CREATE_TABLE("tokens", "`serverId` INT NOT NULL, `type` INT NOT NULL, `token` VARCHAR(128), `targetGroup` INT NOT NULL, `targetChannel` INT, `description` TEXT , `created` INT", command_append_utf8); CREATE_TABLE("complains", "`serverId` INT NOT NULL, `targetId` INT NOT NULL, `reporterId` INT NOT NULL, `reason` TEXT, `created` INT", command_append_utf8); CREATE_TABLE("letters", "`serverId` INT NOT NULL, `letterId` INTEGER NOT NULL PRIMARY KEY, `sender` VARCHAR(" CLIENT_UID_LENGTH "), `receiver` VARCHAR(" CLIENT_UID_LENGTH "), `created` INT, `subject` TEXT, `message` TEXT, `read` INT", command_append_utf8); CREATE_TABLE("musicbots", "`serverId` INT, `botId` INT, `uniqueId` VARCHAR(" CLIENT_UID_LENGTH "), `owner` INT", command_append_utf8); this->changeVersion(0); case 0: CREATE_INDEX("general", "key"); CREATE_INDEX("servers", "serverId"); CREATE_INDEX2R("assignedGroups", "serverId", "cldbid"); CREATE_INDEX2R("groups", "serverId", "groupId"); CREATE_INDEX("groups", "serverId"); CREATE_INDEX("queries", "username"); CREATE_INDEX("clients", "serverId"); CREATE_INDEX2R("clients", "serverId", "cldbid"); CREATE_INDEX("channels", "serverId"); CREATE_INDEX("properties", "serverId"); CREATE_INDEX("permissions", "serverId"); CREATE_INDEX2R("properties", "serverId", "id"); CREATE_INDEX2R("permissions", "serverId", "channelId"); CREATE_INDEX("bannedClients", "serverId"); CREATE_INDEX("bannedClients", "banId"); CREATE_INDEX2R("bannedClients", "serverId", "hwid"); CREATE_INDEX2R("bannedClients", "serverId", "name"); CREATE_INDEX2R("bannedClients", "serverId", "uid"); CREATE_INDEX2R("bannedClients", "serverId", "ip"); CREATE_INDEX("tokens", "serverId"); CREATE_INDEX("complains", "serverId"); CREATE_INDEX("letters", "serverId"); CREATE_INDEX("letters", "letterId"); CREATE_INDEX("musicbots", "serverId"); this->changeVersion(1); case 1: sql::command(this->sql(), "UPDATE `properties` SET `type` = :type WHERE `serverId` = 0 AND `id` = 0", variable{":type", property::PropertyType::PROP_TYPE_INSTANCE}).execute(); this->changeVersion(2); case 2: sql::command(this->sql(), "ALTER TABLE permissions ADD flag_skip BOOL;").execute(); sql::command(this->sql(), "ALTER TABLE permissions ADD flag_negate BOOL;").execute(); this->changeVersion(3); case 3: EXECUTE("Failed to update ban table", "ALTER TABLE `bannedClients` ADD COLUMN `triggered` INT DEFAULT 0;"); CREATE_TABLE("ban_trigger", "`server_id` INT, `ban_id` INT, `unique_id` VARCHAR(" CLIENT_UID_LENGTH "), `hardware_id` VARCHAR(" CLIENT_UID_LENGTH "), `name` VARCHAR(" CLIENT_NAME_LENGTH "), `ip` VARCHAR(128), `timestamp` BIGINT", command_append_utf8); CREATE_INDEX2R("ban_trigger", "server_id", "ban_id"); this->changeVersion(4); case 4: sql::command(this->sql(), "ALTER TABLE queries ADD server INT;").execute(); this->changeVersion(5); case 5: CREATE_TABLE("playlists", "`serverId` INT NOT NULL, `playlist_id` INT", command_append_utf8); CREATE_INDEX("playlists", "serverId"); CREATE_TABLE("playlist_songs", "`serverId` INT NOT NULL, `playlist_id` INT, `song_id` INT, `order_id` INT, `invoker_dbid` INT, `url` TEXT, `url_loader` TEXT", command_append_utf8); CREATE_INDEX2R("playlist_songs", "serverId", "playlist_id"); this->changeVersion(6); sql::command(this->sql(), "UPDATE `permissions ` SET `permId` = `b_client_music_create_temporary` WHERE `permId` = `b_client_music_create`").execute(); case 6: sql::command(this->sql(), "ALTER TABLE playlist_songs ADD loaded BOOL;").execute(); sql::command(this->sql(), "ALTER TABLE playlist_songs ADD metadata TEXT;").execute(); case 7: /* recreate permission table */ /* DROP TABLE `permissions`, `properties`; ALTER TABLE permissions_v6 RENAME permissions; ALTER TABLE properties_v6 RENAME properties; */ /* MySQL command START TRANSACTION; SET SESSION sql_mode='STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION'; -- Modify the permissions ALTER TABLE permissions RENAME TO permissions_v6; CREATE TABLE `permissions`(`serverId` INT NOT NULL, `type` INT, `id` INT, `channelId` INT, `permId` VARCHAR(256), `value` INT, `grant` INT, `flag_skip` TINYINT(1), `flag_negate` TINYINT(1), CONSTRAINT PK PRIMARY KEY(`serverId`, `type`, `id`, `channelId`, `permId`)) CHARACTER SET=utf8; CREATE INDEX `idx_permissions_serverId` ON `permissions` (`serverId`); CREATE INDEX `idx_permissions_serverId_channelId` ON `permissions` (`serverId`, `channelId`); INSERT INTO `permissions` SELECT * FROM `permissions_v6` GROUP BY `serverId`, `type`, `id`, `channelId`, `permId`; -- Modify the properties ALTER TABLE properties RENAME TO properties_v6; CREATE TABLE properties(`serverId` INTEGER DEFAULT -1, `type` INTEGER, `id` INTEGER, `key` VARCHAR(256), `value` TEXT, CONSTRAINT PK PRIMARY KEY (`serverId`, `type`, `id`, `key`)) CHARACTER SET=utf8; CREATE INDEX `idx_properties_serverId` ON `properties` (`serverId`); CREATE INDEX `idx_properties_serverId_id` ON `properties` (`serverId`, `id`); INSERT INTO `properties` SELECT * FROM `properties_v6` GROUP BY `serverId`, `type`, `id`, `key`; -- Delete orphaned permissions and properties DELETE FROM `permissions` WHERE (`type` = 1 OR `type` = 2) AND NOT ((`serverId`, `channelId`) IN (SELECT `serverId`, `channelId` FROM `channels`) OR `channelId` = 0); DELETE FROM `permissions` WHERE `type` = 0 AND NOT (`serverId`, `id`) IN (SELECT `serverId`, `groupId` FROM `groups`); DELETE FROM `permissions` WHERE `type` = 2 AND NOT (`serverId`, `id`) IN (SELECT `serverId`, `cldbid` FROM `clients`); DELETE FROM `properties` WHERE `type` = 1 AND NOT (`serverId` IN (SELECT `serverId` FROM servers) OR `serverId` = 0); ROLLBACK; */ if(manager->getType() == sql::TYPE_MYSQL) { /* * FIXME implement update for MySQL as well! auto mysql = (sql::mysql::MySQLManager*) this->sql(); if(!result) { error = "failed to update database (" + result.fmtStr() + ")"; return false; } */ } else { result = sql::command(this->sql(), "ALTER TABLE permissions RENAME TO permissions_v6;").execute(); if(!result) { error = "Failed to rename permission to permission v6 (" + result.fmtStr() + ")"; return false; } result = sql::command(this->sql(), "CREATE TABLE `permissions`(`serverId` INT NOT NULL, `type` INT, `id` INT, `channelId` INT, `permId` VARCHAR(256), `value` INT, `grant` INT, `flag_skip` BOOL, `flag_negate` BOOL, CONSTRAINT PK PRIMARY KEY(`serverId`, `type`, `id`, `channelId`, `permId`));").execute(); if(!result) { error = "Failed to create new permission table (" + result.fmtStr() + ")"; return false; } result = sql::command(this->sql(), "INSERT INTO `permissions` SELECT * FROM `permissions_v6` GROUP BY `serverId`, `type`, `id`, `channelId`, `permId`;").execute(); if(!result) { error = "Failed to insert unique permissions (" + result.fmtStr() + ")"; return false; } if(manager->getType() == sql::TYPE_SQLITE) { DROP_INDEX("permissions", "serverId"); DROP_INDEX2R("permissions", "serverId", "channelId"); } CREATE_INDEX("permissions", "serverId"); CREATE_INDEX2R("permissions", "serverId", "channelId"); /* recreate property table */ result = sql::command(this->sql(), "ALTER TABLE properties RENAME TO properties_v6;").execute(); if(!result) { error = "Failed to rename properties to properties v6 (" + result.fmtStr() + ")"; return false; } result = sql::command(this->sql(), "CREATE TABLE properties(`serverId` INTEGER DEFAULT -1, `type` INTEGER, `id` INTEGER, `key` VARCHAR(256), `value` TEXT, CONSTRAINT PK PRIMARY KEY (`serverId`, `type`, `id`, `key`));").execute(); if(!result) { error = "Failed to create new properties table (" + result.fmtStr() + ")"; return false; } /* SET SESSION sql_mode='STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION'; INSERT INTO `properties` SELECT * FROM `properties_v6` GROUP BY `serverId`, `type`, `id`, `key`; */ result = sql::command(this->sql(), "INSERT INTO `properties` SELECT * FROM `properties_v6` GROUP BY `serverId`, `type`, `id`, `key`;").execute(); if(!result) { error = "Failed to insert unique properties (" + result.fmtStr() + ")"; return false; } if(manager->getType() == sql::TYPE_SQLITE) { DROP_INDEX("properties", "serverId"); DROP_INDEX2R("properties", "serverId", "id"); } CREATE_INDEX("properties", "serverId"); CREATE_INDEX2R("properties", "serverId", "id"); /* SELECT * FROM `permissions` WHERE `type` = 1 AND (`serverId`, `channelId`) IN (SELECT `serverId`, `channelId` FROM `channels`) */ /* Channel permission cleanup: DELETE FROM `permissions` WHERE `type` = 1 AND NOT (`serverId`, `channelId`) IN (SELECT `serverId`, `channelId` FROM `channels`) */ sql::command(this->sql(), "DELETE FROM `permissions` WHERE (`type` = 1 OR `type` = 2) AND NOT ((`serverId`, `channelId`) IN (SELECT `serverId`, `channelId` FROM `channels`) OR `channelId` = 0);").execute(); sql::command(this->sql(), "DELETE FROM `permissions` WHERE `type` = 0 AND NOT (`serverId`, `id`) IN (SELECT `serverId`, `groupId` FROM `groups`);").execute(); sql::command(this->sql(), "DELETE FROM `permissions` WHERE `type` = 2 AND NOT (`serverId`, `id`) IN (SELECT `serverId`, `cldbid` FROM `clients`);").execute(); sql::command(this->sql(), "DELETE FROM `properties` WHERE `type` = 1 AND NOT (`serverId` IN (SELECT `serverId` FROM servers) OR `serverId` = 0);").execute(); } this->changeVersion(8); case 8: result = sql::command(this->sql(), "UPDATE `queries` SET `server` = 0 WHERE `server` IS NULL").execute(); if(!result) { error = "Failed to drop null query entries (" + result.fmtStr() + ")"; return false; } this->changeVersion(9); case 9: // //"UPDATE `permissions` SET `id` = :id WHERE `type` = :channel_type" ;permission::SQL_PERM_CHANNEL result = sql::command(this->sql(), "UPDATE `permissions` SET `id` = :id WHERE `type` = :channel_type;", variable{":channel_type", permission::SQL_PERM_CHANNEL}, variable{":id", 0}).execute(); if(!result) { if(result.code() == 1) { //constraint failed => duplicated ids for example size_t count = 0; result = sql::command(this->sql(), "SELECT COUNT(*) FROM `permissions` WHERE NOT `id` = :id AND `type` = :type", variable{":type", permission::SQL_PERM_CHANNEL}, variable{":id", 0}).query([&](int, std::string* values, std::string*) { count = stoll(values[0]); }); logError(LOG_GENERAL, "Database contains invalid channel permissions. Deleting permissions ({}).", count); result = sql::command(this->sql(), "DELETE FROM `permissions` WHERE NOT `id` = :id AND `type` = :type", variable{":channel_type", permission::SQL_PERM_CHANNEL}, variable{":id", 0}).execute(); } if(!result) { error = "Failed to fix channel properties (" + result.fmtStr() + ")"; return false; } } this->changeVersion(10); case 10: CREATE_TABLE("conversations", "`server_id` INT, `channel_id` INT, `conversation_id` INT, `file_path` TEXT", command_append_utf8); CREATE_TABLE("conversation_blocks", "`server_id` INT, `conversation_id` INT, `begin_timestamp` INT, `end_timestamp` INT, `block_offset` INT, `flags` INT", command_append_utf8); CREATE_INDEX("conversations", "server_id"); CREATE_INDEX2R("conversation_blocks", "server_id", "conversation_id"); this->changeVersion(11); default: if(manager->getType() == sql::TYPE_SQLITE) { result = sql::command(this->sql(), "COMMIT;").execute(); if(!result) { error = "failed to commit changes"; return false; } } rollback_watch.do_notify = false; /* transaction was successful */ break; } auto timestamp_end = system_clock::now(); logMessage(LOG_GENERAL, "Database upgrade took {}ms", duration_cast(timestamp_end - timestamp_start).count()); } //Advanced locked test { bool property_exists = false; sql::command(this->sql(), "SELECT * FORM `general` WHERE `key` = :key", variable{":key", "lock_test"}).query([](bool& flag, int, string*, string*) { flag = true; }, property_exists); sql::result res; if(!property_exists) { res = sql::command(this->sql(), "INSERT INTO `general` (`key`, `value`) VALUES (:key, :value);", variable{":key", "lock_test"}, variable{":value", "UPDATE ME!"}).execute(); } else { res = sql::command(this->sql(), "UPDATE `general` SET `value`= :value WHERE `key`= :key;", variable{":key", "lock_test"}, variable{":value", "TeaSpeak created by WolverinDEV <3"}).execute(); } if(!res) { if(res.msg().find("database is locked") != string::npos) error = "database is locked"; else error = "Failed to execute lock test! Command result: " + res.fmtStr(); return false; } } return true; } void SqlDataManager::finalize() { if(this->manager) this->manager->disconnect(); delete this->manager; this->manager = nullptr; } void SqlDataManager::detectVersion() { sql::command(this->manager, "SELECT `value` FROM `general` WHERE `key`= :key", variable{":key", "data_version"}).query([&](int length, char** values, char**){ this->version = atoi(values[0]); this->version_present = false; return 0; }); } void SqlDataManager::changeVersion(int version) { string command; if(this->version_present) command = "UPDATE `general` SET `value`= :version WHERE `key`= :key;"; else command = "INSERT INTO `general` (`key`, `value`) VALUES (:key, :version);"; auto result = sql::command(this->manager, command, variable{":version", version}, variable{":key", "data_version"}).execute(); if(!result) logError("Could not update SQL version. (" + result.fmtStr() + ")"); else this->version_present = true; this->version = version; }