cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
ChandanJha25
New Member

Refresh Failure Alert for Multiple Dashboards

Hello Team,

 

I took charge of a BI engineering function having around 400 dashboards. I noted that for the scheduled refresh failures, the emails were going to the individual folks causing lot of bottlenecks in terms of operations.

 

Instead of adding the email group(security enabled email group), is there a way to put this across all dashboards in one go. It will save the team their previous time and will also get an edge in creating a utlity to be used in future. 

 

Thanks in advance!!

Chandan Jha

1 ACCEPTED SOLUTION
v-luwang-msft
Community Support
Community Support

Hi @ChandanJha25 ,

If you use this query  (connected to your PBI report server) in an SSRS report and schedule the SSRS to email out the failures:

WITH cte_LastRefresh AS
(

SELECT 
       MAX(SubscriptionHistoryID) AS SubscriptionHistoryID
       ,SubscriptionID
FROM dbo.SubscriptionHistory 
WHERE [Status] = 2
GROUP BY SubscriptionID

) 

SELECT 
          c.Name                                      as [Report Name]
      --rs.scheduleid
      ,c.path                                  as [Report Path]  
      ,sub.[Description]                 as [Schedule Name]
      --,sub.[LastStatus]                      as [Last Status]
         ,SUBSTRING(sh.Details,CHARINDEX('Message":"',sh.Details)+10,200)+ '...' AS [Error Detail]
      --CASE WHEN sub.[InactiveFlags] = 0 THEN 'Enabled'
             --     WHEN sub.[InactiveFlags] = 128 THEN 'Disabled'
             --     ELSE 'Other' 
             --END  as [Enabled]
      --,sub.[EventType]                       as "Event Type"
      ,CONVERT(Varchar(17),sub.[LastRunTime],113) as [Last Run Time]
         ,SUBSTRING(u_own.UserName,CHARINDEX('\',u_own.UserName)+1,10) as [Created by]
         ,SUBSTRING(u_mod.[UserName],CHARINDEX('\',u_mod.[UserName])+1,10) as [Modified by]
         ,CASE WHEN jsch.next_run_date = 0 THEN '-'
               ELSE Convert(Varchar(17),msdb.dbo.agent_datetime(jsch.next_run_date, jsch.next_run_time),113) 
             END as [Next Run Time]
        --,CASE c.[Type] WHEN 2 THEN 'SSRS'
             --                  WHEN 5 THEN 'Data Source'
             --                  WHEN 7 THEN 'Report Part'
             --                  WHEN 8 THEN 'Shared Dataset'
             --                  When 13 Then 'Power BI'
             --                  ELSE 'Other'
             -- END AS "ReportType"
             ,sub.LastStatus
  FROM [dbo].[Subscriptions] sub
       INNER JOIN dbo.[Catalog] c ON sub.report_oid = c.itemid
       INNER JOIN [dbo].Users u_own ON c.CreatedByID = u_own.UserID
       INNER JOIN [dbo].Users u_mod ON c.ModifiedByID = u_mod.UserID
       INNER JOIN dbo.ReportSchedule rs ON sub.SubscriptionID = rs.SubscriptionID
       INNER JOIN cte_LastRefresh lr ON rs.SubscriptionID = lr.SubscriptionID
       INNER JOIN dbo.SubscriptionHistory sh ON lr.SubscriptionHistoryID = sh.SubscriptionHistoryID
       LEFT OUTER JOIN msdb.dbo.sysjobs j ON CAST(rs.ScheduleID AS VARCHAR(100)) = j.name
       LEFT OUTER JOIN msdb.dbo.sysjobschedules jsch ON j.job_id = jsch.job_id
WHERE 1=1
       AND sub.LastStatus like '%failed%'
       AND jsch.next_run_date <> 0
       AND Convert(smalldatetime,msdb.dbo.agent_datetime(jsch.next_run_date, jsch.next_run_time)) > getdate() 
order by 2

 To learn more details ,refer:

https://community.powerbi.com/t5/Report-Server/Being-alerted-to-scheduled-refresh-failures/m-p/23119... 

 

 

Best Regards

Lucien

View solution in original post

2 REPLIES 2
v-luwang-msft
Community Support
Community Support

Hi @ChandanJha25 ,

Has your problem been solved, if so, please consider Accept a correct reply as the solution or share your own solution to help others find it.

Best Regards
Lucien

v-luwang-msft
Community Support
Community Support

Hi @ChandanJha25 ,

If you use this query  (connected to your PBI report server) in an SSRS report and schedule the SSRS to email out the failures:

WITH cte_LastRefresh AS
(

SELECT 
       MAX(SubscriptionHistoryID) AS SubscriptionHistoryID
       ,SubscriptionID
FROM dbo.SubscriptionHistory 
WHERE [Status] = 2
GROUP BY SubscriptionID

) 

SELECT 
          c.Name                                      as [Report Name]
      --rs.scheduleid
      ,c.path                                  as [Report Path]  
      ,sub.[Description]                 as [Schedule Name]
      --,sub.[LastStatus]                      as [Last Status]
         ,SUBSTRING(sh.Details,CHARINDEX('Message":"',sh.Details)+10,200)+ '...' AS [Error Detail]
      --CASE WHEN sub.[InactiveFlags] = 0 THEN 'Enabled'
             --     WHEN sub.[InactiveFlags] = 128 THEN 'Disabled'
             --     ELSE 'Other' 
             --END  as [Enabled]
      --,sub.[EventType]                       as "Event Type"
      ,CONVERT(Varchar(17),sub.[LastRunTime],113) as [Last Run Time]
         ,SUBSTRING(u_own.UserName,CHARINDEX('\',u_own.UserName)+1,10) as [Created by]
         ,SUBSTRING(u_mod.[UserName],CHARINDEX('\',u_mod.[UserName])+1,10) as [Modified by]
         ,CASE WHEN jsch.next_run_date = 0 THEN '-'
               ELSE Convert(Varchar(17),msdb.dbo.agent_datetime(jsch.next_run_date, jsch.next_run_time),113) 
             END as [Next Run Time]
        --,CASE c.[Type] WHEN 2 THEN 'SSRS'
             --                  WHEN 5 THEN 'Data Source'
             --                  WHEN 7 THEN 'Report Part'
             --                  WHEN 8 THEN 'Shared Dataset'
             --                  When 13 Then 'Power BI'
             --                  ELSE 'Other'
             -- END AS "ReportType"
             ,sub.LastStatus
  FROM [dbo].[Subscriptions] sub
       INNER JOIN dbo.[Catalog] c ON sub.report_oid = c.itemid
       INNER JOIN [dbo].Users u_own ON c.CreatedByID = u_own.UserID
       INNER JOIN [dbo].Users u_mod ON c.ModifiedByID = u_mod.UserID
       INNER JOIN dbo.ReportSchedule rs ON sub.SubscriptionID = rs.SubscriptionID
       INNER JOIN cte_LastRefresh lr ON rs.SubscriptionID = lr.SubscriptionID
       INNER JOIN dbo.SubscriptionHistory sh ON lr.SubscriptionHistoryID = sh.SubscriptionHistoryID
       LEFT OUTER JOIN msdb.dbo.sysjobs j ON CAST(rs.ScheduleID AS VARCHAR(100)) = j.name
       LEFT OUTER JOIN msdb.dbo.sysjobschedules jsch ON j.job_id = jsch.job_id
WHERE 1=1
       AND sub.LastStatus like '%failed%'
       AND jsch.next_run_date <> 0
       AND Convert(smalldatetime,msdb.dbo.agent_datetime(jsch.next_run_date, jsch.next_run_time)) > getdate() 
order by 2

 To learn more details ,refer:

https://community.powerbi.com/t5/Report-Server/Being-alerted-to-scheduled-refresh-failures/m-p/23119... 

 

 

Best Regards

Lucien

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

Thank you 2022 Review

2022 Monthly Feature Releases

We had a great 2022 with a ton of feature releases to help you drive a data culture.