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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
RMD
Frequent Visitor

How to find latest date value in a group

 Hello Experts,

 

I am trying to extract only the latest date record row from a table with multiple dates per group.  

For example:  from this table i need only the record row of 1/1/2017 12:00 am of HMY 12.223 and 12.224

 

So each HMY code can have multiple dates  > I need only the latest date record

 

Thanks for you help!

 

Example1.PNG

 

 

1 ACCEPTED SOLUTION
v-juanli-msft
Community Support
Community Support

Hi AMD,

First, create a measure to see the lasted date of each kind HMY code as following formula:

Measure 2 =
CALCULATE ( MAX ( 'Table1'[date] )ALLEXCEPT ( Table1, Table1[HMY] ) )

Next, create another measure to judge whether the date of every HMY code equals the lasted date of each kind HMY code, this is to say whether the value of ‘date’ column equals ‘Measure 2’ column’s :

Measure 3 = IF ( MAX ( Table1[date] ) = [Measure 2], 1, 0 )

 

Then, you will see them showing in the Report view:

 9.png

 

Finally, on the Visual level filters, select the value of second measure which is equal to 1,and after applying this filter, we will see as follows.

10.png

12.png

 

If you have any question, please feel free to ask.

Best regards,
Maggie Li

 

View solution in original post

5 REPLIES 5
Anonymous
Not applicable

I have a similar situation but if there is a range date slicer that will control the date range then this solution won`t work because this will give the latest date data based on the raw table but using a date range will not evaluate the next latest date based on range slicer selection.

v-juanli-msft
Community Support
Community Support

Hi AMD,

First, create a measure to see the lasted date of each kind HMY code as following formula:

Measure 2 =
CALCULATE ( MAX ( 'Table1'[date] )ALLEXCEPT ( Table1, Table1[HMY] ) )

Next, create another measure to judge whether the date of every HMY code equals the lasted date of each kind HMY code, this is to say whether the value of ‘date’ column equals ‘Measure 2’ column’s :

Measure 3 = IF ( MAX ( Table1[date] ) = [Measure 2], 1, 0 )

 

Then, you will see them showing in the Report view:

 9.png

 

Finally, on the Visual level filters, select the value of second measure which is equal to 1,and after applying this filter, we will see as follows.

10.png

12.png

 

If you have any question, please feel free to ask.

Best regards,
Maggie Li

 

This was super helpful to me, it let me create a measure for a visual that is effectively equivalent to doing TOP 1 * WITH TIES ORDER BY ROW_NUMBER() OVER (PARTITION  BY ID ORDER BY DATE DESC) in sql for my data. Adding in this comment so if anyone is googling how to do TOP 1 WITH TIES in PowerBI, This Is The Way.

@v-juanli-msft is there a way to do this using calculated columns?

I want to pivot the data I have afterwards, so I assume I would need calculated columns instead of measures.

Specifically, I want to do the following:

image.png

Manny thanks Maggie for you help 🙂

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.