Skip to content

Commit 8af1ef3

Browse files
authored
Merge pull request #1455 from TechnologyEnhancedLearning/Develop/Features/TD-6159-dev
Migration of user and profile related tables from elfh to lh db
2 parents eafe61b + 1595b36 commit 8af1ef3

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

46 files changed

+1583
-0
lines changed

WebAPI/LearningHub.Nhs.Database/LearningHub.Nhs.Database.sqlproj

Lines changed: 46 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -101,6 +101,8 @@
101101
<Folder Include="Triggers" />
102102
<Folder Include="Triggers\external" />
103103
<Folder Include="Stored Procedures\External" />
104+
<Folder Include="Tables\Elfh" />
105+
<Folder Include="Stored Procedures\Elfh" />
104106
</ItemGroup>
105107
<ItemGroup>
106108
<None Include="Scripts\learningHub_Data.sql" />
@@ -539,6 +541,50 @@
539541
<Build Include="Stored Procedures\Activity\GetAssessmentActivityCompletionPercentage.sql" />
540542
<Build Include="Tables\Hub\PasswordResetRequests.sql" />
541543
<Build Include="Stored Procedures\External\ExternalSystemUserCreate.sql" />
544+
545+
<Build Include="Schemas\elfh.sql" />
546+
<Build Include="Tables\Elfh\AttributeTBL.sql" />
547+
<Build Include="Tables\Elfh\AttributeTypeTBL.sql" />
548+
<Build Include="Tables\Elfh\CountryTBL.sql" />
549+
<Build Include="Tables\Elfh\DeaneryTBL.sql" />
550+
<Build Include="Tables\Elfh\EmailTemplateTBL.sql" />
551+
<Build Include="Tables\Elfh\EmailTemplateTypeTBL.sql" />
552+
<Build Include="Tables\Elfh\ExternalSystemTBL.sql" />
553+
<Build Include="Tables\Elfh\GdcRegister.sql" />
554+
<Build Include="Tables\Elfh\GmcLrmp.sql" />
555+
<Build Include="Tables\Elfh\GradeTBL.sql" />
556+
<Build Include="Tables\Elfh\IpCountryLookupTBL.sql" />
557+
<Build Include="Tables\Elfh\JobRoleTBL.sql" />
558+
<Build Include="Tables\Elfh\Location.sql" />
559+
<Build Include="Tables\Elfh\locationTypeTBL.sql" />
560+
<Build Include="Tables\Elfh\LoginWizardRuleTBL.sql" />
561+
<Build Include="Tables\Elfh\LoginWizardStageActivityTBL.sql" />
562+
<Build Include="Tables\Elfh\loginWizardStageTBL.sql" />
563+
<Build Include="Tables\Elfh\MedicalCouncilTBL.sql" />
564+
<Build Include="Tables\Elfh\RegionTBL.sql" />
565+
<Build Include="Tables\Elfh\SchoolTBL.sql" />
566+
<Build Include="Tables\Elfh\SpecialtyTBL.sql" />
567+
<Build Include="Tables\Elfh\StaffGroupTBL.sql" />
568+
<Build Include="Tables\Elfh\SystemSettingTBL.sql" />
569+
<Build Include="Tables\Elfh\TenantSmtpTBL.sql" />
570+
<Build Include="Tables\Elfh\TenantTBL.sql" />
571+
<Build Include="Tables\Elfh\TenantUrlTBL.sql" />
572+
<Build Include="Tables\Elfh\TermsAndConditionsTBL.sql" />
573+
<Build Include="Tables\Elfh\UserAttributeTBL.sql" />
574+
<Build Include="Tables\Elfh\UserEmploymentTBL.sql" />
575+
<Build Include="Tables\Elfh\UserGroupTypeInputValidationTBL.sql" />
576+
<Build Include="Tables\Elfh\UserHistoryAttributeTBL.sql" />
577+
<Build Include="Tables\Elfh\UserHistoryTBL.sql" />
578+
<Build Include="Tables\Elfh\userHistoryTypeTBL.sql" />
579+
<Build Include="Tables\Elfh\UserPasswordValidationTokenTBL.sql" />
580+
<Build Include="Tables\Elfh\UserRoleUpgradeTBL.sql" />
581+
<Build Include="Tables\Elfh\UserTermsAndConditionsTBL.sql" />
582+
<Build Include="Stored Procedures\Elfh\LinkEmploymentRecordToUser.sql" />
583+
<Build Include="Stored Procedures\Elfh\UserDetailForAuthenticationByUserName.sql" />
584+
<Build Include="Stored Procedures\Elfh\UserHistoryAttributeSave.sql" />
585+
<Build Include="Stored Procedures\Elfh\UserHistoryInsert.sql" />
586+
<Build Include="Stored Procedures\Elfh\UserHistoryLoadForLearningHubUser.sql" />
587+
<Build Include="Stored Procedures\Elfh\UserHistoryLoadForUser.sql" />
542588
</ItemGroup>
543589
<ItemGroup>
544590
<None Include="Scripts\Pre-Deploy\Scripts\Card5766_AuthorTableChanges.PreDeployment.sql" />
Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
CREATE SCHEMA [elfh]
2+
AUTHORIZATION [dbo];
3+
GO
Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,36 @@
1+
-----------------------------------------------------------------------------------------------
2+
-- Mark Avey 11/06/2020 - Initial Version.
3+
-- Update the UserTBL record with the primaryUserEmploymentId from userEmploymentTBL
4+
------------------------------------------------------------------------------------------------
5+
CREATE PROCEDURE [elfh].[proc_LinkEmploymentRecordToUser]
6+
(
7+
@userId int
8+
)
9+
AS
10+
BEGIN
11+
BEGIN TRANSACTION
12+
BEGIN TRY
13+
SET NOCOUNT OFF
14+
15+
UPDATE [hub].[User]
16+
SET primaryUserEmploymentId = (SELECT userEmploymentId FROM [elfh].[userEmploymentTBL] WHERE userId = @userId)
17+
WHERE Id = @userId
18+
19+
END TRY
20+
21+
BEGIN CATCH
22+
SELECT
23+
ERROR_NUMBER() AS ErrorNumber
24+
,ERROR_SEVERITY() AS ErrorSeverity
25+
,ERROR_STATE() AS ErrorState
26+
,ERROR_PROCEDURE() AS ErrorProcedure
27+
,ERROR_LINE() AS ErrorLine
28+
,ERROR_MESSAGE() AS ErrorMessage;
29+
30+
IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION
31+
END CATCH
32+
33+
IF @@TRANCOUNT > 0 COMMIT TRANSACTION
34+
35+
RETURN @@ERROR
36+
END
Lines changed: 46 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,46 @@
1+
-------------------------------------------------------------------------
2+
-- Jignesh Jethwani 27 Sept 2023 - Initial version
3+
-- Tobi Awe 24 Sept 2025 - swapped elfh user table to hub user table
4+
--------------------------------------------------------------------------
5+
CREATE PROCEDURE [elfh].[proc_UserDetailForAuthenticationByUserName]
6+
(
7+
@userName varchar(100)
8+
)
9+
AS
10+
BEGIN
11+
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
12+
SET NOCOUNT ON
13+
DECLARE @Err int
14+
DECLARE @false bit
15+
SET @false = 0
16+
SELECT elfhuser.Id as Id,
17+
elfhuser.userName,
18+
ISNULL(elfhuser.passwordHash, '') AS 'passwordHash',
19+
elfhuser.RestrictToSSO,
20+
up.Active,
21+
elfhuser.activeFromDate,
22+
elfhuser.activeToDate,
23+
elfhuser.passwordLifeCounter,
24+
userAttribData.userAttributeId as OpenAthensUserAttributeId
25+
FROM
26+
[hub].[User] elfhuser
27+
INNER JOIN hub.UserProfile up
28+
ON elfhuser.Id = up.Id
29+
OUTER APPLY
30+
(
31+
SELECT
32+
TOP 1 userAttrib.userAttributeId
33+
FROM
34+
elfh.userAttributeTBL userAttrib
35+
INNER Join
36+
elfh.attributeTBL attrib ON userAttrib.attributeId = attrib.attributeId AND lower(attrib.attributeName) = 'openathens_userid' AND userAttrib.deleted = 0
37+
WHERE
38+
userAttrib.userId = elfhuser.Id
39+
) userAttribData
40+
WHERE
41+
elfhuser.userName = @userName
42+
AND
43+
elfhuser.deleted = 0
44+
SET @Err = @@Error
45+
RETURN @Err
46+
END
Lines changed: 89 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,89 @@
1+
2+
--------------------------------------------------------------------------
3+
-- Jignesh Jethwani 02-03-2018 Initial version
4+
-- Jignesh Jethwani 02-10-2023 TD-2913, performance improvement, added no lock to select statement
5+
-- Tobi Awe 24-09-2025 Updated table schema
6+
--------------------------------------------------------------------------
7+
CREATE PROCEDURE [elfh].[proc_UserHistoryAttributeSave]
8+
(
9+
@userHistoryAttributeId int OUTPUT,
10+
@userHistoryId int,
11+
@attributeId int,
12+
@intValue int,
13+
@textValue nvarchar(255),
14+
@booleanValue bit,
15+
@dateValue datetimeoffset,
16+
@deleted bit,
17+
@amendUserId int,
18+
@amendDate datetimeoffset
19+
)
20+
AS
21+
BEGIN
22+
DECLARE @currentIntValue int
23+
DECLARE @currentTextValue nvarchar(255)
24+
DECLARE @currentBooleanValue bit
25+
DECLARE @currentDateValue datetimeoffset
26+
SELECT
27+
@userHistoryAttributeId = userHistoryAttributeId,
28+
@currentIntValue = intValue,
29+
@currentTextValue = textValue,
30+
@currentBooleanValue = booleanValue,
31+
@currentDateValue = dateValue
32+
FROM
33+
elfh.userHistoryAttributeTBL WITH (NOLOCK)
34+
WHERE
35+
userHistoryId = @userHistoryId
36+
AND
37+
attributeId = @attributeId
38+
IF @userHistoryAttributeId IS NULL
39+
BEGIN
40+
IF @intValue IS NOT NULL
41+
OR ISNULL(@textValue, '') != ''
42+
OR @booleanValue IS NOT NULL
43+
OR @dateValue IS NOT NULL
44+
BEGIN
45+
INSERT INTO elfh.userHistoryAttributeTBL(userHistoryId,
46+
attributeId,
47+
intValue,
48+
textValue,
49+
booleanValue,
50+
dateValue,
51+
deleted,
52+
amendUserId,
53+
amendDate)
54+
SELECT
55+
userHistoryId = @userHistoryId,
56+
attributeId = @attributeId,
57+
intValue = @intValue,
58+
textValue = @textValue,
59+
booleanValue = @booleanValue,
60+
dateValue = @dateValue,
61+
deleted = @deleted,
62+
amendUserId = @amendUserId,
63+
@amendDate
64+
SELECT @userHistoryAttributeId = SCOPE_IDENTITY()
65+
END
66+
END
67+
ELSE
68+
BEGIN
69+
-- Only update when an Attribute Value has changed
70+
IF (@intValue != @currentIntValue
71+
OR ISNULL(@textValue, '') != ISNULL(@currentTextValue,'')
72+
OR @booleanValue != @currentBooleanValue
73+
OR @dateValue != @currentDateValue)
74+
BEGIN
75+
UPDATE
76+
elfh.userHistoryAttributeTBL
77+
SET
78+
intValue = @intValue,
79+
textValue = @textValue,
80+
booleanValue = @booleanValue,
81+
dateValue = @dateValue,
82+
deleted = @deleted,
83+
amendUserId = @amendUserId,
84+
amendDate = @amendDate
85+
WHERE
86+
userHistoryAttributeId = @userHistoryAttributeId
87+
END
88+
END
89+
END
Lines changed: 143 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,143 @@
1+
2+
--------------------------------------------------------------------------
3+
-- Chris Bain 08 Aug 2014 - Initial Build
4+
-- Killian Davies 12 Aug 2015 - Added userAgent info (for Login history event)
5+
-- Chris Bain 18 Nov 2016 - Added tenant Id
6+
-- Jignesh Jethwani 02 Mar 2018 - Save details to User History Attribute, add url referer
7+
--------------------------------------------------------------------------
8+
CREATE PROCEDURE [elfh].[proc_UserHistoryInsert]
9+
@userId int = 0,
10+
@historyTypeId int,
11+
@detailedInfo NVARCHAR(1000) = NULL,
12+
@userAgent NVARCHAR(1000) = NULL,
13+
@browserName NVARCHAR(1000) = NULL,
14+
@browserVersion NVARCHAR(1000) = NULL,
15+
@urlReferer NVARCHAR(1000) = NULL,
16+
@loginIP NVARCHAR(50) = NULL,
17+
@loginSuccessFul bit = NULL,
18+
@tenantId INT,
19+
@amendUserId INT,
20+
@amendDate DATETIMEOFFSET = NULL
21+
AS
22+
BEGIN
23+
24+
DECLARE @UserHistoryId int
25+
DECLARE @detailInfoAttributeId int, @userAgentAttributeId int, @browserNameAttributeId int, @browserVersionAttributeId int, @urlRefererAttributeId int, @loginSuccessFulAttributeId int
26+
SET @amendDate = CoalEsce(@amendDate,SysDateTimeOffset())
27+
28+
INSERT INTO userHistoryTBL (userId, userHistoryTypeId, tenantId,createdDate)
29+
VALUES (@userId, @historyTypeId, @tenantId, @amendDate)
30+
31+
32+
SET @UserHistoryId = CAST(SCOPE_IDENTITY() AS int)
33+
34+
SELECT @detailInfoAttributeId = attributeId FROM [elfh].[attributeTBL] WHERE [attributeName] = 'UserHistory_DetailedInfo' AND deleted = 0
35+
SELECT @userAgentAttributeId = attributeId FROM [elfh].[attributeTBL] WHERE [attributeName] = 'UserHistory_UserAgent' AND deleted = 0
36+
SELECT @browserNameAttributeId = attributeId FROM [elfh].[attributeTBL] WHERE [attributeName] = 'UserHistory_BrowserName' AND deleted = 0
37+
SELECT @browserVersionAttributeId = attributeId FROM [elfh].[attributeTBL] WHERE [attributeName] = 'UserHistory_BrowserVersion' AND deleted = 0
38+
SELECT @urlRefererAttributeId = attributeId FROM [elfh].[attributeTBL] WHERE [attributeName] = 'UserHistory_UrlReferer' AND deleted = 0
39+
SELECT @loginSuccessFulAttributeId = attributeId FROM [elfh].[attributeTBL] WHERE [attributeName] = 'UserHistory_LoginSuccessful' AND deleted = 0
40+
41+
-- DetailedInfo
42+
IF @detailInfoAttributeId > 0 AND @detailedInfo IS NOT NULL
43+
BEGIN
44+
EXECUTE [elfh].[proc_UserHistoryAttributeSave] null,
45+
@UserHistoryId,
46+
@detailInfoAttributeId,
47+
NULL,
48+
@detailedInfo, -- textValue,
49+
NULL, -- booleanValue,
50+
NULL, -- dateValue,
51+
0, -- deleted
52+
@amendUserId,
53+
@amendDate
54+
END
55+
56+
-- User Agent
57+
IF @userAgentAttributeId > 0 AND @userAgent IS NOT NULL
58+
BEGIN
59+
60+
EXECUTE [elfh].[proc_UserHistoryAttributeSave] null,
61+
@UserHistoryId,
62+
@userAgentAttributeId,
63+
NULL, -- intValue
64+
@userAgent, -- textValue,
65+
NULL, -- booleanValue,
66+
NULL, -- dateValue,
67+
0, -- deleted
68+
@amendUserId,
69+
@amendDate
70+
END
71+
72+
-- Browser Name
73+
IF @browserNameAttributeId > 0 AND @browserName IS NOT NULL
74+
BEGIN
75+
76+
EXECUTE [elfh].[proc_UserHistoryAttributeSave] null,
77+
@UserHistoryId,
78+
@browserNameAttributeId,
79+
NULL, -- intValue
80+
@browserName, -- textValue,
81+
NULL, -- booleanValue,
82+
NULL, -- dateValue,
83+
0, -- deleted
84+
@amendUserId,
85+
@amendDate
86+
87+
END
88+
89+
-- Browser Version
90+
IF @browserVersionAttributeId > 0 AND @browserVersion IS NOT NULL
91+
BEGIN
92+
93+
94+
EXECUTE [elfh].[proc_UserHistoryAttributeSave] null,
95+
@UserHistoryId,
96+
@browserVersionAttributeId,
97+
NULL, -- intValue
98+
@browserVersion,
99+
NULL, -- booleanValue,
100+
NULL, -- dateValue,
101+
0, -- deleted
102+
@amendUserId,
103+
@amendDate
104+
END
105+
106+
107+
-- Url Referer
108+
IF @urlRefererAttributeId > 0 AND @urlReferer IS NOT NULL
109+
BEGIN
110+
111+
EXECUTE [elfh].[proc_UserHistoryAttributeSave] null,
112+
@UserHistoryId,
113+
@urlRefererAttributeId,
114+
NULL, -- intValue
115+
@urlReferer, -- textValue,
116+
NULL, -- booleanValue,
117+
NULL, -- dateValue,
118+
0, -- deleted
119+
@amendUserId,
120+
@amendDate
121+
122+
END
123+
124+
125+
-- Login SuccessFul
126+
IF @loginSuccessFulAttributeId > 0 AND @loginSuccessFul IS NOT NULL
127+
BEGIN
128+
129+
EXECUTE [elfh].[proc_UserHistoryAttributeSave] null,
130+
@UserHistoryId,
131+
@loginSuccessFulAttributeId,
132+
NULL, -- intValue
133+
@loginIP, -- textValue,
134+
@loginSuccessFul, -- booleanValue,
135+
NULL, -- dateValue,
136+
0, -- deleted
137+
@amendUserId,
138+
@amendDate
139+
140+
END
141+
142+
143+
END

0 commit comments

Comments
 (0)