• 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

How to select the most recent date from multiple data for the same ID|Power Query|Excel Forum|My Online Training Hub

You are here: Home / How to select the most recent date from multiple data for the same ID|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 QueryHow to select the most recent date …
sp_PrintTopic sp_TopicIcon
How to select the most recent date from multiple data for the same ID
Avatar
David Hutchinson
Member
Members

Power Query

Xtreme Pivot Tables
Level 0
Forum Posts: 17
Member Since:
July 20, 2016
sp_UserOfflineSmall Offline
1
August 6, 2022 - 4:05 pm
sp_Permalink sp_Print

Good Day

Please can you assist.

We have data which is downloaded from a company server and on a regular basis and we need to extract the rows of data which have the most recent dates – I don’t need the preceding dates. This is the main source of data but there are three other smaller reports that are linked to the main data – these I will merge with the main data.

I am using MS Office 365 and I have some knowledge of Power Query but not an expert. I have tried using grouping but without success – I think that this is the route to go.

Attached is the sample data for your reference.

  1. I have removed customer information.
  2. “Date job closed” is where I need the most recent date for a “vehicle license plate No.”
  3. The “job number” is for a service or repair on a particular date.

I would appreciate your support to come up with a solution. I am open to other solutions that can be done in Excel.

Thanks very much for your help.

Avatar
Alan Sidman
Steamboat Springs, CO
Member
Members


Trusted Members
Level 0
Forum Posts: 132
Member Since:
October 18, 2018
sp_UserOfflineSmall Offline
2
August 6, 2022 - 10:04 pm
sp_Permalink sp_Print sp_EditHistory

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Grouped Rows" = Table.Group(Source, {"License plate no"}, {{"Latest Closed Date", each List.Max([Date job closed]), type nullable datetime}}),
#"Changed Type" = Table.TransformColumnTypes(#"Grouped Rows",{{"Latest Closed Date", type date}})
in
#"Changed Type"

 

If you then need all the data from the particular rows, then self join the original table to this query.  Join on the License plate no and the Date job closed to get only that data for those license plates with the latest date.

Avatar
David Hutchinson
Member
Members

Power Query

Xtreme Pivot Tables
Level 0
Forum Posts: 17
Member Since:
July 20, 2016
sp_UserOfflineSmall Offline
3
August 7, 2022 - 4:48 am
sp_Permalink sp_Print

Hi Alan

Thanks for your quick response.

Would you be able to select the whole row for each of the latest dates? I will use some of the other information in the row to build a report.

If it is ok with you would you mind explain how you did it?

I appreciate your help 

Avatar
Alan Sidman
Steamboat Springs, CO
Member
Members


Trusted Members
Level 0
Forum Posts: 132
Member Since:
October 18, 2018
sp_UserOfflineSmall Offline
4
August 7, 2022 - 10:53 am
sp_Permalink sp_Print sp_EditHistory

1.  With Power Query or Get and Transform Data depending on what version of excel you have, load your data to the PQ editor.

2.  Group your query on the License Tag and select Max Date for the Closed Date.

3.  in PQ, copy your original query and remove all steps except the Source.

4.  Join the two queries on the common fields of the two queries.

 

Power Query is a free AddIn for Excel 2010 and 2013, and is built-in functionality from Excel 2016 onwards (where it is referred to as "Get & Transform Data").

It is a powerful yet simple way of getting, changing and using data from a broad variety of sources, creating steps which may be easily repeated and refreshed. I strongly recommend learning how to use Power Query - it's among the most powerful functionalities of Excel.

- Follow this link to learn how to install Power Query in Excel 2010 / 2013.

- Follow this link for an introduction to Power Query functionality.

- Follow this link for a video which demonstrates how to use Power Query code provided.

 

File is to large to attach.  Here is the second Mcode.

 

let
Source = Table.NestedJoin(Table1, {"License plate no", "Latest Closed Date"}, Table2, {"License plate no", "Date job closed"}, "Table2", JoinKind.LeftOuter),
#"Expanded Table2" = Table.ExpandTableColumn(Source, "Table2", {"Job number", "Order type", "Plant", "Service advisor", "Service advisor name", "Service advisor surname", "Date job opened", "Order reason", "Order reason description", "Customer account number", "Customer name", "Column2", "Column3", "Job closed status", "Distribution Ch", "VIN", "LV Main type", "Sales office", "Milage", "Column1"}, {"Table2.Job number", "Table2.Order type", "Table2.Plant", "Table2.Service advisor", "Table2.Service advisor name", "Table2.Service advisor surname", "Table2.Date job opened", "Table2.Order reason", "Table2.Order reason description", "Table2.Customer account number", "Table2.Customer name", "Table2.Column2", "Table2.Column3", "Table2.Job closed status", "Table2.Distribution Ch", "Table2.VIN", "Table2.LV Main type", "Table2.Sales office", "Table2.Milage", "Table2.Column1"})
in
#"Expanded Table2"

Avatar
David Hutchinson
Member
Members

Power Query

Xtreme Pivot Tables
Level 0
Forum Posts: 17
Member Since:
July 20, 2016
sp_UserOfflineSmall Offline
5
August 7, 2022 - 9:56 pm
sp_Permalink sp_Print

Hi Alan

Thanks very much for your support and I will check out the links you sent to me.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Shanna Henseler, Lawrence Smith
Guest(s) 10
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:
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Uwe von Gostomski
Jonathan Jones
drsven
Forum Stats:
Groups: 3
Forums: 24
Topics: 6212
Posts: 27236

 

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