Setting focus onto a textbox

Diving_Dan

Board Regular
Joined
Oct 20, 2019
Messages
161
Hi all,

I'm having an issue with setting the focus onto a textbox ("txtOrderNumber") on a userform. This is the code I've got at the moment.

VBA Code:
Private Sub txtOrderNumber_AfterUpdate()
    
    Cells.Find(what:=txtOrderNumber.Value, LookIn:=xlValues).Activate
    ActiveCell.Offset(, 5).Value = "Y"
    ActiveCell.Offset(, 6).Value = Format(Date, "dd/mmm/yyyy")
    Me.txtOrderNumber.Value = ""
    Me.txtOrderNumber.SetFocus
    
End Sub

I am entering the order number into the textbox with a barcode scanner. The code all works fine so I click on my barcode with the scanner it finds what I want, puts the values into the sheet and clears the box but it then sets the focus on a command button to close the form instead of setting the focus onto the textbox.

Any help is appreciated as alwways.

Dan
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
Hi

think its because its trying to set focus to itself, if you can set the focus in your code before your after update macro, then it does set focus. not sure what code you have running previous?

Or, can you use the change event at all?

like the below

VBA Code:
Private Sub txtOrderNumber_Change()
    Cells.Find(what:=txtOrderNumber.Value, LookIn:=xlValues).Activate
    ActiveCell.Offset(, 5).Value = "Y"
    ActiveCell.Offset(, 6).Value = Format(Date, "dd/mmm/yyyy")
    Me.txtOrderNumber.SetFocus
    Me.txtOrderNumber.Value = ""
End Sub

OR, your code with the extra as below
VBA Code:
Private Sub txtOrderNumber_AfterUpdate()
Cells.Find(what:=txtOrderNumber.Value, LookIn:=xlValues).Activate
ActiveCell.Offset(, 5).Value = "Y"
ActiveCell.Offset(, 6).Value = Format(Date, "dd/mmm/yyyy")
Me.txtOrderNumber.Value = ""
End Sub
 Private Sub txtOrderNumber_Change()
    Me.txtOrderNumber.SetFocus
end sub

I know its not the answer, but maybe a workaround

Dave
 
Upvote 0
I was initially using the change event but even though I was scanning a barcode to fill the textbox it was trying to input something after each character was input, as if I was typing it in manually so think I've got to use the AfterUpdate Event. I have tried adding the setfocus as a change event as suggested but unfortunately it doesn't work for me.
 
Upvote 0
have you tried
VBA Code:
Private Sub txtOrderNumber_BeforeUpdate(ByVal Cancel As MSForms.ReturnBoolean)

    Cancel = True   '<~~~~~~~~~~~ stay here don't leave this text box
    Cells.Find(what:=txtOrderNumber.Value, LookIn:=xlValues).Activate
    ActiveCell.Offset(, 5).Value = "Y"
    ActiveCell.Offset(, 6).Value = Format(Date, "dd/mmm/yyyy")
    Me.txtOrderNumber.Value = ""

End Sub
 
Upvote 0
Give this a shot
VBA Code:
Private Sub txtOrderNumber_BeforeUpdate(ByVal Cancel As MSForms.ReturnBoolean)
    Dim fndOrderNum As Range
    
    If Me.txtOrderNumber.Value <> "" Then
        Set fndOrderNum = Cells.Find(what:=txtOrderNumber.Value, LookIn:=xlValues)
        If Not fndOrderNum Is Nothing Then
            With fndOrderNum
                .Activate
                .Offset(, 5).Value = "Y"
                .Offset(, 6).Value = Format(Date, "dd/mmm/yyyy")
            End With
            Me.txtOrderNumber.Value = ""
            Cancel = True   '<~~~~~~~~~~~ stay here don't leave
        Else
        '    MsgBox "Sorry, but  " & Me.txtOrderNumber.Value & "  was not found"
        '    Me.txtOrderNumber.Value = ""
        End If
    End If
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,223,911
Messages
6,175,329
Members
452,635
Latest member
laura12345

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