Grouping or Summarizing Data

Grouping or Summarizing Data to Create Compelling Reports

The Scenario

One of the most common request of an Excel pro is to group and summarize data. This pattern shows you how to create a compelling report from just a single source of data, which can be refreshed at any time with a single click.

The scenario uses a simple sales table which includes a listing of all products (t-shirts) sold, the date of sale, the sales channel and the total sales dollars for the product on that specific date.

Our goal is to create a report that shows, for each day in the sales period:

  • Total sales by channel,
  • A list of all the products sold on that day (separated by commas),
  • The name of the product with the highest sales, and
  • The % share of total sales for the top selling product.

Download the Workbook

Our Goals

We will start from a source table that has the following columns:

  • Date
  • ProductName
  • ChannelName
  • Amount

Our goal is to create a final report that summarizes that data and lists:

  • The total amount per day for each channel,
  • The total products sold in that channel,
  • All the products sold, and
  • The product with the highest sales.

Transformating by Grouping

We can break these into three separate sub-goals:

  1. Create the column that sums all the amounts by date and channel,
  2. Create a new column that represents a list of all the products separated by a commas, and
  3. Create two extra columns that give us the name of the top selling product and its proportion of the total sales.

Let’s find out we can get from the Source Table to the Desired Result.

The Start

Once you open the workbook, head over to the Sales worksheet, where you’ll find a table. Select any cell inside that table, click the Power Query tab and choose From Table.

FromTable

You’ll now be launched into the Power Query editor.

Goal 1: Grouping and Total Sum Column

Our first step starts by grouping the rows in our table using some criteria. Click the Group By button and set it up using the following criteria:GroupBy

That should give us a table with a fewer amount of rows because all the data has been grouped by Date and Channel Name. We’ve even managed to create some new data as well, by creating a SUM of the Amount column, and a Count of Distinct Rows (yielding a count of distinct products by channel by day). We’ve also got a list of all products in the final step, which will make a bit more sense later…

A Best Practice: Define DataTypes

Whenever you pull a date into Power Query, we highly recommend that you specifically define the datatype for the date column. If you don’t, the data could be treated as type “any”, which means that it could land as either text or a value in your output instead of a date. It’s not hard to do at all, simply select the column header, go to the Transform tab, and change the Data Type to Date:

Date

So we’ve now got a Total Sales and a Total Products by Channel, finishing our first goal.

Goal 2: Create a Comma Separated List of all Products Sold Each Day

Our next step is to create a formula for a new column that somehow:

  1. Takes all the products that were sold on that specific date and channel
  2. Creates a list of those products
  3. Transforms that List into a table
  4. Transposes that table into a table with multiple columns
  5. Merges all those columns delimited by a comma

Formula List

This is the formula that does just that using Table.ToList Table.Transpose Table.FromList Table.Column and the Combiner function:
Table.ToList(
Table.Transpose(
Table.FromList(
Table.Column([Products], "ProductName")
)
),
Combiner.CombineTextByDelimiter(", ")
)

What this formula is doing...

To better explain what this formula is doing, we are going to do each part of that formula as a new step. The formula defined above basically does all of these steps in a single step.

We start with the most inner function and that is Table.Column([Products], “ProductName”):

what this formula does is simply extract a column from a table and present it to us a List. So we end up having a list with the values from the ProductName column.

The next step is to transform that list into a Table so it can be easier for us to perform other type of operations. The function that transform a list into a table is called Table.FromList and we’ll use it now:
TableToListProductNameas you can see from the picture above, the new column has Table values for that whole column. We did that because we want to use another function to transpose those rows into columns. That function is Table.Transpose and that formula should read like this:

TransposeProductName

the result of that is basically a transposed table. So if we had N amount of rows and only 1 column now we’ll have 1 row with N amount of columns.

Our next step is to combine all the columns using a format similar to “Value1, Value2, Value3, …, ValueN”.

To do that, we use a Table.ToList that automatically does the operation of concatenating all of the strings into a single value. By Default, it uses a comma separator but in this case we want to go with a comma followed by a space (, ) and the second argument of Table.ToList allow us to do so by adding a Combiner function.

In our case, we’ll use this combiner function: Combiner.CombineTextByDelimiter(“, “) that does just exactly what we need.

