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 August 31st. Request your voucher.

Reply
AaronM
New Member

Filtering table by most recent data (with multiple different last entry dates)

I am having issues understanding which measures/filter I should be using to solve a problem I have with one of my Power B.I reports.

 

My report is a status report for a series of projects within a project portfolio. Each week the projects submit a weekly status update. These updates vary from week to week and cover a variety of data fields (Ive given some examples of what the data looks like in the below “DATA SET EXAMPLE”.

 

In my report I only want the most recent entry to be displayed for each project (see below “SUMMARY TABLE”). The problem I am having is using MAX DATE or a DATE FILTER doesn’t work as there are over 30 projects in the tables and they all have varying “most recent entries”.

 

DATA SET EXAMPLE

Project Update                 Project name               Project Status

1/10/2018                        Example 1                    Green 1

/10/2018                          Example 2                    Green

1/10/2018                        Example 3                    Amber

2/10/2018                        Example 1                    Amber

2/10/2018                        Example 2                    Green

2/10/2018                        Example 3                    Red

3/10/2018                        Example 1                    Green

3/10/2018                        Example 2                    Green

3/10/2018                        Example 3                    Amber

 

SUMMARY TABLE

Project name             Project Status

Example 1                 Green*

Example 2                 Green*

Example 3                 Amber*

 

*i only want the most recent row of data to be displayed in this table.

 

The date for each of these entries will vary from project to project. Any help or guidance on how to best solve this would be great appreciated.

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

I'd solve it by create a True/False DAX column like this:

displayInReport = VAR rowDate = [Project Update]
VAR projectName = [Project name]

RETURN
CALCULATE(
	MAX('YourTable'[Project Updates]) = rowDate,
	ALL('YourTable'),
	'YourTable'[Project name] = projectName
)

Then filtering on this column for TRUE.

 

View solution in original post

v-juanli-msft
Community Support
Community Support

Hi @AaronM

As tested, Ross73312's method is helpful, you need to create a caluclated column with his formula,

then add this column in a slicer, add other columns in a Table visual,

finally when you select "true" from that slicer, the table would show the lastest data for each project.

 

2.png

 

Or you could create a measure, then add this measure in the Visual Level filter, select "show items when value is 1".

Measure =
IF (
MAX ( [Project Update] )
= CALCULATE (
MAX ( [Project Update] ),
ALLEXCEPT ( 'DATA SET EXAMPLE', 'DATA SET EXAMPLE'[Project name ] )
),
1,
0
)

1.png

 

Best Regards

Maggie

View solution in original post

4 REPLIES 4
v-juanli-msft
Community Support
Community Support

Hi @AaronM

As tested, Ross73312's method is helpful, you need to create a caluclated column with his formula,

then add this column in a slicer, add other columns in a Table visual,

finally when you select "true" from that slicer, the table would show the lastest data for each project.

 

2.png

 

Or you could create a measure, then add this measure in the Visual Level filter, select "show items when value is 1".

Measure =
IF (
MAX ( [Project Update] )
= CALCULATE (
MAX ( [Project Update] ),
ALLEXCEPT ( 'DATA SET EXAMPLE', 'DATA SET EXAMPLE'[Project name ] )
),
1,
0
)

1.png

 

Best Regards

Maggie

Hi Maggie, 

 

I'm interested in your response here ... and think the Measure is a smarter way to go, but struggling to get the same result.

 

I have 2 tables ... normalised.  For ease of management, I'll write them simplistically below:- 

 

 

Project Table

=========

ID

Project Name

 

 

Project-Status Table

=============

Week Ending

Status

ID-Project

 

 

The output table visual would have the fields

 

Week Ending  |  Project Name  |  Status .... plus other fields

 

The relationships are managed in the dataset model.

 

How do I amend the measure shown above to get the same result and only show the latest status for each project in the list (where week endings might all be different periods for different projects).  I've tried several versions of the Measure and can't seem to get it to work - I get the 0 but not the 1.

 

Many thanks

Andre

Anonymous
Not applicable

I'd solve it by create a True/False DAX column like this:

displayInReport = VAR rowDate = [Project Update]
VAR projectName = [Project name]

RETURN
CALCULATE(
	MAX('YourTable'[Project Updates]) = rowDate,
	ALL('YourTable'),
	'YourTable'[Project name] = projectName
)

Then filtering on this column for TRUE.

 

Thanks Ross this worked perfectly! i really appreciate the help! 

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

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

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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