+ Reply to Thread
Results 1 to 4 of 4

Removing multiple invalid characters for dependent data validation list

  1. #1
    Registered User
    Join Date
    10-14-2009
    Location
    Denver, CO
    MS-Off Ver
    Excel 2010
    Posts
    7

    Removing multiple invalid characters for dependent data validation list

    Can anyone please tell me how to remove multiple numbers or other unacceptable characters for a cell range name?

    Essentially I have a list drop down that is dependent on a first list. The first list has numbers, spaces, and "-" at the beginning I need to get rid of to make it a valid name to reference. The "Substitute" function can't be nested enough times to make this work for me since I have a fairly lengthy list for the independent column which has differing numbers at the beginning.

    The first two examples of the independent drop down (which would dictate the second dependent column and drop down) are:

    00 - Preconstruction
    01 - General Conditions

    I would like to name these something like "Preconstruction" and "GeneralConditions" for valid naming convention.


    Second thought:

    If character removal isn't the most efficient or possible at all, is there a combination of reference functions that could make this work?

    Ultimately I want to use these 2 drop downs for reference functions on a second worksheet


    Please let me know if this doesn't make sense. I know it's a bit convoluted.

    Thanks!
    Last edited by cuclay; 10-15-2009 at 10:41 AM.

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Removing multiple invalid characters for dependent data validation list

    There are a couple of ways to do this. If your layout is consistent and you want the text after the "-" without spaces, you can use this DV formula:

    =INDIRECT(SUBSTITUTE(MID(A2,FIND("-",A2)+2,LEN(A2))," ",""))

    If you want to use more controlled list names, you can actually create a lookup table in your sheet somewhere. The first column could be called List and could be used as the DV source in the first drop box. The second column is the name of the matching list, and can appropriately be called Lists.
    Please Login or Register  to view this content.
    Then you use this as your Data Validation formula:
    =INDIRECT(LOOKUP(A2, List, Lists))

    With this second method, you are no longer constrained by the text, your LISTS can have any list name values you want.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  3. #3
    Registered User
    Join Date
    10-14-2009
    Location
    Denver, CO
    MS-Off Ver
    Excel 2010
    Posts
    7

    Re: Removing multiple invalid characters for dependent data validation list

    JB your second option worked perfectly. Thank you very much. This is great.

  4. #4
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Removing multiple invalid characters for dependent data validation list

    If that takes care of your need, be sure to EDIT your original post, click Go Advanced and mark the PREFIX box [SOLVED].


    (Also, use the blue "scales" icon in our posts to leave Reputation Feedback, it is appreciated)

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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