Referencing Issue on VBA

tripleblack811

New Member
Joined
Jul 31, 2017
Messages
5
Hello,

I am a newbie! I would say my Excel knowledge stretches to "VBA beginner".

I am trying to use VBA to get data from this format (on a tab called "Before"):


[TABLE="width: 464"]
<tbody>[TR]
[TD]Post
[/TD]
[TD]Salary
[/TD]
[TD]Allowance
[/TD]
[TD]NationalInsurance
[/TD]
[TD]Pension
[/TD]
[TD]Department
[/TD]
[/TR]
[TR]
[TD="align: right"]486
[/TD]
[TD="align: right"]£90,998
[/TD]
[TD="align: right"]£0
[/TD]
[TD="align: right"]£12,558
[/TD]
[TD="align: right"]£19,019
[/TD]
[TD="align: right"]1
[/TD]
[/TR]
[TR]
[TD="align: right"]503
[/TD]
[TD="align: right"]£99,020
[/TD]
[TD="align: right"]£99,020
[/TD]
[TD="align: right"]£27,330
[/TD]
[TD="align: right"]£20,695
[/TD]
[TD="align: right"]1
[/TD]
[/TR]
[TR]
[TD="align: right"]787
[/TD]
[TD="align: right"]£69,519
[/TD]
[TD="align: right"]£69,519
[/TD]
[TD="align: right"]£19,187
[/TD]
[TD="align: right"]£14,529
[/TD]
[TD="align: right"]1
[/TD]
[/TR]
[TR]
[TD="align: right"]743
[/TD]
[TD="align: right"]£65,886
[/TD]
[TD="align: right"]£0
[/TD]
[TD="align: right"]£9,092
[/TD]
[TD="align: right"]£13,770
[/TD]
[TD="align: right"]1
[/TD]
[/TR]
</tbody>[/TABLE]

To this format (on a tab called "After":

[TABLE="width: 314"]
<tbody>[TR]
[TD]Post
[/TD]
[TD]Type
[/TD]
[TD]Department
[/TD]
[TD]Amount
[/TD]
[/TR]
[TR]
[TD="align: right"]486
[/TD]
[TD="align: right"]1000
[/TD]
[TD="align: right"]1
[/TD]
[TD="align: right"]90998
[/TD]
[/TR]
[TR]
[TD="align: right"]486
[/TD]
[TD="align: right"]1003
[/TD]
[TD="align: right"]1
[/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: right"]486
[/TD]
[TD="align: right"]1001
[/TD]
[TD="align: right"]1
[/TD]
[TD="align: right"]12557.72
[/TD]
[/TR]
[TR]
[TD="align: right"]486
[/TD]
[TD="align: right"]1002
[/TD]
[TD="align: right"]1
[/TD]
[TD="align: right"]19018.58
[/TD]
[/TR]
[TR]
[TD="align: right"]Reference here
[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
</tbody>[/TABLE]

For each post.

For the first post, I have managed to do this by using the code below. The active cell is whatever post is selected in the "Before" tab.

What I then want to do is reference the next blank cell in Column A on "After" (i.e. where I have typed "Reference here").

Then I would do the same for Post 503, and effectively loop until the post number is blank.

I hope this is a fairly clear request, and I would be most grateful for any advice that you may have.

Sub ImportData()
Dim postID As String
Dim Department As String
Dim SalaryAccount As String
Dim ErnicAccount As String
Dim PensionAccount As String
Dim AllowanceAccount As String
Dim Salary As String
Dim Ernic As String
Dim Allowance As String
Dim Pension As String

postID = ActiveCell.Value
Department = ActiveCell.Offset(0, 5).Value
SalaryAccount = "1000"
ErnicAccount = "1001"
PensionAccount = "1002"
AllowanceAccount = "1003"
Salary = ActiveCell.Offset(0, 1).Value
Ernic = ActiveCell.Offset(0, 3)
Allowance = ActiveCell.Offset(0, 2)
Pension = ActiveCell.Offset(0, 4)


Dim strAddress As String



strAddress = Worksheets(Sheets.Count).Range("A2").Address

Worksheets("After").Range(strAddress).Offset(0, 0) = postID
Worksheets("After").Range(strAddress).Offset(0, 1) = SalaryAccount
Worksheets("After").Range(strAddress).Offset(0, 2) = Department
Worksheets("After").Range(strAddress).Offset(0, 3) = Salary

Worksheets("After").Range(strAddress).Offset(1, 0) = postID
Worksheets("After").Range(strAddress).Offset(1, 1) = AllowanceAccount
Worksheets("After").Range(strAddress).Offset(1, 2) = Department
Worksheets("After").Range(strAddress).Offset(1, 3) = Allowance

Worksheets("After").Range(strAddress).Offset(2, 0) = postID
Worksheets("After").Range(strAddress).Offset(2, 1) = ErnicAccount
Worksheets("After").Range(strAddress).Offset(2, 2) = Department
Worksheets("After").Range(strAddress).Offset(2, 3) = Ernic
Worksheets("After").Range(strAddress).Offset(3, 0) = postID
Worksheets("After").Range(strAddress).Offset(3, 1) = PensionAccount
Worksheets("After").Range(strAddress).Offset(3, 2) = Department
Worksheets("After").Range(strAddress).Offset(3, 3) = Pension
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Try this for results on sheets "After".
Code:
[COLOR="Navy"]Sub[/COLOR] MG31Jul16
[COLOR="Navy"]Dim[/COLOR] n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] oHds [COLOR="Navy"]As[/COLOR] Variant, Ray [COLOR="Navy"]As[/COLOR] Variant, c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
oHds = Array(0, 3, 1, 2)
Ray = Sheets("Before").Cells(1).CurrentRegion
ReDim nray(1 To UBound(Ray, 1) * UBound(Ray, 2), 1 To 4)
  nray(1, 1) = "Post": nray(1, 2) = "Type": nray(1, 3) = "Department": nray(1, 4) = "Amount"
  c = 1
    [COLOR="Navy"]For[/COLOR] n = 2 To UBound(Ray, 1)
          [COLOR="Navy"]For[/COLOR] Ac = 0 To UBound(oHds)
            c = c + 1
            nray(c, 1) = Ray(n, 1)
            nray(c, 2) = "1000" + oHds(Ac)
            nray(c, 3) = Ray(n, 6)
            nray(c, 4) = Ray(n, Ac + 2)
        [COLOR="Navy"]Next[/COLOR] Ac
    [COLOR="Navy"]Next[/COLOR] n
[COLOR="Navy"]With[/COLOR] Sheets("After").Range("A1").Resize(c, 4)
    .Value = nray
    .Borders.Weight = 2
    .Columns.AutoFit
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,849
Members
452,361
Latest member
d3ad3y3

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