Looking for a value in a range and acting if it's not found

TheRedCardinal

Active Member
Joined
Jul 11, 2019
Messages
250
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
Good morning all!

As I am learning VBA I normally try to solve a problem before I break it and then come here for help :rofl:

For this one though I'm not sure where to start.

Basically, I have 2 worksheets of data.

I need to loop through all the rows in one sheet, and find if a specific value exists in a labelled column in the other sheet. If that value is found, then nothing is needed; but if it's not I need certain data copying from one sheet to the other.

I suspect I need to use some Index, Match, Vlookup process but I've only just started playing in this area (beyond VLOOKUPs) so I'm at a loss.


I've attached an extract from my workbook so you can see what I need to happen here:

Invoice match workbook.xlsx

As I am trying to learn any explanation for the wonderful VBA would be brilliant!
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Code:
[color=darkblue]Sub[/color] voucher()
    [color=darkblue]Dim[/color] voucher [color=darkblue]As[/color] Range, v [color=darkblue]As[/color] [color=darkblue]Variant[/color], counter [color=darkblue]As[/color] [color=darkblue]Long[/color]
    [color=darkblue]For[/color] [color=darkblue]Each[/color] voucher [color=darkblue]In[/color] Sheets("Temp").Range("B2", Sheets("Temp").Range("B" & Rows.Count).End(xlUp))
        [color=darkblue]With[/color] Sheets("2. Final Data")
            v = Application.Match(voucher, .Range("C:C"), 0) [color=green]'test for match[/color]
            [color=darkblue]If[/color] IsError(v) [color=darkblue]Then[/color] [color=green]'if no match then copy data[/color]
                [color=darkblue]With[/color] .Range("B" & Rows.Count).End(xlUp)
                    .Offset(1, 0).Value = voucher.Offset(0, -1).Value
                    .Offset(1, 1).Value = voucher.Value
                    .Offset(1, 2).Value = Abs(voucher.Offset(0, 2).Value)
                    counter = counter + 1
                [color=darkblue]End[/color] [color=darkblue]With[/color]
            [color=darkblue]End[/color] [color=darkblue]If[/color]
        [color=darkblue]End[/color] [color=darkblue]With[/color]
    [color=darkblue]Next[/color] voucher
    MsgBox counter & " voucheres copied.", vbInformation, "Copy Complete"
[color=darkblue]End[/color] [color=darkblue]Sub[/color]
 
Upvote 0
Hi AlphaFrog,

This works perfectly in my test sheet. Alas it is never as simple as that!

The data that comes into the 2. Final Data Sheet is possibly in different orders.

As such I modified the code slightly, to find the 3 columns that I need to paste in. My new code looks like this:

Code:
Sub MoveInvoiceNoIntrastat()

    Dim Voucher As Range, v As Variant, Counter As Long
    Dim DateColumn As Long, InvoiceColumn As Long, AdjustedValue As Long
    Dim TextFinder As Range
    
    Set ws1 = Sheets("2. Final Data")
    Set ws2 = Sheets("Temp")
    
    With ws1
        
        Set TextFinder = .Range("A1:Z1").Find("Date")
            DateColumn = TextFinder.Column
            
        Set TextFinder = .Range("A1:Z1").Find("Invoice")
            InvoiceColumn = TextFinder.Column
            
        Set TextFinder = .Range("A1:Z1").Find("Adjusted Value")
            AdjustedValue = TextFinder.Column
    
    End With
    
    For Each Voucher In Sheets("Temp").Range("B2", Sheets("Temp").Range("B" & Rows.Count).End(xlUp))
        With Sheets("2. Final Data")
[B]            v = Application.Match(Voucher, .Range(Columns(DateColumn), Columns(DateColumn)), 0)[/B]
            
            If IsError(v) Then
            
                With .Range(Columns(DateColumn), Rows.Count).End(xlUp)
                    .Offset(1, 0).Value = Voucher.Offset(0, -1).Value
                    .Offset(1, InvoiceColumn - DateColumn).Value = Voucher.Value
                    .Offset(1, AdjustedValue - DateColumn).Value = Abs(Voucher.Offset(0, 2).Value)
                    Counter = Counter + 1
                End With
            End If
        End With
    Next Voucher
    MsgBox Counter & " vouchers copied.", vbInformation, "Copy Complete"
    
End Sub

The bold and underlined line is where it falls over.

I have stepped through and the number values for the 3 columns are correct.

I suspect I have an issue with my naming and referring to ranges here. Because I have a number, I thought I didn't use "" to refer to the range?
 
Upvote 0
Try it like
Code:
Sub MoveInvoiceNoIntrastat()

    Dim Voucher As Range, v As Variant, Counter As Long
    Dim DateColumn As Range, InvoiceColumn As Range, AdjustedValue As Range
    Dim NxtRw As Long
    
    Set Ws1 = Sheets("2. Final Data")
    Set Ws2 = Sheets("Temp")
    
    With Ws1
        
        Set DateColumn = .Range("A1:Z1").Find("Date")
            
        Set InvoiceColumn = .Range("A1:Z1").Find("Invoice")
            
        Set AdjustedValue = .Range("A1:Z1").Find("Adjusted Value")
    
    End With
    
    For Each Voucher In Sheets("Temp").Range("B2", Sheets("Temp").Range("B" & Rows.Count).End(xlUp))
        With Sheets("2. Final Data")
            v = Application.Match(Voucher, DateColumn.EntireColumn, 0)
            
            If IsError(v) Then
               NxtRw = .Cells(Rows.Count, DateColumn.Column).End(xlUp).Offset(1).Row
               .Cells(NxtRw, DateColumn.Column) = Voucher.Offset(0, -1).Value
               .Cells(NxtRw, InvoiceColumn.Column).Value = Voucher.Value
               .Cells(NxtRw, AdjustedValue.Column).Value = Abs(Voucher.Offset(0, 2).Value)
               Counter = Counter + 1
            End If
        End With
    Next Voucher
    MsgBox Counter & " vouchers copied.", vbInformation, "Copy Complete"
    
End Sub
 
Upvote 0
That's working perfectly now, thanks!

I now need to modify it again so that it pulls the right columns from the Temp folder, I'll give it a go.

My question though - you changed how the Sub worked a little bit - can I ask why?

I mean the NxtRw line, rather than the way you changed the variables for the columns, which makes sense to me.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,719
Messages
6,174,089
Members
452,542
Latest member
Bricklin

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