need help to expand formula

chezlinds

New Member
Joined
Feb 25, 2002
Messages
40
I have the following formula:

=IF(ISBLANK(A1),"",IF(OR(A1="a",A1 ="b",A1 = "c",A1 = "d", A1="e", A1="e", A1="f", A1="g", A1="h", A1="i")=TRUE, "PE", "DS"))

but I want to add more arguments to it, so that if A1= "z" the result will also be "PE". However, while this formula works fine as is, if I try to add arguments I get an error that makes me think I've reached the limits allowed. There must be a way! Can anyone help?

Thanks as always,
Lindsay
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
If you want this to be a case sensitive comparison try...

=IF(ISBLANK(A1),"",IF(AND(LEN(A1)=1,ISNUMBER(FIND(A1,"abcdefghijklmnopqrstuvwxyz"))), "PE", "DS"))

...at any rate, this should be easier on the eyes :wink:.
This message was edited by Mark W. on 2002-03-11 10:19
 
Upvote 0
On 2002-03-11 10:01, chezlinds wrote:
I have the following formula:

=IF(ISBLANK(A1),"",IF(OR(A1="a",A1 ="b",A1 = "c",A1 = "d", A1="e", A1="e", A1="f", A1="g", A1="h", A1="i")=TRUE, "PE", "DS"))

but I want to add more arguments to it, so that if A1= "z" the result will also be "PE". However, while this formula works fine as is, if I try to add arguments I get an error that makes me think I've reached the limits allowed. There must be a way! Can anyone help?

Thanks as always,
Lindsay

You should use VLOOKUP. Make a list of your possible values something like:

a True
b True
c True
d True
q SomeValue
z SomeValue

Then use VLOOKUP to get your value.

=VLOOKUP(A1,$C$1:$D$10,2,FALSE)

where C1:D10 is the range where you entered your possible values.

Hope this helps,

Russell
 
Upvote 0
On 2002-03-11 10:01, chezlinds wrote:
I have the following formula:

=IF(ISBLANK(A1),"",IF(OR(A1="a",A1 ="b",A1 = "c",A1 = "d", A1="e", A1="e", A1="f", A1="g", A1="h", A1="i")=TRUE, "PE", "DS"))

but I want to add more arguments to it, so that if A1= "z" the result will also be "PE". However, while this formula works fine as is, if I try to add arguments I get an error that makes me think I've reached the limits allowed. There must be a way! Can anyone help?

Thanks as always,
Lindsay

Lindsay,

A shorter version of your formula would be:

=IF(ISBLANK(A1),"",IF(OR(A1={"a","b","c","d","e","e","f","g","h","i"}), "PE", "DS"))

whose the {"a","b","c","d","e","e","f","g","h","i"} bit can be extended further. However, what follows is much shorter:

=IF(ISBLANK(A1),"",IF(AND(LEN(A1)=1,CODE(UPPER(A1))>64,CODE(UPPER(A1))<=90),"PE","DS"))

will result in PE if A1 houses a letter between A and Z inclusive and case-insensitive, otherwise in DS.

Addendum: Forgat to add the ISBLANK bit to the second formula.

Aladin
This message was edited by Aladin Akyurek on 2002-03-11 10:42
 
Upvote 0
=IF(AND(LEN(A1)=1,CODE(UPPER(A1))>64,CODE(UPPER(A1))<=90),"PE","DS")

Better, make that...

=IF(ISBLANK(A1),"",IF(AND(LEN(A1)=1,CODE(A1)>96,CODE(A1)<123),"PE","DS"))

...if case sensitivity is required.
This message was edited by Mark W. on 2002-03-11 10:35
 
Upvote 0
=IF(ISBLANK(A1),"",IF(OR(A1={"a","b","c","d","e","e","f","g","h","i"}), "PE", "DS"))

whose the {"a","b","c","d","e","e","f","g","h","i"} bit can be extended further.

If case sensitivity is required you could use this instead...

=IF(ISBLANK(A1),"",IF(OR(EXACT(A1,CHAR(ROW($97:$122)))), "PE", "DS"))
This message was edited by Mark W. on 2002-03-13 11:35
 
Upvote 0
(I haven't been able to get back here for a couple of days...)

I guess I should be more specific -- the "a", "b", "c", etc. are actually names of vacation spots (not simple letters). Aladin's formula looks like just what I want, but I still can't get it to accept more than ten names of locations. The formula works fine for the first ten, but not any more. What am I doing wrong?

Lindsay
This message was edited by chezlinds on 2002-03-13 09:22
 
Upvote 0
On 2002-03-13 09:18, chezlinds wrote:
(I haven't been able to get back here for a couple of days...)

I guess I should be more specific -- the "a", "b", "c", etc. are actually names of vacation spots (not simple letters). Aladin's formula looks like just what I want, but I still can't get it to accept more than ten names of locations. The formula works fine for the first ten, but not any more. What am I doing wrong?

Lindsay
This message was edited by chezlinds on 2002-03-13 09:22

Lindsay,

You mean this formula I guess:

=IF(ISBLANK(A1),"",IF(OR(A1={"a","b","c","d","e","e","f","g","h","i"}), "PE", "DS"))

If so, I propose a different, hassle-free approach.

Make a 1-column list of all your vacation spots in a separate sheet you could name Admin. Select all of the cells of this list, go to the Name Box on the Formula Bar, type VacSpots, and enter.

Now use the following formula instead:

=IF(ISBLANK(A1),"",IF(ISNUMBER(MATCH(A1,VacSpots,0)),"PE","DS"))

Aladin
 
Upvote 0
Aladin, forgive the cluelessness, but I don't see a "name box" on my toolbar, and I do have the formula toolbar up.

Lindsay
 
Upvote 0
On 2002-03-13 10:49, chezlinds wrote:
Aladin, forgive the cluelessness, but I don't see a "name box" on my toolbar, and I do have the formula toolbar up.

Lindsay

Left most box on the Formula Bar in which you see cell addresses appear when you are in some cell.

Aladin
 
Upvote 0

Forum statistics

Threads
1,213,534
Messages
6,114,185
Members
448,554
Latest member
Gleisner2

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