Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends September 15. Request your voucher.

Reply
Anonymous
Not applicable

Trying to Find One Value Based on the Latest Date in Another Cell. Grouped By ID

I have one ID column with nonunique IDs.

 

I have another column with dates.

 

I have a third column that has a 0 or 1 depending on a condition.

 

For each ID, I am trying to find the 0 or 1 value for the latest date in the date column grouped by ID and add that for each row for that ID in a new column. I'm trying to create the "Most Recent Active Status" in the below example:

 

IDDatesActive Status at DateMost Recent Active Status
111/1/201310
111/1/201500
15/1/201510
211/1/201211
211/1/201411
35/1/201401
311/1/201311
311/1/201511
35/1/201501

 

 

3 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Hi @Anonymous ,

 

Please try to use the below measure, it works on my desktop:

Measure 8 = CALCULATE(MAX('Table (2)'[Most Recent Active Status]),FILTER(ALL('Table (2)'[Dates]),'Table (2)'[Dates] = CALCULATE(MAX('Table (2)'[Dates]),ALLEXCEPT('Table (2)','Table (2)'[ID]))))

 

Trying to Find One Value Based on the Latest Date in Another Cell. Grouped By ID.PNG

 

Aiolos Zhao

View solution in original post

amitchandak
Super User
Super User

Try new columns

Max date = maxx(filter(table,table[ID] = earlier(table[ID])  ),table[Date])	
Max Status = maxx(filter(table,table[ID] = earlier(table[ID])   && table[date] = earlier(table[Max date ])),table[status])	
Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

View solution in original post

v-kelly-msft
Community Support
Community Support

Hi @Anonymous ,

 

You can create a measure as below:

 

Measure = 
var a =CALCULATE(MAX('Table'[Dates]),ALLEXCEPT('Table','Table'[ID]))
Return
CALCULATE(MAX('Table'[Active Status at Date]),'Table'[Dates]=a)

 

And you will see:

Annotation 2020-04-01 153459.png

 

Or you can create a calculated column as below:

 

Column = 
var a =CALCULATE(MAX('Table'[Dates]),ALLEXCEPT('Table','Table'[ID]))
var b= CALCULATE(MAX('Table'[Active Status at Date]),FILTER('Table','Table'[ID]=EARLIER('Table'[ID])),'Table'[Dates]=a)
Return
b

 

 

And you will see:

 

Annotation 2020-04-01 153650.png

 

For the related .pbix file,pls click here.

 

Best Regards,
Kelly
Did I answer your question? Mark my post as a solution!

View solution in original post

6 REPLIES 6
v-kelly-msft
Community Support
Community Support

Hi @Anonymous ,

 

You can create a measure as below:

 

Measure = 
var a =CALCULATE(MAX('Table'[Dates]),ALLEXCEPT('Table','Table'[ID]))
Return
CALCULATE(MAX('Table'[Active Status at Date]),'Table'[Dates]=a)

 

And you will see:

Annotation 2020-04-01 153459.png

 

Or you can create a calculated column as below:

 

Column = 
var a =CALCULATE(MAX('Table'[Dates]),ALLEXCEPT('Table','Table'[ID]))
var b= CALCULATE(MAX('Table'[Active Status at Date]),FILTER('Table','Table'[ID]=EARLIER('Table'[ID])),'Table'[Dates]=a)
Return
b

 

 

And you will see:

 

Annotation 2020-04-01 153650.png

 

For the related .pbix file,pls click here.

 

Best Regards,
Kelly
Did I answer your question? Mark my post as a solution!
Anonymous
Not applicable

@v-kelly-msftThank you for you reply!

 

I used the calulated column approach since I'm not too familiar with measures. It worked beautifully. It was truly an elegant solution with those variables.

 

I'm still trying to get my head around the EARLIER() function.

 

Thanks for your help!

amitchandak
Super User
Super User

Try new columns

Max date = maxx(filter(table,table[ID] = earlier(table[ID])  ),table[Date])	
Max Status = maxx(filter(table,table[ID] = earlier(table[ID])   && table[date] = earlier(table[Max date ])),table[status])	
Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
Anonymous
Not applicable

@amitchandakThank you for taking the time to respond. Your solution worked! I'm still trying to understand what EARLIER() does, but from playing with the code, it seems like it applies the result of the equation to all rows that meet the filter condition(s) rather than just the row where the maxx() is found. 

Anonymous
Not applicable

Hi @Anonymous ,

 

Please try to use the below measure, it works on my desktop:

Measure 8 = CALCULATE(MAX('Table (2)'[Most Recent Active Status]),FILTER(ALL('Table (2)'[Dates]),'Table (2)'[Dates] = CALCULATE(MAX('Table (2)'[Dates]),ALLEXCEPT('Table (2)','Table (2)'[ID]))))

 

Trying to Find One Value Based on the Latest Date in Another Cell. Grouped By ID.PNG

 

Aiolos Zhao

Anonymous
Not applicable

@AnonymousThank you for taking the time to respond to my question. I tried your solution, and it worked! I'm still trying to understand how measures differ from calculated columns. It looks like one cannot use measures in the Data view, but measures can be used when creating a table in the Report view. Is that right?

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

Find out what's new and trending in the Fabric community.