Traducir el blog

Power Query - multiple slicers (4/4)

Posted on julio 15, 2021 by Excel Pedro Wave

This is the fourth solution with Power Query to transform a poorly designed table into a pivot table but with multiple repeating rows.

In the following dynamic image you can see the 9 steps applied to transform the table.


Fourth solution

This fourth and last solution doesn't use a generic function, as in the previous solutions, it only uses these 9 steps applied with Power Query, which can be seen in the Advanced Editor:

Below I explain each of these applied steps:

1) Source = Excel.CurrentWorkbook(){[Name="TableDetails"]}[Content]

TableDetails is the original table with the Details column, with the details of the 3 data types listed in the Type column: Locations, Ages & Skills. The rest of columns are names of people with a Y o y to indicate that they are part of a specific detail of one of the data types. For example, Mary has been to two different locations: London & Joburg, which should be considered when pivot the table in the step 7).


2) #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"Type", "Details"}, "Name", "Value"),

In this step, the 2 columns on the left (Type & Details) are selected to unpivot the columns with Names, creating a normalized table with 2 additional columns: Name & Value, inserting a row for each pair of values of those columns. Null values don't create new rows. The Table.UnpivotColumns function forces the selected columns to be unpivoted, so the Table.UnpivotOtherColumns function is used, which is independent of the number of columns to be unpivoted, so it is not necessary to select each column with a Name who, a priori, it is not known.


3) #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Value"}),

The Value column is not relevant so it is removed. Notice that it contains both the uppercase Y letter and the lowercase y letter, to indicate that a type detail exists for a given name.


4) #"Group Clust Index" = Table.Group( #"Removed Columns",

List.RemoveItems(Table.ColumnNames(#"Removed Columns"),{"Details"}),

{"ColOfTables",each Table.AddIndexColumn(_,"idx")}),

This step is very important because it creates a column composed of "ColOfTables" tables, one for each pair of Type & Name values, with as many rows as there are Details records for each pair of Type & Name values, adding a consecutive index column " idx" to distinguish each row in that table. The 18 rows from above step 3) have been converted to 15 rows in which the Type & Name value pairs are not duplicated.


5) #"Expanded ColOfTables" = Table.ExpandTableColumn(#"Group Clust Index", "ColOfTables",        {"Details", "idx"}, {"Details", "idx"}),

This step expands the values of the tables of the column "ColdOfTables" in two columns: Details & idx (index of each table), so that the 15 rows become 18 rows in this case, being 3 details with the same pair of Type & Name values, and their indices are 0 and 1 respectively.


6) #"Sorted Rows" = Table.Sort(#"Expanded ColOfTables",{{"idx", Order.Ascending}}),

The trick to correctly pivot this table in the next step 7) is that the index column "idx" is in ascending order.


7) #"Pivoted Column" = Table.Pivot(#"Sorted Rows", List.Distinct(#"Sorted Rows"[Type]), "Type",        "Details"),

This step pivots the table by creating 3 Type columns: Ages, Skills & Locations, with their Details values for each Name. It is observed that it is not an ordinary pivot table, as there are duplications in the Name column, discriminated by the index "idx" column.


8) #"Removed Index" = Table.RemoveColumns(#"Pivoted Column",{"idx"}),

Right now you can remove the index "idx" column, as it has already played its role pivoting the table with repeated names into the several rows.


9) #"Filled Down" = Table.FillDown(#"Removed Index",{"Locations", "Ages", "Skills"})

This last step fills in the nulls with the values on the above row that correspond to the same Name.


This fourth solution allows you to see the result of each step applied in the Power Query Editor, which is not elementary with a generic function, since it applies all the steps without being able to see what each step does with the tables tranformation. This solution also makes it easier to copy these steps in M language code from the Power Query Advanced Editor to paste it into another Excel workbook or even into Power BI.

These 9 steps are a good example that Power Query is an excellent ETL tool to Extract, Transform & Load. An additional loading step is done just before closing the Power Query Editor, choosing to load the transformed table as a normal Excel table.

It is possible to insert in this table 3 slicers, one for Locations, another for Ages and another for Skills, as it was intended to achieve in the statement of the problem that was raised in this forum:

MrExcel.com - multiple slicers
I have a table of data with locations, ages, and skills in the left hand column. Can a slicer be set up for each data type? ie one for the locations, one for the ages, and one for the skills.


Fourth solution download

  • From this link to Microsoft OneDrive:

Multiple Slicers PW4.xlsx

  • From this link to Sites Google Drive:

Multiple Slicers PW4.xlsx


This post completes the 4 solutions proposed to solve this problem, which I hope will help my readers to start and experiment with Power Query, with all its potential as an ETL tool, which allows solving complex problems without the need to program avanced Excel formulas and/or macros VBA.

No Response to "Power Query - multiple slicers (4/4)"

Leave A Reply

Dime si te gusta lo que lees y, si no te gusta, dime por qué. Tengo habilitada la moderación de comentarios. Tu comentario se publicará pronto.

Mi lista de blogs