Problem with Data Validation...

opopanax666

New Member
Joined
Sep 27, 2006
Messages
18
Hi guys & gals,

I'm working on a large worksheet, which the personnel dpt. uses to input the hours of the employees. This data consists of 26 different codes and a numerical prefix, e.g.

8X
3:12CAO
4GZ

Different people use these worksheets, so I'd need some sort of data validation, because the formulas I worked out only apply to these 26 codes. The numerical prefix could be anything, and doesn't have to be checked. So is there any way of using an advanced Data Validation to only check the non-numerical part of the code (1, 2 or 3 characters long)? Or do I need to use VB?

Thanks for any feedback
 

Some videos you may like

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.

pgc01

MrExcel MVP
Joined
Apr 25, 2006
Messages
19,870
Hi opopanax666
Welcome to the board

With these 3 assumptions:

- The code consists of 1, 2 or 3 letters at the end of the input value
- The character immediately before the code is a digit
- The valid codes are in A1:A26

then use in D1

Data>Validation>Settings>Allow: Custom, enter in formula:

Code:
=ISNUMBER(MATCH(IF(ISNUMBER(--LEFT(RIGHT(D1,2),1)),RIGHT(D1,1),IF(ISNUMBER(--LEFT(RIGHT(D1,3),1)),RIGHT(D1,2),RIGHT(D1,3))),$A$1:$A$26,0))

Hope this helps
PGC
 

Watch MrExcel Video

Forum statistics

Threads
1,111,910
Messages
5,541,538
Members
410,547
Latest member
htran4
Top