March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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 colour | Certain Value | Month | Year | Average Value |
Red | 1 | Oct | 2022 | Calculation which shows avearge value based month and year |
Red | 4 | Nov | 2022 | |
Green | 5 | Sept | 2022 | |
Green | 2 | Aug | 2022 | |
Blue | 3 | Oct | 2022 | |
Blue | 4 | Oct | 2022 |
This caluclation now is done via following DAX column:
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!
Solved! Go to 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.
That works, thank you very much for all advice!
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:
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 :
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:
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":
And if change to "Red" and "Blue", it shows all values:
It seems that filter becames invalid when "month" and "year" are matching :
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.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
123 | |
86 | |
73 | |
58 | |
52 |
User | Count |
---|---|
197 | |
133 | |
107 | |
69 | |
65 |