Hi, hoping someone can help me with what must be the first thing I have stumbled on that I can not work out for the life of me. I have been trawling the forums looking for an answer, but haven't been able to find a solution.
I work for a company which holds our clients funds in custody for their investments. Each day, the total holdings for each account will change, depending on movements in the market. An example of how this data may look would be as below.
Date | Account | Account Type | Holdings |
1 Jul 19 | Account A | Personal | 10,000 |
1 Jul 19 | Account B | Personal | 250,500 |
1 Jul 19 | Account C | Business | 95,000 |
2 Jul 19 | Account A | Personal | 10,150 |
2 Jul 19 | Account B | Personal | 251,800 |
2 Jul 19 | Account C | Business | 96,800 |
3 Jul 19 | Account A | Personal | 9,990 |
3 Jul 19 | Account B | Personal | 248,800 |
3 Jul 19 | Account C | Business | 92,200 |
So with the above example, the total holdings for all accounts would be
Date | Total Holdings |
1 Jul 19 | 355,500 |
2 Jul 19 | 358,750 |
3 Jul 19 | 350,990 |
What I am trying to do, is to create a measure that will be able to provide a 12 month rolling average of the total holdings within a period. But with every method I have tried, it keeps taking in to account the granularity of the data and providing the average of all values across the accounts, rather than the average of the aggregated holdings each day. So using the above example, the result being produced (assuming it were a 3 day rolling average) would be 118,360 - but the desire result should be 355,080.
Where I am at the moment with this is the following DAX measure.
Solved! Go to Solution.
Try like
avergageX(summarize(calculatetable(Clients,DATESINPERIOD('Date'[Date],ENDOFMONTH(Clients[Date]),-12,MONTH)),
Date[Date],"_DateOnly",CALCULATE(SUM(Clients[Holdings]))),[_DateOnly])
Hi, @Anonymous
Based on your description, you may create a measure as below.
Result =
CALCULATE(
SUMX(Clients,Clients[Holdings])/DISTINCTCOUNT(Clients[Date]),
DATESINPERIOD(
Dates[Date],
LASTDATE(Dates[Date]),
-1,
YEAR
)
)
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @Anonymous
Based on your description, you may create a measure as below.
Result =
CALCULATE(
SUMX(Clients,Clients[Holdings])/DISTINCTCOUNT(Clients[Date]),
DATESINPERIOD(
Dates[Date],
LASTDATE(Dates[Date]),
-1,
YEAR
)
)
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Try like
avergageX(summarize(calculatetable(Clients,DATESINPERIOD('Date'[Date],ENDOFMONTH(Clients[Date]),-12,MONTH)),
Date[Date],"_DateOnly",CALCULATE(SUM(Clients[Holdings]))),[_DateOnly])
Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!
User | Count |
---|---|
125 | |
79 | |
68 | |
55 | |
55 |
User | Count |
---|---|
200 | |
104 | |
85 | |
80 | |
77 |