Advice for userform code

ipbr21054

Well-known Member
Joined
Nov 16, 2010
Messages
5,738
Office Version
  1. 2007
Platform
  1. Windows
Morning,

I have a userform which opens when i first come to the worksheet.
I then enter all the data in each TextBox & when i press a button the data is then entered into the worksheet.

Once the item has been delivered to the customer i then like to enter the date of its delivery.
At present i come to the worksheet,the userform opens,i then close the userform,look for the customer in the spreadsheet & enter the date in the field for that customer.

Long winded i agree.
So i have now put on the userform a CommandButton3

So this is how i think it should work but need some help with the code please.

All customers names are in column B
The delivered date will always be entered in column G

Once i click the CommandButton3 i should see a list of all the customers name from column B.
I select the customer in question, say TOM JONES row 123
I then enter a date like 19/02/2019
This date should then be entered into the worksheet & in the cell G123 alongside the customer TOM JONES.

Many thanks.

This is the current userform code.

Code:
Private Sub CommandButton1_Click()Cancel = 0
If TextBox2.Text = "" Then
    Cancel = 1
    MsgBox "Customer`s Name Not Entered", vbCritical, "POSTAGE TRANSFER SHEET"
    TextBox2.SetFocus
ElseIf TextBox3.Text = "" Then
    Cancel = 1
    MsgBox "Item Description Not Entered", vbCritical, "POSTAGE TRANSFER SHEET"
    TextBox3.SetFocus
ElseIf TextBox4.Text = "" Then
    Cancel = 1
    MsgBox "Tracking Number Not Entered", vbCritical, "POSTAGE TRANSFER SHEET"
    TextBox4.SetFocus
ElseIf ComboBox1.Text = "" Then
    Cancel = 1
    MsgBox "Username Not Entered", vbCritical, "POSTAGE TRANSFER SHEET"
    TextBox5.SetFocus
    
ElseIf OptionButton1.Value = False And OptionButton2.Value = False And OptionButton3.Value = False Then
    Cancel = 1
    MsgBox "You Must Select An Ebay Account", vbCritical, "POSTAGE TRANSFER SHEET"
    
ElseIf OptionButton4.Value = False And OptionButton5.Value = False And OptionButton6.Value = False Then
    Cancel = 1
    MsgBox "You Must Select An Origin", vbCritical, "POSTAGE TRANSFER SHEET"
    
End If


If Cancel = 1 Then
        Exit Sub
End If


Dim i As Long
Dim x As Long
Dim ctrl As Control
Dim LastRow As Long
LastRow = ThisWorkbook.Worksheets("POSTAGE").Cells(Rows.Count, 1).End(xlUp).Row
    


    
 With ThisWorkbook.Worksheets("POSTAGE")
    .Cells(LastRow + 1, 1).Value = TextBox1.Text: TextBox1.Value = ""
    .Cells(LastRow + 1, 2).Value = TextBox2.Text: TextBox2.Value = ""
    .Cells(LastRow + 1, 3).Value = TextBox3.Text: TextBox3.Value = ""
    .Cells(LastRow + 1, 5).Value = TextBox4.Text: TextBox4.Value = ""
    .Cells(LastRow + 1, 9).Value = ComboBox1.Text: ComboBox1.Value = ""
    .Cells(LastRow + 1, 4).Value = TextBox6.Text: TextBox6.Value = ""
    If OptionButton1.Value = True Then .Cells(LastRow + 1, 8).Value = "DR": OptionButton1.Value = False
    If OptionButton2.Value = True Then .Cells(LastRow + 1, 8).Value = "IVY": OptionButton2.Value = False
    If OptionButton3.Value = True Then .Cells(LastRow + 1, 8).Value = "N/A": OptionButton3.Value = False
    If OptionButton4.Value = True Then .Cells(LastRow + 1, 6).Value = "EBAY": OptionButton4.Value = False
    If OptionButton5.Value = True Then .Cells(LastRow + 1, 6).Value = "WEB SITE": OptionButton5.Value = False
    If OptionButton6.Value = True Then .Cells(LastRow + 1, 6).Value = "N/A": OptionButton6.Value = False
End With
TextBox1.Value = Format(CDbl(Date), "dd/mm/yyyy")
TextBox2.SetFocus
TextBox1.Value = Now
TextBox1.Value = Format(CDbl(Date), "dd/mm/yyyy")
End Sub
Private Sub CommandButton2_Click()
Unload PostageTransferSheet


End Sub
Private Sub DHL_Click()
ActiveWorkbook.FollowHyperlink Address:="http://www.dhl.co.uk/en/express/tracking.html", NewWindow:=True


End Sub
Private Sub HERMES_Click()
ActiveWorkbook.FollowHyperlink Address:="https://www.myhermes.co.uk/tracking-results.html", NewWindow:=True


