Like Beat mentioned, there is nothing within MR that would track that. In the MR Report Library, you can right-click on a report and select Show Versions. That will show you all the versions of that report and when they were generated. I don't have a SQL statement specifically for this, but I do have one that was written to show report generation times. The results will show the Local Finish Time, which you could be used to see when the report was generated. This query will show all reports that have been generated. If you wanted to limit it to one report, you'd need to edit the second to last line and add the Report Definition name.
/*
This query will return:
-Name of the report definition as shown in Report Designer
-The building block group the report definition belongs to
-The “Output Name” of the report definition (from the Output and Distribution tab)
-The company assigned to the report definition
-If the company was @ANY, it will list the default company that was set when the report was generated
-The report date the report was generated for
-The detail level of the report. A 1 will be in each column that is true for the report.
-If Financial = 1, then it was “Financial”; if Financial and Account both = 1, then “Financial & Account”; if Financial, Account & Txn all have 1 then it was a transaction level report
-If a report has only a YTD column, but is set to generate at the “Financial, Account, & Transaction” detail level, this query will show there is only Account level detail available for the report. This is technically true since a YTD column does not have transaction details associated with it.
-The name of the row definition that was used to generate the report
-The name of the column definition that was used to generate the report
-The name of the reporting tree definition that was used to generate the report. If blank, then there was no tree.
-The username that generated the report
-The time the report started to generate in local time (same time as the report queue)
-The time the report finished generating in local time (same time as the report queue)
-The original UTC timestamps can be shown by removing the comment markers
-The calculated amount of time it took to generate the report
-If the report takes more than 24 hours to finish, the 'Approx. Duration' value will be incorrect as it only takes into consideration the amount of hours/minutes/seconds. If there is a need to add days to the calculation, let me know.
Query restrictions
-where [Repository].[StatusType] in (0,1)
-This will show reports with the following states. All other states are technically not ‘final’ and could show an incorrect length of time
-Completed=0, Failed=1. If you also want to see “Canceled” reports, change it to (0,1,2)
-[ReportDesign].[ReportDesignName] like '%Report Definition name%'
-Change the text to be the name of the report definition in question, or comment out to show all reports ever generated (could run for a very long time if a lot of reports have generated)
*/
--Query:
select [ReportDesign].[ReportDesignName] as 'Report Definition'
,[ReportDesign].[SpecificationName] as 'BB Group'
,[Repository].[Name] as 'Output Name'
,[ReportCompany].[Name] as 'Report Def. Company'
,[ReportCompany].[ReportDate]
,[Report].[HasFinancialDetail] as 'Financial'
,[Report].[HasAccountDetail] as 'Account'
,[Report].[HasTransactionDetail] as 'Txn'
,[ReportDesign].[RowName] as 'Row'
,[ReportDesign].[ColumnName] as 'Column'
,[ReportDesign].[TreeName] as 'Tree'
,[SecurityUser].[UserName]
, DATEADD(minute, DATEDIFF(minute,GETUTCDATE(),GETDATE()), [Repository].[CreateDate]) as 'Local Start Time'
, DATEADD(minute, DATEDIFF(minute,GETUTCDATE(),GETDATE()), [Repository].[ModifyDate]) as 'Local Finish Time'
--,[Repository].[CreateDate] as 'UTC Start Time'
--,[Repository].[ModifyDate] as 'UTC Finish Time'
,convert (nvarchar, ([Repository].[ModifyDate] - [Repository].[CreateDate]), 108) as 'Approx. Duration'
from [Reporting].[Repository] with (nolock)
join [Reporting].[SecurityUser] with (nolock) on [Reporting].[Repository].[CreateBy] = [Reporting].[SecurityUser].UserID
join [Reporting].[ReportRepositoryLink] with (nolock) on [Reporting].[Repository].[ID] = [Reporting].[ReportRepositoryLink].[RepositoryID]
join [Reporting].[ReportDesign] with (nolock) on [Reporting].[ReportRepositoryLink].[ReportID] = [Reporting].[ReportDesign].[ReportID]
join [Reporting].[ReportCompany] with (nolock) on [Reporting].[ReportCompany].[ReportID] = [Reporting].[ReportDesign].[ReportID]
join [Reporting].[Report] on [Report].[ID] = [Reporting].[ReportRepositoryLink].ReportID
where [Reporting].[Repository].[StatusType] in (0)
--and [Reporting].[ReportDesign].[ReportDesignName] like '%Report Definition name%'
order by [Reporting].[ReportDesign].[ReportDesignName], [Reporting].[Repository].[CreateDate] desc