And once you expand that column by clicking the arrows that go in opposite directions, and once we rename that column, this is the result of it:

RenamedColumnWe created the column that creates the list of all the products that were sold on that day, so we finished our 2nd goal. Let’s go to the next one.

Goal 3: Add columns for top sold Product and participation of it

Our next step is to extract the top product and also its amount on a row by row basis from the column Products which is this case is a table. We can do so by using a new custom column with the following Table.Max function:

Rankingonce you create this new column, you’ll notice that it’ll populate with records which is a special type of data representation in Power Query and what we need is to extract the ProductName and Amount from that record.

We can do so by simply clicking on the opposite arrows icon that are next to the name of this new column. Click on that icon and you’ll notice a new selection window where you can select what columns you want to extract from that record. For now, just select the ProductName and the Amount columns.

Once we rename those columns this is how our table should look like:

Reportpreview

We are almost there! we are missing the division of the Top Product amount over the Total Sales so we can get a % out of it. Let’s do so by adding a new custom column:

DivideAfter spending some more time cleaning the data, this should be the result of our hard work:

Final Result

You can click on Close & Load to save this table to your Workbook or inside your Data Model.

Note that you can refresh this at any time and it’ll work as desired.

Transform it into a Function

There are many ways to transform this into a function, but the basics of creating a function go into making a part of the whole code a variable.

Which one would you choose to make a variable? Let us know in the comments section below

This time, we’re choosing a simple variable. Since we need the Source step to be a table, let’s define that as our variable.

  1. First we go to the View tab and click on Advanced Editor
  2. Then we look at the M code in this Editor and replace the one that we’re trying to make a variable
  3. We replace it with a variable and add the variable before the code as shown in the picture below

Function
now we need to put this to the test. Let’s create a blank query and grab all the tables from our current Workbook using Excel.CurrentWorkbook():

Excel.CurrentWorkbook

next we add a custom column by using the name of the function that we just created which is the name of the Query SalesReport and the result should look like this:

ResultFunction

Power Query Patterns
Power Query Book
Power Query Workshop

this work was shared 0 times
 900
About

 Power Query Training

  (13 articles)

We are a team committed to delivering the best content for new and seasoned users of a tool that we believe in: Power Query. We firmly believe that this is THE best tool to be added to Microsoft Excel in a long time.

  • Joe Simonson

    Great tutorial and really helped me out to solve this exact issue that I was dealing with.

  • This scenario ends abruptly. What is the function supposed to be named? I’m not clear exactly what this function accomplishes.

    • Hey Sean, Thank you for your comment! We value your input.

      Are you referring to the function that we created in the “Transform it into a Function” section? or is it one of the M functions that was previously used to create the solution? The idea of us creating a function is to apply it to any dataset (in this case a table) that requires the same transformation steps and thus saving us time and effort.
      Best!

  • amanda

    I get this error which prevents me from loading to worksheet:

    [DataFormat.Error] There were more columns in the result than expected.

    • Hey amanda! are you getting this error from our example? I’m trying to reproduce it but I’m not getting the error message.

      If you’re receiving the error message from another example, then you’ll need to check your query step by step in order to see when the error occurs and why its happening. Reading the error message, it appears to be some sort of Data Format error, so you might want to check your data types and make sure that they are all defined and you don’t have data types under “any”.

      I’d suggest that you post your file and situation to this help forum:
      http://www.excelguru.ca/forums/forumdisplay.php?19-Power-Query-(Get-amp-Transform)

      Hope this helps.

      • amanda

        ok thanks will do!

    • amanda

      I belive the error is Due to there being a null value in the Columns being transposed to list; resulting in a list something like
      : a, ,b.

      Is there a quick way around this, aside from replacing null value in the applicable Column

      • good thinking! I highly recommend that you post your scenario in that forum. Would you mind posting the link here once you create the thread on the forum?

        best!

      • amanda

        Ok,I believe the error is Due there being Commas in the Field I am trying to Transpose and create list from

  • Prerana Singh

    can we import data from power bi to excel by the help of Get & Transform Tab. and make that data in Power Query and make a report with multiple files.
    I want this idea because my company used free power bi. where, i have work to download daily multiple files and then make a pivot table to all of them after consolidate(because the data are changes on daily basis).

x