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
admin11
Memorable Member
Memorable Member

How to compute GL Expense average 12 month amount ?

Hi All

I have last 12 month Expense amount in stright table. 

admin11_0-1614493480154.png

Can some one share with me how to create expression for compute last 12 month averyage expense ?

Expected to get = 42,952.00

 

https://www.dropbox.com/s/m30p5vrsmax20ku/PBT_V2021_339%20how%20to%20get%20last%2012%20month%20avery...

Above my PBI :-

 

Paul 

2 ACCEPTED SOLUTIONS

Hi @admin11 ,

Try the following formula:

avg = 
var _table = 
    FILTER(
        'Date',
        NOT(ISBLANK([AMOUNT]))
    )
var _Date = MAXX(_table,'Date'[Date])
var _First =  EOMONTH( _Date, -12 )
return 
    -DIVIDE(
        CALCULATE(
            [AMOUNT],
            FILTER(
                _table,
                'Date'[Date] > _First
            )
        ),
        12
)

v-kkf-msft_0-1614766131567.jpeg

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

Hi @admin11 ,

Try to modify the measure Amount to the following formula:

AMOUNT = 
CALCULATE(
    SUM(GL[AMT])*-1,
    FILTER(
        GL,
        GL[1_EXP]="EXP"
    )
)

v-kkf-msft_0-1614822518373.png

 

Best Regards,
Winniz

View solution in original post

10 REPLIES 10
PhilipTreacy
Super User
Super User

@admin11 

Hi Paul,

try this measure

YTD Avg Expense = TOTALYTD(AVERAGE('GL'[AMT]),'Date'[Date])

But the result is vastly different to your 42952.  How did you arrive at that value?

I can't work out how you are recording expenses.  There are multiple columns in your GK table with the word EXP and another column with the Type E. Are these expenses?

Regards

Phil



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


@PhilipTreacy 

Thank you for your help :-

admin11_0-1614509579839.png

 

Hi @admin11 ,

Try the following formula:

avg = 
-AVERAGEX(
  FILTER(
    'Table',
    'Table'[YrMth Sort] >= EOMONTH( LASTDATE( ALL( 'Table'[YrMth Sort] ) ), -12 )
  ),
  [Amount]
)

v-kkf-msft_0-1614647418064.png

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

 

@v-kkf-msft 

Thank you very much for sharing.

i try to implement your expression to my PBIX file , i don't have error , but it display blank.

admin11_0-1614657783754.png

 

Paul

Hi @admin11 ,

That should be caused by different model. Can you share your PBIX file? The previous link shows that the file has been deleted.

 

Best Regards,

Winniz

@v-kkf-msft 

 

Thank you very much for your help , it work fine now.

 

Paul

Hi @admin11 ,

Try the following formula:

avg = 
var _table = 
    FILTER(
        'Date',
        NOT(ISBLANK([AMOUNT]))
    )
var _Date = MAXX(_table,'Date'[Date])
var _First =  EOMONTH( _Date, -12 )
return 
    -DIVIDE(
        CALCULATE(
            [AMOUNT],
            FILTER(
                _table,
                'Date'[Date] > _First
            )
        ),
        12
)

v-kkf-msft_0-1614766131567.jpeg

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

@v-kkf-msft 

 

For the above avg expression which is working fine . now i need to make use of filter panel , to filter to set 1_EXP=EXP.

 

1_EXP =
SWITCH(TRUE(),
'GL'[Reporting Code]>=00100 &&'GL'[Reporting Code]<=00375,"EXP",
BLANK())
 
Can you pls help me insert 1_EXP to avg expression , so that i don't require do additional step , it will display avg exp amount for Exp. 
I have already try use filter panel , it work fine. But i Tab have initial seletion button , it will cause filter panel setting not work.
See image below :-
admin11_0-1614769419558.png

 

 
Paul 

Hi @admin11 ,

Try to modify the measure Amount to the following formula:

AMOUNT = 
CALCULATE(
    SUM(GL[AMT])*-1,
    FILTER(
        GL,
        GL[1_EXP]="EXP"
    )
)

v-kkf-msft_0-1614822518373.png

 

Best Regards,
Winniz

@v-kkf-msft wow you are very intelligent.

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.