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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
arpost
Post Patron
Post Patron

Help! How do I summarize and get a running total using DAX?

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:

 

DateCustomerCallsReplies
9/1/2022Jane Doe10
9/1/2022Max Jones43
10/1/2022John Smith21
10/2/2022Jane Doe21
11/13/2022Max Jones74
11/13/2022John Smith41

 

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:

 

CustomerCallsMostRecentDate
Jane Doe210/2/22
John Smith411/13/22
Max Jones711/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):

 

DateCalls[EXPLANATION]
11/9/228Jane (10/2), John (10/2), and Max (9/1)
11/10/228Jane (10/2), John (10/2), and Max (9/1)
11/11/228Jane (10/2), John (10/2), and Max (9/1)
11/12/228Jane (10/2), John (10/2), and Max (9/1)
11/13/2213Jane (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. 😝

1 ACCEPTED SOLUTION

Hi,

thank you for your feedback, and please check the attached pbix file if it suits your requirement.

 

Thank you.

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

4 REPLIES 4
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_0-1670386408338.png

 

Jihwan_Kim_1-1670387457085.png

 

 

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] )
    )

 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


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.

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


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,

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors