fbpx

Aggregate Text Values Using Group By in Power Query #12

Power Query - Grouping Text Values - 1. Concatenate Text

Most users know the Group By function in Power Query. It allows you to summarize data and aggregate underlying values. The standard aggregations are Average, Median, Min, Max, Count Rows, Count Distinct Rows and All Rows. Most of these are aimed at numbers. Power Query can however perform different operations more relevant to text. In this post you learn how to group your data and concatenate the underlying text values into a single cell.

Challenge

Imagine below data set. Your goal is to summarize the data, so that only a single row is available for each product. And on top of that, the total sales for this product should be available. This can all be done using the UI (user interface). The challenge here is to also add the underlying names of the sellers into a column. We will have to write some custom code here. Let’s get going!

Power Query - Grouping Text Values - 2. Imported Data

After pulling the blue coloured table into Power Query, you land at below setup:

The first steps can be through the user interface. Let’s summarize the data by Product and Sum the underlying sales. To do that:

  • Go to the Home Tab -> Click Group By

Power Query - Grouping Text Values - 3. Group Data

In the Pop-up screen:

  • Click Advanced
  • Group By -> Product
  • In the aggregation section, add a new column name called ‘Sales’, set the operation to Sum and select Column ‘Sales’.

So far everything can be done by the user interface. The challenge left is to add a column containing all the seller names. The user interface does not provide the right code. Yet it does give an indication of how to write an argument for the Table.Group operation. Therefore it’s comfortable to add a ‘dummy’ aggregation, just so the setup is almost done. What you can do is:

  • Add another aggregation with the name ‘Sellers’, use the Sum Operation and name the column ‘Seller’.
  • Click OK

Power Query - Grouping Text Values - 4. Specify Aggregations

The data is now grouped by Product, and has added the underlying sales. Notice that the last column contains an error. This error occurs since we told Power Query to perform a SUM operation on text values. Clearly, the SUM operation only works on numbers.

Power Query - Grouping Text Values - 5. Troubleshoot

Yet for our purposes, this setup is great. We can now correct the wrong formula without having to write everything from scratch.

How does Table.Group Work

Before we can change the code, it’s good to have a look at how Power Query groups data. When grouping data, Power Query uses the Table.Group formula. You can read more on this here.

The Table.Group formula takes three variables. It needs:

  1. a table. In this case the step #”Changed Type” refers to a table.
  2. the key columns. These columns specify the columns to group the data by. In this case the column named “Product” is the key to group the data by.
  3. aggregated columns as list. The formula’s that are used to aggregate the data should be able to handle a list. The underlying data is always provided as a list for aggregations. In the example the formula List.Sum is used to sum the sales numbers.

Please focus on step 3 for a moment. This argument provides a crucial hint for what formulas you can use to summarize text values. The aggregation formula needs to be able to handle a list as variable. When searching the Power Query formula reference you may stumble upon the formula Text.Combine. A formula that both combines text and takes a list as input. The formula returns a text value that is the result of joining all underlying text values. And each value that is concatenated, can be separated using a separator.

As input arguments, the formula requires text to concatenate (as a list) and it needs to know with what separator to use. This is exactly what we need for our challenge.

Manually Adjusting M-Code

You now know what formula to use for aggregating text. It’s time to adjust the M-code generated by the user interface. We can try to incorporate the Text.Combine formula in the formula containing the error. The part of the formula returning an error is:

{“Seller”, each List.Sum( [Seller] ), type text}

To have it use the Text.Combine function you can change it to:

{“Seller”, each Text.Combine( [Seller] , “, “), type text}

The first argument indicates which column (received as a list) provides the text to combine. In this case the column ‘[Seller]’. The second argument tells us what separator to add between the text. The example contains a comma and a space (“, “). After pressing Enter, below screenshot is the result!

Power Query - Grouping Text Values - 6. End Formula

The names of the Sellers are now all within the same cell, and don’t return an error anymore. Goal reached! That’s how easy adjusting M-Code can be. You’ll get more comfortable with writing code the more you do it.

In this post you have learned that grouping data causes the underlying data to be provided to aggregation functions as a list. Knowing this, you can leverage functions that take a list as argument, when grouping your data. I hope this post opens your mind for more experimentation. If you have any questions, or stumble upon useful formulas to leverage when grouping, please leave a comment below.

Rick de Groot

My name is Rick and my goal is to help you advance with Excel and Power BI. I believe learning is one of the great pleasures in life and I want to share my knowledge with you to help you improve your skills.

3 Responses

Share Your Thoughts!