VBA to move data using an INDEX and MATCH type arrangement?

Storm8585

New Member
Joined
Sep 5, 2014
Messages
47
Hi all,

I'm in need of some help. I have a workbook with two worksheets - Sheet A has (for simplicity) three columns with data in. Col A has a Location ID (this may be duplicated several times), Col B has a number in which relates to a depth, and Col C has a test number in. Sheet B has a table which I require auto completing with VBA. The header for the table is in Row 19. In col A and B in Sheet B I have a start depth and a base depth in Col B. The rest of the table requires the test values (from Col C in Sheet A) to be inserted.
The code needs to loop through each test value in Col C (Sheet A) and for each value, look at what the ID ref is (Col A) and the depth (Col B), and then copy this value into the correct cell in the table, using the corresponding ID ref in row 19 (Sheet B) to work out what col in the table to past to, and working out if the depth falls within the depth range in Col A and B (Sheet B) using basic math to work out what row to paste the value into.

Sheet A
[TABLE="width: 500"]
<tbody>[TR]
[TD][TABLE="width: 106"]
<tbody>[TR]
[TD]Col A[/TD]
[/TR]
</tbody><colgroup><col></colgroup>[/TABLE]
[/TD]
[TD]Col B[/TD]
[TD]Col C[/TD]
[/TR]
[TR]
[TD]WS1[/TD]
[TD]1[/TD]
[TD]45[/TD]
[/TR]
[TR]
[TD]WS1[/TD]
[TD]2[/TD]
[TD]50[/TD]
[/TR]
[TR]
[TD]WS1[/TD]
[TD]4.5[/TD]
[TD]12[/TD]
[/TR]
[TR]
[TD]WS2[/TD]
[TD]1[/TD]
[TD]15[/TD]
[/TR]
</tbody>[/TABLE]

Sheet B

[TABLE="width: 500"]
<tbody>[TR]
[TD]Top (on row 19)
Col A[/TD]
[TD]Base
Col B[/TD]
[TD]WS1
Col C[/TD]
[TD]WS2
Col D[/TD]
[TD]WS3
Col E[/TD]
[TD]BH1
Col F[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]1.99[/TD]
[TD]45[/TD]
[TD]15[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]2.99[/TD]
[TD]50[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]3.99[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]4.99[/TD]
[TD]12[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

I hope the tables help! T
Thanks in advance.
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Maybe something like this

Assumes
Sheet A

[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
LocationID​
[/TD]
[TD]
Depth​
[/TD]
[TD]
Test​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
WS1​
[/TD]
[TD]
1​
[/TD]
[TD]
45​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
WS1​
[/TD]
[TD]
2​
[/TD]
[TD]
50​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
WS1​
[/TD]
[TD]
4,5​
[/TD]
[TD]
12​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
WS2​
[/TD]
[TD]
1​
[/TD]
[TD]
15​
[/TD]
[/TR]
</tbody>[/TABLE]


Sheet B

[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[TD="bgcolor: #DCE6F1"]
D
[/TD]
[TD="bgcolor: #DCE6F1"]
E
[/TD]
[TD="bgcolor: #DCE6F1"]
F
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
19
[/TD]
[TD]
Top​
[/TD]
[TD]
Base​
[/TD]
[TD]
WS1​
[/TD]
[TD]
WS2​
[/TD]
[TD]
WS3​
[/TD]
[TD]
BH1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
20
[/TD]
[TD]
1​
[/TD]
[TD]
1,99​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
21
[/TD]
[TD]
2​
[/TD]
[TD]
2,99​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
22
[/TD]
[TD]
3​
[/TD]
[TD]
3,99​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
23
[/TD]
[TD]
4​
[/TD]
[TD]
4,99​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Run the Sub Main
Code:
Option Explicit

Sub Main()
    Dim vData As Variant, i As Long
    
    With Sheets("Sheet A") '<--adjust sheet name
        vData = .Range("A2:C" & .Cells(.Rows.Count, "A").End(xlUp).Row)
    End With
    
    For i = LBound(vData, 1) To UBound(vData, 1)
        DoJob vData(i, 1), vData(i, 2), vData(i, 3)
    Next i
End Sub

Sub DoJob(ByVal s1 As String, ByVal dbVal1 As Double, ByVal dbVal2 As Double)
    Dim rCol As Range, lRow As Variant
    
    With Sheets("Sheet B") '<--adjust sheet name
        Set rCol = .Range("A19:Z19").Find(s1, LookIn:=xlValues, LookAt:=xlWhole, SearchOrder:=xlByColumns, _
                SearchDirection:=xlNext, MatchCase:=False, SearchFormat:=False)
        If Not rCol Is Nothing Then
            lRow = Application.Match(dbVal1, .Range("A20:A24"))
            If Not IsError(lRow) Then .Cells(lRow + 19, rCol.Column) = dbVal2
        End If
    End With
            
End Sub

After macro

Sheet B

[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[TD="bgcolor: #DCE6F1"]
D
[/TD]
[TD="bgcolor: #DCE6F1"]
E
[/TD]
[TD="bgcolor: #DCE6F1"]
F
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
19
[/TD]
[TD]
Top​
[/TD]
[TD]
Base​
[/TD]
[TD]
WS1​
[/TD]
[TD]
WS2​
[/TD]
[TD]
WS3​
[/TD]
[TD]
BH1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
20
[/TD]
[TD]
1​
[/TD]
[TD]
1,99​
[/TD]
[TD]
45​
[/TD]
[TD]
15​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
21
[/TD]
[TD]
2​
[/TD]
[TD]
2,99​
[/TD]
[TD]
50​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
22
[/TD]
[TD]
3​
[/TD]
[TD]
3,99​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
23
[/TD]
[TD]
4​
[/TD]
[TD]
4,99​
[/TD]
[TD]
12​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Hope this helps

M.
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
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