diff --git a/DigitalLearningSolutions.Data.Migrations/202507030918_CreateOrAlterGetSelfAssessmentReport.cs b/DigitalLearningSolutions.Data.Migrations/202507030918_CreateOrAlterGetSelfAssessmentReport.cs new file mode 100644 index 0000000000..daa85c4f15 --- /dev/null +++ b/DigitalLearningSolutions.Data.Migrations/202507030918_CreateOrAlterGetSelfAssessmentReport.cs @@ -0,0 +1,17 @@ +namespace DigitalLearningSolutions.Data.Migrations +{ + using FluentMigrator; + [Migration(20250703091)] + public class CreateOrAlterGetSelfAssessmentReport : Migration + { + public override void Up() + { + Execute.Sql(Properties.Resources.TD_5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP); + } + public override void Down() + { + Execute.Sql("DROP PROCEDURE IF EXISTS [dbo].[usp_GetSelfAssessmentReport]"); + Execute.Sql("DROP FUNCTION IF EXISTS [dbo].[GetOtherCentresForSelfAssessmentTVF]"); + } + } +} diff --git a/DigitalLearningSolutions.Data.Migrations/Properties/Resources.Designer.cs b/DigitalLearningSolutions.Data.Migrations/Properties/Resources.Designer.cs index f5949119d4..1e78c0fc6d 100644 --- a/DigitalLearningSolutions.Data.Migrations/Properties/Resources.Designer.cs +++ b/DigitalLearningSolutions.Data.Migrations/Properties/Resources.Designer.cs @@ -2524,6 +2524,32 @@ internal static string TD_5514_Alter_SendExpiredTBCReminders_Up { } } + /// + /// Looks up a localized string similar to CREATE OR ALTER FUNCTION dbo.GetOtherCentresForSelfAssessmentTVF + ///( + /// @UserID INT, + /// @SelfAssessmentID INT, + /// @ExcludeCentreID INT + ///) + ///RETURNS TABLE + ///AS + ///RETURN + ///( + /// SELECT + /// STUFF(( + /// SELECT DISTINCT + /// ', ' + c.CentreName + /// FROM Users AS u + /// INNER JOIN DelegateAccounts AS da ON u.ID = da.UserID + /// INNER JOIN Centres AS c ON da.CentreID = c.CentreID + /// INNER JOIN CentreSelfAssessments AS csa ON c.CentreID = csa.CentreID [rest of string was truncated]";. + /// + internal static string TD_5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP { + get { + return ResourceManager.GetString("TD-5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP", resourceCulture); + } + } + /// /// Looks up a localized string similar to /****** Object: StoredProcedure [dbo].[GetActiveAvailableCustomisationsForCentreFiltered_V6] Script Date: 29/09/2022 19:11:04 ******/ ///SET ANSI_NULLS ON diff --git a/DigitalLearningSolutions.Data.Migrations/Properties/Resources.resx b/DigitalLearningSolutions.Data.Migrations/Properties/Resources.resx index c0b77842ad..5410e423e6 100644 --- a/DigitalLearningSolutions.Data.Migrations/Properties/Resources.resx +++ b/DigitalLearningSolutions.Data.Migrations/Properties/Resources.resx @@ -487,4 +487,7 @@ ..\Scripts\TD-5447-Alter_ReorderFrameworkCompetency_Up.sql;System.String, mscorlib, Version=4.0.0.0, Culture=neutral, PublicKeyToken=b77a5c561934e089;utf-16 + + ..\Scripts\TD-5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP.sql;System.String, mscorlib, Version=4.0.0.0, Culture=neutral, PublicKeyToken=b77a5c561934e089;utf-8 + \ No newline at end of file diff --git a/DigitalLearningSolutions.Data.Migrations/Scripts/TD-5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP.sql b/DigitalLearningSolutions.Data.Migrations/Scripts/TD-5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP.sql new file mode 100644 index 0000000000..eb99526d7a --- /dev/null +++ b/DigitalLearningSolutions.Data.Migrations/Scripts/TD-5759_CreateOrAlterSelfAssessmentReportSPandTVF_UP.sql @@ -0,0 +1,145 @@ +CREATE OR ALTER FUNCTION dbo.GetOtherCentresForSelfAssessmentTVF +( + @UserID INT, + @SelfAssessmentID INT, + @ExcludeCentreID INT +) +RETURNS TABLE +AS +RETURN +( + SELECT + STUFF(( + SELECT DISTINCT + ', ' + c.CentreName + FROM Users AS u + INNER JOIN DelegateAccounts AS da ON u.ID = da.UserID + INNER JOIN Centres AS c ON da.CentreID = c.CentreID + INNER JOIN CentreSelfAssessments AS csa ON c.CentreID = csa.CentreID + WHERE u.ID = @UserID + AND da.Active = 1 + AND da.Approved = 1 + AND csa.SelfAssessmentID = @SelfAssessmentID + AND c.CentreID <> @ExcludeCentreID + FOR XML PATH(''), TYPE + ).value('.', 'NVARCHAR(MAX)'), 1, 2, '') AS OtherCentres +); +GO + +CREATE OR ALTER PROCEDURE [dbo].[usp_GetSelfAssessmentReport] + @SelfAssessmentID INT, + @CentreID INT +AS +BEGIN + SET NOCOUNT ON; + + -- Step 1: Materialize the LatestAssessmentResults into a temp table + IF OBJECT_ID('tempdb..#LatestAssessmentResults') IS NOT NULL + DROP TABLE #LatestAssessmentResults; + + SELECT + s.DelegateUserID, + CASE WHEN COALESCE(rr.LevelRAG, 0) = 3 THEN s.ID ELSE NULL END AS SelfAssessed, + CASE + WHEN sv.Verified IS NOT NULL AND sv.SignedOff = 1 AND COALESCE(rr.LevelRAG, 0) = 3 + THEN s.ID ELSE NULL + END AS Confirmed, + CASE WHEN sas.Optional = 1 THEN s.CompetencyID ELSE NULL END AS Optional + INTO #LatestAssessmentResults + FROM SelfAssessmentResults AS s + LEFT JOIN SelfAssessmentStructure AS sas + ON sas.SelfAssessmentID = @SelfAssessmentID + AND s.CompetencyID = sas.CompetencyID + LEFT JOIN SelfAssessmentResultSupervisorVerifications AS sv + ON s.ID = sv.SelfAssessmentResultId + AND sv.Superceded = 0 + LEFT JOIN CompetencyAssessmentQuestionRoleRequirements AS rr + ON s.CompetencyID = rr.CompetencyID + AND s.AssessmentQuestionID = rr.AssessmentQuestionID + AND sas.SelfAssessmentID = rr.SelfAssessmentID + AND s.Result = rr.LevelValue + WHERE sas.SelfAssessmentID = @SelfAssessmentID; + + CREATE NONCLUSTERED INDEX IX_LAR_DelegateUserID ON #LatestAssessmentResults(DelegateUserID); + + -- Step 2: Run the main query + SELECT + sa.Name AS SelfAssessment, + u.LastName + ', ' + u.FirstName AS Learner, + da.Active AS LearnerActive, + u.ProfessionalRegistrationNumber AS PRN, + jg.JobGroupName AS JobGroup, + da.Answer1, + da.Answer2, + da.Answer3, + da.Answer4, + da.Answer5, + da.Answer6, + oc.OtherCentres, + CASE + WHEN aa.ID IS NULL THEN 'Learner' + WHEN aa.IsCentreManager = 1 THEN 'Centre Manager' + WHEN aa.IsCentreAdmin = 1 AND aa.IsCentreManager = 0 THEN 'Centre Admin' + WHEN aa.IsSupervisor = 1 THEN 'Supervisor' + WHEN aa.IsNominatedSupervisor = 1 THEN 'Nominated supervisor' + END AS DLSRole, + da.DateRegistered AS Registered, + ca.StartedDate, + ca.LastAccessed, + COUNT(DISTINCT LAR.Optional) AS [OptionalProficienciesAssessed], + COUNT(DISTINCT LAR.SelfAssessed) AS [SelfAssessedAchieved], + COUNT(DISTINCT LAR.Confirmed) AS [ConfirmedResults], + MAX(casv.Requested) AS SignOffRequested, + MAX(1 * casv.SignedOff) AS SignOffAchieved, + MIN(casv.Verified) AS ReviewedDate + FROM CandidateAssessments AS ca + INNER JOIN DelegateAccounts AS da + ON ca.DelegateUserID = da.UserID + AND da.CentreID = @CentreID + INNER JOIN Users AS u + ON u.ID = da.UserID + INNER JOIN SelfAssessments AS sa + ON ca.SelfAssessmentID = sa.ID + INNER JOIN CentreSelfAssessments AS csa + ON sa.ID = csa.SelfAssessmentID + INNER JOIN Centres AS c + ON csa.CentreID = c.CentreID + AND da.CentreID = c.CentreID + INNER JOIN JobGroups AS jg + ON u.JobGroupID = jg.JobGroupID + LEFT JOIN AdminAccounts AS aa + ON da.UserID = aa.UserID + AND aa.CentreID = da.CentreID + AND aa.Active = 1 + LEFT JOIN CandidateAssessmentSupervisors AS cas + ON ca.ID = cas.CandidateAssessmentID + LEFT JOIN CandidateAssessmentSupervisorVerifications AS casv + ON casv.CandidateAssessmentSupervisorID = cas.ID + LEFT JOIN SupervisorDelegates AS sd + ON cas.SupervisorDelegateId = sd.ID + LEFT JOIN #LatestAssessmentResults AS LAR + ON LAR.DelegateUserID = ca.DelegateUserID + OUTER APPLY dbo.GetOtherCentresForSelfAssessmentTVF(da.UserID, @SelfAssessmentID, c.CentreID) AS oc + WHERE + sa.ID = @SelfAssessmentID + AND sa.ArchivedDate IS NULL + AND c.Active = 1 + AND ca.RemovedDate IS NULL + AND ca.NonReportable = 0 + GROUP BY + sa.Name, + u.LastName + ', ' + u.FirstName, + da.Active, + u.ProfessionalRegistrationNumber, + jg.JobGroupName, + da.Answer1, da.Answer2, da.Answer3, da.Answer4, da.Answer5, da.Answer6, + da.DateRegistered, + ca.StartedDate, + ca.LastAccessed, + oc.OtherCentres, + aa.ID, aa.IsCentreManager, aa.IsCentreAdmin, aa.IsSupervisor, aa.IsNominatedSupervisor + ORDER BY + sa.Name, u.LastName + ', ' + u.FirstName; + +END; +GO \ No newline at end of file diff --git a/DigitalLearningSolutions.Data/DataServices/SelfAssessmentDataService/SelfAsssessmentReportDataService.cs b/DigitalLearningSolutions.Data/DataServices/SelfAssessmentDataService/SelfAsssessmentReportDataService.cs index 0bd5d38f37..d5f56385e1 100644 --- a/DigitalLearningSolutions.Data/DataServices/SelfAssessmentDataService/SelfAsssessmentReportDataService.cs +++ b/DigitalLearningSolutions.Data/DataServices/SelfAssessmentDataService/SelfAsssessmentReportDataService.cs @@ -45,94 +45,9 @@ FROM CentreSelfAssessments AS csa INNER JOIN public IEnumerable GetSelfAssessmentReportDataForCentre(int centreId, int selfAssessmentId) { - return connection.Query( - @"WITH LatestAssessmentResults AS - ( - SELECT s.DelegateUserID - , CASE WHEN COALESCE (rr.LevelRAG, 0) = 3 THEN s.ID ELSE NULL END AS SelfAssessed - , CASE WHEN sv.Verified IS NOT NULL AND sv.SignedOff = 1 AND COALESCE (rr.LevelRAG, 0) = 3 THEN s.ID ELSE NULL END AS Confirmed - , CASE WHEN sas.Optional = 1 THEN s.CompetencyID ELSE NULL END AS Optional - FROM SelfAssessmentResults AS s LEFT OUTER JOIN - SelfAssessmentStructure AS sas ON sas.SelfAssessmentID = @selfAssessmentId AND s.CompetencyID = sas.CompetencyID LEFT OUTER JOIN - SelfAssessmentResultSupervisorVerifications AS sv ON s.ID = sv.SelfAssessmentResultId AND sv.Superceded = 0 LEFT OUTER JOIN - CompetencyAssessmentQuestionRoleRequirements AS rr ON s.CompetencyID = rr.CompetencyID AND s.AssessmentQuestionID = rr.AssessmentQuestionID AND sas.SelfAssessmentID = rr.SelfAssessmentID AND s.Result = rr.LevelValue - WHERE (sas.SelfAssessmentID = @selfAssessmentId) - ) - SELECT - sa.Name AS SelfAssessment - , u.LastName + ', ' + u.FirstName AS Learner - , da.Active AS LearnerActive - , u.ProfessionalRegistrationNumber AS PRN - , jg.JobGroupName AS JobGroup - , da.Answer1 AS RegistrationAnswer1 - , da.Answer2 AS RegistrationAnswer2 - , da.Answer3 AS RegistrationAnswer3 - , da.Answer4 AS RegistrationAnswer4 - , da.Answer5 AS RegistrationAnswer5 - , da.Answer6 AS RegistrationAnswer6 - , dbo.GetOtherCentresForSelfAssessment(da.UserID, @SelfAssessmentID, c.CentreID) AS OtherCentres - , CASE - WHEN aa.ID IS NULL THEN 'Learner' - WHEN aa.IsCentreManager = 1 THEN 'Centre Manager' - WHEN aa.IsCentreAdmin = 1 AND aa.IsCentreManager = 0 THEN 'Centre Admin' - WHEN aa.IsSupervisor = 1 THEN 'Supervisor' - WHEN aa.IsNominatedSupervisor = 1 THEN 'Nominated supervisor' - END AS DLSRole - , da.DateRegistered AS Registered - , ca.StartedDate AS Started - , ca.LastAccessed - , COALESCE(COUNT(DISTINCT LAR.Optional), NULL) AS [OptionalProficienciesAssessed] - , COALESCE(COUNT(DISTINCT LAR.SelfAssessed), NULL) AS [SelfAssessedAchieved] - , COALESCE(COUNT(DISTINCT LAR.Confirmed), NULL) AS [ConfirmedResults] - , max(casv.Requested) AS SignOffRequested - , max(1*casv.SignedOff) AS SignOffAchieved - , min(casv.Verified) AS ReviewedDate - FROM - CandidateAssessments AS ca INNER JOIN - DelegateAccounts AS da ON ca.DelegateUserID = da.UserID and da.CentreID = @centreId INNER JOIN - Users as u ON u.ID = da.UserID INNER JOIN - SelfAssessments AS sa INNER JOIN - CentreSelfAssessments AS csa ON sa.ID = csa.SelfAssessmentID INNER JOIN - Centres AS c ON csa.CentreID = c.CentreID ON da.CentreID = c.CentreID AND ca.SelfAssessmentID = sa.ID INNER JOIN - JobGroups AS jg ON u.JobGroupID = jg.JobGroupID LEFT OUTER JOIN - AdminAccounts AS aa ON da.UserID = aa.UserID AND aa.CentreID = da.CentreID AND aa.Active = 1 LEFT OUTER JOIN - CandidateAssessmentSupervisors AS cas ON ca.ID = cas.CandidateAssessmentID left JOIN - CandidateAssessmentSupervisorVerifications AS casv ON casv.CandidateAssessmentSupervisorID = cas.ID LEFT JOIN - SupervisorDelegates AS sd ON cas.SupervisorDelegateId = sd.ID - LEFT OUTER JOIN LatestAssessmentResults AS LAR ON LAR.DelegateUserID = ca.DelegateUserID - WHERE - (sa.ID = @SelfAssessmentID) AND (sa.ArchivedDate IS NULL) AND (c.Active = 1) AND (ca.RemovedDate IS NULL AND ca.NonReportable = 0) - Group by sa.Name - , u.LastName + ', ' + u.FirstName - , da.Active - , u.ProfessionalRegistrationNumber - , c.CustomField1PromptID - , c.CustomField2PromptID - , c.CustomField3PromptID - , c.CustomField4PromptID - , c.CustomField5PromptID - , c.CustomField6PromptID - , c.CentreID - , jg.JobGroupName - , da.ID - , da.Answer1 - , da.Answer2 - , da.Answer3 - , da.Answer4 - , da.Answer5 - , da.Answer6 - , da.DateRegistered - , da.UserID - , aa.ID - , aa.IsCentreManager - , aa.IsCentreAdmin - , aa.IsSupervisor - , aa.IsNominatedSupervisor - , ca.StartedDate - , ca.LastAccessed - ORDER BY - SelfAssessment, u.LastName + ', ' + u.FirstName", - new { centreId, selfAssessmentId } + return connection.Query("usp_GetSelfAssessmentReport", + new { selfAssessmentId, centreId }, + commandType: CommandType.StoredProcedure ); } }