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
sailorman
Frequent Visitor

Rolling calculation for previous 12 months

I have a cumulative hours (last 12 months) caculator DAX as follows:

 

Cumulative HOURS = CALCULATE( SUM('Unit'[Hours Worked]),
DATESINPERIOD('Unit'[Month],
LASTDATE('Unit'[Month]),-12,MONTH
))
 

This will give me the cumulative value for last 12 months, say June 2021 to May 2022.

 

I now want to plot this agaist cumulative of previous 12 months, that is July 2020 - June 2021. How should I modify DAX to get these values. I want both line graphs in the same plot for comparison. How do I go about doing that?

 

Thanks in advance!

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

@sailorman , if you want to 12 months on axis

Rolling 12 Sales =
var _max = maxx(allselcted(date),date[date]) // or today()
var _min = date(year(_max), month(_max)-12,1)
return
CALCULATE(SUM(Sales[Sales Amount]),filter(date, date[date] <=_max && date[date] >=_min))

 

in case you select one month and want to display 12 months, you need an independent date table


//Date1 is independent Date table, Date is joined with Table
new measure =
var _max = maxx(allselected(Date1),Date1[Date])
var _min = eomonth(_max, -12) +1
return
calculate( sum(Table[Value]), filter('Date', 'Date'[Date] >=_min && 'Date'[Date] <=_max))

 

Need of an Independent Date Table:https://www.youtube.com/watch?v=44fGGmg9fHI

View solution in original post

Hi Thanks. I figured out a way to avoid using seperate date table by using following variables

Cumulative HOURS previous year =
VAR CurrentDate =  
    MAX('Unit'[Month])
VAR StartMonth =
    CurrentDate - 365
Return
    CALCULATE( SUM('Unit'[Hours Worked]),
        DATESINPERIOD('Unit'[Month],
        StartMonth,-12,MONTH
        )
        )

View solution in original post

2 REPLIES 2
amitchandak
Super User
Super User

@sailorman , if you want to 12 months on axis

Rolling 12 Sales =
var _max = maxx(allselcted(date),date[date]) // or today()
var _min = date(year(_max), month(_max)-12,1)
return
CALCULATE(SUM(Sales[Sales Amount]),filter(date, date[date] <=_max && date[date] >=_min))

 

in case you select one month and want to display 12 months, you need an independent date table


//Date1 is independent Date table, Date is joined with Table
new measure =
var _max = maxx(allselected(Date1),Date1[Date])
var _min = eomonth(_max, -12) +1
return
calculate( sum(Table[Value]), filter('Date', 'Date'[Date] >=_min && 'Date'[Date] <=_max))

 

Need of an Independent Date Table:https://www.youtube.com/watch?v=44fGGmg9fHI

Hi Thanks. I figured out a way to avoid using seperate date table by using following variables

Cumulative HOURS previous year =
VAR CurrentDate =  
    MAX('Unit'[Month])
VAR StartMonth =
    CurrentDate - 365
Return
    CALCULATE( SUM('Unit'[Hours Worked]),
        DATESINPERIOD('Unit'[Month],
        StartMonth,-12,MONTH
        )
        )

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.

Top Solution Authors