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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
MP-iCONN
Resolver I
Resolver I

Group Columns using Power Query with Multiple Conditions

I have been converting all of my companies reports from an online system Chartio, which is closing shop in March of 2022, and one of the nice things about that system is you could do Groupings on Columns by MIN, MAX, COUNT DISTINCT, and of course GROUPING (see screenshot below).  I know how to do basic Group By using Power Query but how would you go about doing all of these at once in the Group By function?  Any advice or push in the right direction would be greatly appreciated.

 

Here is a screenshot from the Chartio report writer:

 

MPiCONN_0-1636488633649.png

 

Here is the sample of my data in Power Query:

 

MPiCONN_1-1636488691307.png

 

 

1 ACCEPTED SOLUTION

Hi, @MP-iCONN 

 

You can modify the count part in your original code.

Like this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCvc3sjQwNFLSUTIyMLTUNTDTNbIEciA4VgerAgsgxxSMsSkw1zUAcQwNIAQOJcYgWUMIgaokrzQnByQOxjh0g1wAFlCKjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"WO ID" = _t, #"Day of WKE Lab Start Time" = _t, #"Avg Emp Count" = _t, #"Max Emp Count" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"WO ID", type text}, {"Day of WKE Lab Start Time", type date}, {"Avg Emp Count", Int64.Type}, {"Max Emp Count", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"WO ID"}, {{"Avg", each List.Average([Avg Emp Count]), type nullable number}, {"Max", each List.Max([Max Emp Count]), type nullable number}, {"Count", each Table.RowCount(Table.SelectRows(_,(x)=>x[Day of WKE Lab Start Time]<>null)), Int64.Type}})
in
    #"Grouped Rows"
Table.SelectRows(_,(x)=>x[Day of WKE Lab Start Time]<>null)

vjaneygmsft_1-1636713176497.png

Did I answer your question ? Please mark my reply as solution. Thank you very much.
If not, please feel free to ask me.


Best Regards,
Community Support Team _ Janey

View solution in original post

4 REPLIES 4
smpa01
Community Champion
Community Champion

@MP-iCONN  any chance you can provide sample data and desired output in a table format?

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Actually to make it easier I think I found a way to do this but now I am only stuck on this.  How to get a count of "Day of WKE Lab Start Time" and not include the null.

 

I took this data:

 

WO IDDay of WKE Lab Start TimeAvg Emp CountMax Emp Count
WO290122019-06-2999
WO290122019-06-2855
WO290122019-07-021010
WO290122019-07-031111
WO29012null11
WO290122019-07-0822


Then grouped like this to get the count (which I am not sure I am doing right with the count part):

 

MPiCONN_0-1636564316905.png

 

Then got this.  I ultimatly should have a count of 5 for the "Day of WKE Lab Start Time"

 

WO IDAvgMaxCount
WO290126.33333333333333116

 

Hi, @MP-iCONN 

 

You can modify the count part in your original code.

Like this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCvc3sjQwNFLSUTIyMLTUNTDTNbIEciA4VgerAgsgxxSMsSkw1zUAcQwNIAQOJcYgWUMIgaokrzQnByQOxjh0g1wAFlCKjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"WO ID" = _t, #"Day of WKE Lab Start Time" = _t, #"Avg Emp Count" = _t, #"Max Emp Count" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"WO ID", type text}, {"Day of WKE Lab Start Time", type date}, {"Avg Emp Count", Int64.Type}, {"Max Emp Count", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"WO ID"}, {{"Avg", each List.Average([Avg Emp Count]), type nullable number}, {"Max", each List.Max([Max Emp Count]), type nullable number}, {"Count", each Table.RowCount(Table.SelectRows(_,(x)=>x[Day of WKE Lab Start Time]<>null)), Int64.Type}})
in
    #"Grouped Rows"
Table.SelectRows(_,(x)=>x[Day of WKE Lab Start Time]<>null)

vjaneygmsft_1-1636713176497.png

Did I answer your question ? Please mark my reply as solution. Thank you very much.
If not, please feel free to ask me.


Best Regards,
Community Support Team _ Janey

@smpa01 sure.  Attached are two csv files.  The one called Sample_Data_Before_Grouping.csv is before and grouping's are taken place. The second file, Sample_Data_After_Grouping.csv is after those groupings are taken place from my Chartio screenshot.

 

Before:

https://mechanicalproducts-my.sharepoint.com/:x:/g/personal/csullivan_mechprod_com/Eeu7n1_gvp9OkReWz...

 

After:

https://mechanicalproducts-my.sharepoint.com/:x:/g/personal/csullivan_mechprod_com/ESIWGF2xRhxMrCARy...

 

Thank you for your help on this! 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.