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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
Amrselim1989
Helper II
Helper II

Allselected with filtration

hello Guys,

i hope you can help me with this,

 

i have this code

VAR MaxSales = MAXX ( ALLSELECTED ( dimDate[Year], dimDate[Month], DimDate[MMM] ), [Sum of Net Sales Value] ) 
VAR
MinSales = MINX ( ALLSELECTED ( dimDate[Year], dimDate[Month], dimDate[MMM] ), [Sum of Net Sales Value] )
VAR
Result = IF ( [Sum of Net Sales Value] = MaxSales || [Sum of Net Sales Value] = MinSales,
[Sum of Net Sales Value],
" " )
RETURN
Result

 which is working so fine for me, except for one thing, i wish i can filter this code the min and max value doesn't consider the current month's date in it, because it always shows the current month as the Min sales wish is natural cause the month didn't finish yet...

so I wish to remove the month of July 2023 from this code...

Any help, please?!!

1 ACCEPTED SOLUTION
Martin_D
Super User
Super User

Hi @Amrselim1989 ,

I have two options in my mind to solve this. 

#1 You could in you measure get the latest date with sales data, derive year and month from this date, and filter your data table for including only months before that current month.
# 2 You can add a column to your dimDate table that marks current and previous months and then in the measure you can use this column to only include previous months. This is what I'm gonna show you.

 

Add this as a calculated column to you dimDate Table:

 

Running Month = DATEDIFF ( TODAY(), 'dimDate'[Date], MONTH )

 

This will give you a column that contains 0 for the current month, -1, -2, -3, ... for past months and 1, 2, 3, ... for future month. Instead of using TODAY() in the code, you can alternatively relate to your last date with sales as today if there is some delay in your data processing pipeline until sales data actually arrives in your report.
Then wrap you code into a CALCULATE() function that exludes the current (and future) months:

 

CALCULATE (

    VAR MaxSales = MAXX ( ALLSELECTED ( dimDate[Year], dimDate[Month], DimDate[MMM] ), [Sum of Net Sales Value] ) 
    VAR MinSales = MINX ( ALLSELECTED ( dimDate[Year], dimDate[Month], dimDate[MMM] ), [Sum of Net Sales Value] ) 
    VAR Result = IF ( [Sum of Net Sales Value] = MaxSales || [Sum of Net Sales Value] = MinSales, 
    [Sum of Net Sales Value],
     " " ) 
    RETURN Result

    ,KEEPFILTERS( 'dimDate'[Running Month] < 0 )
)

 

 BR

Martin

github.pnglinkedin.png

View solution in original post

2 REPLIES 2
Martin_D
Super User
Super User

Hi @Amrselim1989 ,

I have two options in my mind to solve this. 

#1 You could in you measure get the latest date with sales data, derive year and month from this date, and filter your data table for including only months before that current month.
# 2 You can add a column to your dimDate table that marks current and previous months and then in the measure you can use this column to only include previous months. This is what I'm gonna show you.

 

Add this as a calculated column to you dimDate Table:

 

Running Month = DATEDIFF ( TODAY(), 'dimDate'[Date], MONTH )

 

This will give you a column that contains 0 for the current month, -1, -2, -3, ... for past months and 1, 2, 3, ... for future month. Instead of using TODAY() in the code, you can alternatively relate to your last date with sales as today if there is some delay in your data processing pipeline until sales data actually arrives in your report.
Then wrap you code into a CALCULATE() function that exludes the current (and future) months:

 

CALCULATE (

    VAR MaxSales = MAXX ( ALLSELECTED ( dimDate[Year], dimDate[Month], DimDate[MMM] ), [Sum of Net Sales Value] ) 
    VAR MinSales = MINX ( ALLSELECTED ( dimDate[Year], dimDate[Month], dimDate[MMM] ), [Sum of Net Sales Value] ) 
    VAR Result = IF ( [Sum of Net Sales Value] = MaxSales || [Sum of Net Sales Value] = MinSales, 
    [Sum of Net Sales Value],
     " " ) 
    RETURN Result

    ,KEEPFILTERS( 'dimDate'[Running Month] < 0 )
)

 

 BR

Martin

github.pnglinkedin.png

Thank you man, you are a genius 🙂

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

AugPowerBI_Carousel

Power BI Monthly Update - August 2024

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

August Carousel

Fabric Community Update - August 2024

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