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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Calculate SUM of a value where another value is max, by date, compared to month-1

Greetings:

 

I need a visual depicting, by date and group, the sum of values rolled up on customerID, but only the values where the transactionID is max for that month (since the accountbalance is calculated cumulatively in the data, so I only need the final one) and a difference calculated between that value, and the same calculation for the previous month.

 

I have been trying to combine different measures to accomplish this and playing aroudn with the DATEDIFF function, but we only started using PowerBI and DAX a week ago and its all still new to me.

 

Here is an example of the Input data (the yellow ones are the rows that should be filtered and calculated)

2Input.PNG

The final result should look like this.

2result.PNG

I have already received some help in creating the first 3 columns in a calculated table, before the month-1 and difference became a requirement (thanks to @Razwan )

2calcs.PNG

 

I would be most appreciative of any help in this regard.

 

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

Hi @Anonymous ,

 

Try the measures:

Max_transID = 
CALCULATE(
    MAX(Input[TransID]),
    ALLEXCEPT(
        Input,
        Input[Date],Input[Group],Input[CustID]
    )
)

SUM_value = 
CALCULATE(
    SUM(Input[Value]),
    FILTER(
        Input,
        Input[TransID] = [Max_transID]
    )
)

SUM_Month-1 = 
CALCULATE(
    [SUM_value],
    DATEADD(Input[Date], -1, MONTH)
)

Diff = 
IF(
    [SUM_Month-1] <> BLANK(),
    [SUM_value]-[SUM_Month-1],
    BLANK()
)

b8.PNG

(You enter a wrong data, right? which should be 150, not 180?)

 

Best regards,
Lionel Chen

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-lionel-msft
Community Support
Community Support

Hi @Anonymous ,

 

Try the measures:

Max_transID = 
CALCULATE(
    MAX(Input[TransID]),
    ALLEXCEPT(
        Input,
        Input[Date],Input[Group],Input[CustID]
    )
)

SUM_value = 
CALCULATE(
    SUM(Input[Value]),
    FILTER(
        Input,
        Input[TransID] = [Max_transID]
    )
)

SUM_Month-1 = 
CALCULATE(
    [SUM_value],
    DATEADD(Input[Date], -1, MONTH)
)

Diff = 
IF(
    [SUM_Month-1] <> BLANK(),
    [SUM_value]-[SUM_Month-1],
    BLANK()
)

b8.PNG

(You enter a wrong data, right? which should be 150, not 180?)

 

Best regards,
Lionel Chen

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Razwan
Helper I
Helper I

@Anonymous 
Hello,
Sorry for the late response.
If you don't have a separate Date column, I would suggest creating one in the Result table (this one will help achieving the value for last month).
So, create a column like:

 

 

DateFormat = DATEVALUE([Date])

 

 

It will format your current YYYY-MM column into first date of that respective month.

Then, the measure Total LM:

 

 

Total LM = 
    CALCULATE( 
        SUM( Result[Total] ),
        DATEADD( Result[DateFormat], -1, MONTH ),
        ALL( Result[Date] )
    )

 

 

And the Difference:

 

 

Difference = 
VAR dif = SUM( Result[Total] ) - [Total LM]
RETURN
IF( ISBLANK( [Total LM]), BLANK(), dif )

 

 

Finally, just drag the Total LM and Difference measures into Result table and it should be fine.

However, in the future, I would suggest (as @amitchandak mentioned) using a dedicated Date table for a better use of time intelligence functions.

 

Please let me know how it works.

Kind regards,
Razwan

amitchandak
Super User
Super User

In case you have date, or can convert month into dates, you can easily make time intelligence work for you

MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD('Date'[Date]))
last MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(dateadd('Date'[Date],-1,MONTH)))
last MTD (complete) Sales =  CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(ENDOFMONTH(dateadd('Date'[Date],-1,MONTH))))

You can take diff

diff= [MTD Sales] -[last MTD sales]

in your month format

Date = date(year(left(month-year,4)),month(mid(month-year,5,2),1)

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s.

Refer
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi

https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

Appreciate your Kudos. In case, this is the solution you are looking for, mark it as the Solution.
In case it does not help, please provide additional information and mark me with @

Thanks. My Recent Blogs -Decoding Direct Query - Time Intelligence, Winner Coloring on MAP, HR Analytics, Power BI Working with Non-Standard TimeAnd Comparing Data Across Date Ranges
Connect on Linkedin

 

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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