From 1fb48536c234030c2004fb406ba6fdf3ff755c41 Mon Sep 17 00:00:00 2001 From: Kamil Date: Fri, 18 Dec 2020 18:59:04 +0100 Subject: [PATCH] created external sql file for tables and 1st migration --- sql/migration1.sql | 18 +++++ sql/tables.sql | 154 ++++++++++++++++++++++++++++++++++++++++ src/Database.cpp | 172 ++++----------------------------------------- 3 files changed, 185 insertions(+), 159 deletions(-) create mode 100644 sql/migration1.sql create mode 100644 sql/tables.sql diff --git a/sql/migration1.sql b/sql/migration1.sql new file mode 100644 index 0000000..d300751 --- /dev/null +++ b/sql/migration1.sql @@ -0,0 +1,18 @@ +BEGIN TRANSACTION; +-- New Columns +ALTER TABLE Accounts ADD BanReason TEXT DEFAULT '' NOT NULL; +ALTER TABLE RaceResults ADD RingCount INTEGER NOT NULL; +ALTER TABLE RaceResults ADD Time INTEGER NOT NULL; +-- Fix timestamps in Meta +INSERT INTO Meta (Key, Value) VALUES ('Created', 0); +INSERT INTO Meta (Key, Value) VALUES ('LastMigration', strftime('%s', 'now')); +UPDATE Meta SET Value = (SELECT Created FROM Meta WHERE Key = 'ProtocolVersion') Where Key = 'Created'; +-- Get rid of 'Created' Collumn +CREATE TABLE Temp(Key TEXT NOT NULL UNIQUE, Value INTEGER NOT NULL); +INSERT INTO Temp SELECT Key, Value FROM Meta; +DROP TABLE Meta; +ALTER TABLE Temp Rename TO Meta; +-- Update DB Version +UPDATE Meta SET Value = 2 WHERE Key = 'DatabaseVersion'; +UPDATE Meta SET Value = strftime('%s', 'now') WHERE Key = 'LastMigration'; +COMMIT; diff --git a/sql/tables.sql b/sql/tables.sql new file mode 100644 index 0000000..af725f5 --- /dev/null +++ b/sql/tables.sql @@ -0,0 +1,154 @@ +CREATE TABLE IF NOT EXISTS Accounts ( + AccountID INTEGER NOT NULL, + Login TEXT NOT NULL UNIQUE, + Password TEXT NOT NULL, + Selected INTEGER DEFAULT 1 NOT NULL, + AccountLevel INTEGER NOT NULL, + Created INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, + LastLogin INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, + BannedUntil INTEGER DEFAULT 0 NOT NULL, + BannedSince INTEGER DEFAULT 0 NOT NULL, + BanReason TEXT DEFAULT '' NOT NULL, + PRIMARY KEY(AccountID AUTOINCREMENT) + ); + + CREATE TABLE IF NOT EXISTS Players ( + PlayerID INTEGER NOT NULL, + AccountID INTEGER NOT NULL, + FirstName TEXT NOT NULL COLLATE NOCASE, + LastName TEXT NOT NULL COLLATE NOCASE, + NameCheck INTEGER NOT NULL, + Slot INTEGER NOT NULL, + Created INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, + LastLogin INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, + Level INTEGER DEFAULT 1 NOT NULL, + Nano1 INTEGER DEFAULT 0 NOT NULL, + Nano2 INTEGER DEFAULT 0 NOT NULL, + Nano3 INTEGER DEFAULT 0 NOT NULL, + AppearanceFlag INTEGER DEFAULT 0 NOT NULL, + TutorialFlag INTEGER DEFAULT 0 NOT NULL, + PayZoneFlag INTEGER DEFAULT 0 NOT NULL, + XCoordinates INTEGER NOT NULL, + YCoordinates INTEGER NOT NULL, + ZCoordinates INTEGER NOT NULL, + Angle INTEGER NOT NULL, + HP INTEGER NOT NULL, + FusionMatter INTEGER DEFAULT 0 NOT NULL, + Taros INTEGER DEFAULT 0 NOT NULL, + BatteryW INTEGER DEFAULT 0 NOT NULL, + BatteryN INTEGER DEFAULT 0 NOT NULL, + Mentor INTEGER DEFAULT 5 NOT NULL, + CurrentMissionID INTEGER DEFAULT 0 NOT NULL, + WarpLocationFlag INTEGER DEFAULT 0 NOT NULL, + SkywayLocationFlag BLOB NOT NULL, + FirstUseFlag BLOB NOT NULL, + Quests BLOB NOT NULL, + PRIMARY KEY(PlayerID AUTOINCREMENT), + FOREIGN KEY(AccountID) REFERENCES Accounts(AccountID) ON DELETE CASCADE, + UNIQUE (AccountID, Slot), + UNIQUE (FirstName, LastName) + ); + + CREATE TABLE IF NOT EXISTS Appearances ( + PlayerID INTEGER UNIQUE NOT NULL, + Body INTEGER DEFAULT 0 NOT NULL, + EyeColor INTEGER DEFAULT 1 NOT NULL, + FaceStyle INTEGER DEFAULT 1 NOT NULL, + Gender INTEGER DEFAULT 1 NOT NULL, + HairColor INTEGER DEFAULT 1 NOT NULL, + HairStyle INTEGER DEFAULT 1 NOT NULL, + Height INTEGER DEFAULT 0 NOT NULL, + SkinColor INTEGER DEFAULT 1 NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE + ); + + CREATE TABLE IF NOT EXISTS Inventory ( + PlayerID INTEGER NOT NULL, + Slot INTEGER NOT NULL, + ID INTEGER NOT NULL, + Type INTEGER NOT NULL, + Opt INTEGER NOT NULL, + TimeLimit INTEGER DEFAULT 0 NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + UNIQUE (PlayerID, Slot) + ); + + CREATE TABLE IF NOT EXISTS QuestItems ( + PlayerID INTEGER NOT NULL, + Slot INTEGER NOT NULL, + ID INTEGER NOT NULL, + Opt INTEGER NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + UNIQUE (PlayerID, Slot) + ); + + CREATE TABLE IF NOT EXISTS Nanos ( + PlayerID INTEGER NOT NULL, + ID INTEGER NOT NULL, + Skill INTEGER NOT NULL, + Stamina INTEGER DEFAULT 150 NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + UNIQUE (PlayerID, ID) + ); + + CREATE TABLE IF NOT EXISTS RunningQuests ( + PlayerID INTEGER NOT NULL, + TaskID INTEGER NOT NULL, + RemainingNPCCount1 INTEGER NOT NULL, + RemainingNPCCount2 INTEGER NOT NULL, + RemainingNPCCount3 INTEGER NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE + ); + + CREATE TABLE IF NOT EXISTS Buddyships ( + PlayerAID INTEGER NOT NULL, + PlayerBID INTEGER NOT NULL, + FOREIGN KEY(PlayerAID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + FOREIGN KEY(PlayerBID) REFERENCES Players(PlayerID) ON DELETE CASCADE + ); + + CREATE TABLE IF NOT EXISTS Blocks ( + PlayerID INTEGER NOT NULL, + BlockedPlayerID INTEGER NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + FOREIGN KEY(BlockedPlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE + ); + + CREATE TABLE IF NOT EXISTS EmailData ( + PlayerID INTEGER NOT NULL, + MsgIndex INTEGER NOT NULL, + ReadFlag INTEGER NOT NULL, + ItemFlag INTEGER NOT NULL, + SenderID INTEGER NOT NULL, + SenderFirstName TEXT NOT NULL COLLATE NOCASE, + SenderLastName TEXT NOT NULL COLLATE NOCASE, + SubjectLine TEXT NOT NULL, + MsgBody TEXT NOT NULL, + Taros INTEGER NOT NULL, + SendTime INTEGER NOT NULL, + DeleteTime INTEGER NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + UNIQUE(PlayerID, MsgIndex) + ); + + CREATE TABLE IF NOT EXISTS EmailItems ( + PlayerID INTEGER NOT NULL, + MsgIndex INTEGER NOT NULL, + Slot INTEGER NOT NULL, + ID INTEGER NOT NULL, + Type INTEGER NOT NULL, + Opt INTEGER NOT NULL, + TimeLimit INTEGER NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, + UNIQUE (MsgIndex, Slot) + ); + + CREATE TABLE IF NOT EXISTS RaceResults( + EPID INTEGER NOT NULL, + PlayerID INTEGER NOT NULL, + Score INTEGER NOT NULL, + RingCount INTEGER NOT NULL, + Time INTEGER NOT NULL, + Timestamp INTEGER NOT NULL, + FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE + ); diff --git a/src/Database.cpp b/src/Database.cpp index 7960aa3..bec9b3e 100644 --- a/src/Database.cpp +++ b/src/Database.cpp @@ -140,7 +140,7 @@ void Database::checkMetaTable() { // db migrations std::cout << "[INFO] Migrating Database to Version " << dbVersion + 1 << std::endl; - std::string path = "sql/migrations/" + std::to_string(dbVersion) + ".sql"; + std::string path = "sql/migration" + std::to_string(dbVersion) + ".sql"; std::ifstream file(path); if (!file.is_open()) { std::cout << "[FATAL] Failed to migrate database: Couldn't open migration file" << std::endl; @@ -215,171 +215,25 @@ void Database::createMetaTable() { } void Database::createTables() { - std::lock_guard lock(dbCrit); + std::ifstream file("sql/tables.sql"); + if (!file.is_open()) { + std::cout << "[FATAL] Failed to open database scheme" << std::endl; + exit(1); + } + std::ostringstream stream; + stream << file.rdbuf(); + std::string read = stream.str(); + const char* sql = read.c_str(); + + dbCrit.lock(); char* errMsg = 0; - const char* sql; - - sql = R"( - CREATE TABLE IF NOT EXISTS Accounts ( - AccountID INTEGER NOT NULL, - Login TEXT NOT NULL UNIQUE, - Password TEXT NOT NULL, - Selected INTEGER DEFAULT 1 NOT NULL, - AccountLevel INTEGER NOT NULL, - Created INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, - LastLogin INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, - BannedUntil INTEGER DEFAULT 0 NOT NULL, - BannedSince INTEGER DEFAULT 0 NOT NULL, - BanReason TEXT, - PRIMARY KEY(AccountID AUTOINCREMENT) - ); - - CREATE TABLE IF NOT EXISTS Players ( - PlayerID INTEGER NOT NULL, - AccountID INTEGER NOT NULL, - FirstName TEXT NOT NULL COLLATE NOCASE, - LastName TEXT NOT NULL COLLATE NOCASE, - NameCheck INTEGER NOT NULL, - Slot INTEGER NOT NULL, - Created INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, - LastLogin INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL, - Level INTEGER DEFAULT 1 NOT NULL, - Nano1 INTEGER DEFAULT 0 NOT NULL, - Nano2 INTEGER DEFAULT 0 NOT NULL, - Nano3 INTEGER DEFAULT 0 NOT NULL, - AppearanceFlag INTEGER DEFAULT 0 NOT NULL, - TutorialFlag INTEGER DEFAULT 0 NOT NULL, - PayZoneFlag INTEGER DEFAULT 0 NOT NULL, - XCoordinates INTEGER NOT NULL, - YCoordinates INTEGER NOT NULL, - ZCoordinates INTEGER NOT NULL, - Angle INTEGER NOT NULL, - HP INTEGER NOT NULL, - FusionMatter INTEGER DEFAULT 0 NOT NULL, - Taros INTEGER DEFAULT 0 NOT NULL, - BatteryW INTEGER DEFAULT 0 NOT NULL, - BatteryN INTEGER DEFAULT 0 NOT NULL, - Mentor INTEGER DEFAULT 5 NOT NULL, - CurrentMissionID INTEGER DEFAULT 0 NOT NULL, - WarpLocationFlag INTEGER DEFAULT 0 NOT NULL, - SkywayLocationFlag BLOB NOT NULL, - FirstUseFlag BLOB NOT NULL, - Quests BLOB NOT NULL, - PRIMARY KEY(PlayerID AUTOINCREMENT), - FOREIGN KEY(AccountID) REFERENCES Accounts(AccountID) ON DELETE CASCADE, - UNIQUE (AccountID, Slot), - UNIQUE (FirstName, LastName) - ); - - CREATE TABLE IF NOT EXISTS Appearances ( - PlayerID INTEGER UNIQUE NOT NULL, - Body INTEGER DEFAULT 0 NOT NULL, - EyeColor INTEGER DEFAULT 1 NOT NULL, - FaceStyle INTEGER DEFAULT 1 NOT NULL, - Gender INTEGER DEFAULT 1 NOT NULL, - HairColor INTEGER DEFAULT 1 NOT NULL, - HairStyle INTEGER DEFAULT 1 NOT NULL, - Height INTEGER DEFAULT 0 NOT NULL, - SkinColor INTEGER DEFAULT 1 NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE - ); - - CREATE TABLE IF NOT EXISTS Inventory ( - PlayerID INTEGER NOT NULL, - Slot INTEGER NOT NULL, - ID INTEGER NOT NULL, - Type INTEGER NOT NULL, - Opt INTEGER NOT NULL, - TimeLimit INTEGER DEFAULT 0 NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - UNIQUE (PlayerID, Slot) - ); - - CREATE TABLE IF NOT EXISTS QuestItems ( - PlayerID INTEGER NOT NULL, - Slot INTEGER NOT NULL, - ID INTEGER NOT NULL, - Opt INTEGER NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - UNIQUE (PlayerID, Slot) - ); - - CREATE TABLE IF NOT EXISTS Nanos ( - PlayerID INTEGER NOT NULL, - ID INTEGER NOT NULL, - Skill INTEGER NOT NULL, - Stamina INTEGER DEFAULT 150 NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - UNIQUE (PlayerID, ID) - ); - - CREATE TABLE IF NOT EXISTS RunningQuests ( - PlayerID INTEGER NOT NULL, - TaskID INTEGER NOT NULL, - RemainingNPCCount1 INTEGER NOT NULL, - RemainingNPCCount2 INTEGER NOT NULL, - RemainingNPCCount3 INTEGER NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE - ); - - CREATE TABLE IF NOT EXISTS Buddyships ( - PlayerAID INTEGER NOT NULL, - PlayerBID INTEGER NOT NULL, - FOREIGN KEY(PlayerAID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - FOREIGN KEY(PlayerBID) REFERENCES Players(PlayerID) ON DELETE CASCADE - ); - - CREATE TABLE IF NOT EXISTS Blocks ( - PlayerID INTEGER NOT NULL, - BlockedPlayerID INTEGER NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - FOREIGN KEY(BlockedPlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE - ); - - CREATE TABLE IF NOT EXISTS EmailData ( - PlayerID INTEGER NOT NULL, - MsgIndex INTEGER NOT NULL, - ReadFlag INTEGER NOT NULL, - ItemFlag INTEGER NOT NULL, - SenderID INTEGER NOT NULL, - SenderFirstName TEXT NOT NULL COLLATE NOCASE, - SenderLastName TEXT NOT NULL COLLATE NOCASE, - SubjectLine TEXT NOT NULL, - MsgBody TEXT NOT NULL, - Taros INTEGER NOT NULL, - SendTime INTEGER NOT NULL, - DeleteTime INTEGER NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - UNIQUE(PlayerID, MsgIndex) - ); - - CREATE TABLE IF NOT EXISTS EmailItems ( - PlayerID INTEGER NOT NULL, - MsgIndex INTEGER NOT NULL, - Slot INTEGER NOT NULL, - ID INTEGER NOT NULL, - Type INTEGER NOT NULL, - Opt INTEGER NOT NULL, - TimeLimit INTEGER NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE, - UNIQUE (MsgIndex, Slot) - ); - - CREATE TABLE IF NOT EXISTS RaceResults( - EPID INTEGER NOT NULL, - PlayerID INTEGER NOT NULL, - Score INTEGER NOT NULL, - Timestamp INTEGER NOT NULL, - FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE - ); - )"; - int rc = sqlite3_exec(db, sql, NULL, NULL, &errMsg); if (rc != SQLITE_OK) { std::cout << "[FATAL] Database failed to create tables: " << errMsg << std::endl; exit(1); } + dbCrit.unlock(); } int Database::getTableSize(std::string tableName) {