Hi @Mark ,
after I change the embedded queries
I'm sorry i don't understand what you mean.
You could obtain the data source name corresponding to the report in the specified database through the following TSQL query:
USE [ReportServer]
GO
SELECT CATALOG.NAME
,CATALOG.[Path]
,DataSource.NAME datasource
,CATALOG.[Description]
,Created.UserName AS CreatedByUser
,CATALOG.[CreationDate]
,Modified.UserName AS ModifiedByUser
,CATALOG.[ModifiedDate]
FROM [dbo].[Catalog]
LEFT JOIN (
SELECT [UserID]
,[UserName]
FROM [dbo].[Users]
) AS Created ON CATALOG.CreatedByID = Created.UserID
LEFT JOIN (
SELECT [UserID]
,[UserName]
FROM [dbo].[Users]
) AS Modified ON CATALOG.ModifiedByID = Modified.UserID
JOIN DataSource ON CATALOG.ItemID = DataSource.ItemID
JOIN CATALOG cat1 ON DataSource.Link = cat1.ItemID
WHERE CATALOG.[Type] = 2
ORDER BY [Path]
,NAME
Output:
-- Connection strings of all SSRS Shared Datasources
;WITH XMLNAMESPACES -- XML namespace def must be the first in with clause.
(DEFAULT 'http://schemas.microsoft.com/sqlserver/reporting/2006/03/reportdatasource'
,'http://schemas.microsoft.com/SQLServer/reporting/reportdesigner'
AS rd)
,SDS AS
(SELECT SDS.name AS SharedDsName
,SDS.[Path]
,CONVERT(xml, CONVERT(varbinary(max), content)) AS DEF
FROM dbo.[Catalog] AS SDS
WHERE SDS.Type = 5) -- 5 = Shared Datasource
SELECT CON.[Path]
,CON.SharedDsName
,CON.ConnString
FROM
(SELECT SDS.[Path]
,SDS.SharedDsName
,DSN.value('ConnectString[1]', 'varchar(150)') AS ConnString
FROM SDS
CROSS APPLY
SDS.DEF.nodes('/DataSourceDefinition') AS R(DSN)
) AS CON
-- Optional filter:
-- WHERE CON.ConnString LIKE '%Initial Catalog%=%TFS%'
ORDER BY CON.[Path]
,CON.SharedDsName;
Best Regards,
Joy
If the answer is helpful, please click "Accept Answer" and upvote it.
Note: Please follow the steps in our documentation to enable e-mail notifications if you want to receive the related email notification for this thread.