Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Sudipta33
Regular Visitor

Data Refresh Email

Hi,

How to set up configuration for power BI Report Server reports to receive emails whenever any data refresh schedule has failed. 

1 ACCEPTED SOLUTION
whereismydata
Resolver IV
Resolver IV

Hi @Sudipta33 ,

 

To achieve this I created a ssis package but it can be done using SQL Server Agent also.

 

For example you can start the refresh automatically after new data has been inserted in your data source. Then you can query the SubscriptionHistory table. From here you can define next steps, like send mail, log error, do something, retry etc...

 

Basically the scripts first gets the max value of the SubscriptionHistoryID, then executes the dashboard refresh, waits for the new entry to be made, then checks the status of the current refresh until it is finished.

 

If [Status] returns 0, then everything is fine, if [Status] returns 2, then there was an error.

 

I configured my package such, that if an error is returned the hole row is put into an html table and sent by mail

 

DECLARE @subscription_id_max INT
DECLARE @subscription_id UNIQUEIDENTIFIER

SET @subscription_id = ?

/* We need to save the max number of SubscriptionHistoryID for the given SubscriptionID */
SELECT @subscription_id_max = MAX(SubscriptionHistoryID)
FROM [pbiReportServer].[dbo].[SubscriptionHistory]
WHERE SubscriptionID = @subscription_id

/* update dashboard */
EXEC [pbiReportServer].dbo.AddEvent @EventType = 'DataModelRefresh'
	,@EventData = @subscription_id

/* Wait for the new entry  */
WHILE (
		SELECT COUNT(*)
		FROM [pbiReportServer].[dbo].[SubscriptionHistory]
		WHERE SubscriptionHistoryID > @subscription_id_max
			AND SubscriptionID = @subscription_id
		) = 0
BEGIN
	WAITFOR DELAY '00:00:02'
END

/* Get new max value */
SELECT @subscription_id_max = MAX(SubscriptionHistoryID)
FROM [pbiReportServer].[dbo].[SubscriptionHistory]
WHERE SubscriptionID = @subscription_id

/* Wait for refresh to be finished */
WHILE (
		SELECT [Status]
		FROM [pbiReportServer].[dbo].[SubscriptionHistory]
		WHERE SubscriptionHistoryID = @subscription_id_max
		) = 1
BEGIN
	WAITFOR DELAY '00:00:05'
END

/* Get details of the refresh */
SELECT SubscriptionHistoryID
	,c.Name
	,[StartTime]
	,[EndTime]
	,[Status]
	,[Message]
	,CASE 
		WHEN ISJSON([Details]) = 1
			THEN JSON_VALUE([Details], '$.Errors[0].Message')
		ELSE ''
		END AS [first_message]
	,[Details]
FROM [pbiReportServer].[dbo].[SubscriptionHistory] a
LEFT JOIN Subscriptions b ON b.SubscriptionID = a.SubscriptionID
LEFT JOIN [pbiReportServer].[dbo].[Catalog] c ON b.Report_OID = c.ItemID
WHERE a.SubscriptionID = @subscription_id
	AND a.SubscriptionHistoryID = @subscription_id_max

 

View solution in original post

2 REPLIES 2
whereismydata
Resolver IV
Resolver IV

Hi @Sudipta33 ,

 

To achieve this I created a ssis package but it can be done using SQL Server Agent also.

 

For example you can start the refresh automatically after new data has been inserted in your data source. Then you can query the SubscriptionHistory table. From here you can define next steps, like send mail, log error, do something, retry etc...

 

Basically the scripts first gets the max value of the SubscriptionHistoryID, then executes the dashboard refresh, waits for the new entry to be made, then checks the status of the current refresh until it is finished.

 

If [Status] returns 0, then everything is fine, if [Status] returns 2, then there was an error.

 

I configured my package such, that if an error is returned the hole row is put into an html table and sent by mail

 

DECLARE @subscription_id_max INT
DECLARE @subscription_id UNIQUEIDENTIFIER

SET @subscription_id = ?

/* We need to save the max number of SubscriptionHistoryID for the given SubscriptionID */
SELECT @subscription_id_max = MAX(SubscriptionHistoryID)
FROM [pbiReportServer].[dbo].[SubscriptionHistory]
WHERE SubscriptionID = @subscription_id

/* update dashboard */
EXEC [pbiReportServer].dbo.AddEvent @EventType = 'DataModelRefresh'
	,@EventData = @subscription_id

/* Wait for the new entry  */
WHILE (
		SELECT COUNT(*)
		FROM [pbiReportServer].[dbo].[SubscriptionHistory]
		WHERE SubscriptionHistoryID > @subscription_id_max
			AND SubscriptionID = @subscription_id
		) = 0
BEGIN
	WAITFOR DELAY '00:00:02'
END

/* Get new max value */
SELECT @subscription_id_max = MAX(SubscriptionHistoryID)
FROM [pbiReportServer].[dbo].[SubscriptionHistory]
WHERE SubscriptionID = @subscription_id

/* Wait for refresh to be finished */
WHILE (
		SELECT [Status]
		FROM [pbiReportServer].[dbo].[SubscriptionHistory]
		WHERE SubscriptionHistoryID = @subscription_id_max
		) = 1
BEGIN
	WAITFOR DELAY '00:00:05'
END

/* Get details of the refresh */
SELECT SubscriptionHistoryID
	,c.Name
	,[StartTime]
	,[EndTime]
	,[Status]
	,[Message]
	,CASE 
		WHEN ISJSON([Details]) = 1
			THEN JSON_VALUE([Details], '$.Errors[0].Message')
		ELSE ''
		END AS [first_message]
	,[Details]
FROM [pbiReportServer].[dbo].[SubscriptionHistory] a
LEFT JOIN Subscriptions b ON b.SubscriptionID = a.SubscriptionID
LEFT JOIN [pbiReportServer].[dbo].[Catalog] c ON b.Report_OID = c.ItemID
WHERE a.SubscriptionID = @subscription_id
	AND a.SubscriptionHistoryID = @subscription_id_max

 

v-xiaoyan-msft
Community Support
Community Support

Hi  @Sudipta33 , 

At the moment, it is not supported to setup email alert for scheduled refresh failure.

 

If you would like to suggest  feature improvements, you may  vote the idea and comment here  to improve this feature. It is a place for customers provide feedback about Microsoft Office products . What’s more, if a feedback is high voted there by other customers, it will be promising that Microsoft Product Team will take it into consideration when designing the next version in the future.

 

Best Regards,
Community Support Team _ Caitlyn

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.