Active Member
August 11, 2016
Given a query with multiple steps, one could have "errors" creep in anywhere in the sequence of steps. These might be errors related to bad file names or paths, calling a SQL stored procedure with an incorrect name, incorrect column names (for example expecting Cost Center but getting CostCenter), etc. When one creates an Excel application, it would be preferable to notify the user that an error has crept into the underlying query, and direct him to open the Power Query pane and research the problem. I try and create apps that are user friendly as possible, giving the user parameter tables and VBA command buttons to Refresh the queries, along with a message box and a timer so they know how long the process took to complete. The message box fires even when there are underlying errors, and the user remains blissfully ignorant of the fact there may be a problem.
I'm not looking to report the exact error to the user, just report that an error exists somewhere in the sequence of steps and to direct him or her to open the Power Query pane and do some research. Any ideas?
July 16, 2010
Hi Kirk,
I'm not aware of any way to detect errors in Power Query that don't prevent the query loading. i.e. you can have row level errors that simply don't load the data for those rows, but the rest of the data will load. As opposed to errors that prevent the whole query loading, which would be easy to detect.
You would need to build some form of audit into your model that checks that the number of rows loaded, matches the number of rows you expect to see. You could do this with a basic query that returns a row count and compare that to the number of rows in your actual query output.
Hope that gives you some ideas.
Mynda
Active Member
August 11, 2016
I was able to find a solution. I'll include it here in the hope that it's helpful to someone else. The solution was found here https://blog.crossjoin.co.uk/2.....wer-query/
In my M code, I created a query with a reference to another query, in this case my referenced query was called Workday. The Workday query contains multiple steps, any of which might throw an error. The error trapping code detects any error in the Source step, and creates a table of alternative output with a single row filled with the text "Process error". If there are no errors, then the table is filled with good data. I have VBA code that detects the presence of "Process error" in the table, and if it exists fires a message box to direct the user to open the Power Query pane and investigate.
let
Source = Workday,
//Define the alternative table to return in case of data source error
AlternativeOutput=#table(type table [#"Employee ID"=text,#"First Name"=text,#"Last Name"=text,#"Worker Type"=text,
#"Job Family Group"=text,#"Company - ID"=text,#"Company - Name"=text,#"Cost Center - ID"=text,SnapshotDate=text,RefreshDate=datetime],
{{"Process error", "Process error", "Process error", "Process error", "Process error",
"Process error", "Process error", "Process error", "Process error", DateTime.LocalNow()}}),
//Does the Source step return an error?
TestForError= try Source,
//If Source returns an error then return the alternative table output else return the value of the previous step
Output = if TestForError[HasError] then AlternativeOutput else Source
in
Output
1 Guest(s)