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
Aden
Advocate I
Advocate I

IF statement with FILTER

When i use this 

Fees % of Budget to last month 2 =

CALCULATE(DIVIDE([Net Fees], SUM('Budgets'[billamt_perday]))*100,
FILTER('Calendar', MONTH([trandate])<MONTH(Today())-0))
 
I get the result i want ie only show data up to the end of last month.
However that dosnt work when looking at a previous year. 
 
So i add an IF to say if the current year is selected use Fees % of Budget to last month 2, if not then just use the unfiltered version.
 
Fees % of Budget to last month =
IF( format(YEAR(TODAY()),"yyyy") = [Selected Year Only] ,
[Fees % of Budget to last month 2], [Fees % of Budget])
 
Problem is by doing this the data displays the current month that i want filtered out. 
Aden_2-1647559038323.png

 


 

What am i doing wrong?
 
The output i want is 
Aden_1-1647559011720.png

 

 
 
 
 
1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @Aden 

In order to filter on months before the current month, I would suggest using EOMONTH to get the last date of the previous month, then filter on dates <= that date. This can be wrapped in KEEPFILTERS to intersect with the current filter context.

 

Here is how you could write the measure:

(Note: I'm assuming your 'Calendar' table is marked as a date table, and 'Calendar'[trandate] is the date column.)

Fees % of Budget to last month 2 =
CALCULATE (
    DIVIDE ( [Net Fees], SUM ( 'Budgets'[billamt_perday] ) ) * 100,
    KEEPFILTERS ( 'Calendar'[trandate] <= EOMONTH ( TODAY (), -1 ) )
)

Does this give the expected result?

 

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

2 REPLIES 2
Aden
Advocate I
Advocate I

Great thanks Owen. That done the trick!

Cheers

OwenAuger
Super User
Super User

Hi @Aden 

In order to filter on months before the current month, I would suggest using EOMONTH to get the last date of the previous month, then filter on dates <= that date. This can be wrapped in KEEPFILTERS to intersect with the current filter context.

 

Here is how you could write the measure:

(Note: I'm assuming your 'Calendar' table is marked as a date table, and 'Calendar'[trandate] is the date column.)

Fees % of Budget to last month 2 =
CALCULATE (
    DIVIDE ( [Net Fees], SUM ( 'Budgets'[billamt_perday] ) ) * 100,
    KEEPFILTERS ( 'Calendar'[trandate] <= EOMONTH ( TODAY (), -1 ) )
)

Does this give the expected result?

 

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

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.

Top Solution Authors