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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
Anonymous
Not applicable

Create Dax measure to locate latest value in table by max date

I have a table holding 12 months of data. My date column is called [Reporting Period]

I have a value called [Total Cost] which is a simple interger. 

I need to multiply [Total Cost] by 12, but I only need to multiply [Total Cost] for the most recent month, if I multiply it by all months it's a nonsensical figure.

How on earth do I do this? 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

I figured it out.

I created two measures. One determines the most recent [Total Cost] for the max date:

 

LATEST COST = 
VAR MAXDATE =
MAX(Azure[Reporting Period])

RETURN
CALCULATE(SUM('Azure'[Cost]),
CALCULATETABLE(LASTDATE(SUMMARIZE('Azure','Azure'[Reporting Period])),
'Azure'[Reporting Period]<=MAXDATE))

 

The second measure simply multiplies this measure by 12. I could probably combine but I like the distiniction.

 

Burn Rate = [LATEST COST]*12

View solution in original post

2 REPLIES 2
Pragati11
Super User
Super User

Hi @Anonymous ,

 

As you haven't provided a data sample, consider the data I have below. I have got Quantity data for 3 Months - Jan, Feb, Mar for 2019:

part1.gif

Now I created the following measure where the Quantity  column will be multiplied by 12 only for the Maximum MONTH & YEAR value in this Date column which March 2019 in this case:

calcprice = 
var maxmonth = CALCULATE(MONTH(MAX('Supermarket Sales'[Date])), ALL('Supermarket Sales'))
var maxYear = CALCULATE(YEAR(MAX('Supermarket Sales'[Date])), ALL('Supermarket Sales'))

RETURN

CALCULATE(
    SUM('Supermarket Sales'[Quantity]) * 12,
    FILTER(
        'Supermarket Sales', MONTH('Supermarket Sales'[Date]) = maxmonth && YEAR('Supermarket Sales'[Date]) = maxYear
        )
    )

Now when I move calculated measure to my table visual, I see that only the Quantity value for March 2020 month-year is multiplied by 12 and for remaining months the measure shows empty as it is not multiplied by 12:

part2.gif

 

This calculation can also be modified to show original quantity for other months, but updated quantity (multiplied by 12) only for the latest month.

Also in my data Latest Month is MARCH, you may have DECEMBER at your end. But this calculation is dynamic to handle maximum month year in the data.

 

Let me know if this is what you were looking for.

 

Thanks,

Pragati

 

Best Regards,

Pragati Jain


MVP logo


LinkedIn | Twitter | Blog YouTube 

Did I answer your question? Mark my post as a solution! This will help others on the forum!

Appreciate your Kudos!!

Proud to be a Super User!!

Anonymous
Not applicable

I figured it out.

I created two measures. One determines the most recent [Total Cost] for the max date:

 

LATEST COST = 
VAR MAXDATE =
MAX(Azure[Reporting Period])

RETURN
CALCULATE(SUM('Azure'[Cost]),
CALCULATETABLE(LASTDATE(SUMMARIZE('Azure','Azure'[Reporting Period])),
'Azure'[Reporting Period]<=MAXDATE))

 

The second measure simply multiplies this measure by 12. I could probably combine but I like the distiniction.

 

Burn Rate = [LATEST COST]*12

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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