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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Combine files with extra top row before column name

I want to import all excel files from a folder and combine them. These files have a top row that needs to be set as column name. But there are some files that have extra first row before column name row, that needs to be removed. Power BI automatically detects the columns names for files without extra first rows, but not for the ones with extra row. How can I remove this extra row from problematic files?

2 ACCEPTED SOLUTIONS
v-yingjl
Community Support
Community Support

Hi @Anonymous ,

If the row just in the sheet not in the table, you can connect to this table separately first.

1.png2.png

 

Then connect to the folder to filter without the 'problem' excel file to combine them and remove uncessary columns.

remove the name columnremove the name column

 

Finally append the previous table and the combined table to get the final combined table:

4.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

watkinnc
Super User
Super User

I'm assuming you have a column of tables (not binary), and that the tables without the extra top row already have the correct column names. This means the other tables will have columns named "Column1, Column2", etc. Before combining, add this step in the formula bar:

= Table.TransformColumns(NameOfPriorStep, {{"NameOfTableColumn", each if Table.ColumnNames(_){0} = "Column1" then Table.SkipFirstN(_, 1) else Table.DemoteHeaders(_)}})

Now all of your headers should be in the first row. You can now combine and PromoteHeaders. 
--Nate


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!

View solution in original post

8 REPLIES 8
watkinnc
Super User
Super User

I'm assuming you have a column of tables (not binary), and that the tables without the extra top row already have the correct column names. This means the other tables will have columns named "Column1, Column2", etc. Before combining, add this step in the formula bar:

= Table.TransformColumns(NameOfPriorStep, {{"NameOfTableColumn", each if Table.ColumnNames(_){0} = "Column1" then Table.SkipFirstN(_, 1) else Table.DemoteHeaders(_)}})

Now all of your headers should be in the first row. You can now combine and PromoteHeaders. 
--Nate


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!
Anonymous
Not applicable

Thank you! It worked.

v-yingjl
Community Support
Community Support

Hi @Anonymous ,

If the row just in the sheet not in the table, you can connect to this table separately first.

1.png2.png

 

Then connect to the folder to filter without the 'problem' excel file to combine them and remove uncessary columns.

remove the name columnremove the name column

 

Finally append the previous table and the combined table to get the final combined table:

4.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Anonymous
Not applicable

Thank you! This really helps in case where we know which particular tables have extra rows, such as in my case.

Jakinta
Solution Sage
Solution Sage

You can find some distinct condition to filter out that row.

But we can only practice our imagination without any sample of your data. 

Anonymous
Not applicable

Sorry for not being descriptive. 

The files with extra row have this structure:

Extra row   
    
Column header 1Header 2Header 3Header 4
1234
1234

While other don't have that first two rows and start from column header.

Also, I am importing all files from folder together, so I am not able to do any transformation before merging them. Is there any way to do that?

Fowmy
Super User
Super User

@Anonymous 

What would be the logic to remove those extra 1st rows as p[er your data? If there anything common in those files, it could used to remove the rows.


Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

Hi,

The files with extra row have this structure:

Extra row   
    
Column header 1Header 2Header 3Header 4
1234
1234

 

While other don't have that first two rows and start from column header.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors