Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 10 of 10

Thread: need help to expand formula

  1. #1
    New Member
    Join Date
    Feb 2002
    Posts
    40
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

  2. #2
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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 .

    [ This Message was edited by: Mark W. on 2002-03-11 10:19 ]

  3. #3
    MrExcel MVP Russell Hauf's Avatar
    Join Date
    Feb 2002
    Location
    Portland, OR Area - USA
    Posts
    1,609
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

  4. #4
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    84,060
    Post Thanks / Like
    Mentioned
    38 Post(s)
    Tagged
    8 Thread(s)

    Default

    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 ]

  5. #5
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    =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 ]

  6. #6
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    =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 ]

  7. #7
    New Member
    Join Date
    Feb 2002
    Posts
    40
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    (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 ]

  8. #8
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    84,060
    Post Thanks / Like
    Mentioned
    38 Post(s)
    Tagged
    8 Thread(s)

    Default

    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

  9. #9
    New Member
    Join Date
    Feb 2002
    Posts
    40
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

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

    Lindsay

  10. #10
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    84,060
    Post Thanks / Like
    Mentioned
    38 Post(s)
    Tagged
    8 Thread(s)

    Default

    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

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •