- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Get latest record by ID
Hi, i am trying to get the last record by ID but it has to work with date filters, for example, i have the following table:
ID Date
A 1 Jan
A 10 Jan
B 29 Jan
B 16 Feb
A 1 Feb
B 20 Feb
So, if i filter the table by January it will show me only the A record with date 10 Jan and B record with date 29 Jan, and if i filter by February it will show A record with Date 1 Feb and B record with Date 20 Feb.
Is there a way to do this in a measure? because i searched for solutions but the majority of them just use a calculate column to get the max date but that doesn´t work in my case since i want to filter "dynamically".
Basically i need that whatever date filter is, show me the last record by ID in that date.
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

There are several ways to do this. See for example my post here from 2018:
https://stackoverflow.com/questions/52525377/return-top-value-ordered-by-another-column
I'd recommend using the INDEX function.
CALCULATE (
[Your Measure Here],
INDEX ( 1, ORDERBY ( Table1[Date] ), DESC ),
PARTITIONBY ( Table1[ID] )
)
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hi @Jabz
Here is my testing.
Date table:
Mesure:
Measure =
VAR _MaxDate = CALCULATE(MAX([Date]), FILTER(ALLEXCEPT('Table','Table'[ID]), MONTH([Date]) = MONTH(SELECTEDVALUE('Date'[Date]))))
RETURN
IF(MAX([Date]) = _MaxDate, 1, 0)
Put the measure into the filter so that the visual only shows data where the measure is equal to 1.
Filter with Date table
Is this the result you expect?
Best Regards,
Yulia Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hi @Jabz
Here is my testing.
Date table:
Mesure:
Measure =
VAR _MaxDate = CALCULATE(MAX([Date]), FILTER(ALLEXCEPT('Table','Table'[ID]), MONTH([Date]) = MONTH(SELECTEDVALUE('Date'[Date]))))
RETURN
IF(MAX([Date]) = _MaxDate, 1, 0)
Put the measure into the filter so that the visual only shows data where the measure is equal to 1.
Filter with Date table
Is this the result you expect?
Best Regards,
Yulia Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

There are several ways to do this. See for example my post here from 2018:
https://stackoverflow.com/questions/52525377/return-top-value-ordered-by-another-column
I'd recommend using the INDEX function.
CALCULATE (
[Your Measure Here],
INDEX ( 1, ORDERBY ( Table1[Date] ), DESC ),
PARTITIONBY ( Table1[ID] )
)

Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Power BI Monthly Update - February 2025
Check out the February 2025 Power BI update to learn about new features.

Subject | Author | Posted | |
---|---|---|---|
02-05-2025 07:30 AM | |||
07-07-2022 01:07 AM | |||
Anonymous
| 03-28-2018 09:11 AM | ||
09-22-2022 10:45 AM | |||
12-11-2024 06:08 AM |
User | Count |
---|---|
81 | |
78 | |
51 | |
38 | |
34 |
User | Count |
---|---|
92 | |
75 | |
53 | |
52 | |
45 |