VBA Userform Textbox Validate Text Between Characters

DixiePiper

New Member
Joined
Oct 19, 2015
Messages
41
Office Version
  1. 365
Platform
  1. Windows
I have a userform that sends a copy of the workbook via email. The primary goal is to send the form back to me (or my counterpart) but it could be useful to send within the company as well. I want to ensure that any email addresses entered have a company domain. I'm not worried about actually validating the address; I just want to limit it to our company domain. I have a simpl InStr validation but if the user enters multiple email addresses and at least one is within the company, the error will not trigger.

How can I validate that all text between "@" and ".com" is one of two company domain names? Using Excel 2013 in Windows 10 OS; validation executes when the "Preview Email" or "Send Email" button is clicked.

The current code looks like this:
Code:
    If InStr(1, Me.cboTo.value, "Company", vbTextCompare) = 0 Or _
            InStr(1, Me.txtCC.value, "Company", vbTextCompare) = 0 Then
        MsgBox "Only Company recipients are allowed. Please review inputs.", vbCritical + vbOKOnly
        Exit Sub
    End If

Right now, I'm just searching the "TO" and "CC" boxes for the company name. I'd like to refine that so it looks for "Company" or "CompanyAlt" (we have two valid domain names) between "@" and "." for every instance of "user@domain.com"

TIA!

p.s. I know this will not completely prevent the file from being improperly distributed. I just want safeguards in my process so it has to be a deliberate action of the user and not an omission on my part.
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
Here's a function to test for your two domain names...

Code:
[COLOR=darkblue]Function[/COLOR] IsValidDom(strAdrs [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]String[/COLOR]) [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Boolean[/COLOR]
    strAdrs = LCase(strAdrs)
    [COLOR=darkblue]If[/COLOR] InStr(strAdrs, "@") [COLOR=darkblue]Then[/COLOR]
        [COLOR=green]'Use lower case domain names[/COLOR]
        IsValidDom = [COLOR=darkblue]UBound[/COLOR](Split(strAdrs, "@company.com")) + [COLOR=darkblue]UBound[/COLOR](Split(strAdrs, "@companyalt.com")) = [COLOR=darkblue]UBound[/COLOR](Split(strAdrs, "@"))
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
End [COLOR=darkblue]Function[/COLOR]


Call the function like this...
Code:
    [COLOR=darkblue]If[/COLOR] [COLOR=darkblue]Not[/COLOR] IsValidDom(Me.cboTo.Value) [COLOR=darkblue]Or[/COLOR] [COLOR=darkblue]Not[/COLOR] IsValidDom(Me.txtCC.Value) [COLOR=darkblue]Then[/COLOR]
        MsgBox "Only Company recipients are allowed." & vbLf & _
               "Please review inputs.", vbCritical + vbOKOnly, "Invalid Email Address"
        [COLOR=darkblue]Exit[/COLOR] [COLOR=darkblue]Sub[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
 
Upvote 0

Forum statistics

Threads
1,223,895
Messages
6,175,257
Members
452,625
Latest member
saadat28

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