Collating data from different tables based on Headers using VBA

gavyy7

New Member
Joined
Aug 16, 2018
Messages
1
Hi,

I am new to VBA and i have been trying to achieve the following but i am stuck. I have different tables in one worksheet with common headers from which i need to collate the data into a single table with one set of headers, in a different worksheet. Example given below is of the Raw data sheet.
[TABLE="width: 616"]
<tbody>[TR]
[TD="class: xl65, width: 77"][/TD]
[TD="class: xl68, width: 77"][/TD]
[TD="class: xl68, width: 77"][/TD]
[TD="class: xl68, width: 77"][/TD]
[TD="class: xl68, width: 77"][/TD]
[TD="class: xl68, width: 77"][/TD]
[TD="class: xl65, width: 77"][/TD]
[TD="class: xl65, width: 77"][/TD]
[/TR]
[TR]
[TD="class: xl66"][/TD]
[TD="class: xl70"]Name[/TD]
[TD="class: xl69"]Physics[/TD]
[TD="class: xl69"]Chemistry[/TD]
[TD="class: xl69"]Maths[/TD]
[TD="class: xl71"]CGPA[/TD]
[TD="class: xl67"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl66"][/TD]
[TD="class: xl67"]Abc[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl65, align: right"]65[/TD]
[TD="class: xl65, align: right"]34[/TD]
[TD="class: xl66, align: right"]4.1[/TD]
[TD="class: xl67"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl66"][/TD]
[TD="class: xl67"]Def[/TD]
[TD="class: xl65, align: right"]78[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]76[/TD]
[TD="class: xl66, align: right"]3.1[/TD]
[TD="class: xl67"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl66"][/TD]
[TD="class: xl72"]Ghi[/TD]
[TD="class: xl68, align: right"]34[/TD]
[TD="class: xl68, align: right"]98[/TD]
[TD="class: xl68, align: right"]45[/TD]
[TD="class: xl73, align: right"]5.6[/TD]
[TD="class: xl67"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl70"]Name[/TD]
[TD="class: xl69"]Physics[/TD]
[TD="class: xl69"]Chemistry[/TD]
[TD="class: xl69"]Maths[/TD]
[TD="class: xl71"]CGPA[/TD]
[TD="class: xl67"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]Jkl[/TD]
[TD="class: xl65, align: right"]87[/TD]
[TD="class: xl65, align: right"]78[/TD]
[TD="class: xl65, align: right"]34[/TD]
[TD="class: xl66, align: right"]7.3[/TD]
[TD="class: xl67"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]Mno[/TD]
[TD="class: xl65, align: right"]69[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl66, align: right"]5.3[/TD]
[TD="class: xl67"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]Pqr[/TD]
[TD="class: xl65, align: right"]94[/TD]
[TD="class: xl65, align: right"]76[/TD]
[TD="class: xl65, align: right"]45[/TD]
[TD="class: xl66, align: right"]6.5[/TD]
[TD="class: xl67"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]Vxw[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]78[/TD]
[TD="class: xl66, align: right"]5.6[/TD]
[TD="class: xl67"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl72"]Xyz[/TD]
[TD="class: xl68, align: right"]98[/TD]
[TD="class: xl68, align: right"]98[/TD]
[TD="class: xl68, align: right"]34[/TD]
[TD="class: xl73, align: right"]3.7[/TD]
[TD="class: xl67"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl68"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl70"]Name[/TD]
[TD="class: xl69"]Physics[/TD]
[TD="class: xl69"]Chemistry[/TD]
[TD="class: xl69"]Maths[/TD]
[TD="class: xl71"]CGPA[/TD]
[TD="class: xl67"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl72"]Stu[/TD]
[TD="class: xl68, align: right"]69[/TD]
[TD="class: xl68, align: right"]79[/TD]
[TD="class: xl68, align: right"]87[/TD]
[TD="class: xl73, align: right"]8.5[/TD]
[TD="class: xl67"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl69"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
</tbody>[/TABLE]

Raw Data sheet can have any number of tables in any location with each table containing any number of rows, but the table headers are the same. So i need to search using a column header, find the list of data below it and then paste it in the new sheet ("Collated"). This process needs to go on till all the instances of a particular column header data re found and pasted in Collated sheet. Also this needs to be done for all Column headers.

So my collated sheet needs to look like this.
[TABLE="width: 448"]
<tbody>[TR]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Name[/TD]
[TD="class: xl65"]Physics[/TD]
[TD="class: xl65"]Chemistry[/TD]
[TD="class: xl65"]Maths[/TD]
[TD="class: xl65"]CGPA[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Abc[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl65, align: right"]65[/TD]
[TD="class: xl65, align: right"]34[/TD]
[TD="class: xl65, align: right"]4.1[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Def[/TD]
[TD="class: xl65, align: right"]78[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]76[/TD]
[TD="class: xl65, align: right"]3.1[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Ghi[/TD]
[TD="class: xl65, align: right"]34[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl65, align: right"]45[/TD]
[TD="class: xl65, align: right"]5.6[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Jkl[/TD]
[TD="class: xl65, align: right"]87[/TD]
[TD="class: xl65, align: right"]78[/TD]
[TD="class: xl65, align: right"]34[/TD]
[TD="class: xl65, align: right"]7.3[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Mno[/TD]
[TD="class: xl65, align: right"]69[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl65, align: right"]5.3[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Pqr[/TD]
[TD="class: xl65, align: right"]94[/TD]
[TD="class: xl65, align: right"]76[/TD]
[TD="class: xl65, align: right"]45[/TD]
[TD="class: xl65, align: right"]6.5[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Vxw[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]56[/TD]
[TD="class: xl65, align: right"]78[/TD]
[TD="class: xl65, align: right"]5.6[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Xyz[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl65, align: right"]98[/TD]
[TD="class: xl65, align: right"]34[/TD]
[TD="class: xl65, align: right"]3.7[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"]Stu[/TD]
[TD="class: xl65, align: right"]69[/TD]
[TD="class: xl65, align: right"]79[/TD]
[TD="class: xl65, align: right"]87[/TD]
[TD="class: xl65, align: right"]8.5[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
</tbody>[/TABLE]

Could someone please help me solve this.

Thanks
Aryan
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Try this:-
NB:- Code running from "CommandButton1"
Code:
Option Explicit
[COLOR="Navy"]Dim[/COLOR] Ray()

Private [COLOR="Navy"]Sub[/COLOR] CommandButton1_Click()
[COLOR="Navy"]Dim[/COLOR] R [COLOR="Navy"]As[/COLOR] Range, Firstaddress [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String,[/COLOR] Rw [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]With[/COLOR] UsedRange
    [COLOR="Navy"]Set[/COLOR] R = .Find("Name", LookIn:=xlValues)
    [COLOR="Navy"]If[/COLOR] Not R [COLOR="Navy"]Is[/COLOR] Nothing [COLOR="Navy"]Then[/COLOR]
        Firstaddress = R.Address
             [COLOR="Navy"]Set[/COLOR] Rng = Range((R.Address), Range(R.Address).End(xlDown))
             Rw = Rng.Rows.Count
             Combine Rng, Rw
        Do
        [COLOR="Navy"]Set[/COLOR] R = .FindNext(R)
            [COLOR="Navy"]If[/COLOR] Not R.Address = Firstaddress [COLOR="Navy"]Then[/COLOR]
                [COLOR="Navy"]Set[/COLOR] Rng = Range((R.Address), Range(R.Address).End(xlDown))
                [COLOR="Navy"]Set[/COLOR] Rng = Rng.Offset(1).Resize(Rng.Count - 1)
                Rw = Rw + Rng.Rows.Count
                Combine Rng, Rw
            [COLOR="Navy"]End[/COLOR] If
        Loop [COLOR="Navy"]While[/COLOR] Not R [COLOR="Navy"]Is[/COLOR] Nothing And R.Address <> Firstaddress
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]End[/COLOR] With
Sheets("Collated").Range("A1").Resize(Rw, 5).Value = Application.Transpose(Ray)
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]



[COLOR="Navy"]Sub[/COLOR] Combine(Rng [COLOR="Navy"]As[/COLOR] Range, rws [COLOR="Navy"]As[/COLOR] Long)
[COLOR="Navy"]Dim[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] dn [COLOR="Navy"]As[/COLOR] Range
c = rws - Rng.Rows.Count
ReDim Preserve Ray(1 To 5, 1 To rws)
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] dn [COLOR="Navy"]In[/COLOR] Rng
    c = c + 1
    [COLOR="Navy"]For[/COLOR] Ac = 0 To 4
        Ray(Ac + 1, c) = dn.Offset(, Ac).Value
    [COLOR="Navy"]Next[/COLOR] Ac
[COLOR="Navy"]Next[/COLOR] dn
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,175
Members
453,021
Latest member
Justyna P

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