SQL Server Reporting Services (SSRS) showed up to the party in SQL Server 2000. A really awesome tool for data delivery. Most SQL Server environments heavily leverage this powerful tool. Microsoft has baked in some excellent views and tables for report rendering information (dbo.ExecutionLog, dbo.ExecutionLog2 and dbo.ExecutionLog3). SSRS also supplies a text log with additional details for errors and warnings. All are useful when trouble shooting a failure or identifying report execution trends, but what happens if you want to know what is running, now?
Recently, I needed to identify an active report that was creating a considerable amount of blocking. We were able to identify a reporting login , verify the blocking originated from SSRS. I could grab the query being executed, but needed to find the report and user or maybe subscription causing the blocking. As I mentioned, for the most part the ReportServer database gives us historical information. I always based most of my queries on the ReportServer database. In a brief moment of clarity, I realized that maybe just maybe this ReportServerTempDB database might just store ‘temporary’ data about active sessions. Welcome back to the show, Jack!
ReportingServerTempDB(default name) has a table dbo.SessionsData. I used it for report path, session owner and session creation time. I wanted to also include report name , user name and data source name. I did so by dipping back into the ReportServer database dbo.Catalog, dbo.DataSource and dbo.users. If the data source had a meaningful name, I could use it to further verify the report was indeed the one connected to the now seriously crippled SQL instance. Previously, we identified the start time of the lead blocker. I used it to look for a session that started just before that time. Need to allow for the time a user takes to enter parameters if required.
It is also a good script to remind that guy in accounting not to run the same report 5 times all at the same time. Favorite saying, ” a fool with a tool is still a fool”!
Blah, blah, blah. Enough said! Here is the script:
/*
SSRS Find Active Session Information
3/11/2014 JCD
Uses standard DB names [ReportServer] and [ReportServerTempDB]
Tested: SQL 2005, SQL 2008 R2 and SQL 2012
*/
SET NOCOUNT ON
GO
SELECT
CONVERT(VARCHAR(20),s.[CreationTime],22) [SessionStart]
,u.[UserName]
,c.[name] [Report]
,d.[name] [DataSource]
,s.[ReportPath]
,s.[EffectiveParams]
,DATEDIFF(minute,s.[CreationTime],GETDATE()) [RunningTimeMinutes]
FROM [ReportServerTempDB].[dbo].[SessionData] as s with (NOLOCK)
JOIN [ReportServer].[dbo].[Catalog] as c with(NOLOCK)
ON c.path= s.reportPath
JOIN [ReportServer].[dbo].[DataSource] as d with(NOLOCK)
ON c.ItemID = d.ItemID
JOIN [ReportServer].[dbo].[Users] as u with(NOLOCK)
on u.UserId = s.ownerID
ORDER BY s.[CreationTime];
GO
Tiny URL for this post:
Comments are closed.