Add scripts to pull various pieces of information from the MP database.
The intent being that I plan to run these once a month and post the results on the forum.
This commit is contained in:
parent
ca9b6a2ecc
commit
67c169ed80
15 changed files with 145 additions and 0 deletions
|
@ -0,0 +1,9 @@
|
|||
select count(distinct player.USER_ID) as USER_COUNT
|
||||
from wesnothd_game_info game, wesnothd_game_player_info player
|
||||
where YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
and game.INSTANCE_UUID = player.INSTANCE_UUID
|
||||
and game.GAME_ID = player.GAME_ID
|
||||
and player.USER_ID != -1
|
|
@ -0,0 +1,6 @@
|
|||
select count(*) as GAME_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
|
@ -0,0 +1,8 @@
|
|||
select date(START_TIME) as GAME_DATE, count(*) as GAME_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
||||
group by GAME_DATE
|
||||
order by GAME_DATE
|
|
@ -0,0 +1,15 @@
|
|||
select CLIENT_SOURCE, count(*) as GAME_COUNT
|
||||
from
|
||||
(
|
||||
select distinct player.USER_ID, player.CLIENT_SOURCE
|
||||
from wesnothd_game_info game, wesnothd_game_player_info player
|
||||
where YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
and player.USER_ID != -1
|
||||
and game.INSTANCE_UUID = player.INSTANCE_UUID
|
||||
and game.GAME_ID = player.GAME_ID
|
||||
) src
|
||||
group by CLIENT_SOURCE
|
||||
order by COUNT(*) desc
|
15
utils/mp-server/query-scripts/05-count-of-versions.sql
Normal file
15
utils/mp-server/query-scripts/05-count-of-versions.sql
Normal file
|
@ -0,0 +1,15 @@
|
|||
select CLIENT_VERSION, count(*) as VERSION_COUNT
|
||||
from
|
||||
(
|
||||
select distinct player.USER_ID, player.CLIENT_VERSION
|
||||
from wesnothd_game_info game, wesnothd_game_player_info player
|
||||
where YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
and game.INSTANCE_UUID = player.INSTANCE_UUID
|
||||
and game.GAME_ID = player.GAME_ID
|
||||
and player.USER_ID != -1
|
||||
) src
|
||||
group by CLIENT_VERSION
|
||||
order by COUNT(*) desc
|
8
utils/mp-server/query-scripts/06-eras-by-game-count.sql
Normal file
8
utils/mp-server/query-scripts/06-eras-by-game-count.sql
Normal file
|
@ -0,0 +1,8 @@
|
|||
select ERA_NAME, count(*) as ERA_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
||||
group by ERA_NAME
|
||||
order by count(*) desc
|
8
utils/mp-server/query-scripts/07-maps-by-game-count.sql
Normal file
8
utils/mp-server/query-scripts/07-maps-by-game-count.sql
Normal file
|
@ -0,0 +1,8 @@
|
|||
select MAP_NAME, count(*) as MAP_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
||||
group by MAP_NAME
|
||||
order by count(*) desc
|
|
@ -0,0 +1,11 @@
|
|||
select IFNULL(MODIFICATION_NAME,'No Modifications') as MODIFICATION_NAME, count(*) as MODIFICATION_COUNT
|
||||
from wesnothd_game_info game
|
||||
left join wesnothd_game_modification_info modif
|
||||
on game.INSTANCE_UUID = modif.INSTANCE_UUID
|
||||
and game.GAME_ID = modif.GAME_ID
|
||||
where YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
group by MODIFICATION_NAME
|
||||
order by count(*) desc
|
6
utils/mp-server/query-scripts/09-oos-vs-game-count.sql
Normal file
6
utils/mp-server/query-scripts/09-oos-vs-game-count.sql
Normal file
|
@ -0,0 +1,6 @@
|
|||
select count(*) as GAME_COUNT, sum(OOS) as OOS_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
9
utils/mp-server/query-scripts/10-oos-count-by-era.sql
Normal file
9
utils/mp-server/query-scripts/10-oos-count-by-era.sql
Normal file
|
@ -0,0 +1,9 @@
|
|||
select ERA_NAME, count(*) as OOS_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
||||
and OOS = 1
|
||||
group by ERA_NAME
|
||||
order by count(*) desc
|
9
utils/mp-server/query-scripts/11-oos-count-by-map.sql
Normal file
9
utils/mp-server/query-scripts/11-oos-count-by-map.sql
Normal file
|
@ -0,0 +1,9 @@
|
|||
select MAP_NAME, count(*) as OOS_COUNT
|
||||
from wesnothd_game_info
|
||||
where YEAR(START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, START_TIME, END_TIME) > 5
|
||||
and OOS = 1
|
||||
group by MAP_NAME
|
||||
order by count(*) desc
|
|
@ -0,0 +1,11 @@
|
|||
select modif.MODIFICATION_NAME, count(*) as OOS_COUNT
|
||||
from wesnothd_game_info game, wesnothd_game_modification_info modif
|
||||
where game.INSTANCE_UUID = modif.INSTANCE_UUID
|
||||
and game.GAME_ID = modif.GAME_ID
|
||||
and game.OOS = 1
|
||||
and YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
group by modif.MODIFICATION_NAME
|
||||
order by count(*) desc
|
|
@ -0,0 +1,12 @@
|
|||
select game.ERA_NAME, game.MAP_NAME, IFNULL(GROUP_CONCAT(distinct modif.MODIFICATION_NAME SEPARATOR '|'), 'No Modifications') AS MODIFICATIONS, count(*) as OOS_COUNT
|
||||
from wesnothd_game_info game
|
||||
left join wesnothd_game_modification_info modif
|
||||
on game.INSTANCE_UUID = modif.INSTANCE_UUID
|
||||
and game.GAME_ID = modif.GAME_ID
|
||||
where game.OOS = 1
|
||||
and YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
group by game.ERA_NAME, game.MAP_NAME
|
||||
order by count(*) desc, game.ERA_NAME, game.MAP_NAME, modif.MODIFICATION_NAME
|
12
utils/mp-server/query-scripts/14-oos-replays-list.sql
Normal file
12
utils/mp-server/query-scripts/14-oos-replays-list.sql
Normal file
|
@ -0,0 +1,12 @@
|
|||
select game.ERA_NAME, game.MAP_NAME, IFNULL(GROUP_CONCAT(distinct modif.MODIFICATION_NAME SEPARATOR '|'), 'No Modifications') AS MODIFICATIONS, concat('https://replays.wesnoth.org/', substring(INSTANCE_VERSION, 1, 4), '/', year(game.END_TIME), '/', lpad(month(game.END_TIME), 2, '0'), '/', lpad(day(game.END_TIME), 2, '0'), '/', game.REPLAY_NAME) AS REPLAY_LOCATION
|
||||
from wesnothd_game_info game
|
||||
left join wesnothd_game_modification_info modif
|
||||
on game.INSTANCE_UUID = modif.INSTANCE_UUID
|
||||
and game.GAME_ID = modif.GAME_ID
|
||||
where game.OOS = 1
|
||||
and YEAR(game.START_TIME) = YEAR(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and MONTH(game.START_TIME) = MONTH(CURRENT_DATE - INTERVAL 1 MONTH)
|
||||
and game.END_TIME is not NULL
|
||||
and TIMESTAMPDIFF(MINUTE, game.START_TIME, game.END_TIME) > 5
|
||||
group by game.INSTANCE_UUID, game.GAME_ID
|
||||
order by game.ERA_NAME, game.MAP_NAME, modif.MODIFICATION_NAME
|
6
utils/mp-server/query-scripts/run-queries.sh
Executable file
6
utils/mp-server/query-scripts/run-queries.sh
Executable file
|
@ -0,0 +1,6 @@
|
|||
#!/bin/sh
|
||||
|
||||
for sql in ./*.sql
|
||||
do
|
||||
mysql < "$sql" > "${sql}.tsv"
|
||||
done
|
Loading…
Add table
Reference in a new issue