Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Score big with last-minute savings on the final tickets to FabCon Vienna. Secure your discount

Reply
StrPod
Frequent Visitor

How to merge multiple matching pairs of columns in one step?

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.

 

 

 

1 REPLY 1
jgeddes
Super User
Super User

You might want to consider renaming the columns before expanding the data. 

As a quick example...
I have three files that I can combine.

jgeddes_1-1709062661951.png

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

jgeddes_2-1709062826363.png

in each row I can now see the contents of each file, including the column names by clicking in the '_excelContent.Data' cells.

jgeddes_3-1709062909549.png

jgeddes_4-1709062933021.pngjgeddes_5-1709062949153.png

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. 

jgeddes_6-1709063140986.pngjgeddes_7-1709063151996.pngjgeddes_8-1709063164419.png

You can now expand the data with the correct headers. 
Hopefully this gets you pointed in the right direction.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

Find out what's new and trending in the Fabric community.

Top Solution Authors