Transpose and sort columns in to rows

elektor

New Member
Joined
Apr 24, 2011
Messages
43
I need a vba excel macro to transpose and sort columns in to rows.
Saple file before transpose:
Sheet 1

------B----------------------C------------------D--------------------E----------------F--------------------G
3----Stock Number-- ------Product ----------Units---------------Room----------Available----------Sum

4----PE22------------------Pen---------------- Pieces ------------R09-------------6---------------------11
5--------------------------------------------------------------------R01-------------3
6--------------------------------------------------------------------R22-------------2
7 Blank row
8----PE25---------------------Pencil-------------- Pieces --------------------------------------------------------
9----C13----------------------Chair----------------Pieces---------R22-------------3----------------------10
10-------------------------------------------------------------------R05-------------2
11-------------------------------------------------------------------R04-------------3
12-------------------------------------------------------------------R01-------------2
13---T05----------------------Computer-----------Pieces---------R02-------------1-----------------------1
14 Blank row
15 Blank row

Note: There are tens of thousands of lines, thousands of products, hundreds of rooms.

Output samle file:
Sheet2

----A --------------B-----------------C----------D--------E------F-------G-------H------I-------J------K
4---Line Nmr.---Stock Nmr.--------Product---Units----R01---R02----R04----R05---R09--- R22-- Sum
5---1-------------- PE22------------ Pen------- Pieces---3------------------------------6------2------11
6---2-------------- C13--------------Chair----- Pieces---2--------------3--------2-------------3------10
7---3-------------- T05-------------Computer- Pieces-----------1---------------------------------------1

Note 1: Pencil doesn’t transpose to sheet2. Because there isn’t any pencil in any room.
Note 2 : The rooms must be sorted.

Any help would be most appreciated!
 
Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG20Jun37
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Room [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] Col [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] nRng [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] nRay
[COLOR="Navy"]Dim[/COLOR] Temp
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("B4"), Range("B" & rows.Count).End(xlUp))
 [COLOR="Navy"]Set[/COLOR] nRng = Rng.Offset(, 3)
   nRay = oRms(nRng)
     ReDim ray(1 To Rng.Count, 1 To UBound(nRay) + 5)
        ray(1, 1) = "Row" & chr(10) & "Number"
        ray(1, 2) = "Stock" & chr(10) & "Number"
          ray(1, 3) = "Product"
            ray(1, 4) = "Units"
[COLOR="Navy"]For[/COLOR] n = 1 To UBound(nRay)
    [COLOR="Navy"]If[/COLOR] UBound(nRay) = 1 [COLOR="Navy"]Then[/COLOR]
        Temp = nRay(n)
    [COLOR="Navy"]Else[/COLOR]
        Temp = nRay(n, 1)
    [COLOR="Navy"]End[/COLOR] If
    ray(1, n + 4) = Temp
[COLOR="Navy"]Next[/COLOR] n
ray(1, UBound(nRay) + 5) = "Sum"
c = 1
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
[COLOR="Navy"]If[/COLOR] Dn <> "" And Dn(, 4) <> "" [COLOR="Navy"]Then[/COLOR]
    
    [COLOR="Navy"]If[/COLOR] UBound(nRay) = 1 [COLOR="Navy"]Then[/COLOR]
        Col = 5
    [COLOR="Navy"]Else[/COLOR]
        [COLOR="Navy"]For[/COLOR] n = 1 To UBound(nRay)
            [COLOR="Navy"]If[/COLOR] nRay(n, 1) = Dn(, 4) [COLOR="Navy"]Then[/COLOR] Col = n + 4: [COLOR="Navy"]Exit[/COLOR] For
        [COLOR="Navy"]Next[/COLOR] n
    [COLOR="Navy"]End[/COLOR] If
        c = c + 1
        ray(c, 1) = Dn.Offset(, -1): ray(c, 2) = Dn: ray(c, 3) = Dn(, 2): ray(c, 4) = Dn(, 3): ray(c, Col) = Dn(, 5):
        [COLOR="Navy"]If[/COLOR] Dn(, 6) <> "" [COLOR="Navy"]Then[/COLOR] ray(c, UBound(ray, 2)) = Dn(, 6)
[COLOR="Navy"]ElseIf[/COLOR] Dn = "" And Dn(, 4) <> "" [COLOR="Navy"]Then[/COLOR]
    [COLOR="Navy"]If[/COLOR] UBound(nRay) = 1 [COLOR="Navy"]Then[/COLOR]
        Col = 5
     [COLOR="Navy"]Else[/COLOR]
        [COLOR="Navy"]For[/COLOR] n = 1 To UBound(nRay)
            [COLOR="Navy"]If[/COLOR] nRay(n, 1) = Dn(, 4) [COLOR="Navy"]Then[/COLOR] Col = n + 4: [COLOR="Navy"]Exit[/COLOR] For
        [COLOR="Navy"]Next[/COLOR] n
    [COLOR="Navy"]End[/COLOR] If
        ray(c, Col) = Dn(, 5)
[COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] Dn
Sheets("sheet2").Range("A1").Resize(c, UBound(ray, 2)) = ray
MsgBox "Run!!"
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Function oRms(Rng [COLOR="Navy"]As[/COLOR] Range) [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] i, j, Temp
[COLOR="Navy"]Dim[/COLOR] ray
[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] Dn <> "" And Not .Exists(Dn.value) [COLOR="Navy"]Then[/COLOR]
        .Add Dn.value, n
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR]
ray = .keys
[COLOR="Navy"]For[/COLOR] i = 0 To UBound(ray)
    [COLOR="Navy"]For[/COLOR] j = i To UBound(ray)
        [COLOR="Navy"]If[/COLOR] ray(j) < ray(i) [COLOR="Navy"]Then[/COLOR]
            Temp = ray(i)
            ray(i) = ray(j)
            ray(j) = Temp
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR] j
[COLOR="Navy"]Next[/COLOR] i
oRms = Application.Transpose(ray)
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] Function
Regards Mick
 
Upvote 0

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college

Forum statistics

Threads
1,224,551
Messages
6,179,472
Members
452,915
Latest member
hannnahheileen

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