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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
D_HL
Frequent Visitor

Help with Excel Data in wide view, over multiple sheets

Good morning all, I hope you are well. 

I'm trying to work out the most effective way to tackle a data set I have been asked to produce visuals from.

The excel sheet consists of separate sheets, per attribute, over time, and is in wide view. Essentially, I need to stack all the sheets, creating a column per attribute and unpivot to get a long view. But I just don't know what's the simplest way. 

Here is some example data:

D_HL_0-1685951309326.png

 

Thanks in advance

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @D_HL 

 

This article will be helpful: Combine Multiple or All Sheets from an Excel File into a Power BI solution Using Power Query Dynamic...

Notice that in the following step, you need to keep "Name" and "Data" columns. The "Name" column contains sheet names that represent the attributes you want. 

vjingzhang_0-1686106352010.png

 

After expanding Data column and filtering out unnecessary rows per your need, you can select Both Name and Data columns at the same time, then unpivot other columns to get a long view table. 

 

Hope this helps. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

5 REPLIES 5
D_HL
Frequent Visitor

Thanks Jing, 

 

Go it to work on most sheets, if one of the sheets' values were a % would that mess things up? 

 

Thanks
Dan 

Hi @D_HL 

 

I think that will not mess things up. But you need to pay attention to the data type of columns. You can change the data type of a column thus all values in the same column will be in that data type. I recommend that you change data types after transforming the table into the expected format. 

 

Best regards,

Jing

D_HL
Frequent Visitor

Thanks Jing,
The tricky element to it is that I need to make the sheet name the column header for the values presented in the sheet. My end game would be something like this... 

 

Primary SectorSecondary SectorDateTotalOutstanding Good Quality Bad Quality
AA01/01/2023

£8.5

£4.5£4.0£0.5
AB 01/01/2023£5.5£2.5£2.5£0
A 01/01/2023£2.1£2.0£0.0£2.0
BA 01/01/2023£8.4£5.4£1.0£7.4

 

Thanks

Dan 

Hi @D_HL 

 

You can try this query. Just replace the file path in the first Source step. 

let
    Source = Excel.Workbook(File.Contents("C:\Users\administrator\Desktop\Data.xlsx"), null, true),
    #"Removed Other Columns" = Table.SelectColumns(Source,{"Name", "Data"}),
    #"Added Custom" = Table.AddColumn(#"Removed Other Columns", "NewData", each Table.UnpivotOtherColumns(Table.PromoteHeaders([Data], [PromoteAllScalars=true]), {"Primary Sector", "Secondary Sector"}, "Attribute", "Value")),
    #"Removed Other Columns1" = Table.SelectColumns(#"Added Custom",{"Name", "NewData"}),
    #"Expanded NewData" = Table.ExpandTableColumn(#"Removed Other Columns1", "NewData", {"Primary Sector", "Secondary Sector", "Attribute", "Value"}, {"Primary Sector", "Secondary Sector", "Attribute", "Value"}),
    #"Pivoted Column" = Table.Pivot(#"Expanded NewData", List.Distinct(#"Expanded NewData"[Name]), "Name", "Value"),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"Attribute", "Date"}})
in
    #"Renamed Columns"

vjingzhang_0-1686127595832.png

I take only two sheets in my sample but never mind this query works with more sheets. 

 

Steps are:

Add a custom column to transform the original Data column first (promote the first row to headers and unpivot).

Remove the original Data column, then expand the NewData column.

Pivot Name column. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

v-jingzhang
Community Support
Community Support

Hi @D_HL 

 

This article will be helpful: Combine Multiple or All Sheets from an Excel File into a Power BI solution Using Power Query Dynamic...

Notice that in the following step, you need to keep "Name" and "Data" columns. The "Name" column contains sheet names that represent the attributes you want. 

vjingzhang_0-1686106352010.png

 

After expanding Data column and filtering out unnecessary rows per your need, you can select Both Name and Data columns at the same time, then unpivot other columns to get a long view table. 

 

Hope this helps. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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

Top Solution Authors