Home > Link, Microsoft SQL Server, MSBI, Optimization, Query, Script, SQL Mentalist, SQL PraRup, SQL Query, SQL Server, Technology,, TSQL, Vishal Pawar > BI SQL # 176 : SQL Server DBA Scripts : List for all SSRS reports that use data sources and datasets with the command text

BI SQL # 176 : SQL Server DBA Scripts : List for all SSRS reports that use data sources and datasets with the command text

Hi Folks,

In this article we are going to cover How to List for all SSRS reports that use data sources and datasets with the command text.

In this post we are going to discuss following points:

  • Problem Statement of SQL Script:
  • Description of SQL Script:
  • Input Parameter of SQL Script
  • SQL Script Code
  • SQL Script Output Screenshot
  • User Level to execute

Problem Statement of SQL Script:

How to find list for all SSRS reports that use datasources and datasets with the command text?

Description of SQL Script:

This Transact-SQL script list for all SSRS reports the used datasources and datasets with the command text.

Input Parameter of SQL Script

Directly execute the script on Report Server Database.

SQL Script Code

WITH XMLNAMESPACES (
    DEFAULT 
    'http://schemas.microsoft.com/sqlserver/reporting/2008/01/reportdefinition'
    ,
    'http://schemas.microsoft.com/sqlserver/reporting/reportdesigner' 
    AS rd
    )
    ,DEF
AS (
    SELECT RPT.ReportPath
        ,R.RptNode.value('(./Query/DataSourceName)[1]', 
            'nvarchar(425)') AS DataSourceName
        ,R.RptNode.value('@Name[1]', 'nvarchar(425)') AS 
        DataSetName
        ,REPLACE(REPLACE(LTRIM((
                        R.RptNode.value(
                            '(./Query/CommandText)[1]', 
                            'nvarchar(4000)')
                        )), '&gt;', '>'), '&lt;', '<') AS 
        CommandText
    FROM (
        SELECT RPT.Path AS ReportPath
            ,RPT.NAME AS ReportName
            ,CONVERT(XML, CONVERT(VARBINARY(max), RPT.content)
            ) AS contentXML
        FROM ReportServer.dbo.[Catalog] AS RPT
        WHERE RPT.Type = 2 -- 2 = Reports 
        ) AS RPT
    CROSS APPLY RPT.contentXML.nodes(
            '/Report/DataSets/DataSet') AS R(RptNode)
    )
SELECT DEF.ReportPath
    ,DEF.DataSourceName
    ,DEF.DataSetName
    ,DEF.CommandText
FROM DEF
-- Optional filter: 
-- WHERE DEF.CommandText LIKE '%/[Team System/]%' -- MDX query against TFS cube 
ORDER BY DEF.ReportPath
    ,DEF.DataSourceName
    ,DEF.DataSetName

SQL Script Output Screenshot

image

User Level to execute

300

    Hope you will like How to List for all SSRS reports that use data sources and datasets with the command text.

    If you really like reading my blog and understood at least few thing then please don’t forget to subscribe my blog.

If you want daily link and analysis or interesting link go to following website which will give @ your inbox please subscribe our following link resource blog :

Link Resource Website

For More information related to BI World visit my Mentalist Blog

SQL Server Mentalist >> SQL Learning Blog

Business Intelligence Mentalist >> BI World

Infographic Mentalist >> Image worth explaining thousand Words

Microsoft Mentalist >> MVC,ASP.NET, WCF & LinQ

DBA Mentalist >>Advance SQL Server Blog

Microsoft BI Mentalist >> MS BI Development Update

Connect With me on

| FaceBook |Twitter | linkedIn| Google+ | WordPress | RSS |

Advertisement
  1. No comments yet.
  1. No trackbacks yet.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

%d bloggers like this: