Unable To Find Match In My Data

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,564
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
I have run into a problem with my attempt to use the Match function with VBA.

consider this code:
Rich (BB code):
Private Sub UserForm_Initialize()
    Dim qw As String
    Dim tqw As String
    Dim nRID As Double
    Dim nsvc As Long, psvcnum As Long, rwprid As Long
    Dim evtf As String, psvcdiv As String, pvrid as string
    
    Me.Caption = "TOURNAMENT SERVICE:  " & tcnt & " of " & ref
Stop
   
    trid = ridt 'rid (text)
    nRID = CDbl(trid) 'rid (number)
    nsvc = tsvcnum 'service (-#) number
    Debug.Print "Full Toun. RID: " & trid & "-" & nsvc
    
    'previous service division
    psvcnum = nsvc - 1
    If psvcnum = 0 Then
        pvrid = trid
    Else
        pvrid = trid & "-" & psvcnum
    End If
    rwprid = Application.WorksheetFunction.Match(CStr(pvrid), ws_master.Columns(1), 0)  'i used CStr to convert any numbers to string so the comparison is between two strings
    evtf = ws_master.Cells(rwprid, 5)
    psvcdiv = Split(Split(evtf, ")")(0), "(")(1)
    Me.lb_pdiv.Caption = psvcdiv

