Skip to main content

Notifications

Announcements

No record found.

Community site session details

Community site session details

Session Id :
Finance | Project Operations, Human Resources, ...
Answered

Report Tracking in MR

(0) ShareShare
ReportReport
Posted on by 466

Is there any tracking feature or table that captures report activity in MR.  I'm  just looking for something that can be used to identify reports that are being actively used.  The client would like to do some cleanup and has a fair amount of old reports that have built up over the years.  Please advise.  Thank you.

JG

Categories:
  • Suggested answer
    JGarcia123 Profile Picture
    JGarcia123 466 on at
    RE: Report Tracking in MR

    Thank you Greg!  This is exactly what we were looking for.  Appreciate the feedback.  

  • Suggested answer
    Lisa at AonC.com Profile Picture
    Lisa at AonC.com 604 on at
    RE: Report Tracking in MR

    While MR doesn't exactly track what you are looking for, what I recommend to our clients is if they think they aren't using a report, move it to an "Archive", "Unused", "ToDelete" or similar folder.  (Alternatively they can rename it, for example put a "z" in front of the name so that it drops to the bottom of the list.)  Instruct users if they find they need one of those reports, to move it back to the proper location.

    Your user may want to do a similar clean-up of the building blocks to determine if they are obsolete.  (Renaming those often work better than the folder approach with Reports.)

    The Associations menu option is a fabulous tool for keeping track of where a specific building block is used.

  • Verified answer
    Greg Byer Profile Picture
    Greg Byer 2,586 on at
    RE: Report Tracking in MR

    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

  • Suggested answer
    Beat Bucher  GP Geek  GPUG All Star Profile Picture
    Beat Bucher GP Gee... 28,058 Moderator on at
    RE: Report Tracking in MR

    Hi,

    There isn't anything like this and you would have to build your own SQL queries..

    That being said, the MR Viewer Client keeps a time stamp for each reports when they are created (not consumed) by the MR Designer or on schedule..

    The table that holds all the reports in the MR database could be your starting point:

    SELECT *   FROM [ManagementReporter].[Reporting].[ControlReport]

    Unfortunately nothing in the MR tables is easy to decipher as all the various tables are linked by UID's which have a different meaning as they refer to either a report ID, a user ID or a company ID, etc..

    It is going to take you some digging to figure out the relationship between the tables as there is no official documentation about the structure.

    PS: if you do some research on the forums threads in under the GP topic, you'll find some older post which might contain some SQL scripts related to MR DB clean-up which you could use

Under review

Thank you for your reply! To ensure a great experience for everyone, your content is awaiting approval by our Community Managers. Please check back later.

Helpful resources

Quick Links

Daivat Vartak – Community Spotlight

We are honored to recognize Daivat Vartak as our March 2025 Community…

Announcing Our 2025 Season 1 Super Users!

A new season of Super Users has arrived, and we are so grateful for the daily…

Kudos to the February Top 10 Community Stars!

Thanks for all your good work in the Community!

Leaderboard

#1
André Arnaud de Calavon Profile Picture

André Arnaud de Cal... 292,516 Super User 2025 Season 1

#2
Martin Dráb Profile Picture

Martin Dráb 231,407 Most Valuable Professional

#3
nmaenpaa Profile Picture

nmaenpaa 101,156

Leaderboard

Product updates

Dynamics 365 release plans