-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Generate a new RouteSegment for each player identity, unique within t…
…he team #626
- Loading branch information
1 parent
869d1e2
commit b7a7cf8
Showing
16 changed files
with
186 additions
and
18 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Binary file modified
BIN
+55 Bytes
(100%)
Stoolball.Data.SqlServer.IntegrationTests/StoolballIntegrationTests.dacpac
Binary file not shown.
Binary file modified
BIN
+55 Bytes
(100%)
...SqlServer.IntegrationTests/StoolballStatisticsMaxResultsDataSourceIntegrationTests.dacpac
Binary file not shown.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
32 changes: 32 additions & 0 deletions
32
....UmbracoMigrations/042_Add_PlayerIdentity_RouteSegment/AddRouteSegmentToPlayerIdentity.cs
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,32 @@ | ||
using Microsoft.Extensions.Logging; | ||
using Stoolball.Data.SqlServer; | ||
using Umbraco.Cms.Infrastructure.Migrations; | ||
|
||
namespace Stoolball.Data.UmbracoMigrations | ||
{ | ||
/// <summary> | ||
/// Adds a RouteSegment column to StoolballPlayerIdentity which is used for routes that edit a single identity rather than a player | ||
/// </summary> | ||
public partial class AddRouteSegmentToPlayerIdentity : MigrationBase | ||
{ | ||
public AddRouteSegmentToPlayerIdentity(IMigrationContext context) : base(context) | ||
{ | ||
} | ||
|
||
protected override void Migrate() | ||
{ | ||
Logger.LogDebug("Running migration {MigrationStep}", typeof(AddRouteSegmentToPlayerIdentity).Name); | ||
|
||
if (!ColumnExists(Tables.PlayerIdentity, "RouteSegment")) | ||
{ | ||
Create.Column("RouteSegment").OnTable(Tables.PlayerIdentity).AsString(255).Nullable().Do(); | ||
Execute.SqlFromFile("042_Add_PlayerIdentity_RouteSegment.StoolballPlayerIdentity_PopulateRouteSegment.sql").Do(); | ||
Execute.SqlFromFile("042_Add_PlayerIdentity_RouteSegment.usp_Player_Async_Update.sql").Do(); | ||
} | ||
else | ||
{ | ||
Logger.LogDebug("The database column {DbTable}.{DbColumn} already exists, skipping", Tables.PlayerIdentity, "RouteSegment"); | ||
} | ||
} | ||
} | ||
} |
21 changes: 21 additions & 0 deletions
21
...ions/042_Add_PlayerIdentity_RouteSegment/StoolballPlayerIdentity_PopulateRouteSegment.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,21 @@ | ||
UPDATE StoolballPlayerIdentity | ||
SET StoolballPlayerIdentity.RouteSegment = Results.RouteSegment | ||
FROM StoolballPlayerIdentity | ||
INNER JOIN ( | ||
SELECT PlayerIdentityId, CASE WHEN RouteSegment = '' THEN CAST(PlayerIdentityId AS varchar(255)) ELSE RouteSegment END AS RouteSegment FROM | ||
( | ||
SELECT PlayerIdentityId, | ||
CASE | ||
WHEN RIGHT(RouteSegment,1) = '-' THEN LEFT(RouteSegment, LEN(RouteSegment)-1) | ||
ELSE RouteSegment | ||
END | ||
AS RouteSegment FROM ( | ||
SELECT PlayerIdentityId, LOWER(LTRIM(RTRIM(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(PlayerIdentityName,' ','-'),'''',''),'`',''),'&',''),'.',''),'(',''),')',''),'/','-'),'#',''),';',''),':',''),'?',''),'|','')))) AS RouteSegment | ||
FROM StoolballPlayerIdentity | ||
) AS Results | ||
) AS Results | ||
) AS Results | ||
ON StoolballPlayerIdentity.PlayerIdentityId = Results.PlayerIdentityId; | ||
|
||
ALTER TABLE StoolballPlayerIdentity | ||
ALTER COLUMN RouteSegment nvarchar(255) NOT NULL |
84 changes: 84 additions & 0 deletions
84
...ll.Data.UmbracoMigrations/042_Add_PlayerIdentity_RouteSegment/usp_Player_Async_Update.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,84 @@ | ||
SET ANSI_NULLS ON | ||
GO | ||
SET QUOTED_IDENTIFIER ON | ||
GO | ||
DROP PROCEDURE [dbo].[usp_Link_Player_To_Member_Async_Update] | ||
GO | ||
|
||
-- ============================================= | ||
-- Author: Rick Mason | ||
-- Create date: 17 Sept 2022 | ||
-- Description: Checks for outstanding work following linking/unlinking a player to a member or renaming a player identity, and completes a batch of that work. | ||
-- This is called asynchronously rather than at the time of linking/unlinking/renaming the player to avoid a slow update of | ||
-- StoolballPlayerInMatchStatistics causing SQL timeouts in production. | ||
-- ============================================= | ||
CREATE OR ALTER PROCEDURE [dbo].[usp_Player_Async_Update] | ||
AS | ||
BEGIN | ||
-- SET NOCOUNT ON added to prevent extra result sets from | ||
-- interfering with SELECT statements. | ||
SET NOCOUNT ON; | ||
|
||
BEGIN TRAN | ||
|
||
DECLARE @DoStatisticsUpdate bit | ||
|
||
-- Check for a batch of up to 10 records that need to be updated with a changed details for a PlayerIdentity. | ||
-- The limit of 10 is to mitigate the risk of SQL timeouts updating the StoolballPlayerInMatchStatistics table in production, | ||
-- because the table is heavily indexed and updates can be slow. | ||
-- SELECT into a temp table with a separate UPDATE, rather than an all in one UPDATE...FROM statement, is the only way to limit to 10. | ||
SELECT TOP 10 PlayerInMatchStatisticsId, p.PlayerId, p.PlayerRoute, pi.PlayerIdentityName, s.PlayerRoute AS PlayerRouteToReplace | ||
INTO #LinkPlayerToMemberAsyncUpdate | ||
FROM StoolballPlayerInMatchStatistics s | ||
INNER JOIN StoolballPlayerIdentity pi ON s.PlayerIdentityId = pi.PlayerIdentityId | ||
INNER JOIN StoolballPlayer p ON pi.PlayerId = p.PlayerId | ||
WHERE s.PlayerRoute != p.PlayerRoute OR s.PlayerId != p.PlayerId OR s.PlayerIdentityName != pi.PlayerIdentityName | ||
|
||
IF @@ROWCOUNT > 0 | ||
SET @DoStatisticsUpdate = 1 | ||
ELSE | ||
SET @DoStatisticsUpdate = 0 | ||
|
||
IF @DoStatisticsUpdate = 1 | ||
BEGIN | ||
UPDATE StoolballPlayerInMatchStatistics | ||
SET | ||
PlayerRoute = todo.PlayerRoute, | ||
PlayerId = todo.PlayerId | ||
FROM StoolballPlayerInMatchStatistics s | ||
INNER JOIN #LinkPlayerToMemberAsyncUpdate todo ON s.PlayerInMatchStatisticsId = todo.PlayerInMatchStatisticsId | ||
|
||
-- Return affected PlayerRoutes so that the calling code can clear the player cache, and so it knows that work was done | ||
-- and it might need to call this procedure again to process further records. | ||
SELECT PlayerRoute FROM #LinkPlayerToMemberAsyncUpdate | ||
UNION | ||
SELECT PlayerRouteToReplace AS PlayerRoute FROM #LinkPlayerToMemberAsyncUpdate | ||
END | ||
|
||
DROP TABLE #LinkPlayerToMemberAsyncUpdate | ||
|
||
-- When combining one player identity with another, there's a leftover player to delete that the identity used to belong to. | ||
-- Once the SELECT above returns no rows we know it is safe to delete these players without a blocking foreign key in the | ||
-- StoolballPlayerInMatchStatistics table. | ||
IF @DoStatisticsUpdate = 0 | ||
BEGIN | ||
SELECT p.PlayerId, p.PlayerRoute | ||
INTO #LinkPlayerToMemberAsyncDelete | ||
FROM StoolballPlayer p | ||
LEFT JOIN StoolballPlayerInMatchStatistics s ON p.PlayerId = s.PlayerId | ||
WHERE ForAsyncDelete = 1 AND s.PlayerInMatchStatisticsId IS NULL | ||
|
||
IF @@ROWCOUNT > 0 | ||
BEGIN | ||
DELETE FROM StoolballPlayer WHERE PlayerId IN (SELECT PlayerId FROM #LinkPlayerToMemberAsyncDelete) | ||
|
||
-- Return affected PlayerRoutes so that the calling code can clear the player cache, and so it knows that work was done | ||
-- and it might need to call this procedure again to process further records. | ||
SELECT PlayerRoute FROM #LinkPlayerToMemberAsyncDelete | ||
END | ||
|
||
DROP TABLE #LinkPlayerToMemberAsyncDelete | ||
END | ||
|
||
COMMIT TRAN | ||
END |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.