+ Reply to Thread
Results 1 to 9 of 9

Getting #VALUE! error if formula returns false.

  1. #1
    Registered User
    Join Date
    07-18-2013
    Location
    Cincinnati
    MS-Off Ver
    2010
    Posts
    35

    Getting #VALUE! error if formula returns false.

    I am trying to remove characters enclosed in parenthesis from anywhere in the string, and add them to the end. If they are not present in the cell, just copy the cell as is.

    =IF(FIND("(",A2),SUBSTITUTE(A2,"(Non Emp) ","") & " (Non Emp)", A2)

    So if "(" is found, remove it and add " (Non Emp) on the end. If not, just copy what is in A2.

    If the IF statement is True, it returns fine. (Example A1. has "John (Non Emp) Jones", and returns "John Jones (Non Emp)"
    If the IF statement is False, it returns #VALUE!, saying a value used in the formula is of the wrong data type. (Example, A2 has "Jack Jones" and returns #VALUE!

    I can't figure out why.

    any help would be appreciated.

  2. #2
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,454

    Re: Getting #VALUE! error if formula returns false.

    Maybe this way:

    Formula: copy to clipboard
    Please Login or Register  to view this content.



    Regards, TMS
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  3. #3
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Getting #VALUE! error if formula returns false.

    One way:

    =IF(COUNTIF(A2,"*(*"),SUBSTITUTE(A2,"(Non Emp) ","") & " (Non Emp)", A2)
    Biff
    Microsoft MVP Excel
    Keep It Simple Stupid

    Let's Go Pens. We Want The Cup.

  4. #4
    Registered User
    Join Date
    07-18-2013
    Location
    Cincinnati
    MS-Off Ver
    2010
    Posts
    35

    Re: Getting #VALUE! error if formula returns false.

    That works TMShucks, thanks!

    Also works Tony, thanks!

    However, for my understanding, if someone can answer what the problem is with the original formula, I would appreciate it!

  5. #5
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Getting #VALUE! error if formula returns false.

    If the FIND function doesn't find what it's looking for then it returns the #VALUE! error.

  6. #6
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: Getting #VALUE! error if formula returns false.

    The FIND function returns the #VALUE! error if the searched string is not found.
    so the formula becomes

    =IF(#VALUE!,SUBSTITUTE(A2,"(Non Emp) ","") & " (Non Emp)", A2)

    The if function can't evaluate an Error value, so it returns the error value as well.

  7. #7
    Registered User
    Join Date
    07-18-2013
    Location
    Cincinnati
    MS-Off Ver
    2010
    Posts
    35

    Re: Getting #VALUE! error if formula returns false.

    Ah ok, Thanks Tony & Jonmo1.

    for the COUNTIF, why the asterisks around the parenthesis? I notice it works without it. What function do they serve for future reference?

    edit: nevermind, I see they are wildcards. Thanks.
    Last edited by Jhail83; 08-13-2013 at 04:51 PM.

  8. #8
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,454

    Re: Getting #VALUE! error if formula returns false.

    You're welcome. Thanks for the rep.



    If you are satisfied with the solution(s) provided, please mark your thread as Solved.


    New quick method:
    Select Thread Tools-> Mark thread as Solved. To undo, select Thread Tools-> Mark thread as Unsolved.

    Or you can use this way:

    How to mark a thread Solved
    Go to the first post
    Click edit
    Click Go Advanced
    Just below the word Title you will see a dropdown with the word No prefix.
    Change to Solved
    Click Save


    You may also want to consider thanking those people who helped you by clicking on the little star at the bottom left of their reply to your question.

  9. #9
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Getting #VALUE! error if formula returns false.

    COUNTIF(A2,"*(*")

    The asterisks are wildcards meaning:

    Find any characters (or no characters) followed by a left parenthesis followed by any characters (or no characters).

    Or, in layman's terms: if the cell contains a left parenthesis anywhere within the cell then COUNTIF returns 1 and this evaluates to TRUE for the IF function.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Vlookup formula returns with False Result, How can I get the exact value ?
    By Midoya in forum Excel Formulas & Functions
    Replies: 20
    Last Post: 02-21-2013, 04:34 AM
  2. Conditional format a cell when the formula returns False
    By eddienole in forum Excel General
    Replies: 1
    Last Post: 05-16-2012, 01:35 PM
  3. IF Statement returns either Value error or False
    By katja328 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 01-07-2010, 12:46 PM
  4. Replies: 2
    Last Post: 08-02-2006, 06:10 PM
  5. How to do nothing if @IF returns FALSE?
    By PMorrisDuke in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 04-11-2006, 11:45 AM

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