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

TheRedCardinal

Board Regular
Joined
Jul 11, 2019
Messages
66
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 :ROFLMAO:

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!
 

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,166
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]
 

TheRedCardinal

Board Regular
Joined
Jul 11, 2019
Messages
66
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?
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,108
Office Version
365
Platform
Windows
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
 

TheRedCardinal

Board Regular
Joined
Jul 11, 2019
Messages
66
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:

Forum statistics

Threads
1,081,774
Messages
5,361,219
Members
400,617
Latest member
barron1

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top