Yuan Zhang
Member
Members
Forum Posts: 32
Member Since:
December 2, 2021
December 2, 2021
Offline
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!!!
Catalin Bombea
Iasi, Romania
Member
Dashboards
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
Forum Posts: 1944
Member Since:
November 8, 2013
November 8, 2013
Offline
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"
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"
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online:
Guest(s) 6
Currently Browsing this Page:
1 Guest(s)
1 Guest(s)
Top Posters:
Catalin Bombea: 1944
SunnyKow: 1432
Anders Sehlstedt: 956
Purfleet: 415
Hans Hallebeek: 377
Frans Visser: 351
David_Ng: 318
lea cohen: 248
Jessica Stewart: 219
A.Maurizio: 216
Newest Members:
Waqas Arshad
Techia Braveboy
Charles Buchanan
Tiago Braga
Rehan Baig
Fred HORVATH
Silke Schmidt
Stuart Barr
Amelia Nolte
David Wier
Forum Stats:
Groups: 3
Forums: 25
Topics: 7157
Posts: 31386
Member Stats:
Guest Posters: 50
Members: 34656
Moderators: 2
Admins: 3
Administrators: Mynda Treacy, Philip Treacy, Jessica
Moderators: Velouria, Riny van Eekelen
© Simple:Press —