Add some useful default view from stats table
This commit is contained in:
parent
f34e0e9dc0
commit
ab9e8b7dcf
@ -147,15 +147,17 @@ The current server configuration xml looks like this:
|
||||
<!-- Set how many states the server will send per second, the higher this value, the more bandwidth requires, also each client will trigger more rewind, which clients with slow device may have problem playing this server, use the default value is recommended. -->
|
||||
<state-frequency value="10" />
|
||||
|
||||
<!-- ip: IP in X.X.X.X/Y (CIDR) format for banning, use Y of 32 for a specific ip, expired-time: unix timestamp to expire, -1 (uint32_t max) for a permanent ban. -->
|
||||
<server-ip-ban-list>
|
||||
<ban ip="0.0.0.0/0" expired-time="0"/>
|
||||
</server-ip-ban-list>
|
||||
<!-- Use sql to manage server stats and banlist, STK needs to be compiled with sqlite3 supported. -->
|
||||
<sql-management value="false" />
|
||||
|
||||
<!-- online-id: online id for banning, expired-time: unix timestamp to expire, -1 (uint32_t max) for a permanent ban. -->
|
||||
<server-online-id-ban-list>
|
||||
<ban online-id="0" expired-time="0"/>
|
||||
</server-online-id-ban-list>
|
||||
<!-- Database filename for sqlite to use, it can be shared for servers creating in this machine, and stk will create specific table for each server. You need to create the database yourself first, see NETWORKING.md for details -->
|
||||
<database-file value="stkservers.db" />
|
||||
|
||||
<!-- Ip ban list table name, you need to create the table first, see NETWORKING.md for details. -->
|
||||
<ip-ban-table value="ipban" />
|
||||
|
||||
<!-- Online ID ban list table name, you need to create the table first, see NETWORKING.md for details. -->
|
||||
<online-id-ban-table value="onlineidban" />
|
||||
|
||||
</server-config>
|
||||
|
||||
@ -229,6 +231,17 @@ CREATE TABLE IF NOT EXISTS (table name above)
|
||||
) WITHOUT ROWID;
|
||||
```
|
||||
|
||||
STK will also create the following default views from the stats table:
|
||||
|
||||
`*_full_stats`
|
||||
Full stats with ip in human readable format and time played of each players in minutes.
|
||||
|
||||
`*_current_players`
|
||||
Current players in server with ip in human readable format and time played of each players in minutes.
|
||||
|
||||
`*_player_stats`
|
||||
All players with online id and username with their time played stats in this server since creation of this database.
|
||||
|
||||
For IP or online ID ban list, you need to create one yourself:
|
||||
```sql
|
||||
CREATE TABLE ipban
|
||||
|
@ -301,6 +301,109 @@ void ServerLobby::initServerStatsTable()
|
||||
if (m_server_stats_table.empty())
|
||||
return;
|
||||
|
||||
// Default views:
|
||||
// _full_stats
|
||||
// Full stats with ip in human readable format and time played of each
|
||||
// players in minutes
|
||||
std::string view_name = std::string("v") +
|
||||
StringUtils::toString(ServerConfig::m_server_db_version) + "_" +
|
||||
ServerConfig::m_server_uid + "_full_stats";
|
||||
std::ostringstream oss;
|
||||
oss << "CREATE VIEW IF NOT EXISTS " << view_name << " AS\n"
|
||||
<< " SELECT host_id, ip,\n"
|
||||
<< " ((ip >> 24) & 255) ||'.'|| ((ip >> 16) & 255) ||'.'|| ((ip >> 8) & 255) ||'.'|| ((ip ) & 255) AS ip_readable,\n"
|
||||
<< " port, online_id, username, player_num, country_id, version,\n"
|
||||
<< " ROUND((STRFTIME(\"%s\", disconnected_time) - STRFTIME(\"%s\", connected_time)) / 60.0, 2) AS time_played,\n"
|
||||
<< " connected_time, disconnected_time, ping\n"
|
||||
<< " FROM " << m_server_stats_table << ";";
|
||||
query = oss.str();
|
||||
ret = sqlite3_prepare_v2(m_db, query.c_str(), -1, &stmt, 0);
|
||||
if (ret == SQLITE_OK)
|
||||
{
|
||||
ret = sqlite3_step(stmt);
|
||||
ret = sqlite3_finalize(stmt);
|
||||
if (ret != SQLITE_OK)
|
||||
{
|
||||
Log::error("ServerLobby",
|
||||
"Error finalize database for query %s: %s",
|
||||
query.c_str(), sqlite3_errmsg(m_db));
|
||||
}
|
||||
}
|
||||
else
|
||||
{
|
||||
Log::error("ServerLobby", "Error preparing database for query %s: %s",
|
||||
query.c_str(), sqlite3_errmsg(m_db));
|
||||
}
|
||||
|
||||
// _current_players
|
||||
// Current players in server with ip in human readable format and time
|
||||
// played of each players in minutes
|
||||
view_name = std::string("v") +
|
||||
StringUtils::toString(ServerConfig::m_server_db_version) + "_" +
|
||||
ServerConfig::m_server_uid + "_current_players";
|
||||
oss.str("");
|
||||
oss.clear();
|
||||
oss << "CREATE VIEW IF NOT EXISTS " << view_name << " AS\n"
|
||||
<< " SELECT host_id, ip,\n"
|
||||
<< " ((ip >> 24) & 255) ||'.'|| ((ip >> 16) & 255) ||'.'|| ((ip >> 8) & 255) ||'.'|| ((ip ) & 255) AS ip_readable,\n"
|
||||
<< " port, online_id, username, player_num, country_id, version,\n"
|
||||
<< " ROUND((STRFTIME(\"%s\", 'now') - STRFTIME(\"%s\", connected_time)) / 60.0, 2) AS time_played,\n"
|
||||
<< " connected_time, ping FROM " << m_server_stats_table << "\n"
|
||||
<< " WHERE connected_time = disconnected_time;";
|
||||
query = oss.str();
|
||||
ret = sqlite3_prepare_v2(m_db, query.c_str(), -1, &stmt, 0);
|
||||
if (ret == SQLITE_OK)
|
||||
{
|
||||
ret = sqlite3_step(stmt);
|
||||
ret = sqlite3_finalize(stmt);
|
||||
if (ret != SQLITE_OK)
|
||||
{
|
||||
Log::error("ServerLobby",
|
||||
"Error finalize database for query %s: %s",
|
||||
query.c_str(), sqlite3_errmsg(m_db));
|
||||
}
|
||||
}
|
||||
else
|
||||
{
|
||||
Log::error("ServerLobby", "Error preparing database for query %s: %s",
|
||||
query.c_str(), sqlite3_errmsg(m_db));
|
||||
}
|
||||
|
||||
// _player_stats
|
||||
// All players with online id and username with their time played stats
|
||||
// in this server since creation of this database
|
||||
view_name = std::string("v") +
|
||||
StringUtils::toString(ServerConfig::m_server_db_version) + "_" +
|
||||
ServerConfig::m_server_uid + "_player_stats";
|
||||
oss.str("");
|
||||
oss.clear();
|
||||
oss << "CREATE VIEW IF NOT EXISTS " << view_name << " AS\n"
|
||||
<< " SELECT online_id, username, COUNT(online_id) AS num_connections,\n"
|
||||
<< " ROUND(SUM((STRFTIME(\"%s\", disconnected_time) - STRFTIME(\"%s\", connected_time)) / 60.0), 2) AS total_time_played,\n"
|
||||
<< " ROUND(AVG((STRFTIME(\"%s\", disconnected_time) - STRFTIME(\"%s\", connected_time)) / 60.0), 2) AS average_time_played,\n"
|
||||
<< " ROUND(MIN((STRFTIME(\"%s\", disconnected_time) - STRFTIME(\"%s\", connected_time)) / 60.0), 2) AS min_time_played,\n"
|
||||
<< " ROUND(MAX((STRFTIME(\"%s\", disconnected_time) - STRFTIME(\"%s\", connected_time)) / 60.0), 2) AS max_time_played\n"
|
||||
<< " FROM " << m_server_stats_table << "\n"
|
||||
<< " WHERE online_id != 0 GROUP BY online_id ORDER BY num_connections DESC;";
|
||||
query = oss.str();
|
||||
ret = sqlite3_prepare_v2(m_db, query.c_str(), -1, &stmt, 0);
|
||||
if (ret == SQLITE_OK)
|
||||
{
|
||||
ret = sqlite3_step(stmt);
|
||||
ret = sqlite3_finalize(stmt);
|
||||
if (ret != SQLITE_OK)
|
||||
{
|
||||
Log::error("ServerLobby",
|
||||
"Error finalize database for query %s: %s",
|
||||
query.c_str(), sqlite3_errmsg(m_db));
|
||||
}
|
||||
}
|
||||
else
|
||||
{
|
||||
Log::error("ServerLobby", "Error preparing database for query %s: %s",
|
||||
query.c_str(), sqlite3_errmsg(m_db));
|
||||
}
|
||||
|
||||
uint32_t last_host_id = 0;
|
||||
query = StringUtils::insertValues("SELECT MAX(host_id) FROM %s;",
|
||||
m_server_stats_table.c_str());
|
||||
|
Loading…
Reference in New Issue
Block a user