Record claimed code items, and other misc DB fixes

* Create new table to store redeemed codes
* Check if a player already used a code when using /redeem
* Change Coordinate columns to non-plural form
* Fixed EmailItems unique constraint not being specific enough
* Bumped DB version to 3
This commit is contained in:
CakeLancelot 2021-01-18 20:44:02 -06:00
parent 74af1ad173
commit 04a17ed862
5 changed files with 104 additions and 9 deletions

37
sql/migration2.sql Normal file
View File

@ -0,0 +1,37 @@
/*
It is recommended in the SQLite manual to turn off
foreign keys when making schema changes that involve them
*/
PRAGMA foreign_keys=OFF;
BEGIN TRANSACTION;
-- New table to store code items
CREATE TABLE RedeemedCodes(
PlayerID INTEGER NOT NULL,
Code TEXT NOT NULL,
FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE,
UNIQUE (PlayerID, Code)
);
-- Change Coordinates in Players table to non-plural form
ALTER TABLE Players RENAME COLUMN XCoordinates TO XCoordinate;
ALTER TABLE Players RENAME COLUMN YCoordinates TO YCoordinate;
ALTER TABLE Players RENAME COLUMN ZCoordinates TO ZCoordinate;
-- Fix email attachments not being unique enough
CREATE TABLE Temp (
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 (PlayerID, MsgIndex, Slot)
);
INSERT INTO Temp SELECT * FROM EmailItems;
DROP TABLE EmailItems;
ALTER TABLE Temp RENAME TO EmailItems;
-- Update DB Version
UPDATE Meta SET Value = 3 WHERE Key = 'DatabaseVersion';
UPDATE Meta SET Value = strftime('%s', 'now') WHERE Key = 'LastMigration';
COMMIT;
PRAGMA foreign_keys=ON;

View File

