Completing the yes no function

quintin

Board Regular
Joined
Jun 26, 2013
Messages
52
Good day, I have the following code in a userform, which worked fine until i tried to put in a yes no function.
I need the code to run and check if the are any duplicate names, which it does, if a no duplicate names are found then add the data.
However if it finds a duplicate name then it should ask the question - there is a person with the same name continue yes or no.
if yes then it adds 1 behind the name, if no then it should exit.
I'm sure i done it half right, but thats not good enough, i think i may have put in the end if's in the incorrect place.
here is the current code, many thx

Code:
Private Sub cmb_submit_Click()
    Dim LastRow As Long
    Dim LR As Integer
    Dim ws As Worksheet
    Dim n As Range
    Dim MSG1 As Long
    
      If tb_surname.Value = "" Then
      Unload Me
      Sheets("DASHBOARD").Activate
      Exit Sub
      End If
      

Set n = [a:a].Find(tb_surname.Value, LookIn:=xlValues, lookat:=xlWhole)
If Not n Is Nothing And tb_surname <> "" Then

''End If
'Exit Sub
      tb_surname.Value = tb_surname & 1
            If tb_surname.Value = tb_surname & 1 Then

      If tb_surname.Value = tb_surname Then
      End If
      'Else
     ' End If
      MSG1 = MsgBox("THERE IS A PATIENT WITH THE SAME NAME, DO YOU WANT TO CONTUNE", vbYesNo)
      'End If
      If MSG1 = vbYes Then


        '     Sheets("DASHBOARD").Activate
'Unload Me
     ' If MSG1 = vbNo Then
    'End If
'Exit Sub
    'End If
    End If

     ' Else
            End If
               ' End If

    LastRow = Sheets("PATIENT DATA").Range("a" & Rows.Count).End(xlUp).Row
    Cells(LastRow + 1, "a").Value = tb_surname.Text
    Cells(LastRow + 1, "b").Value = tb_name.Text
    Cells(LastRow + 1, "c").Value = tb_id.Text
    Cells(LastRow + 1, "d").Value = tb_street.Text
    Cells(LastRow + 1, "e").Value = tb_suburb.Text
    Cells(LastRow + 1, "f").Value = cb_towns.Text
    Cells(LastRow + 1, "g").Value = cb_country.Value
    Cells(LastRow + 1, "h").Value = tb_email.Text
    Cells(LastRow + 1, "i").Value = tb_home.Text
    Cells(LastRow + 1, "j").Value = tb_work.Text
    Cells(LastRow + 1, "k").Value = tb_cell.Text
    Cells(LastRow + 1, "l").Value = tb_refby.Text
    Cells(LastRow + 1, "m").Value = cb_refbypat.Value
    Cells(LastRow + 1, "n").Value = tb_mainsurname.Text
    Cells(LastRow + 1, "o").Value = tb_mainname.Text
    Cells(LastRow + 1, "p").Value = tb_mainid.Text
    Cells(LastRow + 1, "q").Value = tb_scheme.Text
    Cells(LastRow + 1, "r").Value = tb_option.Text
    Cells(LastRow + 1, "s").Value = tb_medno.Text
    Cells(LastRow + 1, "t").Value = tb_maincode.Text
    Cells(LastRow + 1, "u").Value = tb_patcode.Text
    Cells(LastRow + 1, "w").Value = tb_date.Text
    Cells(LastRow + 1, "x").Value = tb_lastv.Text
    'Cells(lastrow + 1, "ar").Value = tb_before.Text
    Cells(LastRow + 1, "aq").Value = tb_medyn.Text
    
LR = Range("A" & Rows.Count).End(xlUp).Row
Application.EnableEvents = False
Range("A3:BI" & LR).Sort Key1:=Range("A3"), Order1:=xlAscending, _
    Header:=xlGuess, OrderCustom:=1, MatchCase:=False, Orientation:=xlTopToBottom
Application.EnableEvents = True

    ActiveWorkbook.Save
    Unload newpatient
    Sheets("DASHBOARD").Activate
      If MSG1 = vbNo Then
      Unload Me
      Sheets("DASHBOARD").Activate
      Exit Sub
      End If
      'End If
End Sub[code]
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
You have commented out so many End Ifs in seemingly random locations, its very difficult to see what you are trying to accomplish.

Would it be possible to provide the working code before you tried to add the yes/no functionality... and then explain what you are trying to achieve with the yes/no?
 
Upvote 0
Hi,
Not tested but see if this re-working of your code helps:


Make back-up of your workbook & place all code in your forms code page:

