Skip to content

Commit

Permalink
Move skills into players table
Browse files Browse the repository at this point in the history
There's no advantage to storing skills in a separate table if every
player has a row for each skill anyway. It would make more sense if we
didn't insert the rows with value 10 and count 0, but that introduces
another set of problems. This will save 7 queries when saving players, 1
query when loading players, 7 queries when inserting new players, and
removes a trigger (hopefully we can get rid of all triggers soon,
they're bad because MySQL requires SUPER privilege to create triggers
and doesn't warn the user if it didn't insert them for that reason).
  • Loading branch information
marksamman committed Aug 2, 2013
1 parent 7cfb8f6 commit e801489
Show file tree
Hide file tree
Showing 8 changed files with 64 additions and 106 deletions.
7 changes: 6 additions & 1 deletion data/migrations/15.lua
@@ -1,3 +1,8 @@
function onUpdateDatabase()
return false
print("> Updating database to version 16 (moving skills into players table)")
db.query("ALTER TABLE `players` ADD `skill_fist` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_fist_tries` bigint(20) unsigned NOT NULL DEFAULT 0, ADD `skill_club` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_club_tries` bigint(20) unsigned NOT NULL DEFAULT 0, ADD `skill_sword` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_sword_tries` bigint(20) unsigned NOT NULL DEFAULT 0, ADD `skill_axe` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_axe_tries` bigint(20) unsigned NOT NULL DEFAULT 0, ADD `skill_dist` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_dist_tries` bigint(20) unsigned NOT NULL DEFAULT 0, ADD `skill_shielding` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_shielding_tries` bigint(20) unsigned NOT NULL DEFAULT 0, ADD `skill_fishing` int(10) unsigned NOT NULL DEFAULT 10, ADD `skill_fishing_tries` bigint(20) unsigned NOT NULL DEFAULT 0")
db.query("UPDATE `players` SET `skill_fist` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 0), `skill_fist_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 0), `skill_club` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 1), `skill_club_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 1), `skill_sword` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 2), `skill_sword_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 2), `skill_axe` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 3), `skill_axe_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 3), `skill_dist` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 4), `skill_dist_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 4), `skill_shielding` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 5), `skill_shielding_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 5), `skill_fishing` = (SELECT `value` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 6), `skill_fishing_tries` = (SELECT `count` FROM `player_skills` WHERE `player_id` = `id` AND `skillid` = 6)")
db.query("DROP TRIGGER `oncreate_players`")
db.query("DROP TABLE `player_skills`")
return true
end
3 changes: 3 additions & 0 deletions data/migrations/16.lua
@@ -0,0 +1,3 @@
function onUpdateDatabase()
return false
end
61 changes: 17 additions & 44 deletions schema.sql
@@ -1,13 +1,3 @@
CREATE TABLE IF NOT EXISTS `groups` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL COMMENT 'group name',
`flags` bigint(20) unsigned NOT NULL DEFAULT '0',
`access` int(11) NOT NULL,
`maxdepotitems` int(11) NOT NULL,
`maxviplist` int(11) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;

