Technical Article

Report Server Report Usage

,

We are in the process of migrating our BI server.

It is handy to know what is being used and what is not.

We will have to change many application config files to achive the migration. With this, we can track down all the reports that are still in use.

Because some of the reports are older than our current team, we are able to identify reports that need a little more attention.

Running this, I found serveral reports that maybe running on bad queries or possibly returning too much data.

2008 R2

Just run this against your ReportServer database.

-- Most commonly used reports
WITH Reps
AS 
( 
SELECT	ReportPath, CAST(MAX(TimeEnd) AS smalldatetime) LastRun, AVG(TimeDataRetrieval) AvgTimeDataRetrieval, AVG(TimeProcessing) AvgTimeProcessing, 
		AVG(TimeRendering) AvgTimeRendering, AVG(ByteCount) AvgBytes, AVG([RowCount]) AvgRows, COUNT(*) Runs,
		ROW_NUMBER() OVER (PARTITION BY ReportPath ORDER BY ReportPath) AS RowNumber
FROM	ExecutionLog2 
--WHERE	TimeEnd >= '2012-11-01'
GROUP BY ReportPath
) 
SELECT	ReportPath, LastRun, AvgTimeDataRetrieval, AvgTimeProcessing, AvgTimeRendering, AvgBytes, AvgRows, Runs
FROM	Reps 
ORDER BY Runs DESC;

--Slowest reports (Generalized)
WITH Reps
AS 
( 
SELECT	ReportPath, CAST(MAX(TimeEnd) AS smalldatetime) LastRun, AVG(TimeDataRetrieval) AvgTimeDataRetrieval, AVG(TimeProcessing) AvgTimeProcessing, 
		AVG(TimeRendering) AvgTimeRendering, AVG(ByteCount) AvgBytes, AVG([RowCount]) AvgRows, COUNT(*) Runs,
		ROW_NUMBER() OVER (PARTITION BY ReportPath ORDER BY ReportPath) AS RowNumber
FROM	ExecutionLog2 
GROUP BY ReportPath
) 
SELECT	ReportPath, LastRun, AvgTimeDataRetrieval, AvgTimeProcessing, AvgTimeRendering, AvgBytes, AvgRows, Runs,
		AvgTimeDataRetrieval + AvgTimeProcessing + AvgTimeRendering / AvgRows AS Slowness
FROM	Reps 
WHERE	AvgRows > 0
ORDER BY Slowness DESC

-- Top 5 users per report
WITH Reps
AS 
( 
SELECT	ReportPath, UserName, CAST(MAX(TimeEnd) AS smalldatetime) LastRun, AVG(TimeDataRetrieval) AvgTimeDataRetrieval, AVG(TimeProcessing) AvgTimeProcessing, 
		AVG(TimeRendering) AvgTimeRendering, AVG(ByteCount) AvgBytes, AVG([RowCount]) AvgRows, COUNT(*) Runs,
		ROW_NUMBER() OVER (PARTITION BY ReportPath ORDER BY ReportPath) AS RowNumber
FROM	ExecutionLog2 
GROUP BY ReportPath, UserName
) 
SELECT	ReportPath, UserName, LastRun, AvgTimeDataRetrieval, AvgTimeProcessing, AvgTimeRendering, AvgBytes, AvgRows, Runs
FROM	Reps 
WHERE	RowNumber <= 5
ORDER BY ReportPath, Runs DESC;

Rate

3.5 (4)

You rated this post out of 5. Change rating

Share

Share

Rate

3.5 (4)

You rated this post out of 5. Change rating