Traducir el blog
Power Query - multiple slicers (4/4)
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:
- From this link to Sites Google Drive:
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.
Mi lista de blogs
-
Women for Technical Talks (W4TT) - 10º evento W4TT Women for Technical Talks (W4TT) es una comunidad de la que formo parte desde sus inicios y que trabajamos para impulsar la visibilidad y...Hace 1 día
-
CONSTRUIR APP PARA ENVIAR MENSAJES DE ONBOARDING A LOS EMPLEADOS NUEVOS CON IA - Hola a todos, Una de las acciones más importantes en la empresa hoy en día es el proceso de OnBoarding. Sí, en efecto, la primera … La entrada CONSTRUIR...Hace 1 día
-
Formulario de Captura en Excel usando VBA - Me lo han preguntado muchas veces: “Hey Sergio, ¿cuándo enseñas a hacer un formulario de captura en Excel? Pero uno […] The post Formulario de Captura en...Hace 2 días
-
Nuevo mapa de municipios - Magos - 🔝*To translate this blog post to your language, select it in the top left Google box. * *ATENCIÓN:* Texto circense generado por Microsoft Copilot a p...Hace 3 días
-
The TrimRange Function - I have just discovered the TRIMRANGE function, and its very useful shortcut version, which were introduced to Excel 365 about a year ago. The function excl...Hace 5 días
-
How to Use the COPILOT Function in Microsoft Excel - Wondering if you could use the mighty Copilot AI from Microsoft in your Excel workbooks to think and work faster? I’ve got you covered! Read on to learn ho...Hace 6 días
-
Primos pitagóricos - Después de dos entradas publicadas sobre ternas pitagóricas, es útil completarlas con las hipotenusas más simples, que son los primos pitagóricos, es dec...Hace 6 días
-
Mostrar datos de dos celdas en un cuadro de texto de Microsoft Excel - En Microsoft Excel es posible vincular el contenido de una celda a un cuadro de texto o a una forma. Vincular contenido de cuadro de texto a valor de cel...Hace 1 semana
-
Planilla Excel: Diseño de canales - Saludos a toda la comunidad de planillas Excel para ingeniería civil: Civil Excel, les presento esta hoja de cálculo que les ayuda a realizar el cálculo, d...Hace 1 semana
-
El error #¡NULO! y el operador de intersección - En este vídeo te muestro la utilidad del operador de intersección (el espacio) para hacer búsquedas en tablas de doble entrada. Te dejo una descripción… ...Hace 1 semana
-
Do Your Excel Files Collapse Like Jenga Blocks? - Before we dig into Modern Excel, can you please help me out? What, exactly, is “Modern Excel”? I can’t find a standard definition on the Microsoft site, or...Hace 5 semanas
-
Who is my boss’s boss? [Data Analytics Challenge – 001] - Let’s try something different. I will share a data analytics challenge here. Post your solutions in the comments. Our first challenge involves Employee D...Hace 3 meses
-
🛠️ Error Formula.Firewall en Power Query: ¿Qué es y cómo solucionarlo? - Power Query es una herramienta poderosa para transformar y combinar datos en Excel o Power BI. Sin embargo, en algunos escenarios comunes, puedes encontrar...Hace 3 meses
-
Cómo hacer gráficos en Excel - Excel es una de las herramientas más potentes y versátiles para el análisis y la presentación de datos. Los gráficos en Excel no solo ayudan a visualizar...Hace 7 meses
-
Fin - Llevo tiempo pensando esta entrada y no sé que decir. Analisis y Decisión nació en 2008 y no ... Leer más »Hace 9 meses
-
Análisis DAFO (FODA, DOFA) las decisiones con Excel - Para conocer la situación de una empresa, proyecto o persona, recurrimos al análisis DAFO (FODA, DOFA) en la toma de decisiones con Excel. El los años sese...Hace 11 meses
-
Color, Conditions, and Copilot: How to save time using conditional formatting with Copilot in Excel - Hi everyone, this is part 11 in a series of posts to show you some of the things that are possible to do with Copilot in Excel. *What is conditional f...Hace 1 año
-
How To Predict Bearing Life With Excel - When you work in mechanical engineering, understanding the reliability and performance of bearings under various conditions is crucial. Bearings are the co...Hace 1 año
-
TikTok’s search evolution - 2 in 5 Americans use TikTok as a search engine. Nearly 1 in 10 Gen Zers are more likely to rely on TikTok than Google as a search engine. More than half of...Hace 1 año
-
Unblocking and Enabling Macros - When Windows detects that a file has come from a computer other than the one you're using, it marks the file as coming from the web, and blocks the file....Hace 2 años
-
Office Scripts: Trabajando con Tablas - [image: Office Scripts: Trabajando con Tablas] Me he dado cuenta que últimamente solo escribo de lenguaje M (es mi pequeño vicio)... pero hay que liberar l...Hace 2 años
-
Hello world! - [image: Hello world!] Welcome to WordPress. This is your first post. Edit or delete it, then start writing!Hace 3 años
-
La importancia de saber mecanografía en 2022 - [image: Resultado de imagen de mecanografía viñeta escribiendo a máquina] Según la RAE, la mecanografía es el arte de escribir a máquina. Hace unos cuantos...Hace 3 años
-
London Excel Meetup Workbooks - The workbooks used in my presentation on “Analytical and Interactive Dashboards in Excel” at the London Excel Meetup, September 3, 2020Hace 5 años
-
Cálculo de jornada que termina al día siguiente (Power Query) y despedida - [image: Cálculo de jornada que termina al día siguiente (Power Query) y despedida] Este blog se ha ocupado de cálculos de tiempo con bastante intensidad, c...Hace 5 años
-
International Keyboard Shortcut Day 2019 - The first Wednesday of every November is International Keyboard Shortcut Day. This Wednesday, people from all over the world will become far less efficient...Hace 6 años
-
Welcome, Prashanth! - Last March, I shared that we were starting to look for a new CEO for Stack Overflow. We were looking for that rare combination of someone who… Read more "W...Hace 6 años
-
Visualize parts and whole - combine clustered column and stacked column charts - *Inga: Disa what?* *Igor: -ppeared.* by The FrankensTeam ------------------------------ Really it was 3 years ago we posted our last article? *Freddy: Th...Hace 6 años
-
Salvador Sostres, analfabeto profesional - Los nuevos tiempos traen nuevas profesiones. Internet, además, ha revolucionado el mundo del periodismo y la palabra escrita. Adaptarse o morir, ese es el ...Hace 7 años
-
Planificación de compras - Realizar una lista con los productos que necesitamos y que formarán parte de nuestra cesta de la compra nos ayuda a *encontrar la combinación de bienes p...Hace 13 años
-
-
-
-
-
-
-
-
-










No Response to "Power Query - multiple slicers (4/4)"
Leave A Reply
Comenta este artículo, critícalo o avisa si detectas algún error que haya que corregir.