Skip to content

Commit ad7e710

Browse files
committed
Merge remote-tracking branch 'origin/hotfix-18.2' into develop
2 parents 8dae2a0 + a3f19a1 commit ad7e710

File tree

1 file changed

+96
-16
lines changed

1 file changed

+96
-16
lines changed

RockWeb/Blocks/Crm/PersonMerge.ascx.cs

Lines changed: 96 additions & 16 deletions
Original file line numberDiff line numberDiff line change
@@ -1857,9 +1857,9 @@ FROM [GroupMember] GMO
18571857
AND gmo.GroupMemberStatus = @GroupMemberStatusPending
18581858
)
18591859
)
1860-
/*
1860+
/**********************************************************************************************
18611861
* Handle RegistrationRegistrant records
1862-
*/
1862+
**********************************************************************************************/
18631863
-- NULL out RegistrationRegistrant Records for the @LessActiveGroupMembersIdsToDelete
18641864
UPDATE [RegistrationRegistrant]
18651865
SET [GroupMemberId] = NULL
@@ -1868,23 +1868,102 @@ SELECT [Id]
18681868
FROM @LessActiveGroupMembersIdsToDelete
18691869
)
18701870
1871-
/*
1871+
/*********************************************************************************************
18721872
* Handle GroupMemberAssignment records
1873-
*/
1874-
-- Delete the GroupMemberAssignment Records for the @LessActiveGroupMembersIdsToDelete
1875-
DELETE FROM [GroupMemberAssignment]
1876-
WHERE [GroupMemberId] IN (
1877-
SELECT [Id]
1878-
FROM @LessActiveGroupMembersIdsToDelete
1879-
)
1880-
1873+
**********************************************************************************************/
1874+
DECLARE @Pairs TABLE (
1875+
OldGMId INT NOT NULL,
1876+
KeepGMId INT NOT NULL,
1877+
GroupId INT NOT NULL,
1878+
FinalWinnerGMId INT NOT NULL,
1879+
FinalLoserGMId INT NOT NULL,
1880+
PRIMARY KEY (FinalLoserGMId, GroupId)
1881+
);
1882+
1883+
-- Because our initial 'Keep' record might be in the @LessActiveGroupMembersIdsToDelete
1884+
-- list, we need to adjust which one we'll keep based on that.
1885+
INSERT INTO @Pairs (OldGMId, KeepGMId, GroupId, FinalWinnerGMId, FinalLoserGMId)
1886+
SELECT
1887+
GMOld.Id,
1888+
GMKeep.Id,
1889+
GMOld.GroupId,
1890+
CASE WHEN LA.Id IS NOT NULL THEN GMOld.Id ELSE GMKeep.Id END,
1891+
CASE WHEN LA.Id IS NOT NULL THEN GMKeep.Id ELSE GMOld.Id END
1892+
FROM dbo.GroupMember AS GMOld
1893+
JOIN dbo.GroupMember AS GMKeep ON GMKeep.GroupId = GMOld.GroupId
1894+
AND GMKeep.GroupRoleId = GMOld.GroupRoleId
1895+
AND GMKeep.PersonId = @NewId
1896+
LEFT JOIN @LessActiveGroupMembersIdsToDelete AS LA ON LA.Id = GMKeep.Id
1897+
WHERE GMOld.PersonId = @OldId;
1898+
1899+
-----------------------------------------------------------------------------
1900+
-- @Assigns: losing assignments and their projected winner.
1901+
-----------------------------------------------------------------------------
1902+
DECLARE @Assigns TABLE (
1903+
GroupMemberAssignmentId INT NOT NULL PRIMARY KEY,
1904+
GroupId INT NOT NULL,
1905+
LocationId INT NULL,
1906+
ScheduleId INT NULL,
1907+
NewGroupMemberId INT NOT NULL
1908+
);
1909+
1910+
INSERT INTO @Assigns (GroupMemberAssignmentId, GroupId, LocationId, ScheduleId, NewGroupMemberId)
1911+
SELECT
1912+
GMA.Id,
1913+
GMA.GroupId,
1914+
GMA.LocationId,
1915+
GMA.ScheduleId,
1916+
P.FinalWinnerGMId
1917+
FROM dbo.GroupMemberAssignment AS GMA
1918+
JOIN @Pairs AS P ON GMA.GroupMemberId = P.FinalLoserGMId
1919+
AND GMA.GroupId = P.GroupId;
1920+
1921+
/*
1922+
12/2/2025 - N.A.
1923+
1924+
Why does this appear to be so complicated?
1925+
1926+
Additional cleanup steps are required when updating GroupMember assignments due to
1927+
the IX_GroupMemberIdLocationIdScheduleId index since you cannot have two
1928+
GroupMemberAssignments for the same groupmember, location and schedule.
1929+
1930+
Specifically:
1931+
1) A 'losing' row might match an existing 'winner' row after remapping, violating
1932+
the unique index. Therefore, the losing row must be deleted before the update.
1933+
*/
1934+
1935+
-- (1) DELETE losing assignments that would collide with EXISTING winner rows.
1936+
DELETE GMA
1937+
FROM dbo.GroupMemberAssignment AS GMA
1938+
JOIN @Assigns AS A ON A.GroupMemberAssignmentId = GMA.Id
1939+
WHERE EXISTS (
1940+
SELECT 1
1941+
FROM dbo.GroupMemberAssignment AS W
1942+
WHERE W.GroupMemberId = A.NewGroupMemberId
1943+
AND W.GroupId = A.GroupId
1944+
AND ( (W.LocationId = A.LocationId) OR (W.LocationId IS NULL AND A.LocationId IS NULL) )
1945+
AND ( (W.ScheduleId = A.ScheduleId) OR (W.ScheduleId IS NULL AND A.ScheduleId IS NULL) )
1946+
);
1947+
1948+
-- Update assignments from Loser -> Winner (@Pairs / @Assigns are scoped by GroupId)
1949+
UPDATE GMA
1950+
SET GMA.GroupMemberId = A.NewGroupMemberId
1951+
FROM dbo.GroupMemberAssignment AS GMA
1952+
JOIN @Assigns AS A ON A.GroupMemberAssignmentId = GMA.Id;
1953+
1954+
/**********************************************************************************************
1955+
* Handle GroupMemberHistory records
1956+
**********************************************************************************************/
18811957
-- If there is GroupMemberHistory, we can't delete, so create a list of GroupMemberIds that we'll archive instead of delete
18821958
INSERT INTO @GroupMembersIdsToArchive
18831959
SELECT [Id] FROM @LessActiveGroupMembersIdsToDelete WHERE Id IN (SELECT GroupMemberId FROM GroupMemberHistorical)
18841960
18851961
DELETE FROM @LessActiveGroupMembersIdsToDelete
18861962
WHERE Id IN (SELECT Id FROM @GroupMembersIdsToArchive)
18871963
1964+
/**********************************************************************************************
1965+
* Handle the final surviving GroupMember records
1966+
**********************************************************************************************/
18881967
-- Delete the @LessActiveGroupMembersIdsToDelete for any GroupMember records that don't have GroupMemberHistory
18891968
DELETE
18901969
FROM GroupMember
@@ -1909,9 +1988,9 @@ LEFT OUTER JOIN [GroupMember] GMN
19091988
AND GMN.[Id] IS NULL
19101989
and GMO.Id NOT IN (SELECT [Id] FROM @GroupMembersIdsToArchive)
19111990
1912-
/*
1991+
/**********************************************************************************************
19131992
* Handle RegistrationRegistrant records
1914-
*/
1993+
**********************************************************************************************/
19151994
-- Update any registrant groups that point to a group member about to be deleted
19161995
UPDATE [RegistrationRegistrant]
19171996
SET [GroupMemberId] = NULL
@@ -1921,9 +2000,10 @@ FROM [GroupMember]
19212000
WHERE [PersonId] = @OldId
19222001
)
19232002
1924-
/*
1925-
* Handle GroupMemberAssignment records
1926-
*/
2003+
/**********************************************************************************************
2004+
* Handle GroupMemberAssignment records (again)
2005+
* NOTE: There should not be any if we did everything correctly earlier/above.
2006+
**********************************************************************************************/
19272007
-- Delete any Group Assignments that point to a group member about to be deleted
19282008
DELETE FROM [GroupMemberAssignment]
19292009
WHERE [GroupMemberId] IN (

0 commit comments

Comments
 (0)