Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi,
I am trying to create a dynamic table combination query where the query looks at all of the tables in the workbook and selects all of the ones that have a specific value in the name, and then combines them. I'm fine with appending tables, but any ideas if it's possible to select which tables to append automatically based on table name? All tables have exactly the same columns.
For example, the query looks through the sheet and finds all of the table names that contain "OPEX", then take these tables and appends them into one master table.
Note that the number of tables will vary in each use, which is why I'm trying to automate the process.
Any help greatly appreciated!
Many Thanks.
Solved! Go to Solution.
try if this scheme is what you want
let
Source = Excel.Workbook(File.Contents("C:\Users\37332115\OneDrive - TIM\MyD2020\BI\tabelle.xlsx"), null, true),
#"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Name], "opex")),
#"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"Data"})
in
#"Removed Other Columns"
Load all the tables and filter by content of name.
then combine the tables filtered in
let
Source = Table.Combine(foglio1[Data])
in
Source
Hello @Andyb431
here the approach you can use.
let
Source = Excel.Workbook(File.Contents("YourExcelFile"), null, true),
SelectNameSheet = Table.SelectRows(Source, each Text.Contains(Text.Upper(_[Name]), "OPEX")),
CombineTable = Table.Combine(SelectNameSheet[Data])
in
CombineTable
The only thing that you have to pay attention is your format of the table in Excel. Its a blank sheet with the data in or it is a table? The problem of combining only the sheet-data is that you will get a table with Column1, Column2 as header, and thats not nice. Then you would need to transform the tables before and then combine. Here a solution to this
let
Source = Excel.Workbook(File.Contents("YourExcelFile"), null, true),
SelectNameSheet = Table.SelectRows(Source, each Text.Contains(Text.Upper(_[Name]), "OPEX")),
TransformTables = Table.TransformColumns
(
SelectNameSheet,
{
{
"Data",
each Table.PromoteHeaders(_)
}
}
),
CombineTable = Table.Combine(TransformTables[Data])
in
CombineTable
Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query, or I could create a custom function what makes it easier to apply if you are not used that much to power query.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Hello @Andyb431
here the approach you can use.
let
Source = Excel.Workbook(File.Contents("YourExcelFile"), null, true),
SelectNameSheet = Table.SelectRows(Source, each Text.Contains(Text.Upper(_[Name]), "OPEX")),
CombineTable = Table.Combine(SelectNameSheet[Data])
in
CombineTable
The only thing that you have to pay attention is your format of the table in Excel. Its a blank sheet with the data in or it is a table? The problem of combining only the sheet-data is that you will get a table with Column1, Column2 as header, and thats not nice. Then you would need to transform the tables before and then combine. Here a solution to this
let
Source = Excel.Workbook(File.Contents("YourExcelFile"), null, true),
SelectNameSheet = Table.SelectRows(Source, each Text.Contains(Text.Upper(_[Name]), "OPEX")),
TransformTables = Table.TransformColumns
(
SelectNameSheet,
{
{
"Data",
each Table.PromoteHeaders(_)
}
}
),
CombineTable = Table.Combine(TransformTables[Data])
in
CombineTable
Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query, or I could create a custom function what makes it easier to apply if you are not used that much to power query.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
try if this scheme is what you want
let
Source = Excel.Workbook(File.Contents("C:\Users\37332115\OneDrive - TIM\MyD2020\BI\tabelle.xlsx"), null, true),
#"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Name], "opex")),
#"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"Data"})
in
#"Removed Other Columns"
Load all the tables and filter by content of name.
then combine the tables filtered in
let
Source = Table.Combine(foglio1[Data])
in
Source
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 19 | |
| 9 | |
| 8 | |
| 7 | |
| 6 |