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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
vbvbvb
Employee
Employee

Add filter to show specific values in calculated columns

Hi all,

 

Trying to solve following task.  I have data in more or less same format, where final goal is to calculate Aveage value based on Month and Year values:

 

Name of colourCertain Value Month YearAverage Value
Red1Oct2022Calculation which shows avearge value based month and year
Red4Nov2022 

Green

5Sept2022 
Green2Aug2022 
Blue 3Oct2022 
Blue4Oct2022 

 

This caluclation now is done via following DAX column:

 

AvgValue =
VAR _table =
    FILTER (TableName, TableName[Year] = EARLIER (TableName[Year]) && TableName[Month] = EARLIER (TableName[Month]) && TableName[Certain Value] <> BLANK())
RETURN
    SUMX ( _table, TableName[Certain Value] / COUNTROWS ( _table )

 

How can I add additional filter to this expression to filter also per name of colour, i.e Red, Green, Blue, so it would be average value per colour value per month+year?

I tried to create 3 additional columns per each colour and add filter values like && TableName[Name of Colour] = "Red" to merge them later into cominbed column , but I still get all values populated in regardless of text value in filter and they are wrong anyways.

 

What would be  correct way to implement such filtering? Appreciate all advice and help!

1 ACCEPTED SOLUTION

Hi @vbvbvb

Modify the formula to:

AvgValue Blue =
VAR _table =
    FILTER (
        TableName,
        TableName[Year] = EARLIER ( TableName[Year] )
            && TableName[Month] = EARLIER ( TableName[Month] )
            && TableName[Certain Value] <> BLANK ()
            && 'TableName'[Name of colour] IN { "Blue" }
    )
RETURN
    IF (
        [Name of colour] IN { "Blue" },
        SUMX ( _table, TableName[Certain Value] / COUNTROWS ( _table ) )
    )

I add an if condition in the code, tweak the color in different color columns.

 

I attach my sample below for your reference.

Best Regards,
Community Support Team _ kalyj

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

7 REPLIES 7
vbvbvb
Employee
Employee

That works, thank you very much for all advice!

v-yanjiang-msft
Community Support
Community Support

Hi @vbvbvb ,

According to your description, here's my solution. Modify the formula like this:

AvgValue =
VAR _table =
    FILTER (
        TableName,
        TableName[Year] = EARLIER ( TableName[Year] )
            && TableName[Month] = EARLIER ( TableName[Month] )
            && TableName[Certain Value] <> BLANK ()
            && 'TableName'[Name of colour] = EARLIER ( TableName[Name of colour] )
    )
RETURN
    SUMX ( _table, TableName[Certain Value] / COUNTROWS ( _table ) )

Get the correct result:

vkalyjmsft_0-1669343085551.png

I attach my sample below for your reference.

 

Best Regards,
Community Support Team _ kalyj

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

Thanks @v-yanjiang-msft , I will try that approach. Just extra quesiton, how  this condition can be expanded to multiple values, for example Red + Blue + Green (and many more)? Does this method scale up?

            && 'TableName'[Name of colour] = EARLIER ( TableName[Name of colour] )

  

No, this doesn't work - I need something like this :

vbvbvb_1-1669371451630.png

Your calculation doesn't filter text values of colour column - I basically need average calculation to happen only if there's hard match of 1 or many values (up to 15 values).

 

Hi @vbvbvb ,

If you want to custom the color, tweak the formula like this:

AvgValue Green+Blue =
VAR _table =
    FILTER (
        TableName,
        TableName[Year] = EARLIER ( TableName[Year] )
            && TableName[Month] = EARLIER ( TableName[Month] )
            && TableName[Certain Value] <> BLANK ()
            && 'TableName'[Name of colour] IN { "Green", "Blue" }
    )
RETURN
    SUMX ( _table, TableName[Certain Value] / COUNTROWS ( _table ) )

You can see, in the formula I only want to calculate the average of Green and Blue, get the correct result:

vkalyjmsft_0-1669605075022.png

You can tweak the formula according to your condition.

 

I attach my sample below for your reference.

Best Regards,
Community Support Team _ kalyj

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

When I add  this part, column still returns all values for all rows regardless of what actual value 'TableName'[Name of colour] has:

 

 

 

 

 

            && 'TableName'[Name of colour] IN { "Green", "Blue" }

 

 

 

 

It doesn't exclude , for example "Red"  from "AvgValue Green+Blue" like in your example, despite DAX and inputs being identical. 

 

It doen't work even in your PBIX example, if change value to only "Blue", it shows "Blue" and "Green": 

vbvbvb_0-1669627065291.png

And if change to "Red" and "Blue", it shows all values: 

vbvbvb_1-1669627113533.png

 

It seems that filter becames invalid when "month" and "year" are matching :

 

vbvbvb_2-1669627524188.png

If there any way to make more explicit filter which filters colour value first and then from it's results looks at month and year for average calculation?

 

 

Hi @vbvbvb

Modify the formula to:

AvgValue Blue =
VAR _table =
    FILTER (
        TableName,
        TableName[Year] = EARLIER ( TableName[Year] )
            && TableName[Month] = EARLIER ( TableName[Month] )
            && TableName[Certain Value] <> BLANK ()
            && 'TableName'[Name of colour] IN { "Blue" }
    )
RETURN
    IF (
        [Name of colour] IN { "Blue" },
        SUMX ( _table, TableName[Certain Value] / COUNTROWS ( _table ) )
    )

I add an if condition in the code, tweak the color in different color columns.

 

I attach my sample below for your reference.

Best Regards,
Community Support Team _ kalyj

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

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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