diff --git a/src/SFA.DAS.AssessorService.Database/PostDeploymentScripts/GrantOrDenyPermissions.sql b/src/SFA.DAS.AssessorService.Database/PostDeploymentScripts/GrantOrDenyPermissions.sql index a76649bf7c..173e9ddd50 100644 --- a/src/SFA.DAS.AssessorService.Database/PostDeploymentScripts/GrantOrDenyPermissions.sql +++ b/src/SFA.DAS.AssessorService.Database/PostDeploymentScripts/GrantOrDenyPermissions.sql @@ -13,3 +13,6 @@ GO GRANT EXECUTE ON [dbo].[DatabaseMaintenance] TO [database_maintenance] AS [dbo] GO + +GRANT EXECUTE ON [DashboardReporting].[CertificatePrintSummary] TO [DashboardReporting] +GO \ No newline at end of file diff --git a/src/SFA.DAS.AssessorService.Database/SFA.DAS.AssessorService.Database.sqlproj b/src/SFA.DAS.AssessorService.Database/SFA.DAS.AssessorService.Database.sqlproj index 3d8248f8cc..2041042796 100644 --- a/src/SFA.DAS.AssessorService.Database/SFA.DAS.AssessorService.Database.sqlproj +++ b/src/SFA.DAS.AssessorService.Database/SFA.DAS.AssessorService.Database.sqlproj @@ -71,6 +71,8 @@ + + @@ -165,6 +167,9 @@ + + + diff --git a/src/SFA.DAS.AssessorService.Database/Security/Roles/DatabaseRoles/DashboardReporting.sql b/src/SFA.DAS.AssessorService.Database/Security/Roles/DatabaseRoles/DashboardReporting.sql new file mode 100644 index 0000000000..110fde3e6c --- /dev/null +++ b/src/SFA.DAS.AssessorService.Database/Security/Roles/DatabaseRoles/DashboardReporting.sql @@ -0,0 +1 @@ +CREATE ROLE [DashboardReporting] diff --git a/src/SFA.DAS.AssessorService.Database/Security/Schemas/DashboardReporting.sql b/src/SFA.DAS.AssessorService.Database/Security/Schemas/DashboardReporting.sql new file mode 100644 index 0000000000..0ec4577d19 --- /dev/null +++ b/src/SFA.DAS.AssessorService.Database/Security/Schemas/DashboardReporting.sql @@ -0,0 +1 @@ +CREATE SCHEMA [DashboardReporting] diff --git a/src/SFA.DAS.AssessorService.Database/StoredProcedures/DashboardReporting/CertificatePrintSummary.sql b/src/SFA.DAS.AssessorService.Database/StoredProcedures/DashboardReporting/CertificatePrintSummary.sql new file mode 100644 index 0000000000..9fed6d46d1 --- /dev/null +++ b/src/SFA.DAS.AssessorService.Database/StoredProcedures/DashboardReporting/CertificatePrintSummary.sql @@ -0,0 +1,58 @@ +CREATE PROCEDURE [DashboardReporting].[CertificatePrintSummary] + @from DATETIME, + @to DATETIME +AS + BEGIN TRY + IF(DATEDIFF(day, @from, @to) > 28) + BEGIN + DECLARE @DateRangeErrorMessage NVARCHAR(100) = 'Date range from: ' + FORMAT(@from, 'g', 'en-gb') + ' to: ' + FORMAT(@to, 'g', 'en-gb') + ' is greater than maximum date range of 28 days' + RAISERROR(@DateRangeErrorMessage, 16, 1) + END + + SELECT + [PivotPrintCertificateLogsByBatchNumber].BatchNumber, + FORMAT([BatchLogs].ScheduledDate, 'g', 'en-gb' ) ScheduledDate, + FORMAT([BatchLogs].FileUploadEndTime, 'g', 'en-gb' ) UploadedDate, + FORMAT(PARSE(JSON_VALUE([BatchLogs].BatchData, '$.PrintedDate') AS DATETIME), 'g', 'en-gb') PrintedDate, + [PivotPrintCertificateLogsByBatchNumber].SentToPrinter, + [PivotPrintCertificateLogsByBatchNumber].Printed, + [PivotPrintCertificateLogsByBatchNumber].Delivered, + [PivotPrintCertificateLogsByBatchNumber].NotDelivered + FROM + ( + SELECT + [PivotPrintCertificateLogs].BatchNumber, + SUM([SentToPrinter]) SentToPrinter, SUM([Printed]) Printed, SUM([Delivered]) Delivered, SUM([NotDelivered]) NotDelivered + FROM + ( + SELECT + Status, BatchNumber, EventTime FROM [CertificateLogs] + WHERE + EventTime >= @from AND EventTime <= @to + AND + ((Action = 'Status' AND Status = 'SentToPrinter') + OR (Action = 'Printed' AND Status = 'Printed') + OR (Action = 'Status' AND Status = 'Delivered') + OR (Action = 'Status' AND Status = 'NotDelivered')) + AND BatchNumber IS NOT NULL + ) AS [PrintCertificateLogs] + PIVOT + ( + COUNT(Status) + FOR Status IN ([SentToPrinter], [Printed], [Delivered], [NotDelivered]) + ) AS [PivotPrintCertificateLogs] + GROUP BY + BatchNumber + ) AS [PivotPrintCertificateLogsByBatchNumber] + JOIN BatchLogs + ON [PivotPrintCertificateLogsByBatchNumber].BatchNumber = [BatchLogs].BatchNumber + ORDER BY [PivotPrintCertificateLogsByBatchNumber].BatchNumber + END TRY + BEGIN CATCH + DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); + DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); + DECLARE @ErrorState INT = ERROR_STATE(); + + RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); + END CATCH +RETURN 0