Change Data Structure

Excel_ZM

New Member
Joined
Aug 16, 2016
Messages
20
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.
 

Some videos you may like

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
4,674
Hope you know how to reorder columns and change headers

Measure201420152016MeasureAttributeValue
Measure #1
1​
2​
3​
Measure #12014
1​
Measure #2
2​
4​
6​
Measure #12015
2​
Measure #3
3​
6​
9​
Measure #12016
3​
Measure #22014
2​
Measure #22015
4​
Measure #22016
6​
Measure #32014
3​
Measure #32015
6​
Measure #32016
9​

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]
 

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
4,674
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]
 

Excel_ZM

New Member
Joined
Aug 16, 2016
Messages
20
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]
 

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
4,674
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:

Excel_ZM

New Member
Joined
Aug 16, 2016
Messages
20
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]
 

Forum statistics

Threads
1,089,485
Messages
5,408,536
Members
403,213
Latest member
Rvbicon

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top