Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
I am pulling data from multiple sheets in multiple files. I already have all the columns in PQ editor after expanding data. Total of 200 columns but like 128 of the columns have matching rows of data in two pairs, but are separated due to different header names, and I don't have write acces to the source to fix this. I could filter the different sheets into separate queries > rename headers and then append queries but I don't want to create a lot of queries.
so currently in a single query my approach has been, select one column then select it's matching column > right click > merge columns. But then I have to do this for each pair and this results in many steps.
so my question is, is it possible to do this in one step? That is merge each pair, rename the merged and remove the originals.
You might want to consider renaming the columns before expanding the data.
As a quick example...
I have three files that I can combine.
I add a column to get the Sheet data for each file.
= Table.AddColumn(PREVIOUSSTEP, "_excelContent", each Excel.Workbook([Content], true))
and expand the resulting tables in the created column so I can filter to keep the sheets I need.
= Table.ExpandTableColumn(PREVIOUSSTEP, "_excelContent", {"Name", "Data"}, {"_excelContent.Name", "_excelContent.Data"})
so I end up with
in each row I can now see the contents of each file, including the column names by clicking in the '_excelContent.Data' cells.
I create a list of column name corrections in a separate query (which I called columnNames)
let
Source =
{
{"colun2", "column2"},
{"col4", "column4"},
{"col1", "column1"},
{"colu2", "column2"},
{"cmn3", "column3"}
}
in
Source
Back in the main query I added the step...
= Table.TransformColumns(PREVIOUSSTEP, {{"_excelContent.Data", each Table.RenameColumns(_, columnNames, MissingField.Ignore)}})
This renames the columns before expanding.
You can now expand the data with the correct headers.
Hopefully this gets you pointed in the right direction.
Proud to be a Super User! | |