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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
deepblue_m45
Frequent Visitor

6 Month Avg (excl. last month) with filters

Hello, 

 

So I have written the below measure that will give me the average of the last 6 months, excluding the most recently completed month. This has worked very well when I'm looking at a scenario where there's 1 statistic to use. 

However, I'm looking at a situation where I need to sum up two types and it's not working as expected. For instance, I have a stacked column visual that is showing two customer types (w/ data labels for type 1, type 2, and grand total). When I apply this measure, it's giving me the average of both types individually (green cells) which is 2888. What I'm looking for is for the measure to average the grand total (yellow) which gives me 5777. I've tried many different ways and I can't quite get it. Any help would be appreciated! 

 

Thanks!

 

deepblue_m45_0-1657301075821.png

 

"6 Mo Avg (Excl Current) = 
CALCULATE(
    AVERAGE('AccountingTable'[Value]),
    DATESINPERIOD('Date Hierarchy'[Month Year],DATEADD(LASTDATE('Date Hierarchy'[Month Year]),-1,MONTH),-6,MONTH)
) "

 

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

Hi @deepblue_m45,

 

You may try this solution.

1 Create a Date column in ‘AccountingTable’ table

Date =
VAR month_ =
    SWITCH (
        LEFT ( AccountingTable[Month], 3 ),
        "Jan", 1,
        "Feb", 2,
        "Mar", 3,
        "Apr", 4,
        "May", 5,
        "Jun", 6,
        "Jul", 7,
        "Aug", 8,
        "Sep", 9,
        "Oct", 10,
        "Nov", 11,
        "Dec", 12
    )
VAR year_ =
    2000 + RIGHT ( AccountingTable[Month], 2 )
RETURN
    DATE ( year_, month_, 1 )

 

2 Build relationship between ‘AccountingTable’ table and ‘Date Hierarchy’ table

vcazhengmsft_0-1657800382411.png

 

6 Mo Avg (Excl Current) =
CALCULATE(
    AVERAGE('AccountingTable'[Total]),     //AVERAGE('AccountingTable'[Value])
    DATESINPERIOD('Date Hierarchy'[Month Year],DATEADD(LASTDATE('Date Hierarchy'[Month Year]),-1,MONTH),-6,MONTH)
)

 

Then, you should see the Measure works.

vcazhengmsft_1-1657800382413.png

Also, attached the pbix file as reference.

 

If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please let me know. Thanks a lot!

 

Best Regards,

Community Support Team _ Caiyun

View solution in original post

3 REPLIES 3
v-cazheng-msft
Community Support
Community Support

Hi @deepblue_m45,

 

You may try this solution.

1 Create a Date column in ‘AccountingTable’ table

Date =
VAR month_ =
    SWITCH (
        LEFT ( AccountingTable[Month], 3 ),
        "Jan", 1,
        "Feb", 2,
        "Mar", 3,
        "Apr", 4,
        "May", 5,
        "Jun", 6,
        "Jul", 7,
        "Aug", 8,
        "Sep", 9,
        "Oct", 10,
        "Nov", 11,
        "Dec", 12
    )
VAR year_ =
    2000 + RIGHT ( AccountingTable[Month], 2 )
RETURN
    DATE ( year_, month_, 1 )

 

2 Build relationship between ‘AccountingTable’ table and ‘Date Hierarchy’ table

vcazhengmsft_0-1657800382411.png

 

6 Mo Avg (Excl Current) =
CALCULATE(
    AVERAGE('AccountingTable'[Total]),     //AVERAGE('AccountingTable'[Value])
    DATESINPERIOD('Date Hierarchy'[Month Year],DATEADD(LASTDATE('Date Hierarchy'[Month Year]),-1,MONTH),-6,MONTH)
)

 

Then, you should see the Measure works.

vcazhengmsft_1-1657800382413.png

Also, attached the pbix file as reference.

 

If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please let me know. Thanks a lot!

 

Best Regards,

Community Support Team _ Caiyun

Whitewater100
Solution Sage
Solution Sage

Hello:

 

Please see attached file for one ay to obtain answer. I added date table and marked as date table. I hope this helps!

https://drive.google.com/file/d/1OW1L6auvvX9j13JmloMCTKRND_X1JLwz/view?usp=sharing 

 

There ae a couple calculated columns but I will show main result below:

Whitewater100_0-1657417063015.png

 

amitchandak
Super User
Super User

@deepblue_m45 , Try like

 

Rolling 12 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date ],eomonth(MAX('Date'[Date ]),-1) ,-12,MONTH))

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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