November 20, 2009 at 1:55 am
Comments posted to this topic are about the item E-Mail Validator
December 9, 2009 at 6:11 am
Very nice.
I would make a couple of suggestions though. To avoid the loop looking at each individual character, use regular expressions to look for invalid characters:
IF (
@vParameter_Length = 0
OR CHARINDEX ('@', @vParameter) < 2
OR CHARINDEX ('.', @vParameter) < 2
OR CHARINDEX ('.@', @vParameter) <> 0
OR CHARINDEX ('..', @vParameter) <> 0
OR CHARINDEX ('.', REVERSE (@vParameter)) < 3
OR CHARINDEX ('.', @vParameter, CHARINDEX ('@',@vParameter)) = 0
OR RIGHT (@vParameter,1) = '@'
OR @vParameter LIKE '%@%@%'
OR @vParameter LIKE '%[!-*]%'
OR @vParameter LIKE '%,%'
OR @vParameter LIKE '%/%'
OR @vParameter LIKE '%[:-?]%'
OR @vParameter LIKE '%[[-^]%'
OR @vParameter LIKE '%`%'
OR @vParameter LIKE '%[{-~]%'
)
Then if you are going to do it on an entire table, you can avoid the function altogether which would probably bring your SQL Server to its knees to have a function in the where clause of a select against a million row table. This query ran against an 800,000+ row table in about 4 seconds.
December 9, 2009 at 8:43 am
I found this code in Internet some time ago.
I modify to Sqlserver
create FUNCTION IsValidEmail
(@Email varchar(100))
RETURNS bit
AS
BEGIN
Declare @Long Int,
@Pos Int,
@Bueno Bit,
@Ext varchar(1000),
@Letras varchar(100),
@I Int
Set @Letras = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ@.-_0123456789'
Set @Email = rtrim(ltrim(@Email))
Set @Long = Len(@Email)
Set @Pos = CharIndex('@',@Email)
Set @Bueno = 0
If not (@Long < 6 -- Muy corto (very short)
Or @Pos = 0 -- No hay arrobas (no @s-2)
Or CharIndex('@',@Email,CharIndex('@',@Email)+1) > 0 -- dos o mas arrobas (more than 1 @)
Or CharIndex(left(@Email,1),'@.-_') > 0 -- No empieza por '@.-_'
Or CharIndex(right(@Email,1),'@.-_') > 0 -- No termina en '@.-_'
Or CharIndex('@.',@Email) > 0
or CharIndex('..',@Email) > 0
or CharIndex('.@',@Email) > 0) -- @. ó ..
Begin
Set @Ext = '.COM.EDU.GOV.NET.BIZ.ORG.TV.INFO'
+ '.AF.AL.DZ.As.AD.AO.AI.AQ.AG.AP.AR.AM.AW.AU.AT.AZ.BS.BH.BD.BB.BY'
+ '.BE.BZ.BJ.BM.BT.BO.BA.BW.BV.BR.IO.BN.BG.BF.MM.BI.KH.CM.CA.CV.KY'
+ '.CF.TD.CL.CN.CX.CC.CO.KM.CG.CD.CK.CR.CI.HR.CU.CY.CZ.DK.DJ.DM.DO'
+ '.TP.EC.EG.SV.GQ.ER.EE.ET.FK.FO.FJ.FI.CS.SU.FR.FX.GF.PF.TF.GA.GM.GE.DE'
+ '.GH.GI.GB.GR.GL.GD.GP.GU.GT.GN.GW.GY.HT.HM.HN.HK.HU.IS.IN.ID.IR.IQ'
+ '.IE.IL.IT.JM.JP.JO.KZ.KE.KI.KW.KG.LA.LV.LB.LS.LR.LY.LI.LT.LU.MO.MK.MG'
+ '.MW.MY.MV.ML.MT.MH.MQ.MR.MU.YT.MX.FM.MD.MC.MN.MS.MA.MZ.NA'
+ '.NR.NP.NL.AN.NT.NC.NZ.NI.NE.NG.NU.NF.KP.MP.NO.OM.PK.PW.PA.PG.PY'
+ '.PE.PH.PN.PL.PT.PR.QA.RE.RO.RU.RW.GS.SH.KN.LC.PM.ST.VC.SM.SA.SN.SC'
+ '.SL.SG.SK.SI.SB.SO.ZA.KR.ES.LK.SD.SR.SJ.SZ.SE.CH.SY.TJ.TW.TZ.TH.TG.TK'
+ '.TO.TT.TN.TR.TM.TC.TV.UG.UA.AE.UK.US.UY.UM.UZ.VU.VA.VE.VN.VG.VI'
+ '.WF.WS.EH.YE.YU.ZR.ZM.ZW'
Set @Pos = @Long + 1 - CharIndex('.',Reverse(@Email)) -- localiza el último punto (locate last period)
If CharIndex(substring(@Email, @Pos,60), @Ext) > 0 -- Chequea terminación válida
Begin
Set @I = 1
While @I <= @Long
Begin
If CharIndex(Substring(@Email,@I,1),@Letras) = 0 -- Letra o caracter inválido (invalid char)
Break
Set @I = @I + 1
End
End
If @Long < @I
Set @Bueno = 1
End
Return @Bueno
December 9, 2009 at 8:46 am
Very nice! Thanks for all of the helpful tips and tricks.
June 2, 2010 at 1:25 pm
Dennis,
I like your pattern matching approach. However, I was concerned about the 128 extended characters, so I suggest the last condition be modified to changed the ~ to a ÿ, like this:
OR @vParameter LIKE '%[{-ÿ]%'
Sincerely,
Daniel
June 2, 2010 at 1:52 pm
Oops, ÿ doesn't work
Sincerely,
Daniel
June 2, 2010 at 4:01 pm
OK, here's the fix for ÿ:
OR @vParameter COLLATE Latin1_General_BIN LIKE '%[{-ÿ]%'
Sincerely,
Daniel
August 24, 2010 at 10:37 am
Thanks Sean! I believe this is a lot more inclusive than the edits I’d coded in my script.
Libby Montgomery
August 24, 2010 at 5:09 pm
Thanks. Hope it helps.
May 23, 2016 at 7:07 am
Thanks for the script.
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy