• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Error Trapping|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Error Trapping|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower QueryError Trapping
sp_PrintTopic sp_TopicIcon
Error Trapping
Avatar
Kirk Phillips

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
August 11, 2016
sp_UserOfflineSmall Offline
1
September 29, 2018 - 2:17 am
sp_Permalink sp_Print

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?

ScreenShot-1.PNGImage Enlarger

sp_PlupAttachments Attachments
  • sp_PlupImage ScreenShot.PNG (6 KB)
  • sp_PlupImage ScreenShot-1.PNG (6 KB)
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4447
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
October 3, 2018 - 7:00 pm
sp_Permalink sp_Print

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

Avatar
Kirk Phillips

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
August 11, 2016
sp_UserOfflineSmall Offline
3
October 4, 2018 - 6:03 am
sp_Permalink sp_Print

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

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Aislinn Mellamphy, Lynnette Altomari, Jessica Stewart, Roy Lutke, Jeff Krueger, Natasha Smith, Monique Roussouw
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Sopi Yuniarti
sandra parker
LAFONSO HERNANDEZ
Hayden Hao
Angela chen
Sean Moore
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Forum Stats:
Groups: 3
Forums: 24
Topics: 6214
Posts: 27243

 

Member Stats:
Guest Posters: 49
Members: 31894
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.