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

Rolling last 13 months/YTD of dataset

Hi all,

 

I have a quick question about calculating two specific measures that I would need in order to automate/simplify the financial reporting in my company:

 

- last 13 months

- YTD.

 

My dataset looks like this, where I have one column "Monat" with a end-of-the-month value ("Wert") for every month:

 

Database.PNG

 

How can I now create the two measures that are automtically adapting following refreshments of the dataset?

 

Many thanks in advance!

BR, Benedikt

 
1 ACCEPTED SOLUTION
az38
Community Champion
Community Champion

Hi @BMaurus 

try

last 13 month = 
CALCULATE(SUM(Table[Wert]), Table[Monat] >= DATEADD(Table[Monat], -13, MONTH), ALL(Table) )

and

YTD = 
TOTALYTD(SUM(Table[Wert]), Table[Monat], ALL(Table) )

do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

View solution in original post

2 REPLIES 2
az38
Community Champion
Community Champion

Hi @BMaurus 

try

last 13 month = 
CALCULATE(SUM(Table[Wert]), Table[Monat] >= DATEADD(Table[Monat], -13, MONTH), ALL(Table) )

and

YTD = 
TOTALYTD(SUM(Table[Wert]), Table[Monat], ALL(Table) )

do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn
amitchandak
Super User
Super User

@BMaurus , you can use following with time intelligence

Rolling 13 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date],ENDOFMONTH(Sales[Sales Date]),-13,MONTH))

Last 13 period Month =
Var _max = maxx(allselected('Date','Date'[Date])
Var _min = date( year(_max),month(_max)-13,day(_max))
return
CALCULATE(SUM(Sales[Net Sales]),FILTER(all('Date'),'Date'[Date]>=_min && 'Date'[Date]<=_max))

Also refer : https://www.youtube.com/watch?v=duMSovyosXE

YTD various ways

YTD QTY = TOTALYTD(Sum('order'[Qty]),'Date'[Date])
LYTD QTY = TOTALYTD(Sum('order'[Qty]),dateadd('Date'[Date],-1,year))
Previous Year = CALCULATE(SUM('order'[Qty]), PREVIOUSYEAR('Date'[Date]))


YTD QTY forced= 
var _max = today()
return
calculate(Sum('order'[Qty]),DATESYTD('Date'[Date]),'Date'[Date]<=_max)
//calculate(TOTALYTD(Sum('order'[Qty]),'Date'[Date]),filter('Date','Date'[Date]<=_max))

LYTD QTY forced= 
var _max = date(year(today())-1,month(today()),day(today()))
return
CALCULATE(Sum('order'[Qty]),DATESYTD(dateadd('Date'[Date],-1,year)),'Date'[Date]<=_max)
//TOTALYTD(Sum('order'[Qty]),dateadd('Date'[Date],-1,year),'Date'[Date]<=_max)


YTD QTY forced= 
var _max = maxx('order',[Order date])
return
calculate(Sum('order'[Qty]),DATESYTD('Date'[Date]),'Date'[Date]<=_max)
//calculate(TOTALYTD(Sum('order'[Qty]),'Date'[Date]),filter('Date','Date'[Date]<=_max))

LYTD QTY forced= 
var _max1 =maxx('order',[Order date])
var _max = date(year(_max1)-1,month(_max1),day(_max1))
return
CALCULATE(Sum('order'[Qty]),DATESYTD(dateadd('Date'[Date],-1,year)),'Date'[Date]<=_max)
//TOTALYTD(Sum('order'[Qty]),dateadd('Date'[Date],-1,year),'Date'[Date]<=_max)

//only work with year 

This Year = CALCULATE(sum('order'[Qty]),filter(ALL('Date'),'Date'[Year]=max('Date'[Year])))
Last Year = CALCULATE(sum('order'[Qty]),filter(ALL('Date'),'Date'[Year]=max('Date'[Year])-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/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.

 

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.