Change Data Structure

Excel_ZM

New Member
Joined
Aug 16, 2016
Messages
24
Hello,

I was looking to do a Power Bi but the excel file that I am using has data in an unfriendly way for Power Bi

Current data structure


2014
2015
2016
Measure #1
1
2
3
Measure #2
2
4
6
Measure #3
3
6
9

<tbody>
</tbody>

Desired Structure


Year
Value
Measure #1
1
2014
Measure #1
2
2015
Measure #1
3
2016
Measure #2
2
2014
Measure #2
4
2015
Measure #2
6
2016
Measure #3
3
2014
Measure #3
6
2015
Measure #3
9
2016

<tbody>
</tbody>

Do you know of any good way I can re-format this data in excel to get it into the new structure?

Alternatively, if there is any way in Power Bi to reformat the data that would be appreciated.
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Hope you know how to reorder columns and change headers

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]Measure[/td][td=bgcolor:#5B9BD5]2014[/td][td=bgcolor:#5B9BD5]2015[/td][td=bgcolor:#5B9BD5]2016[/td][td][/td][td=bgcolor:#70AD47]Measure[/td][td=bgcolor:#70AD47]Attribute[/td][td=bgcolor:#70AD47]Value[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Measure #1[/td][td=bgcolor:#DDEBF7]
1​
[/td][td=bgcolor:#DDEBF7]
2​
[/td][td=bgcolor:#DDEBF7]
3​
[/td][td][/td][td=bgcolor:#E2EFDA]Measure #1[/td][td=bgcolor:#E2EFDA]2014[/td][td=bgcolor:#E2EFDA]
1​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td]Measure #2[/td][td]
2​
[/td][td]
4​
[/td][td]
6​
[/td][td][/td][td]Measure #1[/td][td]2015[/td][td]
2​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Measure #3[/td][td=bgcolor:#DDEBF7]
3​
[/td][td=bgcolor:#DDEBF7]
6​
[/td][td=bgcolor:#DDEBF7]
9​
[/td][td][/td][td=bgcolor:#E2EFDA]Measure #1[/td][td=bgcolor:#E2EFDA]2016[/td][td=bgcolor:#E2EFDA]
3​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td]Measure #2[/td][td]2014[/td][td]
2​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td=bgcolor:#E2EFDA]Measure #2[/td][td=bgcolor:#E2EFDA]2015[/td][td=bgcolor:#E2EFDA]
4​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td]Measure #2[/td][td]2016[/td][td]
6​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td=bgcolor:#E2EFDA]Measure #3[/td][td=bgcolor:#E2EFDA]2014[/td][td=bgcolor:#E2EFDA]
3​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td]Measure #3[/td][td]2015[/td][td]
6​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td=bgcolor:#E2EFDA]Measure #3[/td][td=bgcolor:#E2EFDA]2016[/td][td=bgcolor:#E2EFDA]
9​
[/td][/tr]
[/table]


Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"Measure", type text}, {"2014", Int64.Type}, {"2015", Int64.Type}, {"2016", Int64.Type}}),
    Unpivot = Table.UnpivotOtherColumns(Type, {"Measure"}, "Attribute", "Value")
in
    Unpivot[/SIZE]
 
Upvote 0
with PBI:

Code:
[SIZE=1]let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k1NLC4tSj20QNlQSUcJhI2A2FgpVgdZzggqbgLEZmhyxmD1IHEdJUul2FgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Measure = _t, #"2014" = _t, #"2015" = _t, #"2016" = _t]),
    Type = Table.TransformColumnTypes(Source,{{"Measure", type text}, {"2014", Int64.Type}, {"2015", Int64.Type}, {"2016", Int64.Type}}),
    Unpivot = Table.UnpivotOtherColumns(Type, {"Measure"}, "Attribute", "Value")
in
    Unpivot[/SIZE]
 
Upvote 0
I pasted this into the advanced editor and it didn't work. Do you know what I am doing wrong here? I'm relatively new to power bi.

[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]
let
Source = Excel.Workbook(File.Contents("C:\Users\user_X\Desktop\Book1.xlsx"), null, true),
Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(Sheet1_Sheet,{{"Column1", type text}, {"Column2", Int64.Type}, {"Column3", Int64.Type}, {"Column4", Int64.Type}}),
#"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
#"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"measure", type text}, {"2014", Int64.Type}, {"2015", Int64.Type}, {"2016", Int64.Type}})
in
#"Changed Type1"
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
Type = Table.TransformColumnTypes(Source,{{"Measure", type text}, {"2014", Int64.Type}, {"2015", Int64.Type}, {"2016", Int64.Type}}),
Unpivot = Table.UnpivotOtherColumns(Type, {"Measure"}, "Attribute", "Value")
in
Unpivot
[/FONT]
 
Upvote 0
post your codes using [CODE] ... [/CODE] tags

and usually M-code is not copy/paste solution, you must do each step yourself

the best way: post a link to the shared source data excel file, use googledrive, onedrive or any similar
 
Last edited:
Upvote 0
like this?
Code:
[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]let[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Source = Excel.Workbook(File.Contents("C:\Users\user_X\Desktop\Book1.xlsx"), null, true),[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    #"Changed Type" = Table.TransformColumnTypes(Sheet1_Sheet,{{"Column1", type text}, {"Column2", Int64.Type}, {"Column3", Int64.Type}, {"Column4", Int64.Type}}),[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    #"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"measure", type text}, {"2014", Int64.Type}, {"2015", Int64.Type}, {"2016", Int64.Type}})[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]in[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    #"Changed Type1"[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]let[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Type = Table.TransformColumnTypes(Source,{{"Measure", type text}, {"2014", Int64.Type}, {"2015", Int64.Type}, {"2016", Int64.Type}}),[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Unpivot = Table.UnpivotOtherColumns(Type, {"Measure"}, "Attribute", "Value")[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]in[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Unpivot
[LEFT][COLOR=#333333][FONT=Verdana]
<strike>
</strike>
[/FONT][/COLOR][/LEFT]
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top