Skip to content

Commit

Permalink
Switched recent public games to direct SQL query instead of a nasty L…
Browse files Browse the repository at this point in the history
…INQ query
  • Loading branch information
jakejgordon committed Nov 12, 2018
1 parent 5f417cb commit aecb554
Show file tree
Hide file tree
Showing 6 changed files with 108 additions and 49 deletions.
2 changes: 2 additions & 0 deletions Source/BusinessLogic/BusinessLogic.csproj
Original file line number Diff line number Diff line change
Expand Up @@ -183,6 +183,8 @@
<Compile Include="DataAccess\Repositories\GameDefinitionRepository.cs" />
<Compile Include="DataAccess\Repositories\IChampionRepository.cs" />
<Compile Include="DataAccess\Repositories\IGameDefinitionRepository.cs" />
<Compile Include="DataAccess\Repositories\IPlayedGameRepository.cs" />
<Compile Include="DataAccess\Repositories\PlayedGameRepository.cs" />
<Compile Include="DataAccess\SecuredEntityWithTechnicalKey.cs" />
<Compile Include="DataAccess\Security\GenericSecuredEntityValidator.cs" />
<Compile Include="DataAccess\Security\IGenericSecuredEntityValidator.cs" />
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
using System.Collections.Generic;
using BusinessLogic.Models.Games;
using BusinessLogic.Models.PlayedGames;

namespace BusinessLogic.DataAccess.Repositories
{
public interface IPlayedGameRepository
{
List<PublicGameSummary> GetRecentPublicGames(RecentlyPlayedGamesFilter filter);
}
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,87 @@
using System;
using System.Collections.Generic;
using System.Data.SqlClient;
using System.Linq;
using BusinessLogic.Models.Games;
using BusinessLogic.Models.PlayedGames;

namespace BusinessLogic.DataAccess.Repositories
{
public class PlayedGameRepository : IPlayedGameRepository
{
private readonly IDataContext _dataContext;

public PlayedGameRepository(IDataContext dataContext)
{
_dataContext = dataContext;
}

private const string RAW_SQL = @"WITH GamingGroupsWithGamesInLastTwoDays AS (
SELECT DISTINCT PlayedGame.GamingGroupId, MAX(PlayedGame.ID) AS PlayedGameId
FROM PlayedGame
{0}
WHERE PlayedGame.DatePlayed BETWEEN @MinDate AND @MaxDate
{1}
GROUP BY PlayedGame.GamingGroupId
),
WinningPlayers AS (
SELECT MAX(PlayerGameResult.PlayerId) AS WinningPlayerId, PlayerGameResult.PlayedGameId
FROM PlayerGameResult INNER JOIN GamingGroupsWithGamesInLastTwoDays
ON PlayerGameResult.PlayedGameId = GamingGroupsWithGamesInLastTwoDays.PlayedGameId
WHERE PlayerGameREsult.GameRank = 1
GROUP BY PlayerGameResult.PlayedGameId)
SELECT TOP {2} PlayedGame.Id AS PlayedGameId,
PlayedGame.GamingGroupId,
PlayedGame.DatePlayed,
PlayedGame.WinnerType,
GameDefinition.Id AS GameDefinitionId,
WinningPlayers.WinningPlayerId,
Player.Name AS WinningPlayerName,
GamingGroup.Name AS GamingGroupName,
BoardGameGeekGameDefinition.Thumbnail AS ThumbnailImageUrl,
GameDefinition.Name AS GameDefinitionName
FROM GamingGroupsWithGamesInLastTwoDays
INNER JOIN PlayedGame ON PlayedGame.Id = GamingGroupsWithGamesInLastTwoDays.PlayedGameId
INNER JOIN GamingGroup ON PlayedGame.GamingGroupId = GamingGroup.Id
INNER JOIN GameDefinition ON PlayedGame.GameDefinitionId = GameDefinition.Id
INNER JOIN BoardGameGeekGameDefinition ON GameDefinition.BoardGameGeekGameDefinitionId = BoardGameGeekGameDefinition.Id
INNER JOIN WinningPlayers ON WinningPlayers.PlayedGameId = GamingGroupsWithGamesInLastTwoDays.PlayedGameId
LEFT JOIN Player on WinningPlayers.WinningPlayerId = Player.Id
ORDER BY PlayedGameId DESC";

public List<PublicGameSummary> GetRecentPublicGames(RecentlyPlayedGamesFilter filter)
{
string boardGameGeekGameDefinitionInnerJoin = string.Empty;
string boardGameGeekGameDefinitionIdPredicate = string.Empty;
object[] sqlParams;
if (filter.BoardGameGeekGameDefinitionId.HasValue)
{
boardGameGeekGameDefinitionInnerJoin =
"INNER JOIN BoardGameGeekGameDefinition ON BoardGameGeekGameDefinition.Id = GameDefinition.BoardGameGeekGameDefinitionId ";
boardGameGeekGameDefinitionIdPredicate =
"AND BoardGameGeekGameDefinition.Id = @BoardGameGeekGameDefinitionId ";

sqlParams = new object[4];
sqlParams[3] = new SqlParameter("BoardGameGeekGameDefinitionId", filter.BoardGameGeekGameDefinitionId.Value);
}
else
{
sqlParams = new object[3];
}
sqlParams[0] = new SqlParameter("NumberOfResults", filter.NumberOfGamesToRetrieve);
sqlParams[1] = new SqlParameter("MinDate", filter.MinDate ?? DateTime.UtcNow.AddYears(-10));
sqlParams[2] = new SqlParameter("MaxDate", filter.MaxDate);

var formattedSql = string.Format(RAW_SQL,
boardGameGeekGameDefinitionInnerJoin,
boardGameGeekGameDefinitionIdPredicate,
filter.NumberOfGamesToRetrieve);

var data = _dataContext.MakeRawSqlQuery<PublicGameSummary>(formattedSql, sqlParams);

var results = data.ToList();
return results;
}
}
}
50 changes: 5 additions & 45 deletions Source/BusinessLogic/Logic/PlayedGames/PlayedGameRetriever.cs
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,7 @@
using System.Data.Entity;
using System.Globalization;
using System.Linq;
using BusinessLogic.DataAccess.Repositories;
using BusinessLogic.Logic.BoardGameGeek;
using BusinessLogic.Logic.Players;
using BusinessLogic.Models.User;
Expand All @@ -38,12 +39,14 @@ public class PlayedGameRetriever : IPlayedGameRetriever
private readonly IDataContext _dataContext;
private readonly IPlayerRetriever _playerRetriever;
private readonly IWinnerTypeCalculator _winnerTypeCalculator;
private readonly IPlayedGameRepository _playedGameRepository;