CREATE TABLE IF NOT EXISTS `accounts` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`name` varchar(32) NOT NULL,
Expand All @@ -16,11 +6,9 @@ CREATE TABLE IF NOT EXISTS `accounts` (
`premdays` int(11) NOT NULL DEFAULT '0',
`lastday` int(10) unsigned NOT NULL DEFAULT '0',
`email` varchar(255) NOT NULL DEFAULT '',
`group_id` int(11) NOT NULL DEFAULT '1',
`creation` int(11) NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`),
FOREIGN KEY (`group_id`) REFERENCES `groups` (`id`)
UNIQUE KEY `name` (`name`)
) ENGINE=InnoDB;

CREATE TABLE IF NOT EXISTS `players` (
Expand Down Expand Up @@ -64,10 +52,23 @@ CREATE TABLE IF NOT EXISTS `players` (
`offlinetraining_time` smallint(5) unsigned NOT NULL DEFAULT '43200',
`offlinetraining_skill` int(11) NOT NULL DEFAULT '-1',
`stamina` smallint(5) unsigned NOT NULL DEFAULT '2520',
`skill_fist` int(10) unsigned NOT NULL DEFAULT 10,
`skill_fist_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
`skill_club` int(10) unsigned NOT NULL DEFAULT 10,
`skill_club_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
`skill_sword` int(10) unsigned NOT NULL DEFAULT 10,
`skill_sword_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
`skill_axe` int(10) unsigned NOT NULL DEFAULT 10,
`skill_axe_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
`skill_dist` int(10) unsigned NOT NULL DEFAULT 10,
`skill_dist_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
`skill_shielding` int(10) unsigned NOT NULL DEFAULT 10,
`skill_shielding_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
`skill_fishing` int(10) unsigned NOT NULL DEFAULT 10,
`skill_fishing_tries` bigint(20) unsigned NOT NULL DEFAULT 0,
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`),
FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE,
FOREIGN KEY (`group_id`) REFERENCES `groups` (`id`),
KEY `vocation` (`vocation`)
) ENGINE=InnoDB;

Expand Down Expand Up @@ -128,11 +129,6 @@ CREATE TABLE IF NOT EXISTS `account_viplist` (
FOREIGN KEY (`player_id`) REFERENCES `players` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB;

INSERT INTO `groups` (`id`, `name`, `flags`, `access`, `maxdepotitems`, `maxviplist`) VALUES
(1, 'player', 0, 0, 0, 200),
(2, 'a gamemaster', 137438953471, 1, 0, 0),
(3, 'a god', 127540697997304, 1, 0, 0);

CREATE TABLE IF NOT EXISTS `guilds` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
Expand Down Expand Up @@ -308,16 +304,6 @@ CREATE TABLE IF NOT EXISTS `player_items` (
KEY `sid` (`sid`)
) ENGINE=InnoDB;

CREATE TABLE IF NOT EXISTS `player_skills` (
`player_id` int(11) NOT NULL DEFAULT '0',
`skillid` tinyint(4) NOT NULL DEFAULT '0',
`value` int(10) unsigned NOT NULL DEFAULT '0',
`count` int(10) unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`player_id`, `skillid`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE,
KEY `value_count_index` (`value`,`count`)
) ENGINE=InnoDB;

CREATE TABLE IF NOT EXISTS `player_spells` (
`player_id` int(11) NOT NULL,
`name` varchar(255) NOT NULL,
Expand All @@ -338,31 +324,18 @@ CREATE TABLE IF NOT EXISTS `server_config` (
PRIMARY KEY `config` (`config`)
) ENGINE=InnoDB;

INSERT INTO `server_config` (`config`, `value`) VALUES ('db_version', '14'), ('motd_hash', ''), ('motd_num', '0'), ('players_record', '0');
INSERT INTO `server_config` (`config`, `value`) VALUES ('db_version', '16'), ('motd_hash', ''), ('motd_num', '0'), ('players_record', '0');

CREATE TABLE IF NOT EXISTS `tile_store` (
`house_id` int(11) NOT NULL,
`data` longblob NOT NULL,
FOREIGN KEY (`house_id`) REFERENCES `houses` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB;

DROP TRIGGER IF EXISTS `ondelete_accounts`;
DROP TRIGGER IF EXISTS `oncreate_players`;
DROP TRIGGER IF EXISTS `ondelete_players`;
DROP TRIGGER IF EXISTS `oncreate_guilds`;

DELIMITER //
CREATE TRIGGER `oncreate_players` AFTER INSERT ON `players`
FOR EACH ROW BEGIN
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 0, 10);
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 1, 10);
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 2, 10);
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 3, 10);
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 4, 10);
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 5, 10);
INSERT INTO `player_skills` (`player_id`, `skillid`, `value`) VALUES (NEW.`id`, 6, 10);
END
//
CREATE TRIGGER `ondelete_players` BEFORE DELETE ON `players`
FOR EACH ROW BEGIN
UPDATE `houses` SET `owner` = 0 WHERE `owner` = OLD.`id`;
Expand All @@ -375,4 +348,4 @@ CREATE TRIGGER `oncreate_guilds` AFTER INSERT ON `guilds`
INSERT INTO `guild_ranks` (`name`, `level`, `guild_id`) VALUES ('a Member', 1, NEW.`id`);
END
//
DELIMITER ;
DELIMITER ;
7 changes: 3 additions & 4 deletions src/database.cpp
Expand Up @@ -321,9 +321,8 @@ bool DBResult::next()
return m_row != NULL;
}

