Power Query: Group Text
5 May 2021
Welcome to our Power Query blog. This week, I look at how to modify a grouping statement to accommodate text fields.
I have some data for my imaginary salespeople:
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image1.png/e774d10cbbb9450fc45efbe51abdf434.jpg)
They have been selling off some of the old stock, and I want to see the sales figures for each tent type and who has sold it. I start by extracting my data into Power Query using ‘From Table / Range’ in the ‘Get & Transform Data’ section of the Data tab.
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image2.png/f32e5a15e2cf9c3e4d2d058458ce054d.jpg)
I accept the ‘Create Table’ defaults and view my data in the Power Query Editor.
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image3.png/f1140ff857fc3b6f5f97a6a24f4a6fc7.jpg)
I am going to group my data using the ‘Group By’ option on the Transform tab.
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image4.png/72aa864d2854c6fefb1083fba0ab5792.jpg)
I want to group by Tent Type. To begin with, I want to see the sales totals:
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image5.png/36776d1da4d05b45bb5a5d09375f407c.jpg)
I can achieve this by grouping on Tent Type and summing Price.
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image6.png/23912d3b1671861e02bebcd5183f1607.jpg)
I also want to see which salespeople sold the tents. I go back to the ‘Grouped Rows’ step.
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image7.png/6f49c288a0d88a66b427eaf4ece923d6.jpg)
If I go into the ‘Advanced’ options, I can add another aggregation, but all the operations are aimed at numerical values. However, I am going to go ahead and use a sum, and then amend the M code produced.
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image8.png/b9ee28d90e6b5bc92ea4aeafdad51628.jpg)
This gives me an error, which is not surprising since I am trying to add up text values!
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image9.png/0485ccbc83bdeec1d741bad442a1ea5f.jpg)
Having failed to add up Derek, I look at the M code produced:
= Table.Group(#"Changed Type", {"Tent Type"}, {{"Sales Total", each List.Sum([Price]), type nullable number}, {"Sold By", each List.Sum([Salesperson]), type nullable text}})
I am interested in the code associated with the Sold By column.
{"Sold By", each List.Sum([Salesperson]), type nullable text}
This is currently using List.Sum() to add up the Salesperson column. If I am going to add up text, then I need a text function Text.Combine(). This will allow me to compile a list of the salespeople, separated by a separator of my choice.
{"Sold By", each Text.Combine([Salesperson], “, “), type nullable text}
I have chosen to separate the salespeople with a comma and a space. The full step now looks like this:
= Table.Group(#"Changed Type", {"Tent Type"}, {{"Sales Total", each List.Sum([Price]), type nullable number}, {"Sold By", each Text.Combine([Salesperson], “, “), type nullable text}})
![](http://sumproduct-4634.kxcdn.com/img/containers/main/blog-pictures/2021/power-query/231-2/image10.png/daf8c4f0259ce428269c0d3d4badd32b.jpg)
I now have a list of salespeople in the Sold By column.
Come back next time for more ways to use Power Query!