+ Reply to Thread
Results 1 to 7 of 7

Drop-down list formula based on first 3 characters of variable input in a different cell.

  1. #1
    Registered User
    Join Date
    08-22-2012
    Location
    Oslo, Norway
    MS-Off Ver
    Excel 2003
    Posts
    8

    Drop-down list formula based on first 3 characters of variable input in a different cell.

    Can anyone help defining a formula for data validation for the following:

    In column C, input will either begin with PR7, WS8 or HW9. The range for this input can be anywhere from:
    PR700000 to PR799999, WS800000 to WS899999 and HW900000 to HW999999.

    I have 3 drop-lists I want to use in column H based on the first 3 character-input in column C .

    PR7xxxxx would drop down List1 in column H
    WS8xxxxx would drop down List2 in column H
    HW9xxxxx would drop down list3 in column H

    i.e. PR745862 or PR711145 as input in column C would show drop-down list "List1" for column H.
    i.e. WS850006 or WS899555 as input in column C would show drop-down list "List2" for column H.
    i.e. HW967891 or HW945000 as input in column C would show drop-down list "List3" for column H.

    I've looked, read, watched countless articles for data validation, but all are based on defined input rather than variable input.

    Any help would be appreciated.

    Cheers, ScottyDo

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Drop-down list formula based on first 3 characters of variable input in a different ce

    Have a look here at Dependent Lists: http://www.contextures.com/xlDataVal02.html

    the trick is to make your list names something you can reference from the inputs.

    In this case those 3 characters could be confused with actual cell locations, you can add an underscore...

    so call List1.. PR7, List2: WS8_ and List3: HW9_

    Then in your data validation, use List and formula: =INDIRECT(LEFT(A1,3)&"_") where A1 contains input.
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Registered User
    Join Date
    09-04-2012
    Location
    Mexico
    MS-Off Ver
    Excel 2003
    Posts
    1

    Re: Drop-down list formula based on first 3 characters of variable input in a different ce

    I need to change a cell to a drop down list, can somebody help me??

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Drop-down list formula based on first 3 characters of variable input in a different ce

    Please don't hijack others' threads. You should start your own. In the meantime have a look here: http://www.contextures.com/xlDataVal01.html

    If it does not answer your question, then start a new thread.

  5. #5
    Registered User
    Join Date
    08-22-2012
    Location
    Oslo, Norway
    MS-Off Ver
    Excel 2003
    Posts
    8

    Re: Drop-down list formula based on first 3 characters of variable input in a different ce

    This formula did not work for me. Could be that I'm doing this in Norwegian but I've translated it into what I believe is the correct Norwegian spelling.

    You wrote =INDIRECT(LEFT(A1,3)&"_") and I translated it into =INDIREKTE(VENSTRE(A1,3)&"_")

    On my worksheet called "List", I have 3 columns that hold the lists I need.
    The 1st column is named PR7_, 2nd is WS8_ and 3rd is HW9_ as you suggested.

    On my sheet1, I highlight the H column cells where I want the drop-down list, choose data validating, choose List and then enter the above formula (in Norwegian) that you gave me.
    I get an error msg saying this is not a formula. (same error msg if I use the English version)

  6. #6
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Drop-down list formula based on first 3 characters of variable input in a different ce

    I think, in your version, you need to use semi-colon as separator instead of comma...

    try:

    =INDIREKTE(VENSTRE(A1;3)&"_")

  7. #7
    Registered User
    Join Date
    08-22-2012
    Location
    Oslo, Norway
    MS-Off Ver
    Excel 2003
    Posts
    8

    Re: Drop-down list formula based on first 3 characters of variable input in a different ce

    Thx NBVC, you are right. We use a semi-colon instead of the comma and the formula works perfect for what I need. Thank you for your help.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1