public PlayedGameRetriever(IDataContext dataContext, IPlayerRetriever playerRetriever, IWinnerTypeCalculator winnerTypeCalculator)
public PlayedGameRetriever(IDataContext dataContext, IPlayerRetriever playerRetriever, IWinnerTypeCalculator winnerTypeCalculator, IPlayedGameRepository playedGameRepository)
{
_dataContext = dataContext;
_playerRetriever = playerRetriever;
_winnerTypeCalculator = winnerTypeCalculator;
_playedGameRepository = playedGameRepository;
}

public List<PlayedGame> GetRecentGames(int numberOfGames, int gamingGroupId, IDateRangeFilter dateRangeFilter = null)
Expand Down Expand Up @@ -99,50 +102,7 @@ public PlayedGame GetPlayedGameDetails(int playedGameId)

public List<PublicGameSummary> GetRecentPublicGames(RecentlyPlayedGamesFilter filter)
{
var query = _dataContext.GetQueryable<PlayedGame>()
.Where(x => x.DatePlayed <= filter.MaxDate);

if (filter.MinDate.HasValue)
{
query = query.Where(x => x.DatePlayed >= filter.MinDate);
}

if (filter.BoardGameGeekGameDefinitionId.HasValue)
{
query = query.Where(x => x.GameDefinition.BoardGameGeekGameDefinitionId == filter.BoardGameGeekGameDefinitionId);
}

var publicGameSummaries = (from playedGame in query group new PublicGameSummary
{
PlayedGameId = playedGame.Id,
GameDefinitionId = playedGame.GameDefinitionId,
GameDefinitionName = playedGame.GameDefinition.Name,
GamingGroupId = playedGame.GamingGroupId,
GamingGroupName = playedGame.GamingGroup.Name,
WinnerType = playedGame.WinnerType,
WinningPlayer = playedGame.PlayerGameResults.FirstOrDefault(player => player.GameRank == 1).Player,
DatePlayed = playedGame.DatePlayed,
ThumbnailImageUrl = playedGame.GameDefinition.BoardGameGeekGameDefinition.Thumbnail,
BoardGameGeekObjectId = playedGame.GameDefinition.BoardGameGeekGameDefinitionId
}
by playedGame.GamingGroupId
into gamingGroups
select gamingGroups
.OrderByDescending(x => x.DatePlayed)
.ThenByDescending(y => y.PlayedGameId)
.FirstOrDefault()
)
.OrderByDescending(x => x.DatePlayed)
.ThenByDescending(y => y.PlayedGameId)
.Take(filter.NumberOfGamesToRetrieve)
.ToList();

foreach (var publicGameSummary in publicGameSummaries)
{
publicGameSummary.BoardGameGeekUri =
BoardGameGeekUriBuilder.BuildBoardGameGeekGameUri(publicGameSummary.BoardGameGeekObjectId);
}
return publicGameSummaries;
return _playedGameRepository.GetRecentPublicGames(filter);
}

public List<PlayedGameSearchResult> SearchPlayedGames(PlayedGameFilter playedGameFilter)
Expand Down
5 changes: 2 additions & 3 deletions Source/BusinessLogic/Models/Games/PublicGameSummary.cs
Original file line number Diff line number Diff line change
Expand Up @@ -30,9 +30,8 @@ public class PublicGameSummary
public string GamingGroupName { get; set; }
public int GamingGroupId { get; set; }
public WinnerTypes WinnerType { get; set; }
public Player WinningPlayer { get; set; }
public Uri BoardGameGeekUri { get; set; }
public string ThumbnailImageUrl { get; set; }
public int? BoardGameGeekObjectId { get; set; }
public string WinningPlayerName { get; set; }
public int? WinningPlayerId { get; set; }
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -44,7 +44,7 @@
<td class="gameResult-teamLoss">EVERYONE LOST</td>
break;
default:
<td>@Html.ActionLink(publicGame.WinningPlayer.Name, "Details", "Player", new { id = publicGame.WinningPlayer.Id }, new { title = "View Player details" })</td>
<td>@Html.ActionLink(publicGame.WinningPlayerName, "Details", "Player", new { id = publicGame.WinningPlayerId }, new { title = "View Player details" })</td>
break;
}
<td>@Html.ActionLink(publicGame.DatePlayed.ToShortDateString(), "Details", "PlayedGame", new { id = publicGame.PlayedGameId }, new { title = "View Played Game details" })</td>
Expand Down

0 comments on commit aecb554

Please sign in to comment.