Transpose data in Excel

missminimac

New Member
Joined
Sep 6, 2011
Messages
5
Greetings from Colorado,

Working in Excel 2010.
Is there a transpose solution to create the desire table below?

Current table:
codejobsurvey IDmatch
12345AccountantPHRA-GSK12F395-5
12345AccountantPHRA-GSK123303
12345AccountantPHRA-GSK12Z010-6

<colgroup><col><col><col><col></colgroup><tbody>
</tbody>

Desire table:
codejobSurvey ID + match 1Survey ID + match 2Survey ID + match 3
12345AccountantPHRA-GSK12 F395-5PHRA-GSK12 3303PHRA-GSK12 Z010-6

<colgroup><col><col><col><col><col></colgroup><tbody>
</tbody>

Thanks so much for your help!

Snowed in co all day yesterday Happy May ;)
missminimac
 

Some videos you may like

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
Just thought if you name is a reflection that you are working with a "Mac" then this code will not do !!!!!
I could probably write something else, let me Know !!!

Try this:-
Results start "F1"
Code:
[COLOR=navy]Sub[/COLOR] MG02May53
[COLOR=navy]Dim[/COLOR] Rng         [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] Dn          [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] n           [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Dim[/COLOR] Q
[COLOR=navy]Dim[/COLOR] Num         [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] oMax        [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
ReDim Ray(1 To Rng.Count, 1 To Rng.Count * 3)
[COLOR=navy]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
    [COLOR=navy]If[/COLOR] Not .Exists(Dn.Value) [COLOR=navy]Then[/COLOR]
        n = n + 1
        Ray(n, 1) = Dn
        Ray(n, 2) = Dn.Offset(, 1)
        Ray(n, 3) = IIf(n = 1, Dn.Offset(, 2) & " " & Dn.Offset(, 3) & " 1", Dn.Offset(, 2) & " " & Dn.Offset(, 3))
        .Add Dn.Value, Array(n, 3)
    [COLOR=navy]Else[/COLOR]
        Q = .Item(Dn.Value)
            Num = Q(1)
            Q(1) = Q(1) + 1
            Ray(1, Q(1)) = "Survey ID + match " & Num - 1
            Ray(Q(0), Q(1)) = Dn.Offset(, 2) & " " & Dn.Offset(, 3)
            oMax = Application.Max(oMax, Q(1))
        .Item(Dn.Value) = Q
    [COLOR=navy]End[/COLOR] If
[COLOR=navy]Next[/COLOR]
Range("F1").Resize(.Count, oMax) = Ray
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Last edited:

missminimac

New Member
Joined
Sep 6, 2011
Messages
5
Mick, brilliant solution. Code is rock solid.
You made my day!

Many thanks,
missminimac

Just thought if you name is a reflection that you are working with a "Mac" then this code will not do !!!!!
I could probably write something else, let me Know !!!

Try this:-
Results start "F1"
Code:
[COLOR=navy]Sub[/COLOR] MG02May53
[COLOR=navy]Dim[/COLOR] Rng         [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] Dn          [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] n           [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Dim[/COLOR] Q
[COLOR=navy]Dim[/COLOR] Num         [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] oMax        [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
ReDim Ray(1 To Rng.Count, 1 To Rng.Count * 3)
[COLOR=navy]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
    [COLOR=navy]If[/COLOR] Not .Exists(Dn.Value) [COLOR=navy]Then[/COLOR]
        n = n + 1
        Ray(n, 1) = Dn
        Ray(n, 2) = Dn.Offset(, 1)
        Ray(n, 3) = IIf(n = 1, Dn.Offset(, 2) & " " & Dn.Offset(, 3) & " 1", Dn.Offset(, 2) & " " & Dn.Offset(, 3))
        .Add Dn.Value, Array(n, 3)
    [COLOR=navy]Else[/COLOR]
        Q = .Item(Dn.Value)
            Num = Q(1)
            Q(1) = Q(1) + 1
            Ray(1, Q(1)) = "Survey ID + match " & Num - 1
            Ray(Q(0), Q(1)) = Dn.Offset(, 2) & " " & Dn.Offset(, 3)
            oMax = Application.Max(oMax, Q(1))
        .Item(Dn.Value) = Q
    [COLOR=navy]End[/COLOR] If
[COLOR=navy]Next[/COLOR]
Range("F1").Resize(.Count, oMax) = Ray
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 

Watch MrExcel Video

Forum statistics

Threads
1,122,499
Messages
5,596,515
Members
414,074
Latest member
Matthew Kakde

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
Top