Merge pull request #930 from wesnoth/sql_prepared_statements

Sql prepared statements
This commit is contained in:
Sergey Popov 2017-03-03 14:27:16 +03:00 committed by GitHub
commit eca27ae16f
3 changed files with 265 additions and 60 deletions

View file

@ -15,6 +15,7 @@
#ifdef HAVE_MYSQLPP
#include "server/forum_user_handler.hpp"
#include "server/mysql_prepared_statement.ipp"
#include "hash.hpp"
#include "log.hpp"
#include "config.hpp"
@ -115,9 +116,8 @@ bool fuh::user_exists(const std::string& name) {
// Make a test query for this username
try {
mysql_result res = db_query("SELECT username FROM " + db_users_table_ + " WHERE UPPER(username)=UPPER('" + name + "')");
return mysql_fetch_row(res.get());
} catch (error& e) {
return prepared_statement<bool>("SELECT 1 FROM `" + db_users_table_ + "` WHERE UPPER(username)=UPPER(?)", name);
} catch (sql_error& e) {
ERR_UH << "Could not execute test query for user '" << name << "' :" << e.message << std::endl;
// If the database is down just let all usernames log in
return false;
@ -126,9 +126,9 @@ bool fuh::user_exists(const std::string& name) {
bool fuh::user_is_active(const std::string& name) {
try {
int user_type = std::stoi(get_detail_for_user(name, "user_type"));
int user_type = get_detail_for_user<int>(name, "user_type");
return user_type != USER_INACTIVE && user_type != USER_IGNORE;
} catch (error& e) {
} catch (sql_error& e) {
ERR_UH << "Could not retrieve user type for user '" << name << "' :" << e.message << std::endl;
return false;
}
@ -139,8 +139,8 @@ bool fuh::user_is_moderator(const std::string& name) {
if(!user_exists(name)) return false;
try {
return get_writable_detail_for_user(name, "user_is_moderator") == "1";
} catch (error& e) {
return get_writable_detail_for_user<int>(name, "user_is_moderator") == 1;
} catch (sql_error& e) {
ERR_UH << "Could not query user_is_moderator for user '" << name << "' :" << e.message << std::endl;
// If the database is down mark nobody as a mod
return false;
@ -152,8 +152,8 @@ void fuh::set_is_moderator(const std::string& name, const bool& is_moderator) {
if(!user_exists(name)) return;
try {
write_detail(name, "user_is_moderator", is_moderator ? "1" : "0");
} catch (error& e) {
write_detail(name, "user_is_moderator", int(is_moderator));
} catch (sql_error& e) {
ERR_UH << "Could not set is_moderator for user '" << name << "' :" << e.message << std::endl;
}
}
@ -201,8 +201,8 @@ std::string fuh::get_valid_details() {
std::string fuh::get_hash(const std::string& user) {
try {
return get_detail_for_user(user, "user_password");
} catch (error& e) {
return get_detail_for_user<std::string>(user, "user_password");
} catch (sql_error& e) {
ERR_UH << "Could not retrieve password for user '" << user << "' :" << e.message << std::endl;
return "";
}
@ -210,8 +210,8 @@ std::string fuh::get_hash(const std::string& user) {
std::string fuh::get_mail(const std::string& user) {
try {
return get_detail_for_user(user, "user_email");
} catch (error& e) {
return get_detail_for_user<std::string>(user, "user_email");
} catch (sql_error& e) {
ERR_UH << "Could not retrieve email for user '" << user << "' :" << e.message << std::endl;
return "";
}
@ -219,9 +219,9 @@ std::string fuh::get_mail(const std::string& user) {
time_t fuh::get_lastlogin(const std::string& user) {
try {
int time_int = std::stoi(get_writable_detail_for_user(user, "user_lastvisit"));
int time_int = get_writable_detail_for_user<int>(user, "user_lastvisit");
return time_t(time_int);
} catch (error& e) {
} catch (sql_error& e) {
ERR_UH << "Could not retrieve last visit for user '" << user << "' :" << e.message << std::endl;
return time_t(0);
}
@ -229,9 +229,9 @@ time_t fuh::get_lastlogin(const std::string& user) {
time_t fuh::get_registrationdate(const std::string& user) {
try {
int time_int = std::stoi(get_detail_for_user(user, "user_regdate"));
int time_int = get_detail_for_user<int>(user, "user_regdate");
return time_t(time_int);
} catch (error& e) {
} catch (sql_error& e) {
ERR_UH << "Could not retrieve registration date for user '" << user << "' :" << e.message << std::endl;
return time_t(0);
}
@ -239,58 +239,54 @@ time_t fuh::get_registrationdate(const std::string& user) {
void fuh::set_lastlogin(const std::string& user, const time_t& lastlogin) {
std::stringstream ss;
ss << lastlogin;
try {
write_detail(user, "user_lastvisit", ss.str());
} catch (error& e) {
write_detail(user, "user_lastvisit", int(lastlogin));
} catch (sql_error& e) {
ERR_UH << "Could not set last visit for user '" << user << "' :" << e.message << std::endl;
}
}
fuh::mysql_result fuh::db_query(const std::string& sql) {
if(mysql_query(conn, sql.c_str())) {
WRN_UH << "not connected to database, reconnecting..." << std::endl;
template<typename T, typename... Args>
inline T fuh::prepared_statement(const std::string& sql, Args&&... args)
{
try {
return ::prepared_statement<T>(conn, sql, std::forward<Args>(args)...);
} catch (sql_error&) {
WRN_UH << "caught sql error, trying to reconnect and retry..." << std::endl;
//Try to reconnect and execute query again
if(!mysql_real_connect(conn, db_host_.c_str(), db_user_.c_str(), db_password_.c_str(), db_name_.c_str(), 0, nullptr, 0)
|| mysql_query(conn, sql.c_str())) {
if(!mysql_real_connect(conn, db_host_.c_str(), db_user_.c_str(), db_password_.c_str(), db_name_.c_str(), 0, nullptr, 0)) {
ERR_UH << "Could not connect to database: " << mysql_errno(conn) << ": " << mysql_error(conn) << std::endl;
throw error("Error querying database.");
throw sql_error("Error querying database.");
}
}
return mysql_result(mysql_store_result(conn), mysql_free_result);
return ::prepared_statement<T>(conn, sql, std::forward<Args>(args)...);
}
std::string fuh::db_query_to_string(const std::string& sql) {
mysql_result res = db_query(sql);
MYSQL_ROW row = mysql_fetch_row(res.get());
if(row == NULL)
throw error("query returned no rows");
if(row[0] == NULL)
throw error("got null value from the database");
return std::string(row[0]);
template<typename T>
T fuh::get_detail_for_user(const std::string& name, const std::string& detail) {
return prepared_statement<T>(
"SELECT `" + detail + "` FROM `" + db_users_table_ + "` WHERE UPPER(username)=UPPER(?)",
name);
}
std::string fuh::get_detail_for_user(const std::string& name, const std::string& detail) {
return db_query_to_string("SELECT " + detail + " FROM " + db_users_table_ + " WHERE UPPER(username)=UPPER('" + name + "')");
template<typename T>
T fuh::get_writable_detail_for_user(const std::string& name, const std::string& detail) {
if(!extra_row_exists(name)) throw sql_error("row doesn't exist");
return prepared_statement<T>(
"SELECT `" + detail + "` FROM `" + db_extra_table_ + "` WHERE UPPER(username)=UPPER(?)",
name);
}
std::string fuh::get_writable_detail_for_user(const std::string& name, const std::string& detail) {
if(!extra_row_exists(name)) throw error("row doesn't exist");
return db_query_to_string("SELECT " + detail + " FROM " + db_extra_table_ + " WHERE UPPER(username)=UPPER('" + name + "')");
}
void fuh::write_detail(const std::string& name, const std::string& detail, const std::string& value) {
template<typename T>
void fuh::write_detail(const std::string& name, const std::string& detail, T&& value) {
try {
// Check if we do already have a row for this user in the extra table
if(!extra_row_exists(name)) {
// If not create the row
db_query("INSERT INTO " + db_extra_table_ + " VALUES('" + name + "','" + value + "','0')");
prepared_statement<void>("INSERT INTO `" + db_extra_table_ + "` VALUES(?,?,'0')", name, std::forward<T>(value));
}
db_query("UPDATE " + db_extra_table_ + " SET " + detail + "='" + value + "' WHERE UPPER(username)=UPPER('" + name + "')");
} catch (error& e) {
prepared_statement<void>("UPDATE `" + db_extra_table_ + "` SET " + detail + "=? WHERE UPPER(username)=UPPER(?)", std::forward<T>(value), name);
} catch (sql_error& e) {
ERR_UH << "Could not set detail for user '" << name << "': " << e.message << std::endl;
}
}
@ -299,9 +295,8 @@ bool fuh::extra_row_exists(const std::string& name) {
// Make a test query for this username
try {
mysql_result res = db_query("SELECT username FROM " + db_extra_table_ + " WHERE UPPER(username)=UPPER('" + name + "')");
return mysql_fetch_row(res.get());
} catch (error& e) {
return prepared_statement<bool>("SELECT 1 FROM `" + db_extra_table_ + "` WHERE UPPER(username)=UPPER(?)", name);
} catch (sql_error& e) {
ERR_UH << "Could not execute test query for user '" << name << "' :" << e.message << std::endl;
return false;
}

View file

@ -96,19 +96,19 @@ class fuh : public user_handler {
typedef std::unique_ptr<MYSQL_RES, decltype(&mysql_free_result)> mysql_result;
// Throws user_handler::error
mysql_result db_query(const std::string& query);
// Throws user_handler::error via db_query()
std::string db_query_to_string(const std::string& query);
MYSQL *conn;
template<typename T, typename... Args>
inline T prepared_statement(const std::string& sql, Args&&...);
// Query a detail for a particular user from the database
std::string get_detail_for_user(const std::string& name, const std::string& detail);
std::string get_writable_detail_for_user(const std::string& name, const std::string& detail);
template<typename T>
T get_detail_for_user(const std::string& name, const std::string& detail);
template<typename T>
T get_writable_detail_for_user(const std::string& name, const std::string& detail);
// Write something to the write table
void write_detail(const std::string& name, const std::string& detail, const std::string& value);
template<typename T>
void write_detail(const std::string& name, const std::string& detail, T&& value);
// Same as user_exists() but checks if we have a row for this user in the extra table
bool extra_row_exists(const std::string& name);

View file

@ -0,0 +1,210 @@
/*
Copyright (C) 2016 by Sergey Popov <loonycyborg@gmail.com>
Part of the Battle for Wesnoth Project http://www.wesnoth.org
This program is free software; you can redistribute it and/or modify
it under the terms of the GNU General Public License 2
the Free Software Foundation; either version 2 of the License, or
(at your option) any later version.
This program is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY.
See the COPYING file for more details.
*/
#ifndef MYSQL_PREPARED_STATEMENT_IPP
#define MYSQL_PREPARED_STATEMENT_IPP
#include <array>
#include <utility>
#include <memory>
#include <string>
#include <string.h>
#define BOOST_SCOPE_EXIT_CONFIG_USE_LAMBDAS
#include <boost/scope_exit.hpp>
#include <mysql/mysql.h>
#include "exceptions.hpp"
struct sql_error : public game::error
{
sql_error(const std::string& message, const std::string& sql)
: game::error("Error evaluating SQL statement: '" + sql + "': " + message) {}
sql_error(const std::string& message) : game::error(message) {}
};
// make_bind functions embed pointers to their arguments in the
// MYSQL_BIND structure returned. It's caller's responsibility
// to ensure that argument's lifetime doesn't end before mysql
// is done with those MYSQL_BINDs
MYSQL_BIND make_bind(const std::string& str, my_bool* is_null = 0)
{
MYSQL_BIND result;
memset(&result, 0, sizeof (MYSQL_BIND));
result.buffer_type = MYSQL_TYPE_STRING;
result.buffer = const_cast<void*>(static_cast<const void*>(str.c_str()));
result.buffer_length = str.size();
result.is_unsigned = 0;
result.is_null = is_null;
result.length = 0;
return result;
}
MYSQL_BIND make_bind(char* str, std::size_t* len, my_bool* is_null = 0)
{
MYSQL_BIND result;
memset(&result, 0, sizeof (MYSQL_BIND));
result.buffer_type = MYSQL_TYPE_STRING;
result.buffer = static_cast<void*>(str);
result.buffer_length = *len;
result.is_unsigned = 0;
result.is_null = is_null;
result.length = len;
return result;
}
MYSQL_BIND make_bind(int& i, my_bool* is_null = 0)
{
MYSQL_BIND result;
memset(&result, 0, sizeof (MYSQL_BIND));
result.buffer_type = MYSQL_TYPE_LONG;
result.buffer = static_cast<void*>(&i);
result.is_unsigned = 0;
result.is_null = is_null;
return result;
}
MYSQL_BIND make_bind(int&& i, my_bool* is_null = 0)
{
MYSQL_BIND result;
memset(&result, 0, sizeof (MYSQL_BIND));
result.buffer_type = MYSQL_TYPE_LONG;
result.buffer = static_cast<void*>(&i);
result.is_unsigned = 0;
result.is_null = is_null;
return result;
}
template<typename... Args> constexpr auto make_binds(Args&&... args)
-> std::array<MYSQL_BIND, sizeof...(Args)>
{
return { (make_bind(std::forward<Args>(args)))... };
}
template<typename T> T fetch_result(MYSQL_STMT* stmt, const std::string& sql);
template<> std::string fetch_result<std::string>(MYSQL_STMT* stmt, const std::string& sql)
{
char* buf = nullptr;
std::string result;
std::size_t len = 0;
my_bool is_null;
MYSQL_BIND result_bind[1] = { make_bind(buf, &len, &is_null) };
if(mysql_stmt_bind_result(stmt, result_bind) != 0)
throw sql_error(mysql_stmt_error(stmt), sql);
BOOST_SCOPE_EXIT(&stmt) {
mysql_stmt_free_result(stmt);
} ;
int res = mysql_stmt_fetch(stmt);
if(len > 0) {
buf = new char[len];
result_bind[0].buffer = buf;
result_bind[0].buffer_length = len;
res = mysql_stmt_fetch_column(stmt, result_bind, 0, 0);
result = std::string(buf, len);
delete[] buf;
}
if(res == MYSQL_NO_DATA)
throw sql_error("no data returned", sql);
if(is_null)
throw sql_error("null value returned", sql);
if(res != 0)
throw sql_error(mysql_stmt_error(stmt), sql);
return result;
}
template<> int fetch_result<int>(MYSQL_STMT* stmt, const std::string& sql)
{
int result;
my_bool is_null;
MYSQL_BIND result_bind[1] = { make_bind(result, &is_null) };
if(mysql_stmt_bind_result(stmt, result_bind) != 0)
throw sql_error(mysql_stmt_error(stmt), sql);
BOOST_SCOPE_EXIT(&stmt) {
mysql_stmt_free_result(stmt);
} ;
int res = mysql_stmt_fetch(stmt);
if(res == MYSQL_NO_DATA)
throw sql_error("no data returned", sql);
if(is_null)
throw sql_error("null value returned", sql);
if(res != 0)
throw sql_error(mysql_stmt_error(stmt), sql);
return result;
}
template<> bool fetch_result<bool>(MYSQL_STMT* stmt, const std::string& sql)
{
int result;
my_bool is_null;
MYSQL_BIND result_bind[1] = { make_bind(result, &is_null) };
if(mysql_stmt_bind_result(stmt, result_bind) != 0)
throw sql_error(mysql_stmt_error(stmt), sql);
BOOST_SCOPE_EXIT(&stmt) {
mysql_stmt_free_result(stmt);
} ;
int res = mysql_stmt_fetch(stmt);
if(res == MYSQL_NO_DATA)
return false;
if(is_null)
throw sql_error("null value returned", sql);
if(res != 0)
throw sql_error(mysql_stmt_error(stmt), sql);
return true;
}
template<> void fetch_result<void>(MYSQL_STMT*, const std::string&)
{
}
/**
* Execute an sql query using mysql prepared statements API
* This function can convert its arguments and results to appropriate
* MYSQL_BIND structures automatically based on their C++ type
* though each type requires explicit support. For now only ints and
* std::strings are supported.
* Setting return type to bool causes this function to do a test query
* and return true if there is any data in result set, false otherwise
*/
template<typename R, typename... Args>
R prepared_statement(MYSQL* conn, const std::string& sql, Args&&... args)
{
auto arg_binds = make_binds(args...);
std::unique_ptr<MYSQL_STMT, decltype(&mysql_stmt_close)> stmt{mysql_stmt_init(conn), mysql_stmt_close};
if(stmt == NULL)
throw sql_error("mysql_stmt_init failed", sql);
if(mysql_stmt_prepare(stmt.get(), sql.c_str(), sql.size()) != 0)
throw sql_error(mysql_stmt_error(stmt.get()), sql);
if(mysql_stmt_bind_param(stmt.get(), arg_binds.data()) != 0)
throw sql_error(mysql_stmt_error(stmt.get()), sql);
if(mysql_stmt_execute(stmt.get()) != 0)
throw sql_error(mysql_stmt_error(stmt.get()), sql);
return fetch_result<R>(stmt.get(), sql);
}
#endif // MYSQL_PREPARED_STATEMENT_IPP