If the cell you're validating is A1, with the current value of: abcd1234567 --------------------------------- Your first criteria is easy: Len(A1)=11 --------------------------------- The second criteria: "last 7 characters are numeric" CAN be fairly simple, depending on your definition of "numeric". right(A1,7) gives you the last 7 characters. "normallY", ISNUMBER() would tell you if the characters are numeric. But for some reason, since your cell value is alphanumeric, Excel considers the last 7 characters as "text" and therefore, ISNUMBER(RIGHT(A1,7)) would return FALSE. So, you have to convert it to an number. you can either use: INT(RIGHT(A1,7)) or RIGHT(A1,7)*1 I chose ISNUMBER(RIGHT(A2,7)*1) Now, as the to your definition of "numeric": To Excel all of these are 7 digit "numerics": 1234567 .123456 123.456 123456% If that is acceptable, than all is well and good, if NOT then we'll have to work on testing each individual character to see if it is between 0 and 9. --------------------------------- Your third criteria: "the first 4 characters as alpha" requires testing each character separately. To extract the character, you can use the MID() function MID(A1,4,1) extracts the fourth character MID(A1,3,1) extracts the third character MID(A1,2,1) extracts the second character. MID(A1,1,1) extract the first character (you COULD use LEFT(A1,1) but to keep it looking the same, I prefer to use MID()) Now, to test to see if it is alpha, use ISTEXT() Resulting in: ISTEXT(MID(A1,1,1)) --------------------------------- Now, for the validation formula, each of these criteria must be met. By combining them, you get: =AND(LEN(A1)=11, ISNUMBER(INT(RIGHT(A1,7))), ISTEXT(MID(A1,1,1)), ISTEXT(MID(A1,2,1)), ISTEXT(MID(A1,3,1)), ISTEXT(MID(A1,4,1)) )
Hope this helps Paul ----------------------------------------- “Do all the good you can, By all the means you can, In all the ways you can, In all the places you can, At all the times you can, To all the people you can, As long as ever you can.” - John Wesley ----------------------------------------- From: Ashish Bhalara <ashishbhalar...@gmail.com> >To: excel-macros@googlegroups.com >Sent: Thursday, February 26, 2015 10:50 PM >Subject: $$Excel-Macros$$ Function for Data validataion > > > >Dear experts, > > >I want to formula for data validation to fulfill below conditions. > > > 1. Total character should be 11 degit > > 2. Last 7 character should be numeric > > 3. First 4 character should be Alphabatic (A to Z) >Please see attached file in which 3rd criteria I can't make it. >PPlease do not print this email unless it is absolutely necessary. Spread environmental üawareness.♣♣♣ > > -- >Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be? It’s >=TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @ >https://www.facebook.com/discussexcel > >FORUM RULES > >1) Use concise, accurate thread titles. Poor thread titles, like Please Help, >Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get >quick attention or may not be answered. >2) Don't post a question in the thread of another member. >3) Don't post questions regarding breaking or bypassing any security measure. >4) Acknowledge the responses you receive, good or bad. >5) Jobs posting is not allowed. >6) Sharing copyrighted material and their links is not allowed. > >NOTE : Don't ever post confidential data in a workbook. Forum owners and >members are not responsible for any loss. >--- >You received this message because you are subscribed to the Google Groups "MS >EXCEL AND VBA MACROS" group. >To unsubscribe from this group and stop receiving emails from it, send an >email to excel-macros+unsubscr...@googlegroups.com. >To post to this group, send email to excel-macros@googlegroups.com. >Visit this group at http://groups.google.com/group/excel-macros. >For more options, visit https://groups.google.com/d/optout. > > > -- Are you =EXP(E:RT) or =NOT(EXP(E:RT)) in Excel? And do you wanna be? It’s =TIME(2,DO:IT,N:OW) ! Join official Facebook page of this forum @ https://www.facebook.com/discussexcel FORUM RULES 1) Use concise, accurate thread titles. Poor thread titles, like Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get quick attention or may not be answered. 2) Don't post a question in the thread of another member. 3) Don't post questions regarding breaking or bypassing any security measure. 4) Acknowledge the responses you receive, good or bad. 5) Jobs posting is not allowed. 6) Sharing copyrighted material and their links is not allowed. NOTE : Don't ever post confidential data in a workbook. Forum owners and members are not responsible for any loss. --- You received this message because you are subscribed to the Google Groups "MS EXCEL AND VBA MACROS" group. To unsubscribe from this group and stop receiving emails from it, send an email to excel-macros+unsubscr...@googlegroups.com. To post to this group, send email to excel-macros@googlegroups.com. Visit this group at http://groups.google.com/group/excel-macros. For more options, visit https://groups.google.com/d/optout.