Skip to content

Commit

Permalink
Update query scripts for new table.
Browse files Browse the repository at this point in the history
  • Loading branch information
Pentarctagon committed Oct 27, 2020
1 parent 517cbf7 commit e43a0d8
Show file tree
Hide file tree
Showing 15 changed files with 151 additions and 96 deletions.
17 changes: 10 additions & 7 deletions utils/mp-server/query-scripts/06-eras-by-game-count.sql
@@ -1,8 +1,11 @@
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
select content.ID as ERA, count(*) as ERA_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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 = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'era'
group by content.ID
order by count(*) desc
@@ -1,8 +1,11 @@
select ERA_NAME, ERA_SOURCE_ADDON, ERA_VERSION, 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, ERA_SOURCE_ADDON, ERA_VERSION
select content.ID as ERA, content.SOURCE as ADDON, content.VERSION, count(*) as ERA_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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 = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'era'
group by content.ID, content.SOURCE, content.VERSION
order by count(*) desc
17 changes: 10 additions & 7 deletions utils/mp-server/query-scripts/08-maps-by-game-count.sql
@@ -1,8 +1,11 @@
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
select content.ID as MAP, count(*) as MAP_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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 = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'scenario'
group by content.ID
order by count(*) desc
@@ -1,8 +1,11 @@
select MAP_NAME, MAP_SOURCE_ADDON, MAP_VERSION, 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, MAP_SOURCE_ADDON, MAP_VERSION
select content.ID as MAP, content.SOURCE as ADDON, content.VERSION, count(*) as MAP_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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 = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'scenario'
group by content.ID, content.SOURCE, content.VERSION
order by count(*) desc
11 changes: 6 additions & 5 deletions utils/mp-server/query-scripts/10-modifications-by-game-count.sql
@@ -1,11 +1,12 @@
select IFNULL(MODIFICATION_NAME,'No Modifications') as MODIFICATION_NAME, count(*) as MODIFICATION_COUNT
select IFNULL(content.ID,'No Modifications') as MODIFICATION, 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
left join wesnothd_game_content_info content
on game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'modification'
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
group by MODIFICATIOn
order by count(*) desc
@@ -1,11 +1,12 @@
select IFNULL(modif.MODIFICATION_NAME,'No Modifications') as MODIFICATION_NAME, IFNULL(modif.SOURCE_ADDON,'') as SOURCE_ADDON, IFNULL(modif.VERSION,'') as VERSION, count(*) as MODIFICATION_COUNT
select IFNULL(content.ID,'No Modifications') as MODIFICATION, IFNULL(content.SOURCE,'') as ADDON, IFNULL(content.VERSION,'') as VERSION, 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
left join wesnothd_game_content_info content
on game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'modification'
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 modif.MODIFICATION_NAME, modif.SOURCE_ADDON, modif.VERSION
group by content.ID, content.SOURCE, content.VERSION
order by count(*) desc
19 changes: 11 additions & 8 deletions utils/mp-server/query-scripts/13-oos-count-by-era.sql
@@ -1,9 +1,12 @@
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
select content.ID as ERA, count(*) as OOS_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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.OOS = 1
and game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'era'
group by content.ID
order by count(*) desc
19 changes: 11 additions & 8 deletions utils/mp-server/query-scripts/14-oos-count-by-era-and-version.sql
@@ -1,9 +1,12 @@
select ERA_NAME, ERA_SOURCE_ADDON, ERA_VERSION, 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, ERA_SOURCE_ADDON, ERA_VERSION
select content.ID as ERA, content.SOURCE as ADDON, content.VERSION, count(*) as OOS_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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.OOS = 1
and game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'era'
group by content.ID, content.SOURCE, content.VERSION
order by count(*) desc
19 changes: 11 additions & 8 deletions utils/mp-server/query-scripts/15-oos-count-by-map.sql
@@ -1,9 +1,12 @@
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
select content.ID as MAP, count(*) as OOS_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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.OOS = 1
and game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'scenario'
group by content.ID
order by count(*) desc
19 changes: 11 additions & 8 deletions utils/mp-server/query-scripts/16-oos-count-by-map-and-version.sql
@@ -1,9 +1,12 @@
select MAP_NAME, MAP_SOURCE_ADDON, MAP_VERSION, 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, MAP_SOURCE_ADDON, MAP_VERSION
select content.ID as MAP, content.SOURCE as ADDON, content.VERSION, count(*) as OOS_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
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.OOS = 1
and game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'scenario'
group by content.ID, content.SOURCE, content.VERSION
order by count(*) desc
11 changes: 6 additions & 5 deletions utils/mp-server/query-scripts/17-oos-count-by-modification.sql
@@ -1,11 +1,12 @@
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
select content.ID as MODIFICATION, count(*) as OOS_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
where game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'modification'
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
group by content.ID
order by count(*) desc
@@ -1,11 +1,12 @@
select modif.MODIFICATION_NAME, modif.SOURCE_ADDON, modif.VERSION, 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
select content.ID as MODIFICATION, content.SOURCE as ADDON, content.VERSION, count(*) as OOS_COUNT
from wesnothd_game_info game, wesnothd_game_content_info content
where game.INSTANCE_UUID = content.INSTANCE_UUID
and game.GAME_ID = content.GAME_ID
and content.TYPE = 'modification'
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, modif.SOURCE_ADDON, modif.VERSION
group by content.ID, content.SOURCE, content.VERSION
order by count(*) desc
@@ -1,12 +1,21 @@
select game.ERA_NAME, game.ERA_SOURCE_ADDON, game.ERA_VERSION, game.MAP_NAME, game.MAP_SOURCE_ADDON, game.MAP_VERSION, IFNULL(GROUP_CONCAT(distinct concat(modif.MODIFICATION_NAME,'(',modif.SOURCE_ADDON,':',modif.VERSION,')') SEPARATOR '|'), 'No Modifications') AS MODIFICATIONS, count(*) as OOS_COUNT
select count(*) as OOS_COUNT, eras.ID as ERA, eras.SOURCE as ERA_ADDON, eras.VERSION as ERA_VERSION, scenarios.ID as MAP, scenarios.SOURCE as MAP_ADDON, scenarios.VERSION as MAP_VERSION, IFNULL(GROUP_CONCAT(distinct concat(mods.ID,'(',mods.SOURCE,':',mods.VERSION,')') SEPARATOR '|'), 'No Modifications') AS MODIFICATIONS
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
inner join wesnothd_game_content_info scenarios
on game.INSTANCE_UUID = scenarios.INSTANCE_UUID
and game.GAME_ID = scenarios.GAME_ID
and scenarios.TYPE = 'scenario'
inner join wesnothd_game_content_info eras
on game.INSTANCE_UUID = eras.INSTANCE_UUID
and game.GAME_ID = eras.GAME_ID
and eras.TYPE = 'era'
left join wesnothd_game_content_info mods
on game.INSTANCE_UUID = mods.INSTANCE_UUID
and game.GAME_ID = mods.GAME_ID
and mods.TYPE = 'modification'
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.ERA_SOURCE_ADDON, game.ERA_VERSION, game.MAP_NAME, game.MAP_SOURCE_ADDON, game.MAP_VERSION
order by count(*) desc, game.ERA_NAME, game.MAP_NAME, modif.MODIFICATION_NAME
group by eras.ID, eras.SOURCE, eras.VERSION, scenarios.ID, scenarios.SOURCE, scenarios.VERSION
order by count(*) desc, eras.ID, scenarios.ID, mods.ID
19 changes: 14 additions & 5 deletions utils/mp-server/query-scripts/20-oos-replays-list.sql
@@ -1,12 +1,21 @@
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
select eras.ID as ERA, scenarios.ID as MAP, IFNULL(GROUP_CONCAT(distinct mods.ID SEPARATOR '|'), 'No Modifications') AS MODIFICATIONS, concat('https://replays.wesnoth.org/', substring(game.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
inner join wesnothd_game_content_info scenarios
on game.INSTANCE_UUID = scenarios.INSTANCE_UUID
and game.GAME_ID = scenarios.GAME_ID
and scenarios.TYPE = 'scenario'
inner join wesnothd_game_content_info eras
on game.INSTANCE_UUID = eras.INSTANCE_UUID
and game.GAME_ID = eras.GAME_ID
and eras.TYPE = 'era'
left join wesnothd_game_content_info mods
on game.INSTANCE_UUID = mods.INSTANCE_UUID
and game.GAME_ID = mods.GAME_ID
and mods.TYPE = 'modification'
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
order by eras.ID, scenarios.ID, mods.ID
19 changes: 14 additions & 5 deletions utils/mp-server/query-scripts/21-oos-replays-list-and-version.sql
@@ -1,12 +1,21 @@
select game.ERA_NAME, game.ERA_SOURCE_ADDON, game.ERA_VERSION, game.MAP_NAME, game.MAP_SOURCE_ADDON, game.MAP_VERSION, IFNULL(GROUP_CONCAT(distinct concat(modif.MODIFICATION_NAME,'(',modif.SOURCE_ADDON,':',modif.VERSION,')') 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
select eras.ID as ERA, eras.SOURCE as ERA_ADDON, eras.VERSION as ERA_VERSION, scenarios.ID as MAP, scenarios.SOURCE as MAP_ADDON, scenarios.VERSION as MAP_VERSION, IFNULL(GROUP_CONCAT(distinct concat(mods.ID,'(',mods.SOURCE,':',mods.VERSION,')') SEPARATOR '|'), 'No Modifications') AS MODIFICATIONS, concat('https://replays.wesnoth.org/', substring(game.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
inner join wesnothd_game_content_info scenarios
on game.INSTANCE_UUID = scenarios.INSTANCE_UUID
and game.GAME_ID = scenarios.GAME_ID
and scenarios.TYPE = 'scenario'
inner join wesnothd_game_content_info eras
on game.INSTANCE_UUID = eras.INSTANCE_UUID
and game.GAME_ID = eras.GAME_ID
and eras.TYPE = 'era'
left join wesnothd_game_content_info mods
on game.INSTANCE_UUID = mods.INSTANCE_UUID
and game.GAME_ID = mods.GAME_ID
and mods.TYPE = 'modification'
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
order by eras.ID, scenarios.ID, mods.ID

0 comments on commit e43a0d8

Please sign in to comment.