The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hello,
I recently used DAX to create a 3 and 6 month rolling average which wasn't too difficult because it's a time intelligence calculation but now I'm looking to get an average of 10 email sends per campaign.
Attached below is a table with the columns as reference. For example, Adobe sends are usually 100K - 200K per send. I want to calculate the sum of 10 sends and get an average on that.
Any help will be greatly appreciated.
Thank you!
Solved! Go to Solution.
Hi, @jytech
You can try the following methods. First figure out how to determine the order in which each point in time is sent.
Count =
CALCULATE (
COUNTROWS ( 'Table' ),
FILTER (
ALL ( 'Table' ),
[Campaign Name] = SELECTEDVALUE ( 'Table'[Campaign Name] )
&& [Sent time] >= SELECTEDVALUE ( 'Table'[Sent time] )
)
)
Then sum the 10 most recent time sends.
Sum of the nearest 10 =
SUMX(FILTER('Table',[Count]<=10),[Sent])
Average of the nearest 10 =
AVERAGEX(FILTER('Table',[Count]<=10),[Sent])
Please see the attachment for details.
Best Regards,
Community Support Team _Charlotte
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @jytech
Is there a time point for each send? Is it to calculate the sum of the 10 most recent sends at the most recent time? Is there any relevant example data, preferably available?
Best Regards
Hi @v-zhangti
Each send has a send date linked to it, and yes, I would like to calculate the sum of the 10 most recent sends filtered by the Campaign. Here's a screen shot (minus some sensitive data) as a reference.
Hi, @jytech
You can try the following methods. First figure out how to determine the order in which each point in time is sent.
Count =
CALCULATE (
COUNTROWS ( 'Table' ),
FILTER (
ALL ( 'Table' ),
[Campaign Name] = SELECTEDVALUE ( 'Table'[Campaign Name] )
&& [Sent time] >= SELECTEDVALUE ( 'Table'[Sent time] )
)
)
Then sum the 10 most recent time sends.
Sum of the nearest 10 =
SUMX(FILTER('Table',[Count]<=10),[Sent])
Average of the nearest 10 =
AVERAGEX(FILTER('Table',[Count]<=10),[Sent])
Please see the attachment for details.
Best Regards,
Community Support Team _Charlotte
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
112 | |
81 | |
78 | |
43 | |
37 |
User | Count |
---|---|
157 | |
112 | |
64 | |
60 | |
54 |