End Sub
Private Sub LABEL_Click()
TrackingLabel.Show


End Sub
Private Sub ROYALMAIL_Click()
ActiveWorkbook.FollowHyperlink Address:="https://www.royalmail.com/track-your-item", NewWindow:=True


End Sub


Private Sub TextBox1_Change()
    TextBox1 = UCase(TextBox1)
End Sub
Private Sub TextBox2_Change()
    TextBox2 = UCase(TextBox2)
End Sub
Private Sub TextBox3_Change()
    TextBox3 = UCase(TextBox3)
End Sub
Private Sub TextBox4_Change()
    TextBox4 = UCase(TextBox4)
End Sub
Private Sub ComboBox1_Change()
    ComboBox1 = UCase(ComboBox1)
End Sub
Private Sub TextBox6_Change()
    TextBox6 = UCase(TextBox6)
End Sub
Private Sub CustomerSearchBox_Change()
'Modified  10/3/2018  5:51:42 AM  EDT
Dim SearchString As String
Dim SearchRange As Range
SearchString = CustomerSearchBox.Value
Dim LastRow As Long
LastRow = Cells(Rows.Count, "B").End(xlUp).Row
Set SearchRange = Range("B2:B" & LastRow).Find(SearchString, LookIn:=xlValues, lookat:=xlWhole)
If SearchRange Is Nothing Then MsgBox SearchString & "  Not Found": Exit Sub
SearchRange.Select
Unload Me
End Sub
Private Sub UserForm_Initialize()
'Modified  10/3/2018  5:51:42 AM  EDT
Application.ScreenUpdating = False
Dim LastRow As Long
LastRow = Sheets("POSTAGE").Cells(Rows.Count, "B").End(xlUp).Row
Dim Lastrowa As Long
Sheets("POSTAGE").Cells(8, 2).Resize(LastRow - 7).Copy Sheets("POSTAGE").Cells(1, 12)
Lastrowa = Sheets("POSTAGE").Cells(Rows.Count, "L").End(xlUp).Row
Sheets("POSTAGE").Cells(1, 12).Resize(Lastrowa).Sort key1:=Cells(1, 12).Resize(Lastrowa), order1:=xlAscending, Header:=xlNo
CustomerSearchBox.List = Sheets("POSTAGE").Cells(1, 12).Resize(Lastrowa).Value
Sheets("POSTAGE").Cells(1, 12).Resize(Lastrowa).Clear
Application.ScreenUpdating = True


'USERNAME COMBOBOX




TextBox1.Value = Format(CDbl(Date), "dd/mm/yyyy")
TextBox2.SetFocus
End Sub
Private Sub TextBox2_BeforeUpdate(ByVal Cancel As MSForms.ReturnBoolean)
    Dim fndRng As Range, findString As String, i As Integer


If Me.TextBox2.Value = "" Then Exit Sub
findString = Me.TextBox2.Value


With Sheets("POSTAGE").Range("B:B")
    Set fndRng = .Find(What:=findString, LookIn:=xlValues, lookat:=xlWhole, _
                   SearchOrder:=xlByRows, SearchDirection:=xlNext, MatchCase:=False)
                   
    If Not fndRng Is Nothing Then
        'what was entered already exists - alter the name until not found
        For i = 2 To 20
            findString = Me.TextBox2.Value & " " & i
            Set fndRng = .Find(What:=findString, LookIn:=xlValues, lookat:=xlWhole, _
                       SearchOrder:=xlByRows, SearchDirection:=xlNext, MatchCase:=False)
            If fndRng Is Nothing Then Exit For
        Next i
        
        'message saying what name should be
        'MsgBox "The name to use is " & findString
        
        'enter that name into textbox 2
        With Me.TextBox2
            .Value = findString
            .SelStart = 0
            .SelLength = Len(.Text)
            .SetFocus
        End With
        
        'cancel moving out of text box
        Cancel = True
    End If
End With
    
End Sub
 
Re: Advice for userform code please

Also on this list box is a text field etc where I enter the date.


That is not possible you should have a textbox, in my example I put the textbox3.



The list box would have a CANCEL & OK button.


That is also not possible, the Cancel and Ok buttons must be in the form



----

Then let's start from the fact that you already have a userform and inside a listbox and a commandbutton3.


Now, you need in your userform a textbox (maybe TextBoxDate)to capture the date, a commandbutton OK and a commandbutton Cancel.


Then this is the code for your commandbutton3

Code:
Private Sub CommandButton3_Click()


    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Sheets("POSTAGE").Cells(Rows.Count, "B").End(xlUp).Row
    Dim Lastrowa As Long
    Sheets("POSTAGE").Cells(8, 2).Resize(LastRow - 7).Copy Sheets("POSTAGE").Cells(1, 12)
    Lastrowa = Sheets("POSTAGE").Cells(Rows.Count, "L").End(xlUp).Row
    Sheets("POSTAGE").Cells(1, 12).Resize(Lastrowa).Sort key1:=Cells(1, 12).Resize(Lastrowa), order1:=xlAscending, Header:=xlNo
    CustomerSearchBox.List = Sheets("POSTAGE").Cells(1, 12).Resize(Lastrowa).Value
    Sheets("POSTAGE").Cells(1, 12).Resize(Lastrowa).Clear
    Application.ScreenUpdating = True


    MsgBox "Select customer name from list"
    
End Sub

Here is the code for your OK button


Code:
Private Sub OkButton1_Click()


    Dim sh As Worksheet
    Dim b As Range
    Dim wName As String
    
    If CustomerSearchBox.ListIndex = -1 Then
        MsgBox "Select customer name from list"
        Exit Sub
    End If
    
    If [I]TextBoxDate[/I].Value = "" Or Not IsDate([I]TextBoxDate[/I].Value) Then
        MsgBox "Enter a valid date"
        [I]TextBoxDate[/I].SetFocus
        Exit Sub
    End If
    
    wName = CustomerSearchBox.List(CustomerSearchBox.ListIndex)
    Set sh = Sheets("POSTAGE")
    Set b = sh.Columns("B").Find(wName, LookIn:=xlValues, lookat:=xlWhole)
    If Not b Is Nothing Then
        sh.Cells(b.Row, "G").Value = CDate([I]TextBoxDate[/I].Value)
        MsgBox "Delivered date updated"
    End If


End Sub



And the code for your Cancel button


Code:
Private Sub CancelButton2_Click()
    Unload Me
End Sub
 
Upvote 0

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Re: Advice for userform code please

This just doesnt work for me,i will tell you why.

I click the commandbutton3
Straight away i am told to select a name from the list.
So all that code for this button did not work as i received the message.


The only list i have to select a customers name is the existing list BUT its for my purpose to then go straight to the customer in the worksheet.
So by clicking a name will not work for you.
 
Upvote 0
Re: Advice for userform code please

I now have it working with a few alterations.
Thanks
 
Upvote 0
Re: Advice for userform code please

Check the following file.
Follow the next steps.
1. Open the file
2. Press the "openform" button
3. Select a customer from the list
4. Enter the date in textbox
5. Press the OK button
Ready, with these steps you can put a date to the selected client, and then you can continue with another client without closing the form.

https://www.dropbox.com/s/muqfs8zznkquct0/test11.xlsm?dl=0
 
Upvote 0
Re: Advice for userform code please

Hi,
If the worksheet names are all mixed up how when you open the userform see the name list in order A-Z
 
Upvote 0
Re: Advice for userform code please

Use the following code in the Activate event

Replace the previous one with this

Code:
Private Sub UserForm_Activate()
    'ListBox1.RowSource = "B2:B" & Range("B" & Rows.Count).End(xlUp).Row
    Dim i As Long, j As Long, ws As Worksheet
    Set ws = Sheets("POSTAGE")
    For i = 2 To ws.Range("B" & Rows.Count).End(xlUp).Row
        added = False
        For j = 0 To ListBox1.ListCount - 1
            Select Case StrComp(ListBox1.List(j), ws.Cells(i, "B").Value, vbTextCompare)
                Case 0: added = True: Exit For
                Case 1: added = True: ListBox1.AddItem ws.Cells(i, "B").Value, j
                Exit For
            End Select
        Next
        If added = False Then ListBox1.AddItem ws.Cells(i, "B").Value
    Next
End Sub
 
Upvote 0
Re: Advice for userform code please

Thanks I will check that out tomorrow.

I was wondering if it's possible to click a button etc which then shows a small calendar.
Upon selecting the date from that calendar it would then enter it into the appropriate cell like the format of 22/02/2019.
just a thought.
 
Upvote 0
Re: Advice for userform code please

You can use a control in your userform, it can be DTPicker or MonthView, but you should check if your excel version supports these controls.
 
Upvote 0
Re: Advice for userform code please

Morning,
Many thanks for the sort code it works well.

One thing i didnt mention & didnt know until now is the following.

In the list where i see all the customers names,which we have just put in order A-Z
There is a space BEFORE the names are shown.
So example,

Space.
Andy
Bob
Charlie

Can we have it so i see no space,
so example
Andy
Bob
Charlie

In my worksheet row 7 is headers then row 8 is where the name start to go down the page in column B

Thanks
 
Upvote 0
Re: Advice for userform code please

Change in this line 2 by 8

Check the cells in column B, perhaps after your last name a cell in a space inside the cell.

Code:
For i = 2 To ws.Range("B" & Rows.Count).End(xlUp).Row
 
Upvote 0

Forum statistics

Threads
1,223,910
Messages
6,175,316
Members
452,634
Latest member
cpostell

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