diff --git a/src/Database.cpp b/src/Database.cpp index beafddc..0e3f9d3 100644 --- a/src/Database.cpp +++ b/src/Database.cpp @@ -20,8 +20,6 @@ std::mutex dbCrit; sqlite3* db; -#pragma region LoginServer - void Database::open() { int rc = sqlite3_open(settings::DBPATH.c_str(), &db); @@ -127,6 +125,15 @@ void Database::createTables() { 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, @@ -176,7 +183,8 @@ void Database::createTables() { "Id" INTEGER NOT NULL, "Type" INTEGER NOT NULL, "Opt" INTEGER NOT NULL, - "TimeLimit" INTEGER NOT NULL + "TimeLimit" INTEGER NOT NULL, + UNIQUE ("MsgIndex", "Slot") ); CREATE TABLE IF NOT EXISTS "RaceResults"( @@ -608,427 +616,554 @@ bool Database::finishTutorial(int playerID) { int Database::deleteCharacter(int characterID, int userID) { std::lock_guard lock(dbCrit); - auto find = - db.get_all(where(c(&DbPlayer::PlayerID) == characterID and c(&DbPlayer::AccountID)==userID)); - int slot = find.front().slot; - db.remove(find.front().PlayerID); - db.remove_all(where(c(&Inventory::playerId) == characterID)); - db.remove_all(where(c(&Nano::playerId) == characterID)); + const char* sql = R"( + SELECT "Slot" + FROM "Players" + WHERE "AccountID" = ? AND "PlayerID" = ? + LIMIT 1; + )"; + + sqlite3_stmt* stmt; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, userID); + sqlite3_bind_int(stmt, 2, characterID); + int rc = sqlite3_step(stmt); + if (rc != SQLITE_ROW) + { + sqlite3_finalize(stmt); + return 0; + } + int slot = sqlite3_column_int(stmt, 0); + + sql = R"( + DELETE FROM "Players" + WHERE "AccountID" = ? AND "PlayerID" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, userID); + sqlite3_bind_int(stmt, 2, characterID); + rc = sqlite3_step(stmt); + sqlite3_finalize(stmt); + + if (rc != SQLITE_DONE) + return 0; return slot; } -std::vector Database::getCharacters(int UserID) { - std::lock_guard lock(dbCrit); - - std::vectorcharacters = - db.get_all(where - (c(&DbPlayer::AccountID) == UserID)); - // parsing DbPlayer to Player - std::vector result = std::vector(); - for (auto &character : characters) { - Player toadd = DbToPlayer(character); - result.push_back( - toadd - ); - } - return result; -} - std::vector Database::getCharInfo(int userID) { + std::vector result = std::vector(); std::lock_guard lock(dbCrit); - std::vectorcharacters = - db.get_all(where - (c(&DbPlayer::AccountID) == userID)); + const char* sql = R"( + SELECT p.PlayerID, p.Slot, p.Firstname, p.LastName, p.Level, p.AppearanceFlag, p.TutorialFlag, p.PayZoneFlag, + p.XCoordinates, p.YCoordinates, p.ZCoordinates, p.NameCheck, + a.Body, a.EyeColor, a.FaceStyle, a.Gender, a.HairColor, a.HairStyle, a.Height, a.SkinColor + FROM "Players" as p + INNER JOIN "Appearances" as a ON p.PlayerID = a.PlayerID + WHERE p.AccountID = ? + )"; + sqlite3_stmt* stmt; - std::vector result = std::vector(); - for (auto& character : characters) { + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, userID); + + while (sqlite3_step(stmt) == SQLITE_ROW) { sP_LS2CL_REP_CHAR_INFO toAdd = {}; - toAdd.iX = character.x_coordinates; - toAdd.iY = character.y_coordinates; - toAdd.iZ = character.z_coordinates; - toAdd.iLevel = character.Level; - toAdd.iSlot = character.slot; - toAdd.sPC_Style.iBody = character.Body; - toAdd.sPC_Style.iClass = character.Class; - toAdd.sPC_Style.iEyeColor = character.EyeColor; - toAdd.sPC_Style.iFaceStyle = character.FaceStyle; - toAdd.sPC_Style.iGender = character.Gender; - toAdd.sPC_Style.iHairColor = character.HairColor; - toAdd.sPC_Style.iHairStyle = character.HairStyle; - toAdd.sPC_Style.iHeight = character.Height; - toAdd.sPC_Style.iNameCheck = character.NameCheck; - toAdd.sPC_Style.iPC_UID = character.PlayerID; - toAdd.sPC_Style.iSkinColor = character.SkinColor; - U8toU16(character.FirstName, toAdd.sPC_Style.szFirstName, sizeof(toAdd.sPC_Style.szFirstName)); - U8toU16(character.LastName, toAdd.sPC_Style.szLastName, sizeof(toAdd.sPC_Style.szLastName)); - toAdd.sPC_Style2.iAppearanceFlag = character.AppearanceFlag; - toAdd.sPC_Style2.iPayzoneFlag = character.PayZoneFlag; - toAdd.sPC_Style2.iTutorialFlag = character.TutorialFlag; + toAdd.sPC_Style.iPC_UID = sqlite3_column_int(stmt, 0); + toAdd.iSlot = sqlite3_column_int(stmt, 1); - //get equipment - auto items = db.get_all( - where(c(&Inventory::playerId) == character.PlayerID && c(&Inventory::slot) < AEQUIP_COUNT)); + // parsing const unsigned char* to char16_t + std::string placeHolder = std::string(reinterpret_cast(sqlite3_column_text(stmt, 2))); + U8toU16(placeHolder, toAdd.sPC_Style.szFirstName, sizeof(toAdd.sPC_Style.szFirstName)); + placeHolder = std::string(reinterpret_cast(sqlite3_column_text(stmt, 3))); + U8toU16(placeHolder, toAdd.sPC_Style.szLastName, sizeof(toAdd.sPC_Style.szLastName)); + + toAdd.iLevel = sqlite3_column_int(stmt, 4); + toAdd.sPC_Style2.iAppearanceFlag = sqlite3_column_int(stmt, 5); + toAdd.sPC_Style2.iTutorialFlag = sqlite3_column_int(stmt, 6); + toAdd.sPC_Style2.iPayzoneFlag = sqlite3_column_int(stmt, 7); + toAdd.iX = sqlite3_column_int(stmt, 8); + toAdd.iY = sqlite3_column_int(stmt, 9); + toAdd.iZ = sqlite3_column_int(stmt, 10); + toAdd.sPC_Style.iNameCheck = sqlite3_column_int(stmt, 11); + toAdd.sPC_Style.iBody = sqlite3_column_int(stmt, 12); + toAdd.sPC_Style.iEyeColor = sqlite3_column_int(stmt, 13); + toAdd.sPC_Style.iFaceStyle = sqlite3_column_int(stmt, 14); + toAdd.sPC_Style.iGender = sqlite3_column_int(stmt, 15); + toAdd.sPC_Style.iHairColor = sqlite3_column_int(stmt, 16); + toAdd.sPC_Style.iHairStyle = sqlite3_column_int(stmt, 17); + toAdd.sPC_Style.iHeight = sqlite3_column_int(stmt, 18); + toAdd.sPC_Style.iSkinColor = sqlite3_column_int(stmt, 19); - for (auto& item : items) { - sItemBase addItem = {}; - addItem.iID = item.id; - addItem.iType = item.Type; - addItem.iOpt = item.Opt; - addItem.iTimeLimit = item.TimeLimit; - toAdd.aEquip[item.slot] = addItem; + // request aEquip + const char* sql2 = R"( + SELECT "Slot", "Type", "Id", "Opt", "TimeLimit" from Inventory + WHERE "PlayerID" = ? AND "Slot"< ? + )"; + sqlite3_stmt* stmt2; + + sqlite3_prepare_v2(db, sql2, -1, &stmt2, 0); + sqlite3_bind_int(stmt2, 1, toAdd.sPC_Style.iPC_UID); + sqlite3_bind_int(stmt2, 2, AEQUIP_COUNT); + + while (sqlite3_step(stmt2) == SQLITE_ROW) { + sItemBase* item = &toAdd.aEquip[sqlite3_column_int(stmt2, 0)]; + item->iType = sqlite3_column_int(stmt2, 1); + item->iID = sqlite3_column_int(stmt2, 2); + item->iOpt = sqlite3_column_int(stmt2, 3); + item->iTimeLimit = sqlite3_column_int(stmt2, 4); } + sqlite3_finalize(stmt2); result.push_back(toAdd); } + sqlite3_finalize(stmt); return result; + } // XXX: This is never called? void Database::evaluateCustomName(int characterID, CustomName decision) { std::lock_guard lock(dbCrit); - DbPlayer player = getDbPlayerById(characterID); - player.NameCheck = (int)decision; - db.update(player); + const char* sql = R"( + UPDATE "Players" + SET "NameCheck" = ? + WHERE "PlayerID" = ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, int(decision)); + sqlite3_bind_int(stmt, 2, characterID); + + if (sqlite3_step(stmt) != SQLITE_DONE) + std::cout << "[WARN] Database: Failed to update nameCheck" << std::endl; + sqlite3_finalize(stmt); } -void Database::changeName(sP_CL2LS_REQ_CHANGE_CHAR_NAME* save) { +bool Database::changeName(sP_CL2LS_REQ_CHANGE_CHAR_NAME* save, int accountId) { std::lock_guard lock(dbCrit); - DbPlayer Player = getDbPlayerById(save->iPCUID); - Player.FirstName = U16toU8(save->szFirstName); - Player.LastName = U16toU8(save->szLastName); - if (settings::APPROVEALLNAMES || save->iFNCode) - Player.NameCheck = 1; - else - Player.NameCheck = 0; - db.update(Player); + const char* sql = R"( + UPDATE "Players" + SET "Firstname" = ?, + "LastName" = ? + WHERE "PlayerID" = ? AND "AccountID" = ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_text(stmt, 1, U16toU8(save->szFirstName).c_str(), -1, 0); + sqlite3_bind_text(stmt, 2, U16toU8(save->szLastName).c_str(), -1, 0); + sqlite3_bind_int(stmt, 3, save->iPCUID); + sqlite3_bind_int(stmt, 4, accountId); + + int rc = sqlite3_step(stmt); + sqlite3_finalize(stmt); + return rc == SQLITE_DONE; } -Database::DbPlayer Database::playerToDb(Player *player) { - // TODO: move stuff that is never updated to separate table so it doesn't try to update it every time - DbPlayer result = {}; +void Database::getPlayer(Player* plr, int id) { + std::lock_guard lock(dbCrit); - result.PlayerID = player->iID; - result.AccountID = player->accountId; - result.AppearanceFlag = player->PCStyle2.iAppearanceFlag; - result.Body = player->PCStyle.iBody; - result.Class = player->PCStyle.iClass; - result.EyeColor = player->PCStyle.iEyeColor; - result.FaceStyle = player->PCStyle.iFaceStyle; - result.FirstName = U16toU8( player->PCStyle.szFirstName); - result.FusionMatter = player->fusionmatter; - result.Gender = player->PCStyle.iGender; - result.HairColor = player->PCStyle.iHairColor; - result.HairStyle = player->PCStyle.iHairStyle; - result.Height = player->PCStyle.iHeight; - result.HP = player->HP; - result.AccountLevel = player->accountLevel; - result.LastName = U16toU8(player->PCStyle.szLastName); - result.Level = player->level; - result.NameCheck = player->PCStyle.iNameCheck; - result.PayZoneFlag = player->PCStyle2.iPayzoneFlag; - result.PlayerID = player->PCStyle.iPC_UID; - result.SkinColor = player->PCStyle.iSkinColor; - result.slot = player->slot; - result.Taros = player->money; - result.TutorialFlag = player->PCStyle2.iTutorialFlag; - if (player->instanceID == 0 && !player->onMonkey) { // only save coords if player isn't instanced - result.x_coordinates = player->x; - result.y_coordinates = player->y; - result.z_coordinates = player->z; - result.angle = player->angle; - } else { - result.x_coordinates = player->lastX; - result.y_coordinates = player->lastY; - result.z_coordinates = player->lastZ; - result.angle = player->lastAngle; + const char* sql = R"( + SELECT p.AccountID, p.Slot, p.Firstname, p.LastName, + p.Level, p.Nano1, p.Nano2, p.Nano3, + p.AppearanceFlag, p.TutorialFlag, p.PayZoneFlag, + p.XCoordinates, p.YCoordinates, p.ZCoordinates, p.NameCheck, + p.Angle, p.HP, p.AccountLevel, p.FusionMatter, p.Taros, p.Quests, + p.BatteryW, p.BatteryN, p.Mentor, p.WarpLocationFlag, + p.SkywayLocationFlag1, p.SkywayLocationFlag2, p.CurrentMissionID + a.Body, a.EyeColor, a.FaceStyle, a.Gender, a.HairColor, a.HairStyle, a.Height, a.SkinColor + FROM "Players" as p + INNER JOIN "Appearances" as a ON p.PlayerID = a.PlayerID + WHERE p.PlayerID = ? + )"; + sqlite3_stmt* stmt; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, id); + if (sqlite3_step(stmt) != SQLITE_ROW) { + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to load character [" << id << "]" << std::endl; + return; } - result.Nano1 = player->equippedNanos[0]; - result.Nano2 = player->equippedNanos[1]; - result.Nano3 = player->equippedNanos[2]; - result.BatteryN = player->batteryN; - result.BatteryW = player->batteryW; - result.Mentor = player->mentor; - result.WarpLocationFlag = player->iWarpLocationFlag; - result.SkywayLocationFlag1 = player->aSkywayLocationFlag[0]; - result.SkywayLocationFlag2 = player->aSkywayLocationFlag[1]; - result.CurrentMissionID = player->CurrentMissionID; - // timestamp - result.LastLogin = getTimestamp(); - result.Created = player->creationTime; + plr->iID = id; + plr->PCStyle.iPC_UID = id; - // save completed quests - result.QuestFlag = std::vector((char*)player->aQuestFlag, (char*)player->aQuestFlag + 128); + plr->accountId = sqlite3_column_int(stmt, 0); + plr->slot = sqlite3_column_int(stmt, 1); + + // parsing const unsigned char* to char16_t + std::string placeHolder = std::string(reinterpret_cast(sqlite3_column_text(stmt, 2))); + U8toU16(placeHolder, plr->PCStyle.szFirstName , sizeof(plr->PCStyle.szFirstName)); + placeHolder = std::string(reinterpret_cast(sqlite3_column_text(stmt, 3))); + U8toU16(placeHolder, plr->PCStyle.szLastName, sizeof(plr->PCStyle.szLastName)); - return result; -} + plr->level = sqlite3_column_int(stmt, 4); + plr->equippedNanos[0] = sqlite3_column_int(stmt, 5); + plr->equippedNanos[1] = sqlite3_column_int(stmt, 6); + plr->equippedNanos[2] = sqlite3_column_int(stmt, 7); -Player Database::DbToPlayer(DbPlayer player) { - Player result = {}; // fixes some weird memory errors, this zeros out the members (not the padding inbetween though) + plr->PCStyle2.iAppearanceFlag = sqlite3_column_int(stmt, 8); + plr->PCStyle2.iTutorialFlag = sqlite3_column_int(stmt, 9); + plr->PCStyle2.iPayzoneFlag = sqlite3_column_int(stmt, 10); - result.iID = player.PlayerID; - result.accountId = player.AccountID; - result.creationTime = player.Created; - result.PCStyle2.iAppearanceFlag = player.AppearanceFlag; - result.PCStyle.iBody = player.Body; - result.PCStyle.iClass = player.Class; - result.PCStyle.iEyeColor = player.EyeColor; - result.PCStyle.iFaceStyle = player.FaceStyle; - U8toU16(player.FirstName, result.PCStyle.szFirstName, sizeof(result.PCStyle.szFirstName)); - result.PCStyle.iGender = player.Gender; - result.PCStyle.iHairColor = player.HairColor; - result.PCStyle.iHairStyle = player.HairStyle; - result.PCStyle.iHeight = player.Height; - result.HP = player.HP; - result.accountLevel = player.AccountLevel; - U8toU16(player.LastName, result.PCStyle.szLastName, sizeof(result.PCStyle.szLastName)); - result.level = player.Level; - result.PCStyle.iNameCheck = player.NameCheck; - result.PCStyle2.iPayzoneFlag = player.PayZoneFlag; - result.iID = player.PlayerID; - result.PCStyle.iPC_UID = player.PlayerID; - result.PCStyle.iSkinColor = player.SkinColor; - result.slot = player.slot; - result.PCStyle2.iTutorialFlag = player.TutorialFlag; - result.x = player.x_coordinates; - result.y = player.y_coordinates; - result.z = player.z_coordinates; - result.angle = player.angle; - result.money = player.Taros; - result.fusionmatter = player.FusionMatter; - result.batteryN = player.BatteryN; - result.batteryW = player.BatteryW; - result.mentor = player.Mentor; - result.CurrentMissionID = player.CurrentMissionID; + plr->x = sqlite3_column_int(stmt, 11); + plr->y = sqlite3_column_int(stmt, 12); + plr->z = sqlite3_column_int(stmt, 13); + plr->PCStyle.iNameCheck = sqlite3_column_int(stmt, 14); - result.equippedNanos[0] = player.Nano1; - result.equippedNanos[1] = player.Nano2; - result.equippedNanos[2] = player.Nano3; + plr->angle = sqlite3_column_int(stmt, 15); + plr->HP = sqlite3_column_int(stmt, 16); + plr->accountLevel = sqlite3_column_int(stmt, 17); + plr->fusionmatter = sqlite3_column_int(stmt, 18); + plr->money = sqlite3_column_int(stmt, 19); - result.inCombat = false; + const void* questBuffer = plr->aQuestFlag; + questBuffer = sqlite3_column_blob(stmt, 20); - result.iWarpLocationFlag = player.WarpLocationFlag; - result.aSkywayLocationFlag[0] = player.SkywayLocationFlag1; - result.aSkywayLocationFlag[1] = player.SkywayLocationFlag2; + plr->batteryW = sqlite3_column_int(stmt, 21); + plr->batteryN = sqlite3_column_int(stmt, 22); + plr->mentor = sqlite3_column_int(stmt, 23); + plr->iWarpLocationFlag = sqlite3_column_int(stmt, 24); + + plr->aSkywayLocationFlag[0] = sqlite3_column_int(stmt, 25); + plr->aSkywayLocationFlag[1] = sqlite3_column_int(stmt, 26); + plr->CurrentMissionID = sqlite3_column_int(stmt, 27); - Database::getInventory(&result); - Database::removeExpiredVehicles(&result); - Database::getNanos(&result); - Database::getQuests(&result); - Database::getBuddies(&result); + plr->PCStyle.iBody = sqlite3_column_int(stmt, 28); + plr->PCStyle.iEyeColor = sqlite3_column_int(stmt, 29); + plr->PCStyle.iFaceStyle = sqlite3_column_int(stmt, 30); + plr->PCStyle.iGender = sqlite3_column_int(stmt, 31); + plr->PCStyle.iHairColor = sqlite3_column_int(stmt, 32); + plr->PCStyle.iHairStyle = sqlite3_column_int(stmt, 33); + plr->PCStyle.iHeight = sqlite3_column_int(stmt, 34); + plr->PCStyle.iSkinColor = sqlite3_column_int(stmt, 35); - // load completed quests - memcpy(&result.aQuestFlag, player.QuestFlag.data(), std::min(sizeof(result.aQuestFlag), player.QuestFlag.size())); + // get inventory - return result; -} + sql = R"( + SELECT "Slot", "Type", "Id", "Opt", "TimeLimit" from Inventory + WHERE "PlayerID" = ? AND "Slot" < ? + )"; -Database::DbPlayer Database::getDbPlayerById(int id) { - auto player = db.get_all(where(c(&DbPlayer::PlayerID) == id)); - if (player.size() < 1) { - // garbage collection - db.remove_all(where(c(&Inventory::playerId) == id)); - db.remove_all(where(c(&Nano::playerId) == id)); - db.remove_all(where(c(&DbQuest::PlayerId) == id)); - db.remove_all(where(c(&Buddyship::PlayerAId) == id || c(&Buddyship::PlayerBId) == id)); - db.remove_all(where(c(&EmailData::PlayerId) == id)); - db.remove_all(where(c(&EmailItem::PlayerId) == id)); - return DbPlayer{ -1 }; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + + sqlite3_bind_int(stmt, 1, id); + // we don't want bank items here + sqlite3_bind_int(stmt, 2, AEQUIP_COUNT + AINVEN_COUNT); + + while (sqlite3_step(stmt) == SQLITE_ROW) { + int slot = sqlite3_column_int(stmt, 0); + + sItemBase* item = slot < AEQUIP_COUNT ? &plr->Equip[slot] : &plr->Inven[slot = AEQUIP_COUNT]; + item->iType = sqlite3_column_int(stmt, 1); + item->iID = sqlite3_column_int(stmt, 2); + item->iOpt = sqlite3_column_int(stmt, 3); + item->iTimeLimit = sqlite3_column_int(stmt, 4); } - return player.front(); + + Database::removeExpiredVehicles(plr); + + // get quest inventory + + sql = R"( + SELECT "Slot", "Id", "Opt" from QuestItems + WHERE "PlayerID" = ? + )"; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + + sqlite3_bind_int(stmt, 1, id); + + while (sqlite3_step(stmt) == SQLITE_ROW) { + int slot = sqlite3_column_int(stmt, 0); + + sItemBase* item = &plr->QInven[slot]; + item->iType = 8; + item->iID = sqlite3_column_int(stmt, 1); + item->iOpt = sqlite3_column_int(stmt, 2); + } + + + // get nanos + sql = R"( + SELECT "Id", "Skill", "Stamina" from "Nanos" + WHERE "PlayerID" = ? + )"; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, id); + + while (sqlite3_step(stmt) == SQLITE_ROW) { + int id = sqlite3_column_int(stmt, 0); + sNano* nano = &plr->Nanos[id]; + nano->iID = id; + nano->iSkillID = sqlite3_column_int(stmt, 1); + nano->iStamina = sqlite3_column_int(stmt, 2); + } + + // get active quests + sql = R"( + SELECT "TaskId", "RemainingNPCCount1", "RemainingNPCCount2", "RemainingNPCCount3" from "RunningQuests" + WHERE "PlayerID" = ? + )"; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, id); + + int i = 0; + while (sqlite3_step(stmt) == SQLITE_ROW && i < ACTIVE_MISSION_COUNT) { + plr->tasks[i] = sqlite3_column_int(stmt, 0); + plr->RemainingNPCCount[i][0] = sqlite3_column_int(stmt, 1); + plr->RemainingNPCCount[i][1] = sqlite3_column_int(stmt, 2); + plr->RemainingNPCCount[i][2] = sqlite3_column_int(stmt, 3); + } + + // get buddies + sql = R"( + SELECT "PlayerAId", "PlayerBId" from "Buddyships" + WHERE "PlayerAId" = ? OR "PlayerBId" = ? + )"; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, id); + sqlite3_bind_int(stmt, 2, id); + + i = 0; + while (sqlite3_step(stmt) == SQLITE_ROW && i < 50) { + int PlayerAId = sqlite3_column_int(stmt, 0); + int PlayerBId = sqlite3_column_int(stmt, 1); + + plr->buddyIDs[i] = id == PlayerAId ? PlayerBId : PlayerAId; + } + + sqlite3_finalize(stmt); } -Player Database::getPlayer(int id) { - return DbToPlayer( - getDbPlayerById(id) - ); -} - -#pragma endregion LoginServer - -#pragma region ShardServer - void Database::updatePlayer(Player *player) { std::lock_guard lock(dbCrit); - DbPlayer toUpdate = playerToDb(player); - db.update(toUpdate); - updateInventory(player); - updateNanos(player); - updateQuests(player); - //updateBuddies(player); we add/remove buddies explicitly now + sqlite3_exec(db, "BEGIN TRANSACTION", NULL, NULL, NULL); + + const char* sql = R"( + UPDATE "Players" + SET + "Level" = ? , "Nano1" = ?, "Nano2" = ?, "Nano3" = ?, + "XCoordinates" = ?, "YCoordinates" = ?, "ZCoordinates" = ?, + "Angle" = ?, "HP" = ?, "FusionMatter" = ?, "Taros" = ?, "Quests" = ?, + "BatteryW" = ?, "BatteryN" = ?, "WarplocationFlag" = ?, + "SkywayLocationFlag1" = ?, "SkywayLocationFlag2" = ?, "CurrentMissionID" = ? + WHERE "PlayerID" = ? + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, player->level); + sqlite3_bind_int(stmt, 2, player->equippedNanos[0]); + sqlite3_bind_int(stmt, 3, player->equippedNanos[1]); + sqlite3_bind_int(stmt, 4, player->equippedNanos[2]); + sqlite3_bind_int(stmt, 5, player->x); + sqlite3_bind_int(stmt, 6, player->y); + sqlite3_bind_int(stmt, 7, player->z); + sqlite3_bind_int(stmt, 8, player->angle); + sqlite3_bind_int(stmt, 9, player->HP); + sqlite3_bind_int(stmt, 10, player->fusionmatter); + sqlite3_bind_int(stmt, 11, player->money); + sqlite3_bind_blob(stmt, 12, player->aQuestFlag, sizeof(player->aQuestFlag), 0); + sqlite3_bind_int(stmt, 13, player->batteryW); + sqlite3_bind_int(stmt, 14, player->batteryN); + sqlite3_bind_int(stmt, 15, player->iWarpLocationFlag); + sqlite3_bind_int(stmt, 16, player->aSkywayLocationFlag[0]); + sqlite3_bind_int(stmt, 17, player->aSkywayLocationFlag[1]); + sqlite3_bind_int(stmt, 18, player->CurrentMissionID); + sqlite3_bind_int(stmt, 19, player->iID); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to save player to database" << std::endl; + return; + } + + // update inventory + sql = R"( + DELETE FROM "Inventory" WHERE "PlayerID" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_step(stmt); + + sql = R"( + INSERT INTO "Inventory" + ("PlayerID", "Slot", "Type", "Opt" "Id", "Timelimit") + VALUES (?, ?, ?, ?, ?, ?); + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + + int i = -1; + while (++i < AEQUIP_COUNT && player->Equip[i].iID != 0) { + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_bind_int(stmt, 2, i); + sqlite3_bind_int(stmt, 3, player->Equip[i].iType); + sqlite3_bind_int(stmt, 4, player->Equip[i].iOpt); + sqlite3_bind_int(stmt, 5, player->Equip[i].iID); + sqlite3_bind_int(stmt, 6, player->Equip[i].iTimeLimit); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to save player to database" << std::endl; + return; + } + sqlite3_reset(stmt); + } + + i = -1; + while (++i < AINVEN_COUNT && player->Inven[i].iID != 0) { + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_bind_int(stmt, 2, i + AEQUIP_COUNT); + sqlite3_bind_int(stmt, 3, player->Inven[i].iType); + sqlite3_bind_int(stmt, 4, player->Inven[i].iOpt); + sqlite3_bind_int(stmt, 5, player->Inven[i].iID); + sqlite3_bind_int(stmt, 6, player->Inven[i].iTimeLimit); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to save player to database" << std::endl; + return; + } + sqlite3_reset(stmt); + } + + // Update Quest Inventory + sql = R"( + DELETE FROM "QuestItems" WHERE "PlayerID" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_step(stmt); + + sql = R"( + INSERT INTO "QuestItems" + ("PlayerID", "Slot", "Opt" "Id") + VALUES (?, ?, ?, ?); + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + + i = -1; + while (++i < AQINVEN_COUNT && player->QInven[i].iID != 0) { + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_bind_int(stmt, 2, i); + sqlite3_bind_int(stmt, 3, player->QInven[i].iOpt); + sqlite3_bind_int(stmt, 4, player->QInven[i].iID); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to save player to database" << std::endl; + return; + } + sqlite3_reset(stmt); + } + + // Update Nanos + sql = R"( + DELETE FROM "Nanos" WHERE "PlayerID" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_step(stmt); + + sql = R"( + INSERT INTO "Nanos" + ("PlayerID", "Id", "SKill" "Stamina") + VALUES (?, ?, ?, ?); + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + + i = -1; + while (++i < SIZEOF_NANO_BANK_SLOT && player->Nanos[i].iID != 0) { + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_bind_int(stmt, 2, player->Nanos[i].iID); + sqlite3_bind_int(stmt, 3, player->Nanos[i].iSkillID); + sqlite3_bind_int(stmt, 4, player->Nanos[i].iStamina); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to save player to database" << std::endl; + return; + } + sqlite3_reset(stmt); + } + + // Update Running Quests + sql = R"( + DELETE FROM "RunningQuests" WHERE "PlayerID" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_step(stmt); + + sql = R"( + INSERT INTO "RunningQuests" + ("PlayerID", "TaskId", "RemainingNPCCount1", "RemainingNPCCount2", "RemainingNPCCount3") + VALUES (?, ?, ?, ?, ?); + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + + i = -1; + while (++i < ACTIVE_MISSION_COUNT && player->tasks[i] != 0) { + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_bind_int(stmt, 2, player->tasks[i]); + sqlite3_bind_int(stmt, 3, player->RemainingNPCCount[i][0]); + sqlite3_bind_int(stmt, 4, player->RemainingNPCCount[i][1]); + sqlite3_bind_int(stmt, 5, player->RemainingNPCCount[i][2]); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + std::cout << "[WARN] Database: Failed to save player to database" << std::endl; + return; + } + sqlite3_reset(stmt); + } + + sqlite3_exec(db, "END TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); } -void Database::updateInventory(Player *player){ - // start transaction - db.begin_transaction(); - // remove all - db.remove_all( - where(c(&Inventory::playerId) == player->iID) - ); - // insert equip - for (int i = 0; i < AEQUIP_COUNT; i++) { - if (player->Equip[i].iID != 0) { - sItemBase* next = &player->Equip[i]; - Inventory toAdd = {}; - toAdd.playerId = player->iID; - toAdd.slot = i; - toAdd.id = next->iID; - toAdd.Opt = next->iOpt; - toAdd.Type = next->iType; - toAdd.TimeLimit = next->iTimeLimit; - db.insert(toAdd); - } - } - // insert inventory - for (int i = 0; i < AINVEN_COUNT; i++) { - if (player->Inven[i].iID != 0) { - sItemBase* next = &player->Inven[i]; - Inventory toAdd = {}; - toAdd.playerId = player->iID; - toAdd.slot = i + AEQUIP_COUNT; - toAdd.id = next->iID; - toAdd.Opt = next->iOpt; - toAdd.Type = next->iType; - toAdd.TimeLimit = next->iTimeLimit; - db.insert(toAdd); - } - } - // insert bank - for (int i = 0; i < ABANK_COUNT; i++) { - if (player->Bank[i].iID != 0) { - sItemBase* next = &player->Bank[i]; - Inventory toAdd = {}; - toAdd.playerId = player->iID; - toAdd.slot = i + AEQUIP_COUNT + AINVEN_COUNT; - toAdd.id = next->iID; - toAdd.Opt = next->iOpt; - toAdd.Type = next->iType; - toAdd.TimeLimit = next->iTimeLimit; - db.insert(toAdd); - } - } - // insert quest items - for (int i = 0; i < AQINVEN_COUNT; i++) { - if (player->QInven[i].iID != 0) { - sItemBase* next = &player->QInven[i]; - Inventory toAdd = {}; - toAdd.playerId = player->iID; - toAdd.slot = i + AEQUIP_COUNT + AINVEN_COUNT + ABANK_COUNT; - toAdd.id = next->iID; - toAdd.Opt = next->iOpt; - toAdd.Type = next->iType; - toAdd.TimeLimit = next->iTimeLimit; - db.insert(toAdd); - } - } - db.commit(); -} - -void Database::updateNanos(Player *player) { - // start transaction - db.begin_transaction(); - // remove all - db.remove_all( - where(c(&Nano::playerId) == player->iID) - ); - // insert - for (int i=1; i < SIZEOF_NANO_BANK_SLOT; i++) { - if ((player->Nanos[i]).iID == 0) - continue; - Nano toAdd = {}; - sNano* next = &player->Nanos[i]; - toAdd.playerId = player->iID; - toAdd.iID = next->iID; - toAdd.iSkillID = next->iSkillID; - toAdd.iStamina = next->iStamina; - db.insert(toAdd); - } - db.commit(); -} - -void Database::updateQuests(Player* player) { - // start transaction - db.begin_transaction(); - // remove all - db.remove_all( - where(c(&DbQuest::PlayerId) == player->iID) - ); - // insert - for (int i = 0; i < ACTIVE_MISSION_COUNT; i++) { - if (player->tasks[i] == 0) - continue; - DbQuest toAdd = {}; - toAdd.PlayerId = player->iID; - toAdd.TaskId = player->tasks[i]; - toAdd.RemainingNPCCount1 = player->RemainingNPCCount[i][0]; - toAdd.RemainingNPCCount2 = player->RemainingNPCCount[i][1]; - toAdd.RemainingNPCCount3 = player->RemainingNPCCount[i][2]; - db.insert(toAdd); - } - db.commit(); -} // note: do not use. explicitly add/remove records instead. void Database::updateBuddies(Player* player) { - db.begin_transaction(); + //db.begin_transaction(); - db.remove_all( // remove all buddyships with this player involved - where(c(&Buddyship::PlayerAId) == player->iID || c(&Buddyship::PlayerBId) == player->iID) - ); - - // iterate through player's buddies and add records for each non-zero entry - for (int i = 0; i < 50; i++) { - if (player->buddyIDs[i] != 0) { - Buddyship record; - record.PlayerAId = player->iID; - record.PlayerBId = player->buddyIDs[i]; - record.Status = 0; // still not sure how we'll handle blocking - db.insert(record); - } - } - - db.commit(); -} - -void Database::getInventory(Player* player) { - // get items from DB - auto items = db.get_all( - where(c(&Inventory::playerId) == player->iID) - ); - // set items - for (const Inventory ¤t : items) { - sItemBase toSet = {}; - toSet.iID = current.id; - toSet.iType = current.Type; - toSet.iOpt = current.Opt; - toSet.iTimeLimit = current.TimeLimit; - // assign to proper arrays - if (current.slot < AEQUIP_COUNT) - player->Equip[current.slot] = toSet; - else if (current.slot < (AEQUIP_COUNT + AINVEN_COUNT)) - player->Inven[current.slot - AEQUIP_COUNT] = toSet; - else if (current.slot < (AEQUIP_COUNT + AINVEN_COUNT + ABANK_COUNT)) - player->Bank[current.slot - AEQUIP_COUNT - AINVEN_COUNT] = toSet; - else - player->QInven[current.slot - AEQUIP_COUNT - AINVEN_COUNT - ABANK_COUNT] = toSet; - } + //db.remove_all( // remove all buddyships with this player involved + // where(c(&Buddyship::PlayerAId) == player->iID || c(&Buddyship::PlayerBId) == player->iID) + // ); + //// iterate through player's buddies and add records for each non-zero entry + //for (int i = 0; i < 50; i++) { + // if (player->buddyIDs[i] != 0) { + // Buddyship record; + // record.PlayerAId = player->iID; + // record.PlayerBId = player->buddyIDs[i]; + // record.Status = 0; // still not sure how we'll handle blocking + // db.insert(record); + // } + //} + //db.commit(); } void Database::removeExpiredVehicles(Player* player) { int32_t currentTime = getTimestamp(); - // remove from bank immediately - for (int i = 0; i < ABANK_COUNT; i++) { - if (player->Bank[i].iType == 10 && player->Bank[i].iTimeLimit < currentTime) - player->Bank[i] = {}; - } - // for the rest, we want to leave only 1 expired vehicle on player to delete it with the client packet + + // we want to leave only 1 expired vehicle on player to delete it with the client packet std::vector toRemove; // equiped vehicle @@ -1052,100 +1187,78 @@ void Database::removeExpiredVehicles(Player* player) { } } -void Database::getNanos(Player* player) { - // get from DB - auto nanos = db.get_all( - where(c(&Nano::playerId) == player->iID) - ); - // set - for (const Nano& current : nanos) { - sNano *toSet = &player->Nanos[current.iID]; - toSet->iID = current.iID; - toSet->iSkillID = current.iSkillID; - toSet->iStamina = current.iStamina; - } -} - -void Database::getQuests(Player* player) { - // get from DB - auto quests = db.get_all( - where(c(&DbQuest::PlayerId) == player->iID) - ); - // set - int i = 0; - for (const DbQuest& current : quests) { - player->tasks[i] = current.TaskId; - player->RemainingNPCCount[i][0] = current.RemainingNPCCount1; - player->RemainingNPCCount[i][1] = current.RemainingNPCCount2; - player->RemainingNPCCount[i][2] = current.RemainingNPCCount3; - i++; - } -} - -void Database::getBuddies(Player* player) { - auto buddies = db.get_all( // player can be on either side - where(c(&Buddyship::PlayerAId) == player->iID || c(&Buddyship::PlayerBId) == player->iID) - ); - - // there should never be more than 50 buddyships per player, but just in case - for (int i = 0; i < 50 && i < buddies.size(); i++) { - // if the player is player A, then the buddy is player B, and vice versa - player->buddyIDs[i] = player->iID == buddies.at(i).PlayerAId - ? buddies.at(i).PlayerBId : buddies.at(i).PlayerAId; - } -} - int Database::getNumBuddies(Player* player) { std::lock_guard lock(dbCrit); - auto buddies = db.get_all( // player can be on either side - where(c(&Buddyship::PlayerAId) == player->iID || c(&Buddyship::PlayerBId) == player->iID) - ); + const char* sql = R"( + SELECT COUNT(*) FROM "Buddyships" + WHERE "PlayerAId" = ? OR "PlayerBId" = ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, player->iID); + sqlite3_bind_int(stmt, 2, player->iID); + sqlite3_step(stmt); + int result = sqlite3_column_int(stmt, 0); + sqlite3_finalize(stmt); // again, for peace of mind - return buddies.size() > 50 ? 50 : buddies.size(); + return result > 50 ? 50 : result; } // buddies void Database::addBuddyship(int playerA, int playerB) { std::lock_guard lock(dbCrit); - db.begin_transaction(); + const char* sql = R"( + INSERT INTO "Buddyships" + ("PlayerAId", "PlayerBId", Status") + VALUES (?, ?, ?); + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerA); + sqlite3_bind_int(stmt, 2, playerB); + // blocking??? + sqlite3_bind_int(stmt, 3, 0); - Buddyship record; - record.PlayerAId = playerA; - record.PlayerBId = playerB; - record.Status = 0; // blocking ??? - db.insert(record); - - db.commit(); + if (sqlite3_step(stmt) != SQLITE_DONE) + std::cout << "[WARN] Database: failed to add buddies" << std::endl; + sqlite3_finalize(stmt); } void Database::removeBuddyship(int playerA, int playerB) { std::lock_guard lock(dbCrit); - db.begin_transaction(); + const char* sql = R"( + DELETE FROM "Buddyships" + WHERE ("PlayerAId" = ? AND "PlayerBId" = ?) OR ("PlayerAId" = ? AND "PlayerBId" = ?); + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerA); + sqlite3_bind_int(stmt, 2, playerB); + sqlite3_bind_int(stmt, 3, playerB); + sqlite3_bind_int(stmt, 4, playerA); - db.remove_all( - where(c(&Buddyship::PlayerAId) == playerA && c(&Buddyship::PlayerBId) == playerB) - ); - - db.remove_all( // the pair could be in either position - where(c(&Buddyship::PlayerAId) == playerB && c(&Buddyship::PlayerBId) == playerA) - ); - - db.commit(); + if (sqlite3_step(stmt) != SQLITE_DONE) + std::cout << "[WARN] Database: failed to remove buddies" << std::endl; + sqlite3_finalize(stmt); } // email int Database::getUnreadEmailCount(int playerID) { std::lock_guard lock(dbCrit); - auto emailData = db.get_all( - where(c(&Database::EmailData::PlayerId) == playerID && c(&Database::EmailData::ReadFlag) == 0) - ); - - return emailData.size(); + const char* sql = R"( + SELECT COUNT (*) FROM "EmailData" + WHERE "PlayerId" = ? AND "ReadFlag" = 0; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_step(stmt); + return sqlite3_column_int(stmt, 0); } std::vector Database::getEmails(int playerID, int page) { @@ -1153,17 +1266,38 @@ std::vector Database::getEmails(int playerID, int page) { std::vector emails; - auto emailData = db.get_all( - where(c(&Database::EmailData::PlayerId) == playerID), - order_by(&Database::EmailData::MsgIndex).desc(), - limit(5 * (page - 1), 5) - ); + const char* sql = R"( + SELECT "MsgIndex", "ItemFlag", "ReadFlag", "SenderId", "SenderFirstName", "SenderLastName", "SubjectLine", "MsgBody", + "Taros", "SendTime", "DeleteTime" + FROM "EmailData" + WHERE "PlayerId" = ? + ORDER BY "MsgIndex" DESC + LIMIT 5 + OFFSET ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + int offset = 5 * page - 5; + sqlite3_bind_int(stmt, 2, offset); + while (sqlite3_step(stmt) == SQLITE_ROW) { + Database::EmailData toAdd; + toAdd.PlayerId = playerID; + toAdd.MsgIndex = sqlite3_column_int(stmt, 0); + toAdd.ItemFlag = sqlite3_column_int(stmt, 1); + toAdd.ReadFlag = sqlite3_column_int(stmt, 2); + toAdd.SenderId = sqlite3_column_int(stmt, 3); + toAdd.SenderFirstName = std::string(reinterpret_cast(sqlite3_column_text(stmt, 4))); + toAdd.SenderLastName = std::string(reinterpret_cast(sqlite3_column_text(stmt, 5))); + toAdd.SubjectLine = std::string(reinterpret_cast(sqlite3_column_text(stmt, 6))); + toAdd.MsgBody = std::string(reinterpret_cast(sqlite3_column_text(stmt, 7))); + toAdd.Taros = sqlite3_column_int(stmt, 8); + toAdd.SendTime = sqlite3_column_int64(stmt, 9); + toAdd.DeleteTime = sqlite3_column_int64(stmt, 10); - int i = 0; - for (Database::EmailData email : emailData) { - emails.push_back(email); - i++; + emails.push_back(toAdd); } + sqlite3_finalize(stmt); return emails; } @@ -1171,14 +1305,42 @@ std::vector Database::getEmails(int playerID, int page) { Database::EmailData Database::getEmail(int playerID, int index) { std::lock_guard lock(dbCrit); - auto emailData = db.get_all( - where(c(&Database::EmailData::PlayerId) == playerID && c(&Database::EmailData::MsgIndex) == index) - ); + const char* sql = R"( + SELECT "ItemFlag", "ReadFlag", "SenderId", "SenderFirstName", "SenderLastName", "SubjectLine", "MsgBody", + "Taros", "SendTime", "DeleteTime" + FROM "EmailData" + WHERE "PlayerId" = ? AND "MsgIndex" = ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_bind_int(stmt, 2, index); - if (emailData.size() > 1) - std::cout << "[WARN] Duplicate emails detected (player " << playerID << ", index " << index << ")" << std::endl; + Database::EmailData result; + if (sqlite3_step(stmt) != SQLITE_ROW) { + std::cout << "[WARN] Database: Email not found!" << std::endl; + sqlite3_finalize(stmt); + return result; + } - return emailData.at(0); + result.PlayerId = playerID; + result.MsgIndex = index; + result.ItemFlag = sqlite3_column_int(stmt, 0); + result.ReadFlag = sqlite3_column_int(stmt, 1); + result.SenderId = sqlite3_column_int(stmt, 2); + result.SenderFirstName = std::string(reinterpret_cast(sqlite3_column_text(stmt, 3))); + result.SenderLastName = std::string(reinterpret_cast(sqlite3_column_text(stmt, 4))); + result.SubjectLine = std::string(reinterpret_cast(sqlite3_column_text(stmt, 5))); + result.MsgBody = std::string(reinterpret_cast(sqlite3_column_text(stmt, 6))); + result.Taros = sqlite3_column_int(stmt, 7); + result.SendTime = sqlite3_column_int64(stmt, 8); + result.DeleteTime = sqlite3_column_int64(stmt, 9); + + if (sqlite3_step(stmt) == SQLITE_ROW) + std::cout << "[WARN] Database: Player has multiple emails with the same index ?!" << std::endl; + + sqlite3_finalize(stmt); + return result; } sItemBase* Database::getEmailAttachments(int playerID, int index) { @@ -1186,107 +1348,221 @@ sItemBase* Database::getEmailAttachments(int playerID, int index) { sItemBase* items = new sItemBase[4]; for (int i = 0; i < 4; i++) - items[i] = { 0, 0, 0, 0 }; // zero out items + items[i] = { 0, 0, 0, 0 }; - auto attachments = db.get_all( - where(c(&Database::EmailItem::PlayerId) == playerID && c(&Database::EmailItem::MsgIndex) == index) - ); + const char* sql = R"( + SELECT "Slot", "Id", "Type", "Opt", "TimeLimit" + FROM "EmailItems" + WHERE "PlayerId" = ? AND "MsgIndex" = ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_bind_int(stmt, 2, index); - if (attachments.size() > 4) - std::cout << "[WARN] Email has too many attachments (player " << playerID << ", index " << index << ")" << std::endl; + while (sqlite3_step(stmt) == SQLITE_ROW) { + int slot = sqlite3_column_int(stmt, 0) - 1; + if (slot < 0 || slot > 3) { + std::cout << "[WARN] Email item has invalid slot number ?!" << std::endl; + continue; + } - for (Database::EmailItem& item : attachments) { - items[item.Slot - 1] = { item.Type, item.Id, item.Opt, item.TimeLimit }; + items[slot].iID = sqlite3_column_int(stmt, 1); + items[slot].iType = sqlite3_column_int(stmt, 2); + items[slot].iOpt = sqlite3_column_int(stmt, 3); + items[slot].iTimeLimit = sqlite3_column_int(stmt, 4); } - + return items; } void Database::updateEmailContent(EmailData* data) { std::lock_guard lock(dbCrit); + + const char* sql = R"( + SELECT COUNT(*) FROM "EmailItems" + WHERE "PlayerId" = ? AND "MsgIndex" = ?; + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, data->PlayerId); + sqlite3_bind_int(stmt, 2, data->MsgIndex); + sqlite3_step(stmt); + int attachmentsCount = sqlite3_column_int(stmt, 0); - db.begin_transaction(); + data->ItemFlag = (data->Taros > 0 || attachmentsCount > 0) ? 1 : 0; // set attachment flag dynamically + // TODO: CHANGE THIS TO UPDATE + sqlite3_exec(db, "BEGIN TRANSACTION", NULL, NULL, NULL); - auto attachments = db.get_all( - where(c(&Database::EmailItem::PlayerId) == data->PlayerId && c(&Database::EmailItem::MsgIndex) == data->MsgIndex) - ); - data->ItemFlag = (data->Taros > 0 || attachments.size() > 0) ? 1 : 0; // set attachment flag dynamically + const char* sql = R"( + DELETE FROM "EmailData" + WHERE "PlayerId" = ? AND "MsgIndex" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, data->PlayerId); + sqlite3_bind_int(stmt, 2, data->MsgIndex); + sqlite3_step(stmt); - db.remove_all( - where(c(&Database::EmailData::PlayerId) == data->PlayerId && c(&Database::EmailData::MsgIndex) == data->MsgIndex) - ); - db.insert(*data); + const char* sql = R"( + INSERT INTO "EmailData" + ("PlayerId", "MsgIndex", "ReadFlag", "ItemFlag", "SenderId", "SenderFirstName", "SenderLastName", + "SubjectLine", "MsgBody", "Taros", "SendTime", "DeleteTime" + VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?); + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, data->PlayerId); + sqlite3_bind_int(stmt, 2, data->MsgIndex); + sqlite3_bind_int(stmt, 3, data->ReadFlag); + sqlite3_bind_int(stmt, 4, data->ItemFlag); + sqlite3_bind_int(stmt, 5, data->SenderId); + sqlite3_bind_text(stmt, 6, data->SenderFirstName.c_str(), -1, 0); + sqlite3_bind_text(stmt, 7, data->SenderLastName.c_str(), -1, 0); + sqlite3_bind_text(stmt, 8, data->SubjectLine.c_str(), -1, 0); + sqlite3_bind_text(stmt, 9, data->MsgBody.c_str(), -1, 0); + sqlite3_bind_int(stmt, 10, data->Taros); + sqlite3_bind_int64(stmt, 11, data->SendTime); + sqlite3_bind_int64(stmt, 12, data->DeleteTime); - db.commit(); + if (sqlite3_step(stmt) != SQLITE_DONE) + std::cout << "[WARN] Database: failed to update email" << std::endl; + + sqlite3_exec(db, "END TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); } void Database::deleteEmailAttachments(int playerID, int index, int slot) { std::lock_guard lock(dbCrit); - db.begin_transaction(); + sqlite3_stmt* stmt; if (slot == -1) { // delete all - db.remove_all( - where(c(&Database::EmailItem::PlayerId) == playerID && c(&Database::EmailItem::MsgIndex) == index) - ); + const char* sql = R"( + DELETE FROM "EmailItems" + WHERE "PlayerId" = ? AND "MsgIndex" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_bind_int(stmt, 2, index); + if (sqlite3_step(stmt) != SQLITE_DONE) + std::cout << "[wARN] Database: Failed to delete email attachemtns" << std::endl; + } else { // delete single by comparing slot num - db.remove_all( - where(c(&Database::EmailItem::PlayerId) == playerID && c(&Database::EmailItem::MsgIndex) == index - && c(&Database::EmailItem::Slot) == slot) - ); + const char* sql = R"( + DELETE FROM "EmailItems" + WHERE "PlayerId" = ? AND "MsgIndex" = ? AND "Slot" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_bind_int(stmt, 2, index); + sqlite3_bind_int(stmt, 3, slot); + if (sqlite3_step(stmt) != SQLITE_DONE) + std::cout << "[wARN] Database: Failed to delete email attachemtns" << std::endl; } - - db.commit(); + sqlite3_finalize(stmt); } void Database::deleteEmails(int playerID, int64_t* indices) { std::lock_guard lock(dbCrit); - db.begin_transaction(); + sqlite3_exec(db, "BEGIN TRANSACTION", NULL, NULL, NULL); + sqlite3_stmt* stmt; + + const char* sql = R"( + DELETE FROM "EmailData" + WHERE "PlayerId" = ? AND "MsgIndex" = ?; + )"; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); for (int i = 0; i < 5; i++) { - db.remove_all( - where(c(&Database::EmailData::PlayerId) == playerID && c(&Database::EmailData::MsgIndex) == indices[i]) - ); // no need to check if the index is 0, since an email will never have index < 1 + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_bind_int64(stmt, 2, indices[i]); + sqlite3_step(stmt); + sqlite3_reset(stmt); } + sqlite3_finalize(stmt); - db.commit(); + sqlite3_exec(db, "END TRANSACTION", NULL, NULL, NULL); } int Database::getNextEmailIndex(int playerID) { std::lock_guard lock(dbCrit); - auto emailData = db.get_all( - where(c(&Database::EmailData::PlayerId) == playerID), - order_by(&Database::EmailData::MsgIndex).desc(), - limit(1) - ); + const char* sql = R"( + SELECT "MsgIndex" FROM "EmailData" + WHERE "PlayerId" = ? + ORDER BY "MsgIndex" DESC + LIMIT 1 + )"; + sqlite3_stmt* stmt; + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, playerID); + sqlite3_step(stmt); + int index = sqlite3_column_int(stmt, 0); - return (emailData.size() > 0 ? emailData.at(0).MsgIndex + 1 : 1); + return (index > 0 ? index + 1 : 1); } void Database::sendEmail(EmailData* data, std::vector attachments) { std::lock_guard lock(dbCrit); - db.begin_transaction(); + sqlite3_exec(db, "BEGIN TRANSACTION", NULL, NULL, NULL); - db.insert(*data); // add email data to db - // add email attachments to db email inventory - int slot = 1; - for (sItemBase item : attachments) { - EmailItem dbItem = { - data->PlayerId, - data->MsgIndex, - slot++, - item.iType, - item.iID, - item.iOpt, - item.iTimeLimit - }; - db.insert(dbItem); + const char* sql = R"( + INSERT INTO "EmailData" + ("PlayerId", "MsgIndex", "ReadFlag", "ItemFlag", "SenderId", "SenderFirstName", "SenderLastName", + "SubjectLine", "MsgBody", "Taros", "SendTime", "DeleteTime" + VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?); + )"; + sqlite3_stmt* stmt; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, data->PlayerId); + sqlite3_bind_int(stmt, 2, data->MsgIndex); + sqlite3_bind_int(stmt, 3, data->ReadFlag); + sqlite3_bind_int(stmt, 4, data->ItemFlag); + sqlite3_bind_int(stmt, 5, data->SenderId); + sqlite3_bind_text(stmt, 6, data->SenderFirstName.c_str(), -1, 0); + sqlite3_bind_text(stmt, 7, data->SenderLastName.c_str(), -1, 0); + sqlite3_bind_text(stmt, 8, data->SubjectLine.c_str(), -1, 0); + sqlite3_bind_text(stmt, 9, data->MsgBody.c_str(), -1, 0); + sqlite3_bind_int(stmt, 10, data->Taros); + sqlite3_bind_int64(stmt, 11, data->SendTime); + sqlite3_bind_int64(stmt, 12, data->DeleteTime); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + std::cout << "[WARN] Database: Failed to send email" << std::endl; + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + return; } - db.commit(); + int slot = 1; + for (sItemBase item : attachments) { + sql = R"( + INSERT INTO EmailItems + ("PlayerId", "MsgIndex", "Slot", "Id", "Type", "Opt", "TimeLimit") + VALUES (?, ?, ?, ?, ?, ?, ?); + )"; + sqlite3_stmt* stmt; + + sqlite3_prepare_v2(db, sql, -1, &stmt, 0); + sqlite3_bind_int(stmt, 1, data->PlayerId); + sqlite3_bind_int(stmt, 2, data->MsgIndex); + sqlite3_bind_int(stmt, 3, slot++); + sqlite3_bind_int(stmt, 4, item.iID); + sqlite3_bind_int(stmt, 5, item.iType); + sqlite3_bind_int(stmt, 6, item.iOpt); + sqlite3_bind_int(stmt, 7, item.iTimeLimit); + + if (sqlite3_step(stmt) != SQLITE_DONE) { + std::cout << "[WARN] Database: Failed to send email" << std::endl; + sqlite3_exec(db, "ROLLBACK TRANSACTION", NULL, NULL, NULL); + sqlite3_finalize(stmt); + return; + } + sqlite3_reset(stmt); + } + sqlite3_finalize(stmt); + sqlite3_exec(db, "END TRANSACTION", NULL, NULL, NULL); } -#pragma endregion ShardServer diff --git a/src/Database.hpp b/src/Database.hpp index 11bc202..ece1ec4 100644 --- a/src/Database.hpp +++ b/src/Database.hpp @@ -85,7 +85,6 @@ namespace Database { bool finishTutorial(int playerID); // returns slot number int deleteCharacter(int characterID, int userID); - std::vector getCharacters(int userID); std::vector getCharInfo(int userID); // accepting/declining custom name enum class CustomName { @@ -93,10 +92,10 @@ namespace Database { DISAPPROVE = 2 }; void evaluateCustomName(int characterID, CustomName decision); - void changeName(sP_CL2LS_REQ_CHANGE_CHAR_NAME* save); + bool changeName(sP_CL2LS_REQ_CHANGE_CHAR_NAME* save, int accountId); // getting players - Player getPlayer(int id); + void getPlayer(Player* plr, int id); void updatePlayer(Player *player); void updateInventory(Player *player); @@ -104,11 +103,8 @@ namespace Database { void updateQuests(Player* player); void updateBuddies(Player* player); - void getInventory(Player* player); void removeExpiredVehicles(Player* player); - void getNanos(Player* player); - void getQuests(Player* player); - void getBuddies(Player* player); + int getNumBuddies(Player* player); // buddies diff --git a/src/Player.hpp b/src/Player.hpp index 3ec533e..002433b 100644 --- a/src/Player.hpp +++ b/src/Player.hpp @@ -17,7 +17,6 @@ struct Player { int64_t SerialKey; int32_t iID; uint64_t FEKey; - time_t creationTime; int level; int HP; @@ -45,7 +44,6 @@ struct Player { uint64_t instanceID; sItemBase Equip[AEQUIP_COUNT]; sItemBase Inven[AINVEN_COUNT]; - sItemBase Bank[ABANK_COUNT]; sItemTrade Trade[12]; int32_t moneyInTrade; bool isTrading;