Extract Data from Table into Columns

wildturkey

Board Regular
Joined
Feb 21, 2006
Messages
189
Office Version
  1. 365
Platform
  1. Windows
HI, clutching at straws but looking to take the small table and format as the three columns below...the actual table is a little bigger hence the ask :)

Book3
ABCDEFG
1Inc ItemsBobJaneDavidEmmaTom
2Apple21.8520.2923.220.2920.85
3Pear23.2821.4125.0721.4122.28
4Carrot38.9536.7152.4936.7137.95
5Ptato50.3548.9455.5948.9449.35
6Grape33.9240.0543.840.0533.92
7Carrot61.7567.177.4967.160.75
8Tomato7.326.688.896.686.92
9
10
11
12
13Inc Items
14AppleBob21.85
15PearBob23.28
16CarrotBob38.95
17PtatoBob50.35
18GrapeBob33.92
19CarrotBob61.75
20TomatoBob7.32
21AppleJane20.29
22PearJane21.41
23CarrotJane36.71
24PtatoJane48.94
25GrapeJane40.05
26CarrotJane67.1
27TomatoJane6.68
28AppleDavid23.2
29PearDavid25.07
30CarrotDavid52.49
31PtatoDavid55.59
Sheet1
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Easy with PQ
Book1
ABCDEF
1Inc ItemsBobJaneDavidEmmaTom
2Apple21.8520.2923.220.2920.85
3Pear23.2821.4125.0721.4122.28
4Carrot38.9536.7152.4936.7137.95
5Ptato50.3548.9455.5948.9449.35
6Grape33.9240.0543.840.0533.92
7Carrot61.7567.177.4967.160.75
8Tomato7.326.688.896.686.92
9
10
11
12
13Inc ItemsInc ItemsAttributeValue
14AppleBob21.85GrapeBob33.92
15PearBob23.28PearBob23.28
16CarrotBob38.95CarrotBob38.95
17PtatoBob50.35PtatoBob50.35
18GrapeBob33.92CarrotBob61.75
19CarrotBob61.75TomatoBob7.32
20TomatoBob7.32AppleBob21.85
21AppleJane20.29TomatoDavid8.89
22PearJane21.41CarrotDavid52.49
23CarrotJane36.71CarrotDavid77.49
24PtatoJane48.94GrapeDavid43.8
25GrapeJane40.05PtatoDavid55.59
26CarrotJane67.1AppleDavid23.2
27TomatoJane6.68PearDavid25.07
28AppleDavid23.2PtatoEmma48.94
29PearDavid25.07CarrotEmma67.1
30CarrotDavid52.49AppleEmma20.29
31PtatoDavid55.59PearEmma21.41
32GrapeEmma40.05
33CarrotEmma36.71
34TomatoEmma6.68
35CarrotJane67.1
36AppleJane20.29
37TomatoJane6.68
38PtatoJane48.94
39GrapeJane40.05
40CarrotJane36.71
41PearJane21.41
42TomatoTom6.92
43PearTom22.28
44CarrotTom37.95
45AppleTom20.85
46GrapeTom33.92
47PtatoTom49.35
48CarrotTom60.75
Sheet1


Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Inc Items", type text}, {"Bob", type number}, {"Jane", type number}, {"David", type number}, {"Emma", type number}, {"Tom", type number}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Inc Items"}, "Attribute", "Value"),
    #"Sorted Rows" = Table.Sort(#"Unpivoted Columns",{{"Attribute", Order.Ascending}})
in
    #"Sorted Rows"
 
Upvote 0
Another option with a formula
Fluff.xlsm
ABCDEF
1Inc ItemsBobJaneDavidEmmaTom
2Apple21.8520.2923.220.2920.85
3Pear23.2821.4125.0721.4122.28
4Carrot38.9536.7152.4936.7137.95
5Ptato50.3548.9455.5948.9449.35
6Grape33.9240.0543.840.0533.92
7Carrot61.7567.177.4967.160.75
8Tomato7.326.688.896.686.92
9
10
11
12
13Inc Items
14AppleBob21.85
15PearBob23.28
16CarrotBob38.95
17PtatoBob50.35
18GrapeBob33.92
19CarrotBob61.75
20TomatoBob7.32
21AppleJane20.29
22PearJane21.41
23CarrotJane36.71
24PtatoJane48.94
25GrapeJane40.05
26CarrotJane67.1
27TomatoJane6.68
28AppleDavid23.2
29PearDavid25.07
30CarrotDavid52.49
31PtatoDavid55.59
32GrapeDavid43.8
33CarrotDavid77.49
34TomatoDavid8.89
35AppleEmma20.29
36PearEmma21.41
37CarrotEmma36.71
38PtatoEmma48.94
39GrapeEmma40.05
40CarrotEmma67.1
41TomatoEmma6.68
42AppleTom20.85
43PearTom22.28
44CarrotTom37.95
45PtatoTom49.35
46GrapeTom33.92
47CarrotTom60.75
48TomatoTom6.92
Sheet6
Cell Formulas
RangeFormula
A14:C48A14=HSTACK(TOCOL(IF(B2:F8<>"",A2:A8,1/0),2,1),TOCOL(IF(B2:F8<>"",B1:F1,1/0),2,3),TOCOL(B2:F8,1,1))
Dynamic array formulas.
 
Upvote 0
Solution
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,215,737
Messages
6,126,576
Members
449,318
Latest member
Son Raphon

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