Power Query 2016: return the latest date in a subset

SOQLee

Board Regular
Joined
Mar 18, 2015
Messages
58
Office Version
  1. 365
Platform
  1. Windows
I have tracking data that contains many dates for the same person. How can records be cleaned up so that it shows only the latest date for each person. Here is an example of the data:

[TABLE="width: 0"]
<tbody>[TR]
[TD]Date[/TD]
[TD]Personnel[/TD]
[TD]Sold[/TD]
[/TR]
[TR]
[TD]2017-11-11[/TD]
[TD]Bill[/TD]
[TD]87[/TD]
[/TR]
[TR]
[TD]2017-11-11[/TD]
[TD]Susan[/TD]
[TD]73[/TD]
[/TR]
[TR]
[TD]2017-11-11[/TD]
[TD]Susan[/TD]
[TD]-5[/TD]
[/TR]
[TR]
[TD]2017-11-09[/TD]
[TD]Alexis[/TD]
[TD]26[/TD]
[/TR]
[TR]
[TD]2017-11-12[/TD]
[TD]Alexis[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]2017-11-12[/TD]
[TD]Alexis[/TD]
[TD]75[/TD]
[/TR]
[TR]
[TD]2017-11-08[/TD]
[TD]Kate[/TD]
[TD]19[/TD]
[/TR]
[TR]
[TD]2017-11-07[/TD]
[TD]Bill[/TD]
[TD]33[/TD]
[/TR]
[TR]
[TD]2017-11-07[/TD]
[TD]Bill[/TD]
[TD]-15[/TD]
[/TR]
[TR]
[TD]2017-11-13[/TD]
[TD]Susan[/TD]
[TD]25[/TD]
[/TR]
[TR]
[TD]2017-11-14[/TD]
[TD]Kate[/TD]
[TD]82[/TD]
[/TR]
[TR]
[TD]2017-11-13[/TD]
[TD]Kate[/TD]
[TD]-7[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
1) I've assumed your data source is an Excel table in the current workbook called "Tracking".
2) I've assumed your columns are called "Date", "Personnel" and "Sold", as shown in your example.

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Tracking"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"Personnel"}, {{"All Rows", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Last Record", each Table.Max([All Rows], "Date")),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Last Date", each Record.Field([Last Record], "Date")),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Last Sales", each Record.Field([Last Record], "Sold")),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom2",{"Personnel", "Last Date", "Last Sales"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Removed Other Columns",{{"Personnel", type text}, {"Last Date", type date}, {"Last Sales", type number}})
in
    #"Changed Type"
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,184
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top