Download all Report Server RDL’s

Download all Report Server RDL’s

Thanks kindly to Vinay: http://bit.ly/1mfZY5n

There is no option to download all RDL’s at once from Report Server. This handy script will at least collect them all and dump them into a folder of your choosing. It won’t place them into relevant folders but if you’re like me, merely having the ability to quickly obtain the hundred or more RDL’s is a massive time saver.

Essentially SSRS stores its reports in binary form within ReportServer database – Catalog table. Using BCP we can dump the contents into a folder.

Note: xp_cmdshell is required and is likely disabled by default, your organization should have policies around its use. Please be sure to work with your DBA.

-- Allow advanced options to be changed.
EXEC sp_configure 'show advanced options', 1
GO
 
-- Update the currently configured value for advanced options.
RECONFIGURE
GO
 
-- Enable xp_cmdshell
EXEC sp_configure 'xp_cmdshell', 1
GO
 
-- Update the currently configured value for xp_cmdshell
RECONFIGURE
GO
 
-- Disallow further advanced options to be changed.
EXEC sp_configure 'show advanced options', 0
GO
 
-- Update the currently configured value for advanced options.
RECONFIGURE
GO

Now run the following, having configured the @OutputPath variable and changing the [ReportServer] database name if it is named something else.

--Replace NULL with keywords of the ReportManager's Report Path, 
--if reports from any specific path are to be downloaded
DECLARE @FilterReportPath AS VARCHAR(500) = NULL 
 
--Replace NULL with the keyword matching the Report File Name,
--if any specific reports are to be downloaded
DECLARE @FilterReportName AS VARCHAR(500) = NULL
 
--Replace this path with the Server Location where you want the
--reports to be downloaded..
DECLARE @OutputPath AS VARCHAR(500) = 'C:\export\'
 
--Used to prepare the dynamic query
DECLARE @TSQL AS NVARCHAR(MAX)
 
--Reset the OutputPath separator.
SET @OutputPath = REPLACE(@OutputPath,'\','/')
 
--Simple validation of OutputPath; this can be changed as per ones need.
IF LTRIM(RTRIM(ISNULL(@OutputPath,''))) = ''
BEGIN
  SELECT 'Invalid Output Path'
END
ELSE
BEGIN
   --Prepare the query for download.
   /*
   Please note the following points -
   1. The BCP command could be modified as per ones need. E.g. Providing UserName/Password, etc.
   2. Please update the SSRS Report Database name. Currently, it is set to default - [ReportServer]
   3. The BCP does not create missing Directories. So, additional logic could be implemented to handle that.
   4. SSRS stores the XML items (Report RDL and Data Source definitions) using the UTF-8 encoding. 
      It just so happens that UTF-8 Unicode strings do not NEED to have a BOM and in fact ideally would not have one. 
      However, you will see some report items in your SSRS that begin with a specific sequence of bytes (0xEFBBBF). 
      That sequence is the UTF-8 Byte Order Mark. Itโ€™s character representation is the following three characters, โ€œรฏยปยฟโ€. 
      While it is supported, it can cause problems with the conversion to XML, so it is removed.
   */
   SET @TSQL = STUFF((SELECT
	';EXEC master..xp_cmdshell ''bcp " ' +
	' SELECT ' +
	' CONVERT(VARCHAR(MAX), ' +
	'       CASE ' +
	'         WHEN LEFT(C.Content,3) = 0xEFBBBF THEN STUFF(C.Content,1,3,'''''''') '+
	'         ELSE C.Content '+
	'       END) ' +
	' FROM ' +
	' [ReportServer].[dbo].[Catalog] CL ' +
	' CROSS APPLY (SELECT CONVERT(VARBINARY(MAX),CL.Content) Content) C ' +
	' WHERE ' +
	' CL.ItemID = ''''' + CONVERT(VARCHAR(MAX), CL.ItemID) + ''''' " queryout "' + @OutputPath + '' + CL.Name + '.rdl" ' + '-T -c -x'''
  FROM [ReportServer].[dbo].[Catalog] CL
  WHERE CL.[Type] = 2 --Report
	AND '/' + CL.[Path] + '/' LIKE COALESCE('%/%' + @FilterReportPath + '%/%', '/' + CL.[Path] + '/')
	AND CL.Name LIKE COALESCE('%' + @FilterReportName + '%', CL.Name)
  FOR XML PATH('')), 1,1,'')
  
  --SELECT @TSQL
  
  --Execute the Dynamic Query
  EXEC SP_EXECUTESQL @TSQL
END

The script does provide the ability to download reports matching a keyword, so you could get creative and download specific reports to folders of your choosing. If your catalog is well organized.

Enjoy, I did!

Mike250

Australian. Sport. Passionate Cricket Fan. Go Pro. Abseiling. Snorkeling. Travel. Golf R. SQL Server Developer. Three sons. One daughter. Last Trip: New York.

Related Posts
Leave a comment

Your email address will not be published. Required fields are marked *