diff --git a/WebAPI/LearningHub.Nhs.Database/LearningHub.Nhs.Database.sqlproj b/WebAPI/LearningHub.Nhs.Database/LearningHub.Nhs.Database.sqlproj index 1c0d8ebe..a6970798 100644 --- a/WebAPI/LearningHub.Nhs.Database/LearningHub.Nhs.Database.sqlproj +++ b/WebAPI/LearningHub.Nhs.Database/LearningHub.Nhs.Database.sqlproj @@ -681,7 +681,6 @@ - @@ -692,6 +691,7 @@ + diff --git a/WebAPI/LearningHub.Nhs.Database/Scripts/Post-Deploy/Scripts/TD-6148-ADFtableData.sql b/WebAPI/LearningHub.Nhs.Database/Scripts/Post-Deploy/Scripts/TD-6148-ADFtableData.sql index e748cbf8..d9e8acd3 100644 --- a/WebAPI/LearningHub.Nhs.Database/Scripts/Post-Deploy/Scripts/TD-6148-ADFtableData.sql +++ b/WebAPI/LearningHub.Nhs.Database/Scripts/Post-Deploy/Scripts/TD-6148-ADFtableData.sql @@ -42,4 +42,5 @@ VALUES ('ELFHtoLH', 'JobRoleTbl', '1900-01-01'), ('ELFHtoLH', 'userTermsAndConditionsTBL', '1900-01-01'), ('ELFHtoLH', 'medicalCouncilTBL', '1900-01-01'), -('ELFHtoLH', 'staffGroupTBL', '1900-01-01') +('ELFHtoLH', 'staffGroupTBL', '1900-01-01'), +('ELFHtoLH', 'usergroupreportertbl', '1900-01-01') diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserAdminLocation.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserAdminLocation.sql index 28e48027..5128603f 100644 --- a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserAdminLocation.sql +++ b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserAdminLocation.sql @@ -7,44 +7,56 @@ -- -- 04-11-2025 Sarathlal Initial Revision ------------------------------------------------------------------------------- -CREATE PROCEDURE [AdfMergeUserAdminLocation] +CREATE PROCEDURE [dbo].[AdfMergeUserAdminLocation] @UserAdminLocationList dbo.UserAdminLocationType READONLY AS BEGIN SET NOCOUNT ON; - MERGE [elfh].[userAdminLocationTBL] AS target - USING @UserAdminLocationList AS source - ON target.[userId] = source.[userId] - AND target.[adminLocationId] = source.[adminLocationId] -- composite key match + -- Deduplicate source first + ;WITH DedupedSource AS ( + SELECT *, + ROW_NUMBER() OVER ( + PARTITION BY userId, adminLocationId, deleted + ORDER BY amendDate DESC, createdDate DESC + ) AS rn + FROM @UserAdminLocationList + ), + CleanSource AS ( + SELECT * FROM DedupedSource WHERE rn = 1 + ) + + MERGE elfh.userAdminLocationTBL AS target + USING CleanSource AS source + ON target.userId = source.userId + AND target.adminLocationId = source.adminLocationId + AND target.deleted = source.deleted -- IMPORTANT! WHEN MATCHED THEN UPDATE SET - target.[deleted] = source.[deleted], - target.[amendUserId] = source.[amendUserId], - target.[amendDate] = source.[amendDate], - target.[createdUserId] = source.[createdUserId], - target.[createdDate] = source.[createdDate] + target.amendUserId = source.amendUserId, + target.amendDate = source.amendDate, + target.createdUserId = source.createdUserId, + target.createdDate = source.createdDate WHEN NOT MATCHED BY TARGET THEN INSERT ( - [userId], - [adminLocationId], - [deleted], - [amendUserId], - [amendDate], - [createdUserId], - [createdDate] + userId, + adminLocationId, + deleted, + amendUserId, + amendDate, + createdUserId, + createdDate ) VALUES ( - source.[userId], - source.[adminLocationId], - source.[deleted], - source.[amendUserId], - source.[amendDate], - source.[createdUserId], - source.[createdDate] + source.userId, + source.adminLocationId, + source.deleted, + source.amendUserId, + source.amendDate, + source.createdUserId, + source.createdDate ); - END GO diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserEmploymentReference.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserEmploymentReference.sql index 5a5aa29a..e6f0d2ad 100644 --- a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserEmploymentReference.sql +++ b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserEmploymentReference.sql @@ -7,13 +7,14 @@ -- -- 04-11-2025 Sarathlal Initial Revision ------------------------------------------------------------------------------- -CREATE PROCEDURE [AdfMergeUserEmploymentReference] +CREATE PROCEDURE [dbo].[AdfMergeUserEmploymentReference] @UserEmploymentReferenceList dbo.UserEmploymentReferenceType READONLY AS BEGIN SET NOCOUNT ON; SET IDENTITY_INSERT [elfh].[userEmploymentReferenceTBL] ON; + ALTER TABLE [elfh].[userEmploymentReferenceTBL] NOCHECK CONSTRAINT ALL; MERGE [elfh].[userEmploymentReferenceTBL] AS target USING @UserEmploymentReferenceList AS source ON target.[userEmploymentReferenceId] = source.[userEmploymentReferenceId] @@ -47,5 +48,6 @@ BEGIN source.[amendDate] ); SET IDENTITY_INSERT [elfh].[userEmploymentReferenceTBL] OFF; + ALTER TABLE [elfh].[userEmploymentReferenceTBL] NOCHECK CONSTRAINT ALL; END GO diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserGroupReporter.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserGroupReporter.sql new file mode 100644 index 00000000..d1817a38 --- /dev/null +++ b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserGroupReporter.sql @@ -0,0 +1,50 @@ +------------------------------------------------------------------------------- +-- Author Sarathlal +-- Created 25-11-2025 +-- Purpose ELFH-LH Data sync +-- +-- Modification History +-- +-- 25-11-2025 Sarathlal Initial Revision +------------------------------------------------------------------------------- +CREATE PROCEDURE [dbo].[AdfMergeUserGroupReporter] + @UserGroupReporterList [dbo].[UserGroupReporterType] READONLY +AS +BEGIN + SET NOCOUNT ON; + SET IDENTITY_INSERT [elfh].[userGroupReporterTBL] ON; + ALTER TABLE elfh.userGroupReporterTBL NOCHECK CONSTRAINT FK_userGroupReporterTBL_userGroupTBL; + MERGE [elfh].[userGroupReporterTBL] AS target + USING @UserGroupReporterList AS source + ON target.[userGroupReporterId] = source.[userGroupReporterId] + + WHEN MATCHED THEN + UPDATE SET + target.[userId] = source.[userId], + target.[userGroupId] = source.[userGroupId], + target.[deleted] = source.[deleted], + target.[amendUserId] = source.[amendUserId], + target.[amendDate] = source.[amendDate] + + WHEN NOT MATCHED BY TARGET THEN + INSERT ( + [userGroupReporterId], + [userId], + [userGroupId], + [deleted], + [amendUserId], + [amendDate] + ) + VALUES ( + source.[userGroupReporterId], + source.[userId], + source.[userGroupId], + source.[deleted], + source.[amendUserId], + source.[amendDate] + ); + SET IDENTITY_INSERT [elfh].[userGroupReporterTBL] OFF; + ALTER TABLE elfh.userGroupReporterTBL CHECK CONSTRAINT FK_userGroupReporterTBL_userGroupTBL; +END +GO + diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserHistoryAttribute.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserHistoryAttribute.sql deleted file mode 100644 index cc17b95f..00000000 --- a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserHistoryAttribute.sql +++ /dev/null @@ -1,62 +0,0 @@ -------------------------------------------------------------------------------- --- Author Sarathlal --- Created 04-11-2025 --- Purpose ELFH-LH Data sync --- --- Modification History --- --- 04-11-2025 Sarathlal Initial Revision -------------------------------------------------------------------------------- -CREATE PROCEDURE [AdfMergeUserHistoryAttribute] - @UserHistoryAttributeList dbo.UserHistoryAttributeType READONLY -AS -BEGIN - SET NOCOUNT ON; - - ALTER TABLE [elfh].[userHistoryAttributeTBL] NOCHECK CONSTRAINT ALL; - SET IDENTITY_INSERT [elfh].[userHistoryAttributeTBL] ON; - MERGE [elfh].[userHistoryAttributeTBL] AS target - USING @UserHistoryAttributeList AS source - ON target.[userHistoryAttributeId] = source.[userHistoryAttributeId] - - WHEN MATCHED THEN - UPDATE SET - target.[userHistoryId] = source.[userHistoryId], - target.[attributeId] = source.[attributeId], - target.[intValue] = source.[intValue], - target.[textValue] = source.[textValue], - target.[booleanValue] = source.[booleanValue], - target.[dateValue] = source.[dateValue], - target.[deleted] = source.[deleted], - target.[amendUserId] = source.[amendUserId], - target.[amendDate] = source.[amendDate] - - WHEN NOT MATCHED BY TARGET THEN - INSERT ( - [userHistoryAttributeId], - [userHistoryId], - [attributeId], - [intValue], - [textValue], - [booleanValue], - [dateValue], - [deleted], - [amendUserId], - [amendDate] - ) - VALUES ( - source.[userHistoryAttributeId], - source.[userHistoryId], - source.[attributeId], - source.[intValue], - source.[textValue], - source.[booleanValue], - source.[dateValue], - source.[deleted], - source.[amendUserId], - source.[amendDate] - ); - SET IDENTITY_INSERT [elfh].[userHistoryAttributeTBL] OFF; - ALTER TABLE [elfh].[userHistoryAttributeTBL] CHECK CONSTRAINT ALL; -END -GO diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserPasswordValidationToke.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserPasswordValidationToke.sql index d9c65fd6..c37cbd56 100644 --- a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserPasswordValidationToke.sql +++ b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeUserPasswordValidationToke.sql @@ -15,6 +15,8 @@ BEGIN -- Enable identity insert if userPasswordValidationTokenId is an IDENTITY column SET IDENTITY_INSERT [elfh].[userPasswordValidationTokenTBL] ON; + ALTER TABLE [elfh].[userPasswordValidationTokenTBL] NOCHECK CONSTRAINT ALL; + ALTER TABLE [hub].[User] NOCHECK CONSTRAINT ALL; MERGE [elfh].[userPasswordValidationTokenTBL] AS target USING @userPasswordValidationTokenList AS source ON target.userPasswordValidationTokenId = source.userPasswordValidationTokenId @@ -56,5 +58,7 @@ BEGIN -- Disable identity insert SET IDENTITY_INSERT [elfh].[userPasswordValidationTokenTBL] OFF; + ALTER TABLE [hub].[User] CHECK CONSTRAINT ALL; + ALTER TABLE [elfh].[userPasswordValidationTokenTBL] CHECK CONSTRAINT ALL; END GO diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeattribute.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeattribute.sql index d6851b39..33969535 100644 --- a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeattribute.sql +++ b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeattribute.sql @@ -32,20 +32,6 @@ CREATE TYPE dbo.UserReportingUserType AS TABLE [AmendDate] DATETIMEOFFSET ); GO -CREATE TYPE UserHistoryAttributeType AS TABLE -( - [userHistoryAttributeId] INT, - [userHistoryId] INT, - [attributeId] INT, - [intValue] INT NULL, - [textValue] NVARCHAR(1000) NULL, - [booleanValue] BIT NULL, - [dateValue] DATETIMEOFFSET NULL, - [deleted] BIT, - [amendUserId] INT, - [amendDate] DATETIMEOFFSET -); -GO CREATE TYPE UserEmploymentResponsibilityType AS TABLE ( [userEmploymentResponsibilityId] INT, @@ -584,6 +570,16 @@ CREATE TYPE dbo.MedicalCouncil AS TABLE amendDate datetimeoffset(7) ); GO +CREATE TYPE [dbo].[UserGroupReporterType] AS TABLE +( + [userGroupReporterId] INT, + [userId] INT, + [userGroupId] INT, + [deleted] BIT, + [amendUserId] INT, + [amendDate] DATETIMEOFFSET(7) +); +GO CREATE PROCEDURE [dbo].[AdfMergeattribute] @attributeList dbo.Attribute READONLY -- Table-valued parameter AS diff --git a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeuserEmployment.sql b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeuserEmployment.sql index 7e4dc75e..5be94cd1 100644 --- a/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeuserEmployment.sql +++ b/WebAPI/LearningHub.Nhs.Database/Stored Procedures/Adf/AdfMergeuserEmployment.sql @@ -14,6 +14,8 @@ BEGIN SET NOCOUNT ON; SET IDENTITY_INSERT [elfh].[userEmploymentTBL] ON; + ALTER TABLE [elfh].[userEmploymentTBL] NOCHECK CONSTRAINT ALL; + ALTER TABLE [hub].[User] NOCHECK CONSTRAINT ALL; MERGE [elfh].[userEmploymentTBL] AS target USING @userEmploymentList AS source ON target.userEmploymentId = source.userEmploymentId @@ -73,5 +75,7 @@ BEGIN -- Disable identity insert SET IDENTITY_INSERT [elfh].[userEmploymentTBL] OFF; + ALTER TABLE [elfh].[userEmploymentTBL] NOCHECK CONSTRAINT ALL; + ALTER TABLE [hub].[User] NOCHECK CONSTRAINT ALL; END GO