Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin 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.
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!
"6 Mo Avg (Excl Current) =
CALCULATE(
AVERAGE('AccountingTable'[Value]),
DATESINPERIOD('Date Hierarchy'[Month Year],DATEADD(LASTDATE('Date Hierarchy'[Month Year]),-1,MONTH),-6,MONTH)
) "
Solved! Go to Solution.
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
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.
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
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
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.
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
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:
@deepblue_m45 , Try like
Rolling 12 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date ],eomonth(MAX('Date'[Date ]),-1) ,-12,MONTH))
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
10 | |
9 | |
8 | |
8 | |
7 |
User | Count |
---|---|
13 | |
12 | |
11 | |
11 | |
8 |