@ -28,9 +28,9 @@ CREATE TABLE IF NOT EXISTS Players (
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,
XCoordinate INTEGER NOT NULL,
YCoordinate INTEGER NOT NULL,
ZCoordinate INTEGER NOT NULL,
Angle INTEGER NOT NULL,
HP INTEGER NOT NULL,
FusionMatter INTEGER DEFAULT 0 NOT NULL,
@ -140,7 +140,7 @@ CREATE TABLE IF NOT EXISTS EmailItems (
Opt INTEGER NOT NULL,
TimeLimit INTEGER NOT NULL,
FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE,
UNIQUE (MsgIndex, Slot)
UNIQUE (PlayerID, MsgIndex, Slot)
);
CREATE TABLE IF NOT EXISTS RaceResults(
@ -152,3 +152,10 @@ CREATE TABLE IF NOT EXISTS RaceResults(
Timestamp INTEGER NOT NULL,
FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS RedeemedCodes(
PlayerID INTEGER NOT NULL,
Code TEXT NOT NULL,
FOREIGN KEY(PlayerID) REFERENCES Players(PlayerID) ON DELETE CASCADE,
UNIQUE (PlayerID, Code)
)

View File

@ -1,6 +1,7 @@
#include "CNShardServer.hpp"
#include "CNStructs.hpp"
#include "ChatManager.hpp"
#include "Database.hpp"
#include "PlayerManager.hpp"
#include "TransportManager.hpp"
#include "TableData.hpp"
@ -754,6 +755,12 @@ void redeemCommand(std::string full, std::vector<std::string>& args, CNSocket* s
}
Player* plr = PlayerManager::getPlayer(sock);
if (Database::isCodeRedeemed(plr->iID, code)) {
ChatManager::sendServerMessage(sock, "/redeem: You have already redeemed this code item");
return;
}
int itemCount = ItemManager::CodeItems[code].size();
int slots[4];
@ -772,6 +779,8 @@ void redeemCommand(std::string full, std::vector<std::string>& args, CNSocket* s
plr->Inven[slots[i]] = { 999, 999, 999, 0 }; // temp item; overwritten later
}
Database::recordCodeRedemption(plr->iID, code);
for (int i = 0; i < itemCount; i++) {
std::pair<int32_t, int32_t> item = ItemManager::CodeItems[code][i];
INITSTRUCT(sP_FE2CL_REP_PC_GIVE_ITEM_SUCC, resp);

View File

@ -428,7 +428,7 @@ int Database::createCharacter(sP_CL2LS_REQ_SAVE_CHAR_NAME* save, int AccountID)
const char* sql = R"(
INSERT INTO Players
(AccountID, Slot, FirstName, LastName,
XCoordinates, YCoordinates, ZCoordinates, Angle,
XCoordinate, YCoordinate, ZCoordinate, Angle,
HP, NameCheck, Quests, SkywayLocationFlag, FirstUseFlag)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?);
)";
@ -693,7 +693,7 @@ void Database::getCharInfo(std::vector <sP_LS2CL_REP_CHAR_INFO>* result, int use
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,
p.XCoordinate, p.YCoordinate, p.ZCoordinate, 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
@ -815,7 +815,7 @@ void Database::getPlayer(Player* plr, int id) {
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.XCoordinate, p.YCoordinate, p.ZCoordinate, p.NameCheck,
p.Angle, p.HP, acc.AccountLevel, p.FusionMatter, p.Taros, p.Quests,
p.BatteryW, p.BatteryN, p.Mentor, p.WarpLocationFlag,
p.SkywayLocationFlag, p.CurrentMissionID, p.FirstUseFlag,
@ -1061,7 +1061,7 @@ void Database::updatePlayer(Player *player) {
UPDATE Players
SET
Level = ? , Nano1 = ?, Nano2 = ?, Nano3 = ?,
XCoordinates = ?, YCoordinates = ?, ZCoordinates = ?,
XCoordinate = ?, YCoordinate = ?, ZCoordinate = ?,
Angle = ?, HP = ?, FusionMatter = ?, Taros = ?, Quests = ?,
BatteryW = ?, BatteryN = ?, WarplocationFlag = ?,
SkywayLocationFlag = ?, CurrentMissionID = ?,
@ -1840,3 +1840,41 @@ void Database::postRaceRanking(Database::RaceRanking ranking) {
sqlite3_finalize(stmt);
}
bool Database::isCodeRedeemed (int playerId, std::string code) {
std::lock_guard<std::mutex> lock(dbCrit);
const char* sql = R"(
SELECT COUNT(*)
FROM RedeemedCodes
WHERE PlayerID = ? AND Code = ?
LIMIT 1;
)";
sqlite3_stmt* stmt;
sqlite3_prepare_v2(db, sql, -1, &stmt, NULL);
sqlite3_bind_int(stmt, 1, playerId);
sqlite3_bind_text(stmt, 2, code.c_str(), -1, NULL);
sqlite3_step(stmt);
int result = sqlite3_column_int(stmt, 0);
sqlite3_finalize(stmt);
return result;
}
void Database::recordCodeRedemption(int playerId, std::string code) {
std::lock_guard<std::mutex> lock(dbCrit);
const char* sql = R"(
INSERT INTO RedeemedCodes (PlayerID, Code)
VALUES (?, ?);
)";
sqlite3_stmt* stmt;
sqlite3_prepare_v2(db, sql, -1, &stmt, NULL);
sqlite3_bind_int(stmt, 1, playerId);
sqlite3_bind_text(stmt, 2, code.c_str(), -1, NULL);
if (sqlite3_step(stmt) != SQLITE_DONE)
std::cout << "[WARN] Database: recording of code redemption failed: " << sqlite3_errmsg(db) << std::endl;
sqlite3_finalize(stmt);
}

View File

@ -4,7 +4,7 @@
#include <string>
#include <vector>
#define DATABASE_VERSION 2
#define DATABASE_VERSION 3
namespace Database {
@ -100,4 +100,8 @@ namespace Database {
// racing
RaceRanking getTopRaceRanking(int epID, int playerID);
void postRaceRanking(RaceRanking ranking);
// code items
bool isCodeRedeemed(int playerId, std::string code);
void recordCodeRedemption(int playerId, std::string code);
}