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
JamesBockett
Helper I
Helper I

Current year volume vs previous 5 year average volume

Hi Everyone

 

What I have:

I have a sales data table with a row for each sale.

I have a calendar lookup table with a row per date.

I have a 'countrows' measure that calculates how many rows are in the table, giving me the total number of sales.

I have a line graph showing the total number of sales over a period of time.

 

Goal:

I would like to be able to display total number of sales, by month, for the current year on a line graph, with the average number of sales, by month, for the previous years on the same graph. Any suggestions on how to get the past 5 years average would be appreciated.

 

Below is an example of what I am looking to achieve.

JamesBockett_0-1639583673941.png

 

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Picture2.png

 

Orders count: =
CALCULATE ( COUNTROWS ( Sales ), Dates[Year] = MAX ( Dates[Year] ) )

 

Orders count prev 5 years avg: =
VAR selectedyear =
MAX ( Dates[Year] )
VAR previous5years = selectedyear - 5
VAR newdatetable =
CALCULATETABLE (
VALUES ( Dates[Year] ),
FILTER (
ALL ( Dates ),
Dates[Year] < selectedyear
&& Dates[Year] >= previous5years
)
)
RETURN
AVERAGEX ( newdatetable, [Orders count:] )

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.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

View solution in original post

2 REPLIES 2
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Picture2.png

 

Orders count: =
CALCULATE ( COUNTROWS ( Sales ), Dates[Year] = MAX ( Dates[Year] ) )

 

Orders count prev 5 years avg: =
VAR selectedyear =
MAX ( Dates[Year] )
VAR previous5years = selectedyear - 5
VAR newdatetable =
CALCULATETABLE (
VALUES ( Dates[Year] ),
FILTER (
ALL ( Dates ),
Dates[Year] < selectedyear
&& Dates[Year] >= previous5years
)
)
RETURN
AVERAGEX ( newdatetable, [Orders count:] )

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.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

@Jihwan_Kim You're a genius! It worked so, thank you very much for your help.

 

As a bonus, please could you explain the DAX to me, for the 5yr average? I like to have a vague understanding of what is going on so I know for future.

 

Many thanks

James

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.