Lookup ID and Return Column Data to Form if Found - Code Tweak Needed

reasonablenesscheck

New Member
Joined
Jul 2, 2009
Messages
42
This code works, well kindof. If it is looking for ID 74578, it returns the FIRST INSTANCE of that number (Like 7457899) instead of the ACTUAL unique number I want.

How do I alter this code so it looks for the EXACT number?


Code:
Private Sub RecordR_Click()
'prompts user
'prompts user
Dim MyResponse As String
MyResponse7 = InputBox("Paste Record ID")
If MyResponse7 = "" Then
    MsgBox "No Number Entered.  Aborting.", vbCritical
    Exit Sub
End If

'takes entry and searches for it and returns that row to the form

    Dim strFind, FirstAddress As String   'what to find
    Dim rSearch As Range, intRange As Range  'range to search
    
Dim ws1
Dim ws2

Dim Rng1 As Range
Dim Rng2 As Range
Dim Rng3 As Range
Dim RNG4 As Range
Dim RNG5 As Range
Dim cell As Range

WB1 = "Watar.xlsm"


ws2 = "DATA"
ws3 = "Miss Q Data"

Dim ws5 As Worksheet
Dim Found As Range

Dim AddressStr As String
Set ws5 = ActiveSheet

    Set rSearch = Workbooks(WB1).Sheets(ws2).Range("F1:F" &  Workbooks(WB1).Sheets(ws2).Range("F" &  Workbooks(WB1).Sheets(ws2).Rows.Count).End(xlUp).Row)
    strFind = MyResponse7   'what to look for
    Dim f As Integer, strRange As Range
        With rSearch
        Set C = .Find(strFind, LookIn:=xlValues)
        
 'if item not found then check Miss Q sheet
 
 If C Is Nothing Then
              MsgBox "The Discogs item number doesn't exist on DATA sheet."
              cbodiscogs = MyResponse7
Me.cboartist.SetFocus
            
              
End If

            If Not C Is Nothing Then    'found it
                
                
            
            cbodiscogs = MyResponse7
                
Me.cboartist.Value = C.Offset(0, -5).Value
Me.cbotitle.Value = C.Offset(0, -4).Value
Me.cborecdescshort.Value = C.Offset(0, -3).Value
Me.cboreleaseno.Value = C.Offset(0, -2).Value
Me.txtstockno.Value = 1
'Me.txtprice.Value = C.Offset(0, 1).Value
'Me.cborecordcond = C.Offset(0, 2).Value
'Me.cbocovercond = C.Offset(0, 3).Value
'Me.cbocoverinfo = C.Offset(0, 4).Value
'Me.cbocondcomments = C.Offset(0, 5).Value
Me.cbogenre.Value = C.Offset(0, 6).Value
Me.txtyear.Value = C.Offset(0, 7).Value
Me.cbolabel.Value = C.Offset(0, 8).Value
Me.cbocountry.Value = C.Offset(0, 9).Value
Me.txtdescription.Value = C.Offset(0, 11).Value
                
              Me.txtprice.SetFocus
              

End If
               End With

Exit Sub


One more thing...

All the values that have a ' in front of them...

These.

Code:
'Me.txtprice.Value = C.Offset(0, 1).Value
'Me.cborecordcond = C.Offset(0, 2).Value
'Me.cbocovercond = C.Offset(0, 3).Value
'Me.cbocoverinfo = C.Offset(0, 4).Value
'Me.cbocondcomments = C.Offset(0, 5).Value
I want the values returned in RED PRINT, so that my the user knows they need to be changed. Obviously I can remove the ticks, to make the value returned, but how can I make them appear in red, and then go back to black after refreshing the form?

Thanks in advance.
 

p45cal

Well-known Member
Joined
Nov 10, 2009
Messages
4,763
Untested, adjust:
Code:
Set C = .Find(strFind, LookIn:=xlValues)
to:
Code:
Set C = .Find(strFind, LookIn:=xlValues, LookAt:=xlwhole)
 

p45cal

Well-known Member
Joined
Nov 10, 2009
Messages
4,763
For the colours:
Code:
Me.txtprice.Value = C.Offset(0, 1).Value 
Me.txtprice.ForeColor = vbRed

Me.cborecordcond = C.Offset(0, 2).Value
Me.cborecordcond.ForeColor = vbRed
but don't forget to make them black again at some stage, eg.:
Code:
Me.txtprice.ForeColor = vbBlack
You could do it in the change event for each control:
Code:
Private Sub TextBox1_Change()
Me.TextBox1.ForeColor = vbBlack
End Sub

Private Sub ComboBox1_Change()
Me.ComboBox1.ForeColor = vbBlack
End Sub
 
Last edited:

Forum statistics

Threads
1,082,283
Messages
5,364,268
Members
400,787
Latest member
bs04c

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