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
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
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
 
Upvote 0

Forum statistics

Threads
1,222,195
Messages
6,164,510
Members
451,900
Latest member
lamski

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