I am getting an error with the line in red ("Unable to get the Match property of the WorksheetFunction class") I am trying to find a match of string variable 'pvrid' with the mix of string ("########-#") and numbers (########) in column A of worksheet ws_master. In my stesting, pvrid = "45072004", which matches the numeric value in cell A14.

Here is the data in column A of ws_master in which I'm seeking the match.

Is anyone able to identify my error?
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
Sorry, I have been keeping
Rich (BB code):
 Application.Match(CStr(pvrid)
in the code, but CStr has to be removed

Please retry...
 
Upvote 1
Solution
I forgot the data ...

WS 26-May-23.xlsx
A
10Record ID
11
12
1345072003
1445072004
1545072018
1645072019
1745072011
1845072012
1945072013
2045072021
2145072004-1
2245072018-1
2345072019-1
2445072009
2545072010
2645072004-1
2745072018-2
28
2945072005
3045072017
3145072006
3245072007
3345072008
3445072014
3545072015
3645072016
3745072020
3845072001
39
4045072002
41
42
43Facility Maintenance Activities
Master
 
Upvote 0
pvrid is defined as string, so CStr adds nothing to the situation
So I think you need to look carefully to your column A and pvrid and search for "hard to detect" differences. For example, are even those values that look like a number (eg 45072003) stored as string?

In general Application.WorksheetFunction.Match throws a run-time error if the match fails. Thus I suggest you use Application.Match, that returns Error(2042) as the result; something like this:
VBA Code:
Dim rwprid As Variant           'watch As Variant
rwprid = Application.Match(CStr(pvrid), ws_master.Columns(1), 0)
If Not IsError(rwprid) Then
    'successful Match, run the other instructions:
    'your instruction
    'your instruction
    'your instruction
End If
Try to adapt to your situation
 
Upvote 0
Hi Anthony, I just caught the same thing about Cstr'ng a string. Kinda redundant.
In my data, all but those values that have a '-#' are indeed numbers. The others are text. So I think the problems is trying to match a text value to a number.
I adjusted my code as per your suggestion, and it threw the error code then just ended. So. No match I suppose.
Perhaps I should change all the data in Column A to a string? Not sure how to do that.
 
Upvote 0
Try modifying how pvrid is generated:
VBA Code:
    If psvcnum = 0 Then
        pvrid = nRID
    Else
        pvrid = trid & "-" & psvcnum
    End If
This requires pvrid be declared As Variant
 
Upvote 0
Hmmm, Excel isn't cooperating with us.
Still no match.

VBA Code:
Private Sub UserForm_Initialize()
    Dim qw As String
    Dim tqw As String
    Dim nRID As Double
    Dim nsvc As Long, psvcnum As Long
    Dim evtf As String, psvcdiv As String
    Dim pvrid As Variant
    Dim rwprid As Variant
    Me.Caption = "TOURNAMENT SERVICE:  " & tcnt & " of " & ref
Stop
   
    trid = ridt 'rid (text)
    nRID = CDbl(trid) 'rid (number)
    nsvc = tsvcnum 'service (-#) number
    Debug.Print "Full Toun. RID: " & trid & "-" & nsvc
    
    'previous service division
    psvcnum = nsvc - 1
    If psvcnum = 0 Then
        pvrid = nRID
    Else
        pvrid = trid & "-" & psvcnum
    End If
    pdaEnd = Application.WorksheetFunction.Match("Facility Maintenance Activities", ws_master.Columns(1), 0) - 2
    'With ws_master.Range("A13:A" & pdaEnd)
    '    .NumberFormat = "Text"
    '    .Value = .Value
    'End With
    rwprid = Application.Match(CStr(pvrid), ws_master.Columns(1), 0)
    If Not IsError(rwprid) Then
        evtf = ws_master.Cells(rwprid, 5)
        psvcdiv = Split(Split(evtf, ")")(0), "(")(1)
        Me.lb_pdiv.Caption = psvcdiv
        
        cntsvc = 0

I did experiment with ...

VBA Code:
With ws_master.Range("A13:A" & pdaEnd)
        .NumberFormat = "Text"
       .Value = .Value
 End With
using both "General" and "Text" numberformats but I don't think any of them changed the numbers to a string value.
 
Upvote 0
I used your data in Column A with the following snippet:
Code:
psvcnum = 2                 '<<<< Change manually
nRid = 45072018             '<<< Change manually
trid = CStr(nRid)

Debug.Print ">>> psvcnum: " & psvcnum, "nRid: " & nRid, "trid: " & trid
    If psvcnum = 0 Then
        pvrid = nRid
    Else
        pvrid = trid & "-" & psvcnum
    End If
Debug.Print pvrid, TypeName(pvrid)
    rwprid = Application.Match(pvrid, ws_master.Columns(1), 0)
Debug.Print "rwprid: " & CStr(rwprid)
Debug.Print
I run the code changing manually the value assigned to psvcnum: 2 / 0 / 22

Debug.Print provided in the vba “Immediate window” the following debug information:
Code:
>>> psvcnum: 2              nRid: 45072018              trid: 45072018
45072018-2    String
rwprid: 21

>>> psvcnum: 0              nRid: 45072018              trid: 45072018
 45072018     Long
rwprid: 9

>>> psvcnum: 22             nRid: 45072018              trid: 45072018
45072018-22   String
rwprid: Errore 2042

With pvrid = 45072018-2 (String) the result of Match was 21
With pvrid = 45072018 (Long) the result of Match was 9
With pvrid = 45072018-22 (String) the result of Match was Error 2042

These results are in agreement with the content of column A


Try adding the same Debug.Print in your code as follows:
Code:
    trid = ridt 'rid (text)
    nRID = CDbl(trid) 'rid (number)
    nsvc = tsvcnum 'service (-#) number
    Debug.Print "Full Toun. RID: " & trid & "-" & nsvc
    
    'previous service division
    psvcnum = nsvc - 1
    If psvcnum = 0 Then
        pvrid = nRID
    Else
        pvrid = trid & "-" & psvcnum
    End If
    
Debug.Print pvrid, TypeName(pvrid)
    
    pdaEnd = Application.WorksheetFunction.Match("Facility Maintenance Activities", ws_master.Columns(1), 0) - 2
    'With ws_master.Range("A13:A" & pdaEnd)
    '    .NumberFormat = "Text"
    '    .Value = .Value
    'End With

Debug.Print "pdaEnd: " & pdaEnd

    rwprid = Application.Match(CStr(pvrid), ws_master.Columns(1), 0)
    
Debug.Print "rwprid: " & CStr(rwprid)
Debug.Print
    
    If Not IsError(rwprid) Then
        'etc etc

Then examine the log in the Immediate window and try to guess what doesn’t work; share the log and we will share the thoughts
 
Upvote 0
Hi Anthony, I really appreciate your continued support. Thank you.
I added your diagnostic lines, and although a different set of similar data, I'm running into the same issues.

Here is the 'log' from the first instance ...

VBA Code:
Full Toun. RID: 45073009-1
 45073009     Double
pdaEnd: 64
rwprid: Error 2042

The data I'm using ...
WS 27-May-23.xlsx
A
12
1345073008
1445073009
1545073023
1645073024
1745073014
1845073015
1945073016
2045073009-1
2145073009-2
2245073008-1
2345073023-1
2445073024-1
2545073015-1
2645073014-1
2745073016-1
2845073011
2945073009-3
3045073008-2
3145073023-2
3245073024-2
3345073014-2
3445073009-4
3545073008-3
3645073023-3
3745073024-1
38
3945073012
4045073013
4145073018
4245073019
4345073020
4445073017
4545073001
4645073003
4745073004
4845073006
4945073022
5045073030
5145073010
5245073002
53
5445073005
55
5645073029
5745073007
5845073027
5945073025
6045073028
6145073026
6245073099
6345073021
64
65
66Facility Maintenance Activities
Master_WRK
 
Upvote 0
Does the error happens both for Numbers and strings?

Can you show the debug.print that produced such output?

In a free area of your worksheet (I used I1:J1):
-in I1 TYPE (do not COPY from column A) the Number that failed to match (for example 45073009)
-in J1 set the formula =COUNTIF(A:A,I1)
Check that the result is 1 or higher; if it is 0 then doublecheck in column A the cell that seems to contain 45073009, and look for trailing or leading spaces; format the cell with 2 decimals and check that it display correctly; extend the decimal to 10 and check the number is always shown as an Integer (all decimals at 0); retype the whole Number. At any test check the result of the COUNTIF formula
 
Last edited:
Upvote 0

Forum statistics

Threads
1,216,086
Messages
6,128,736
Members
449,466
Latest member
Peter Juhnke

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