Rearranging Data in Excel

astout920

New Member
Joined
Apr 21, 2014
Messages
5
Hi, all. I have a table where I need to rearrange the data. The below is a small sample size. The real table is about 100 rows and 700 columns. The first table is what it looks like now, and the second table is what I'd like it to look like. Is there an easy way to do this. I tried pivot tables but it wasn't working right (for me). Would MS Access be a better tool? Although I'm not sure how to build the right query.

Any help would be greatly appreciated!!! Thanks!!!

Current Input
QualifierModel 1Model 2Model 3
A0.10.2
B0.50.1
C0.40.10.1
D0.60.1
E0.30.5

<tbody>
</tbody>


Desired Output (the headers in the top row can be any text as far as I'm concerned)
ModelQualifierValue
Model 1A0.1
Model 1B0.5
Model 1C0.4
Model 1D
Model 1E
Model 2A
Model 2B
Model 2C0.1
Model 2D0.6
Model 2E0.3
Model 3A0.2
Model 3B0.1
Model 3C0.1
Model 3D0.1
Model 3E0.5

<tbody>
</tbody>

 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
It looks like what you are trying to do is called unpivot. If you have excel 2016+ you can use the built in power query to do this I think -- I've never done it, but you should be able to google it. If you are using an older version of excel (2007+) you can use the free nutilities add-in from iwishexcel.com. once installed, the nutility you are looking for is also called unpivot. The pic below shows the instructions from the nutilities menu.

3Yyj2Gv

3Yyj2Gv
https://ibb.co/3Yyj2Gv
 
Upvote 0
or with PowerQuery aka Get&Transform

QualifierModel 1Model 2Model 3ModelQualifierValue
A
0.1​
0.2​
Model 1A
0.1​
B
0.5​
0.1​
Model 1B
0.5​
C
0.4​
0.1​
0.1​
Model 1C
0.4​
D
0.6​
0.1​
Model 1D
E
0.3​
0.5​
Model 1E
Model 2A
Model 2B
Model 2C
0.1​
Model 2D
0.6​
Model 2E
0.3​
Model 3A
0.2​
Model 3B
0.1​
Model 3C
0.1​
Model 3D
0.1​
Model 3E
0.5​

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    ReplaceNull = Table.ReplaceValue(Source,null,999,Replacer.ReplaceValue,{"Model 1", "Model 2", "Model 3"}),
    Unpivot = Table.UnpivotOtherColumns(ReplaceNull, {"Qualifier"}, "Attribute", "Value"),
    Replace = Table.ReplaceValue(Unpivot,999,null,Replacer.ReplaceValue,{"Value"}),
    Sort = Table.Sort(Replace,{{"Attribute", Order.Ascending}, {"Qualifier", Order.Ascending}}),
    Finish = Table.RenameColumns(Table.ReorderColumns(Sort,{"Attribute", "Qualifier", "Value"}),{{"Attribute", "Model"}})
in
    Finish[/SIZE]
 
Upvote 0
Hi Sandy

Maybe a silly question - starting to learn Power Query... :confused:
I got the desired result (see below), but couldn't in Power Query replace null with "" (empty string).

A
B
C
1
Model​
Qualifier​
Valor​
2
Model 1​
A​
0,1​
3
Model 1​
B​
0,5​
4
Model 1​
C​
0,4​
5
Model 1​
D​
6
Model 1​
E​
7
Model 2​
A​
8
Model 2​
B​
9
Model 2​
C​
0,1​
10
Model 2​
D​
0,6​
11
Model 2​
E​
0,3​
12
Model 3​
A​
0,2​
13
Model 3​
B​
0,1​
14
Model 3​
C​
0,1​
15
Model 3​
D​
0,1​
16
Model 3​
E​
0,5​

<tbody>
</tbody>


The alternative way I found was:
Replace null with zero
Unpivot 3 columns
Move Model column left
Replace zero with null (reverting)
Sort
Load

Is there a better way?

M.
 
Last edited:
Upvote 0
Complementing previous post
M-Code (in Portuguese, I hope you can understand it ;))

Code:
let
    Fonte = Excel.CurrentWorkbook(){[Name="Tabela2"]}[Content],
    #"Tipo Alterado" = Table.TransformColumnTypes(Fonte,{{"Qualifier", type text}, {"Model 1", type number}, {"Model 2", type number}, {"Model 3", type number}}),
    #"Valor Substituído" = Table.ReplaceValue(#"Tipo Alterado",null,0,Replacer.ReplaceValue,{"Model 1", "Model 2", "Model 3"}),
    #"Somente as Colunas Selecionadas Foram Transformadas em Linhas" = Table.Unpivot(#"Valor Substituído", {"Model 1", "Model 2", "Model 3"}, "Atributo", "Valor"),
    #"Colunas Reordenadas" = Table.ReorderColumns(#"Somente as Colunas Selecionadas Foram Transformadas em Linhas",{"Atributo", "Qualifier", "Valor"}),
    #"Linhas Classificadas" = Table.Sort(#"Colunas Reordenadas",{{"Atributo", Order.Ascending}, {"Qualifier", Order.Ascending}}),
    #"Valor Substituído1" = Table.ReplaceValue(#"Linhas Classificadas",0,null,Replacer.ReplaceValue,{"Valor"})
in
    #"Valor Substituído1"

M.
 
Upvote 0
The alternative way I found was:
Replace null with zero
Unpivot 3 columns
Move Model column left
Replace zero with null (reverting)
Sort
Load
Is there a better way?
Hi Marcelo,
but this is the same method except these differences: (null to 999 then 999 to null / null to 0 then 0 to null). IMHO with 999 is harder to make mistake because 0 is very close to the values in the source.
The important thing is that the goal has been achieved :devilish:

edit: (with Google Translate)
Code:
[SIZE=1]let
     Source = Excel.CurrentWorkbook () {[Name = "Table2"]} [Content],
     # "Changed Type" = Table.TransformColumnTypes (Source, {{"Qualifier", type text}, {"Model 1", type number}, {"Model 2", type number}, {"Model 3", type number }}),
     # "Replaced Value" = Table.ReplaceValue (# "Changed Type", null, 0, Replacer.ReplaceValue, {"Model 1", "Model 2", "Model 3"}),
     # "Only Selected Columns Transformed into Rows" = Table.Unpivot (# "Replaced Value", {"Model 1", "Model 2", "Model 3"}, "Attribute", "Value"),
     # "Reordered Columns" = Table.ReorderColumns (# "Only Selected Columns Transformed into Rows", {"Attribute", "Qualifier", "Value"}),
     # "Sorted Rows" = Table.Sort (# "Reordered Columns", {{"Attribute", Order.Ascending}, {"Qualifier", Order.Ascending}}),
     # "Substituted Value1" = Table.ReplaceValue (# "Sorted Rows", 0, null, Replacer.ReplaceValue, {"Value"})
in
     # "Substituted Value1"[/SIZE]
 
Last edited:
Upvote 0
Odin, Sandy, and Marcelo... all very helpful. Both strategies worked. And I learned something new with Power Queries. Cheers!
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,972
Members
448,537
Latest member
Et_Cetera

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