Code:
Option Base 1
Private Sub cmb_submit_Click()
    Dim LastRow As Long, LR As Long
    Dim i As Integer, Adjust As Integer
    Dim ws As Worksheet
    Dim FoundCell As Range
    Dim MSG1 As VbMsgBoxResult
    Dim Search As String
    
    Search = tb_surname.Value
    
    Set ws = ThisWorkbook.Worksheets("PATIENT DATA")
Top:
    Set FoundCell = ws.Columns(1).Find(Search, LookIn:=xlValues, lookat:=xlWhole)
    If Not FoundCell Is Nothing Then
        
        MSG1 = MsgBox(Search & Chr(10) & "THERE IS A PATIENT WITH THE SAME NAME" & Chr(10) & _
        "DO YOU WANT TO CONTUNE?", 36, "Duplicate Patient Name")
        
        If MSG1 = vbNo Then GoTo exitsub
        
'increment duplicate name
        Search = AddNumber(Search)
        
'update textbox
    Me.tb_surname.Text = Search
    
'try again
        GoTo Top
    End If
 
'find lastrow +1
    LastRow = ws.Range("a" & ws.Rows.Count).End(xlUp).Row + 1
    
'add values to range
    For i = LBound(ControlsArray) To UBound(ControlsArray)
        
        With Me.Controls(ControlsArray(i))
            If i = UBound(ControlsArray) Then Adjust = 19
            If IsDate(.Text) Then
                ws.Cells(LastRow, i + Adjust).Value = DateValue(.Text)
            Else
                ws.Cells(LastRow, i + Adjust) = .Text
            End If
        End With
        
    Next i
        
        ws.Range("A3:BI" & LastRow).Sort Key1:=ws.Range("A3"), Order1:=xlAscending, _
        Header:=xlGuess, OrderCustom:=1, MatchCase:=False, Orientation:=xlTopToBottom
        
        ThisWorkbook.Save
        
'report complete
        MsgBox Search & Chr(10) & "Record Saved", 48, "Record Saved"
        
exitsub:
        Sheets("DASHBOARD").Activate
        Unload Me
    End Sub
    
    Function AddNumber(ByVal Text As String) As String
    Dim Temp As String
    Dim Index As Integer
    For Index = 1 To Len(Text)
        If Mid(Text, Index, 1) Like "#" Then
        Temp = Mid(Text, 1, Index - 1)
        Index = Mid(Text, Index) + 1
        AddNumber = Temp & Index
        Exit Function
        End If
    Next
    AddNumber = Text & "1"
    End Function
    
    Function ControlsArray() As Variant
        ControlsArray = Array("tb_surname", "tb_name", "tb_id", "tb_street", "tb_suburb", "cb_towns", _
        "cb_country", "tb_email", "tb_home", "tb_work", "tb_cell", "tb_refby", _
        "cb_refbypat", "tb_mainsurname", "tb_mainname", "tb_mainid", "tb_scheme", "tb_option", _
        "tb_medno", "tb_maincode", "tb_patcode", "tb_date", "tb_lastv", "tb_medyn")
    End Function
    
    Private Sub tb_surname_Change()
        Me.cmb_submit.Enabled = Len(Me.tb_surname.Text) > 0
    End Sub
    
    
    Private Sub UserForm_Initialize()
        Me.cmb_submit.Enabled = False
    End Sub


I have added function that will increment duplicate Surname by one each time until next available number found.

As stated, Code is not tested and should be adjusted as required.

Dave
 
Last edited:
Upvote 0
Cross-posted: The yes/ no function

While we do not prohibit Cross-Posting on this site, we do ask that you please mention you are doing so and provide links in each of the threads pointing to the other thread (see rule #13 here: Forum Rules).

This way, other members can see what has already been done in regards to a question, and do not waste time working on a question that may already be answered.

For a more complete explanation on cross-posting, see here: Excelguru Help Site - A message to forum cross posters).
 
Upvote 0
Cross-posted: The yes/ no function

While we do not prohibit Cross-Posting on this site, we do ask that you please mention you are doing so and provide links in each of the threads pointing to the other thread (see rule #13 here: Forum Rules).

This way, other members can see what has already been done in regards to a question, and do not waste time working on a question that may already be answered.

For a more complete explanation on cross-posting, see here: Excelguru Help Site - A message to forum cross posters).


Thanks for highlighting this – I put a lot of effort in to resolving a problem for an OP recently only to find they took solution to another board where posted same question for others to work with – as you can imagine, I was not too pleased. I like many who contribute to MrExcel forum do it freely to help and only expect at most an acknowledgment for help given & hope that we are shown a little courtesy.

Dave
 
Upvote 0

Forum statistics

Threads
1,215,787
Messages
6,126,905
Members
449,348
Latest member
Rdeane

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