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

Issue with filter function in rolling month formula

Hi All,

 

I am trying to make a table that creates a total with postings which aren't "ment" for current month.
So like a posting thats created in feb 2021 which is a correction of jan 2021

 

So I want like a running total so we can see which bookings aren't cleared excluded the postings for that month which are ment for this month (economic peirod).

 

At first I have created a rolling total for last year with the following formula: 

Actuals rolling period = calculate(sum('F Total Actuals'[Value])/1000,DATESINPERIOD('F Total Actuals'[Posting date],ENDOFMONTH('F Total Actuals'[Posting date]),-12,MONTH))
 
At second I have created a formula based on this rolling periode with a filter to exclude if the posting date is the same as the economic period : 
Accruals >30D = CALCULATE([Actuals rolling period],filter('F Total Actuals','F Total Actuals'[Posting date]>'F Total Actuals'[Eco. Per. in date]))
 
When I put this in a table I get following results
 
Rolling month actuals.png
 
Want I want to achive is a formule that gives the values from the "Actual rolling period" but without the values that I boxed in black.

With the second formula where I used the filter funciton the januari bookings are going correct, but when I check the following months it picksup the actual value and not the rolling value.
 
Any ideas how to solve this?
 
Thanks in advance!

Kind Regards,
Ramon
 
 

 

 

1 ACCEPTED SOLUTION

Hi @Anonymous ,

 

I think you need to create two new measures and add them to the visual.

 

Total Actuals rolling period = 
IF(
    ISFILTERED('F Total Actuals'[Eco. Per. in date]),
    [Actuals rolling period],
    SUMX(ALLSELECTED('F Total Actuals'[Eco. Per. in date]),[Actuals rolling period])
)
Total Accruals >30D = 
IF(
    ISFILTERED('F Total Actuals'[Eco. Per. in date]),
    [Accruals >30D],
    SUMX(ALLSELECTED('F Total Actuals'[Eco. Per. in date]),[Accruals >30D])
)

 


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

4 REPLIES 4
v-kkf-msft
Community Support
Community Support

Hi @Anonymous ,

 

Try the following formula:

 

Actuals rolling period = 
IF(
    FORMAT( MAX('F Total Actuals'[Posting date]), "yyyymm" ) = FORMAT( MAX('F Total Actuals'[Eco. Per. in date]), "yyyymm" ),
    BLANK(),
    calculate(
        sum('F Total Actuals'[Value]) / 1000,
        DATESINPERIOD(
            'F Total Actuals'[Posting date],
            ENDOFMONTH('F Total Actuals'[Posting date]),
            -12,
            MONTH
        )
    )
)
Accruals >30D = 
IF(
    MIN('F Total Actuals'[Posting date]) > MAX('F Total Actuals'[Eco. Per. in date]),
    [Actuals rolling period]
)

 

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.

Anonymous
Not applicable

@v-kkf-msft  Hi Winniz,

Thanks alot, this looks like the solution!

The only thing I have now with this formula is that it looks like the values aren't in a number format (I won't get totals).

I also tried to change the format to decimal/ whole number, but I still don't get the Totals in the table like bellow

 

No totals.PNG

 

Any Idea how I could solve this?

 

Thanks alot!

BR,

Ramon

 

Hi @Anonymous ,

 

I think you need to create two new measures and add them to the visual.

 

Total Actuals rolling period = 
IF(
    ISFILTERED('F Total Actuals'[Eco. Per. in date]),
    [Actuals rolling period],
    SUMX(ALLSELECTED('F Total Actuals'[Eco. Per. in date]),[Actuals rolling period])
)
Total Accruals >30D = 
IF(
    ISFILTERED('F Total Actuals'[Eco. Per. in date]),
    [Accruals >30D],
    SUMX(ALLSELECTED('F Total Actuals'[Eco. Per. in date]),[Accruals >30D])
)

 


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.

Anonymous
Not applicable

Hi @v-kkf-msft,

 

Thanks a lot! This solved my issue!

Kind Regards,

Ramon

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.