- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Need help to get the conditional average in power query
Hi,
I am a newbie to PowerQuery. I need a M Query solution to the below problem
Suppose I have a Country column, Value column. Now I wanted to average the Value column not equal to 0, for each country in the country column. Kindly see the below example.
Let me know if you have any questions.
Thank you...
Vj
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hi, Fowmy's solution surely works. When your dataset consists of 2k+ rows, you might try this,
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg1W0lEyNFCK1YGxTRFsIyQ2VIk3SBiJDVPuDVfiGIrKNERmQ1Q7OyLEwWwgMxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Value = _t]),
#"Added Custom" = Table.AddColumn(Source, "Custom", each Table.Group(Source, {"Country"}, {{"grouped", each _}}){[Country = [Country]]}[grouped][Value]),
Avg = Table.TransformColumns(#"Added Custom", {{"Custom", each List.Average(List.RemoveItems(List.Transform(_, Number.From), {0}))}})
in
Avg
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hello
the simplest thing is to include all in ONE Group-Step... the average except 0 and All rows (to keep the value-column for later)
Check it out
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg1W0lEyNFCK1YGxTRFsIyQ2VIk3SBiJDVPuDVfiGIrKNERmQ1Q7OyLEwWwgMxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", type number}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Country"}, {{"Average", each List.Average(List.Select([Value], each _ >0)), type number}, {"AllRows", each _, type table [Country=text, Value=number]}}),
#"Expanded AllRows" = Table.ExpandTableColumn(#"Grouped Rows", "AllRows", {"Value"}, {"Value"})
in
#"Expanded AllRows"
This function of the group-function makes the average without 0
{"Average", each List.Average(List.Select([Value], each _ >0)), type number}
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Try this:
// output
let
Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65Wcs4vzSspqlSyUgoNVtJRCkvMKU1VsjI0qNXBKWeKW84Ijxy6kd5I2vDIYVjnjdNIx1CipNA9hyKHZpuzI259yHIGtbEA", BinaryEncoding.Base64),Compression.Deflate))),
group = Table.Group(Source, {"Country"}, {"Foo", each Table.SplitColumn(_, "Value", (val)=>{val, List.Average(List.RemoveItems([Value], {0}))}, {"Value", "Avg"}), type table}),
result = Table.Combine(group[Foo])
in
result
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hi, Fowmy's solution surely works. When your dataset consists of 2k+ rows, you might try this,
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg1W0lEyNFCK1YGxTRFsIyQ2VIk3SBiJDVPuDVfiGIrKNERmQ1Q7OyLEwWwgMxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Value = _t]),
#"Added Custom" = Table.AddColumn(Source, "Custom", each Table.Group(Source, {"Country"}, {{"grouped", each _}}){[Country = [Country]]}[grouped][Value]),
Avg = Table.TransformColumns(#"Added Custom", {{"Custom", each List.Average(List.RemoveItems(List.Transform(_, Number.From), {0}))}})
in
Avg
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hi @CNENFRNL ,
Could you please help me understand the 2nd and 3rd step?
Also kindly let me know the best way to learn the power query... I followed a book to learn, but it looks like I don't know anything 😞
Thanks and regards,
Vj
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hello
the simplest thing is to include all in ONE Group-Step... the average except 0 and All rows (to keep the value-column for later)
Check it out
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg1W0lEyNFCK1YGxTRFsIyQ2VIk3SBiJDVPuDVfiGIrKNERmQ1Q7OyLEwWwgMxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", type number}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Country"}, {{"Average", each List.Average(List.Select([Value], each _ >0)), type number}, {"AllRows", each _, type table [Country=text, Value=number]}}),
#"Expanded AllRows" = Table.ExpandTableColumn(#"Grouped Rows", "AllRows", {"Value"}, {"Value"})
in
#"Expanded AllRows"
This function of the group-function makes the average without 0
{"Average", each List.Average(List.Select([Value], each _ >0)), type number}
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Hi, @anvikuttu , in my code, step 2 and 3 finish the following tasks respectively,
step 2 adds an extra column; in this column each row contains a list of all values of the same country;
step 3 averages the list in step 2 excluding 0.
As to the study of M language, I myself is also a learner for half of a year or so. I recommend such a roadmap,
Study fundamental concepts of M, in particular, table/list/record, relationships and conversions from one to another;
Spend some time studying codes by UI;
Try to master some most frequently used functions such as Tabel.AddColumn, Table.TransformColumns, etc.
Use advanced editor to practise user defined functions.
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

@anvikuttu
Click Add Column < Custom and paste the below code to get the average excluding zero and by country.
(r)=>
List.Average(
Table.SelectRows(#"Changed Type", each [VALUE] <> 0 and [COUNTRY] = r[COUNTRY])[VALUE])
________________________
If my answer was helpful, please consider Accept it as the solution to help the other members find it
Click on the Thumbs-Up icon if you like this reply 🙂
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group

Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Power BI Monthly Update - February 2025
Check out the February 2025 Power BI update to learn about new features.

Subject | Author | Posted | |
---|---|---|---|
04-20-2024 06:08 AM | |||
05-16-2024 02:50 AM | |||
09-12-2024 04:19 AM | |||
10-16-2023 07:38 AM | |||
01-22-2023 05:09 AM |
User | Count |
---|---|
26 | |
25 | |
24 | |
13 | |
10 |
User | Count |
---|---|
24 | |
21 | |
18 | |
17 | |
10 |