• 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

Mynda's solution in 2012|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Mynda's solution in 2012|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 QueryMynda's solution in 2012
sp_PrintTopic sp_TopicIcon
Mynda's solution in 2012
Avatar
Cedric McKeever
Member
Members
Level 0
Forum Posts: 15
Member Since:
January 20, 2019
sp_UserOfflineSmall Offline
1
June 13, 2021 - 9:31 am
sp_Permalink sp_Print

Hi All,

As you see below, Mynda provided this solution in 2012 (Way to go Mynda).  Just wondering if in 2021 that this could be solved in Power Query.

January 12, 2012, by Mynda Treacy

Reference: https://www.myonlinetraininghu.....th-a-twist

The Challenge

Christy wanted to find the last value in a row for a specific part number using a table of data in Sheet1 like this:

Index Match FormulaImage Enlarger

Notice how some rows don’t have a value in every cell? This is what makes this challenge unique.

You see Christy wanted to find the value for say, part A10106, for the month of June, but if June didn’t have a value then find the value for the previous month, and if May didn’t have a value then go to the previous month and so on.

And it wasn’t just one part, it was over 2000 parts and for every month of the year.

Not being one to shy away from a challenge I persisted, and this is my formula.

The Solution

 

=IFERROR(INDEX(INDIRECT("Sheet1!"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)),MATCH(9.99999999999999E+307,INDIRECT("Sheet1!" &ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)))),0)

sp_AnswersTopicSeeAnswer See Answer
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4443
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
June 13, 2021 - 12:42 pm
sp_Permalink sp_Print

Hi Cedric,

Power Query can certainly give you a list of the last value for each part number, but it's not clear from your question as to whether you want to be able to easily switch which month's value you want to return. e.g. in my example I needed to find the value for June and if June didn't have a value, then the previous value. What did you have in mind?

Mynda

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1807
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
3
June 13, 2021 - 12:54 pm
sp_Permalink sp_Print

Should be easier in PQ.
There are also other ways to get that result with formulas: =LOOKUP(2, 1/OFFSET(Sheet1!B1,MATCH(A4,part_number,0),0,1,MATCH(B3,Sheet1!B1:M1,0)), OFFSET(Sheet1!B1,MATCH(A4,part_number,0),0,1,MATCH(B3,Sheet1!B1:M1,0)))

 

In PQ:
(x)=> try List.Last(List.RemoveNulls(List.FirstN(Record.ToList(x) ,Pos+1))) otherwise null

File attached.

sp_AnswersTopicAnswer
Answers Post
Avatar
Cedric McKeever
Member
Members
Level 0
Forum Posts: 15
Member Since:
January 20, 2019
sp_UserOfflineSmall Offline
4
June 14, 2021 - 12:59 am
sp_Permalink sp_Print

Hi,

I was just looking for a Power Query solution that accomplished what your formula accomplished.  But since you asked, could you switch which month value you wanted to be returned?

I have not had a chance to look at Catalin's solution yet.  Busy with some repairs around the homestead.

Thank you for your replies.

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4443
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
5
June 14, 2021 - 9:53 am
sp_Permalink sp_Print

Hi Cedric,

Check out Catalin's workbook as it allows you to choose both the part number and month.

Mynda

Avatar
Cedric McKeever
Member
Members
Level 0
Forum Posts: 15
Member Since:
January 20, 2019
sp_UserOfflineSmall Offline
6
June 14, 2021 - 10:23 am
sp_Permalink sp_Print

Hi,

I looked at Catalin's solution, and I'm impressed.  Both the formula and Power Query work for any part number and any month.  I noted the formula updates automatically, but the Power Query solution must be refreshed if you change part number or month.

I asked this question as a learning experience.  However, it is going to take me weeks to figure out that elegant formula.  But, it will give e something to do.

A couple questions on the Power Query solution.

= Table.AddColumn(#"Filtered Rows", "Result", (x)=> try List.Last(List.RemoveNulls(List.FirstN(Record.ToList(x) ,Pos+1))) otherwise null)

The “x” in (Record.ToList(x). Does it refer to the “Filtered Rows” table?

The “Pos+1.” I understand the “+1” part, because of the first column, but “Pos,” is that a keyword?  Also, “try” and “otherwise,” where do I find information on them?

I am sorry if these are stupid questions, but I’m old and I am just trying to keep my mind active.

Anyway,

Thanks In Advance, Cedric

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1807
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
7
June 14, 2021 - 1:55 pm
sp_Permalink sp_Print

Hi Cedric,

The x from (x)=> try List.Last(List.RemoveNulls(List.FirstN(Record.ToList(x) ,Pos+1))) otherwise null

represents the current row of the "#Filtered Rows" table (the formula will be applied to each row of the table)

Few things to keep in mind:

-A row from a table is a record

-A column from a table is a list

Because I am referring to the current row (x), I have to apply Record functions (first, I convert the record to list, then I apply list functions: FirstN, RemoveNulls, Last)

If look at the PQ steps, you will see:
Part
Month
Pos (short from Position), it simply calculates the position of the month "Jun" for example from the list of months (table headers), in order to remove subsequent months.

try-otherwise is just the PQ way of saying: IFERROR(formula, "")

You have to explore the PQ documentation, you will find there many examples for each function:
https://docs.microsoft.com/en-.....-reference

Avatar
Cedric McKeever
Member
Members
Level 0
Forum Posts: 15
Member Since:
January 20, 2019
sp_UserOfflineSmall Offline
8
June 15, 2021 - 1:16 am
sp_Permalink sp_Print

Hi,

Thank you for taking the time to answer my questions.  I should have picked up on the "Pos."

I am working on your formula and found an explanation of "LOOKUP" and finding the last position.  Quite complicated.  I am using the "Evaluate Formula" feature to try to figure how the "TRUE" - "FALSE" results line up.  Something else to keep my busy.  I am really impressed with your knowledge.

Have a great day,

Cedric

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Richard Benson-King, Janset Beyaz
Guest(s) 9
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:
wahab tunde
Cong Le Duc
Faisal Bashir
Ivica Cvetkovski
Blaine Cox
Shankar Srinivasan
riyepa fdgf
Hannah Cave
Len Matthews
Kristine Arthy
Forum Stats:
Groups: 3
Forums: 24
Topics: 6205
Posts: 27209

 

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