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

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.

anvikuttu_0-1600515234584.png

 

Let me know if you have any questions.

 

Thank you...

Vj

2 ACCEPTED SOLUTIONS
CNENFRNL
Community Champion
Community Champion

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!

View solution in original post

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

View solution in original post

6 REPLIES 6
ziying35
Impactful Individual
Impactful Individual

@anvikuttu 

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
CNENFRNL
Community Champion
Community Champion

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!

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

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

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!

Fowmy
Super User
Super User

@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])

Fowmy_0-1600517421919.png

________________________

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 🙂

YouTube  LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

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
Top Kudoed Authors