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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Rolling 12 month average of all account holdings

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.

 

DateAccountAccount Type

Holdings

1 Jul 19Account APersonal

10,000

1 Jul 19Account BPersonal

250,500

1 Jul 19Account CBusiness

95,000

2 Jul 19

Account APersonal

10,150

2 Jul 19Account BPersonal

251,800

2 Jul 19Account CBusiness

96,800

3 Jul 19Account APersonal

9,990

3 Jul 19Account BPersonal

248,800

3 Jul 19Account CBusiness

92,200

 

So with the above example, the total holdings for all accounts would be

DateTotal Holdings
1 Jul 19355,500
2 Jul 19358,750
3 Jul 19350,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.

12m Rolling Holdings =
CALCULATE(AVERAGE(Clients[Holdings]),
SUMMARIZE(Clients,Clients[Date],"DateOnly",
CALCULATE(SUM(Clients[Holdings]),
DATESBETWEEN(Dates[Date],
NEXTDAY(SAMEPERIODLASTYEAR(LASTDATE(Dates[Date]))),
LASTDATE(Dates[Date])))))
 
I think I am almost there, but am struggling to structure this in a way that filters the data the way I want for the purpose of the measure. I have tried a few other variations, some producing the same result and others producing an error. Perfectly aware that using 2 sets of CALCULATE probably isn't the best practice, but have run out of ideas here and tearing my hair out.
 
Please help!
2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

Try like

avergageX(summarize(calculatetable(Clients,DATESINPERIOD('Date'[Date],ENDOFMONTH(Clients[Date]),-12,MONTH)),
	Date[Date],"_DateOnly",CALCULATE(SUM(Clients[Holdings]))),[_DateOnly])

View solution in original post

v-alq-msft
Community Support
Community Support

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:

c1.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-alq-msft
Community Support
Community Support

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:

c1.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Thanks @v-alq-msft @amitchandak both solutions make perfect sense and both work. 

 

Much appreciated.

amitchandak
Super User
Super User

Try like

avergageX(summarize(calculatetable(Clients,DATESINPERIOD('Date'[Date],ENDOFMONTH(Clients[Date]),-12,MONTH)),
	Date[Date],"_DateOnly",CALCULATE(SUM(Clients[Holdings]))),[_DateOnly])

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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