Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Greetings, PBI community! Have an interesting conundrum and wanted to see if anyone could offer a solution. Here's the two parts of the scenario with an example.
Let's say I have a dataset set up as follows along with a standard Calendar table with a date column:
Date | Customer | Calls | Replies |
9/1/2022 | Jane Doe | 1 | 0 |
9/1/2022 | Max Jones | 4 | 3 |
10/1/2022 | John Smith | 2 | 1 |
10/2/2022 | Jane Doe | 2 | 1 |
11/13/2022 | Max Jones | 7 | 4 |
11/13/2022 | John Smith | 4 | 1 |
Need #1: Most Recent Value per Customer
I want to write a measure that sums up a total using the most recent value for each customer. So if I wanted to sum up the Calls, the interim "table" would be as follows:
Customer | Calls | MostRecentDate |
Jane Doe | 2 | 10/2/22 |
John Smith | 4 | 11/13/22 |
Max Jones | 7 | 11/13/22 |
The measure's final total would be 13.
Need #2: Most Recent Value based on Date Context
As part of the above, I ALSO need to make sure that this is based on the date context in which the measure is calculated, meaning it only shows the most recent value as of the date in question. Basically, I need a running total using the most recent values.
So if I put the Date from the Calendar table and the total measure in a table, it would look something like this (explanation column added to clarify which dates are being used):
Date | Calls | [EXPLANATION] |
11/9/22 | 8 | Jane (10/2), John (10/2), and Max (9/1) |
11/10/22 | 8 | Jane (10/2), John (10/2), and Max (9/1) |
11/11/22 | 8 | Jane (10/2), John (10/2), and Max (9/1) |
11/12/22 | 8 | Jane (10/2), John (10/2), and Max (9/1) |
11/13/22 | 13 | Jane (10/2), John (11/13), and Max (11/13) |
Hoping this makes sense. Any ideas would be greatly appreciated. I've been able to get #1 thanks to this article from EnterpriseDNA, and I've been able to get #2 on its own using this article from SQLBI but I can't get them merged into one calc. 😝
Solved! Go to Solution.
Hi,
thank you for your feedback, and please check the attached pbix file if it suits your requirement.
Thank you.
Hi,
Please check the below picture and the attached pbix file.
Most recent date: =
IF ( HASONEVALUE ( Customer[Customer] ), MAX ( Data[Date] ) )
Most recent call #: =
VAR _mostrecentdate = [Most recent date:]
RETURN
CALCULATE ( SUM ( Data[Calls] ), 'Calendar'[Date] = _mostrecentdate )
Calls accumulate by most recent calls: =
VAR _currentdate =
MAX ( 'Calendar'[Date] )
VAR _currentdatecallnumbers =
ADDCOLUMNS (
DISTINCT ( Customer[Customer] ),
"@lastdate", CALCULATE ( MAX ( Data[Date] ), 'Calendar'[Date] <= _currentdate )
)
RETURN
CALCULATE (
SUM ( Data[Calls] ),
TREATAS ( _currentdatecallnumbers, Customer[Customer], 'Calendar'[Date] )
)
Greetings, @Jihwan_Kim! Thanks for the reply. That's really helpful.
Quick question: this requires that there is a separate dimension table (Customers). Any chance you know of a solution that can work on the data in the data table itself? To put it another way, is there a form of the above that would work with just a Calendar table and a Data table?
Hi,
thank you for your feedback, and please check the attached pbix file if it suits your requirement.
Thank you.
Boom! That worked like a charm. 😁 Thanks for the help. I'm trying to figure out a related (but somewhat different) issue over here (link) as well, so if you have any sage advice you could offer, that'd be appreciated,
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
10 | |
10 | |
10 | |
9 | |
7 |
User | Count |
---|---|
17 | |
12 | |
11 | |
11 | |
10 |