DBInsert::DBInsert(Database* db)
DBInsert::DBInsert()
{
m_db = db;
m_rows = 0;
}

Expand All @@ -342,7 +341,7 @@ bool DBInsert::addRow(const std::string& row)
size_t size = m_buf.length();
if (size == 0) {
m_buf = "(" + row + ")";
} else if (size > 8192) {
} else if (size > 32768) {
if (!execute()) {
return false;
}
Expand Down Expand Up @@ -370,7 +369,7 @@ bool DBInsert::execute()
m_rows = 0;

// executes buffer
bool res = m_db->executeQuery(m_query + m_buf);
bool res = Database::getInstance()->executeQuery(m_query + m_buf);
m_buf = "";
return res;
}
8 changes: 1 addition & 7 deletions src/database.h
Expand Up @@ -190,12 +190,7 @@ class DBResult
class DBInsert
{
public:
/**
* Associates with given database handler.
*
* @param Database* database wrapper
*/
DBInsert(Database* db);
DBInsert();
~DBInsert() {}

/**
Expand Down Expand Up @@ -225,7 +220,6 @@ class DBInsert
std::string m_query;
std::string m_buf;

Database* m_db;
uint32_t m_rows;
};

Expand Down
78 changes: 31 additions & 47 deletions src/iologindata.cpp
Expand Up @@ -248,7 +248,7 @@ bool IOLoginData::loadPlayer(Player* player, const std::string& name)
Database* db = Database::getInstance();

std::ostringstream query;
query << "SELECT `id`, `account_id`, `group_id`, `sex`, `vocation`, `experience`, `level`, `maglevel`, `health`, `healthmax`, `blessings`, `mana`, `manamax`, `manaspent`, `soul`, `lookbody`, `lookfeet`, `lookhead`, `looklegs`, `looktype`, `lookaddons`, `posx`, `posy`, `posz`, `cap`, `lastlogin`, `lastlogout`, `lastip`, `conditions`, `skulltime`, `skull`, `town_id`, `balance`, `offlinetraining_time`, `offlinetraining_skill`, `stamina` FROM `players` WHERE `name` = " << db->escapeString(name);
query << "SELECT `id`, `account_id`, `group_id`, `sex`, `vocation`, `experience`, `level`, `maglevel`, `health`, `healthmax`, `blessings`, `mana`, `manamax`, `manaspent`, `soul`, `lookbody`, `lookfeet`, `lookhead`, `looklegs`, `looktype`, `lookaddons`, `posx`, `posy`, `posz`, `cap`, `lastlogin`, `lastlogout`, `lastip`, `conditions`, `skulltime`, `skull`, `town_id`, `balance`, `offlinetraining_time`, `offlinetraining_skill`, `stamina`, `skill_fist`, `skill_fist_tries`, `skill_club`, `skill_club_tries`, `skill_sword`, `skill_sword_tries`, `skill_axe`, `skill_axe_tries`, `skill_dist`, `skill_dist_tries`, `skill_shielding`, `skill_shielding_tries`, `skill_fishing`, `skill_fishing_tries` FROM `players` WHERE `name` = " << db->escapeString(name);

DBResult* result = db->storeQuery(query.str());
if (!result) {
Expand Down Expand Up @@ -391,6 +391,19 @@ bool IOLoginData::loadPlayer(Player* player, const std::string& name)

player->staminaMinutes = result->getDataInt("stamina");

std::string skillNames[] = {"skill_fist", "skill_club", "skill_sword", "skill_axe", "skill_dist", "skill_shielding", "skill_fishing"};
for (int i = 0, size = sizeof(skillNames) / sizeof(std::string); i < size; ++i) {
uint32_t skillLevel = result->getDataInt(skillNames[i]);
uint64_t skillTries = result->getDataLong(skillNames[i] + "_tries");
uint64_t nextSkillTries = player->vocation->getReqSkillTries(i, skillLevel + 1);
if (skillTries > nextSkillTries) {
skillTries = 0;
}
player->skills[i][SKILL_LEVEL] = skillLevel;
player->skills[i][SKILL_TRIES] = skillTries;
player->skills[i][SKILL_PERCENT] = Player::getPercentLevel(skillTries, nextSkillTries);
}

db->freeResult(result);

query.str("");
Expand Down Expand Up @@ -448,44 +461,13 @@ bool IOLoginData::loadPlayer(Player* player, const std::string& name)
}
}

// we need to find out our skills
// so we query the skill table
query.str("");
query << "SELECT `skillid`, `value`, `count` FROM `player_skills` WHERE `player_id` = " << player->getGUID();

if ((result = db->storeQuery(query.str()))) {
//now iterate over the skills
do {
int32_t skillid = result->getDataInt("skillid");

if (skillid >= SKILL_FIRST && skillid <= SKILL_LAST) {
uint32_t skillLevel = result->getDataInt("value");
uint64_t skillCount = result->getDataLong("count");

uint64_t nextSkillCount = player->vocation->getReqSkillTries(skillid, skillLevel + 1);

if (skillCount > nextSkillCount) {
skillCount = 0;
}

player->skills[skillid][SKILL_LEVEL] = skillLevel;
player->skills[skillid][SKILL_TRIES] = skillCount;
player->skills[skillid][SKILL_PERCENT] = Player::getPercentLevel(skillCount, nextSkillCount);
}
} while (result->next());

db->freeResult(result);
}

query.str("");
query << "SELECT `player_id`, `name` FROM `player_spells` WHERE `player_id` = " << player->getGUID();

if ((result = db->storeQuery(query.str()))) {
do {
std::string spellName = result->getDataString("name");
player->learnedInstantSpellList.push_back(spellName);
} while (result->next());

db->freeResult(result);
}

Expand All @@ -494,7 +476,6 @@ bool IOLoginData::loadPlayer(Player* player, const std::string& name)

query.str("");
query << "SELECT `pid`, `sid`, `itemtype`, `count`, `attributes` FROM `player_items` WHERE `player_id` = " << player->getGUID() << " ORDER BY `sid` DESC";

if ((result = db->storeQuery(query.str()))) {
loadItems(itemMap, result);
db->freeResult(result);
Expand All @@ -503,7 +484,6 @@ bool IOLoginData::loadPlayer(Player* player, const std::string& name)
const std::pair<Item*, int32_t>& pair = it->second;
Item* item = pair.first;
int32_t pid = pair.second;

if (pid >= 1 && pid <= 10) {
player->__internalAddThing(pid, item);
} else {
Expand All @@ -525,7 +505,6 @@ bool IOLoginData::loadPlayer(Player* player, const std::string& name)

query.str("");
query << "SELECT `pid`, `sid`, `itemtype`, `count`, `attributes` FROM `player_depotitems` WHERE `player_id` = " << player->getGUID() << " ORDER BY `sid` DESC";

if ((result = db->storeQuery(query.str()))) {
loadItems(itemMap, result);
db->freeResult(result);
Expand Down Expand Up @@ -791,6 +770,22 @@ bool IOLoginData::savePlayer(Player* player)
query << "`offlinetraining_time` = " << player->getOfflineTrainingTime() / 1000 << ", ";
query << "`offlinetraining_skill` = " << player->getOfflineTrainingSkill() << ", ";
query << "`stamina` = " << player->getStaminaMinutes() << ", ";

query << "`skill_fist` = " << player->skills[SKILL_FIST][SKILL_LEVEL] << ", ";
query << "`skill_fist_tries" << player->skills[SKILL_FIST][SKILL_TRIES] << ", ";
query << "`skill_club` = " << player->skills[SKILL_CLUB][SKILL_LEVEL] << ", ";
query << "`skill_club_tries" << player->skills[SKILL_CLUB][SKILL_TRIES] << ", ";
query << "`skill_sword` = " << player->skills[SKILL_SWORD][SKILL_LEVEL] << ", ";
query << "`skill_sword_tries" << player->skills[SKILL_SWORD][SKILL_TRIES] << ", ";
query << "`skill_axe` = " << player->skills[SKILL_AXE][SKILL_LEVEL] << ", ";
query << "`skill_axe_tries" << player->skills[SKILL_AXE][SKILL_TRIES] << ", ";
query << "`skill_dist` = " << player->skills[SKILL_DIST][SKILL_LEVEL] << ", ";
query << "`skill_dist_tries" << player->skills[SKILL_DIST][SKILL_TRIES] << ", ";
query << "`skill_shielding` = " << player->skills[SKILL_SHIELD][SKILL_LEVEL] << ", ";
query << "`skill_shielding_tries" << player->skills[SKILL_SHIELD][SKILL_TRIES] << ", ";
query << "`skill_fishing` = " << player->skills[SKILL_FISH][SKILL_LEVEL] << ", ";
query << "`skill_fishing_tries" << player->skills[SKILL_FISH][SKILL_TRIES] << ", ";

if (!player->isOffline()) {
query << "`onlinetime` = `onlinetime` + " << (time(NULL) - player->lastLoginSaved) << ", ";
}
Expand All @@ -806,27 +801,16 @@ bool IOLoginData::savePlayer(Player* player)
return false;
}

// skills
for (int32_t i = SKILL_FIRST; i <= SKILL_LAST; i++) {
query.str("");
query << "UPDATE `player_skills` SET `value` = " << player->skills[i][SKILL_LEVEL] << ", `count` = " << player->skills[i][SKILL_TRIES] << " WHERE `player_id` = " << player->getGUID() << " AND `skillid` = " << i;

if (!db->executeQuery(query.str())) {
return false;
}
}

// learned spells
query.str("");
query << "DELETE FROM `player_spells` WHERE `player_id` = " << player->getGUID();

if (!db->executeQuery(query.str())) {
return false;
}

query.str("");

DBInsert stmt(db);
DBInsert stmt;
stmt.setQuery("INSERT INTO `player_spells` (`player_id`, `name` ) VALUES ");

for (LearnedInstantSpellList::const_iterator it = player->learnedInstantSpellList.begin();
Expand Down
4 changes: 2 additions & 2 deletions src/iomapserialize.cpp
Expand Up @@ -98,7 +98,7 @@ bool IOMapSerialize::saveMap(Map* map)
return false;
}

DBInsert stmt(db);
DBInsert stmt;
stmt.setQuery("INSERT INTO `tile_store` (`house_id`, `data`) VALUES ");

//clear old tile data
Expand Down Expand Up @@ -362,7 +362,7 @@ bool IOMapSerialize::saveHouseInfo(Map* map)
query.str("");
}

DBInsert stmt(db);
DBInsert stmt;
stmt.setQuery("INSERT INTO `house_lists` (`house_id` , `listid` , `list`) VALUES ");

for (const auto& it : Houses::getInstance().getHouses()) {
Expand Down
2 changes: 1 addition & 1 deletion src/luascript.cpp
Expand Up @@ -151,7 +151,7 @@ bool ScriptEnvironment::saveGameState()

db->executeQuery("TRUNCATE TABLE `global_storage`");

DBInsert stmt(db);
DBInsert stmt;
stmt.setQuery("INSERT INTO `global_storage` (`key`, `value`) VALUES ");

std::ostringstream query;
Expand Down

2 comments on commit e801489

@diath
Copy link
Contributor

@diath diath commented on e801489 Aug 3, 2013

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Wouldn't it be a good idea to make skillNames a static variable?

@marksamman
Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Indeed it would. I've changed it to static and also added another static array with _tries appended to each column name so that we don't need to do the string concatenation.

Please sign in to comment.