• 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

vlookup query very slow|Power Query|Excel Forum|My Online Training Hub

You are here: Home / vlookup query very slow|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search
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 Queryvlookup query very slow
sp_PrintTopic sp_TopicIcon
vlookup query very slow
Avatar
Yuan Zhang
Member
Members
Level 0
Forum Posts: 26
Member Since:
December 2, 2021
sp_UserOfflineSmall Offline
1
December 2, 2021 - 9:07 am
sp_Permalink sp_Print

Dear,

I watched your video VLOOKUP in Power Query Using List Functions. The lookup for my standard variance analysis (current version vs last, or current version vs beginning of quarter etc.) works fine but when I tried to use it in my 'ad hoc' analysis model where end users can define which ad hoc periods to analyze), it is extremely slow to load data.
 
Please find enclosed sample data. I only included a few columns to show what I want to achieve.
 
So basically no PO number is filled in for earlier forecast versions (column Status). PO is linked in the current forecast version. What I want to achieve is, for the forecasts with the same ID number, PO number will be picked up for older versions also. The lookup for my standard variance analysis works fine.
 
But when I want to make variance analysis for my ad hoc versions: pick up PO number given in ad hoc version 1 (which is given in another file, and loaded in a query, in this file it is just given as a reference table) to ad hoc version 2 for the lines with same ID number. E.g. PO NR for FYForecast5F will be filled in as 2020-5383 (picked up from FY21Forecast11F same ID number 113.1)
 
Note: My query Adhoc1 only includes the ad hoc 1 period given in the reference table (FY21Forecast11F). My query Adhoc2 only includes the ad hoc 2 period given in the reference table (FY21Forecast5F). 
 
Before adding column 'PO Index' and 'PO number AdHoc1', the query is very fast. After adding the column  'PO Index' and 'PO number AdHoc1'  , the query becomes extremely slow...
 
Can you please kindly take a look at it and help?
 
Thank you so much!!!
Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
December 5, 2021 - 4:48 pm
sp_Permalink sp_Print sp_EditHistory

Hi Yuan,

Referring to items in a table by position is very slow, PQ was not built for cell references.

Instead, you should merge Adhoc2 with Adhoc1 using ID columns as merge keys then expand the Po NR column from the merge column.

Here is your adjusted query:

let
Source = Excel.CurrentWorkbook(){[Name="Input"]}[Content],
#"Filter Only include AdHocVersion2" = Table.SelectRows(Source, each List.Contains(AdHocVersion2,[Status]) = true),
#"Merged Queries" = Table.NestedJoin(#"Filter Only include AdHocVersion2", {"ID"}, AdHoc1, {"ID"}, "AdHoc1", JoinKind.LeftOuter),
#"Expanded AdHoc1" = Table.ExpandTableColumn(#"Merged Queries", "AdHoc1", {"PO NR"}, {"AdHoc1.PO NR"})
in
#"Expanded AdHoc1"
sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Shanna Getschel, andria young, Bruce Tang Nian
Guest(s) 10
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 871
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
Jessica Stewart: 205
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Bruce Tang Nian
Scot C
Othman AL MUTAIRI
Misael Gutierrez Sr.
Attif Ihsan
Kieran Fee
Murat Hasanoglu
Brett Dryland
Saeed Aldousari
Bhuwan Devkota
Forum Stats:
Groups: 3
Forums: 24
Topics: 6222
Posts: 27293

 

Member Stats:
Guest Posters: 49
Members: 31918
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.