+ Reply to Thread
Results 1 to 3 of 3

Truncating List to avoid blanks, errors etc.

  1. #1
    Registered User
    Join Date
    05-19-2013
    Location
    Chester, England
    MS-Off Ver
    Excel 2013
    Posts
    40

    Truncating List to avoid blanks, errors etc.

    I have a formula which generates a list of unique values from a table in another worksheet.
    These entries are used as a validated list for drop-downs in other parts of the workbook.
    Because I don't know how many entries my list will have I have to define the list with a larger range than is likely to be needed(or I'll miss some entries).
    This means I'll get zeros or NA errors when the formula runs out of unique values - and these then show in the drop-downs.
    Which is annoying if not catastrophic.
    {=INDEX(DataPull!$I7:$I$1000, MATCH(0, COUNTIF(C$1:$C8, DataPull!$I7:$I1006), 0))}......this gives me my values, typically 10-20 entries.
    Would love to know how to restrict my validated list to just these entries.

  2. #2
    Forum Expert
    Join Date
    03-23-2004
    Location
    London, England
    MS-Off Ver
    Excel 2019
    Posts
    7,062

    Re: Truncating List to avoid blanks, errors etc.

    Are you sure that should be an array formula?

    I have this which works and is not an array:
    With values in column B starting at B1...
    in A1
    =B1

    in A2
    =IFERROR(IF(INDEX($B$2:$B$20,MATCH(0,INDEX(COUNTIF($A$1:A4,$B$2:$B$20),0,0),0))<>0,INDEX($B$2:$B$20,MATCH(0,INDEX(COUNTIF($A$1:A4,$B$2:$B$20),0,0),0)),""),"")
    copy the formula in A2 ddown the column
    Regards
    Special-K

    Ensure you describe your problem clearly, I have little time available to solve these problems and do not appreciate numerous changes to them.

  3. #3
    Registered User
    Join Date
    05-19-2013
    Location
    Chester, England
    MS-Off Ver
    Excel 2013
    Posts
    40

    Re: Truncating List to avoid blanks, errors etc.

    This works for me if I change A4 to A2 - or the equivalent for the range in my worksheet - but use it as an array in B1(or equivalent, again).
    Thanks for pointing me in the right direction.

+ 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. IF statement trying to avoid blanks
    By thoron6 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 03-31-2016, 05:39 AM
  2. [SOLVED] Create a list of uppercase data from a range excluding blanks and errors
    By PAexcel in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 06-17-2014, 01:32 PM
  3. How to avoid #DVI/0! errors and average correctly
    By nsmjc in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 02-21-2014, 04:23 AM
  4. [SOLVED] Can I avoid Hyperlink formulas with #VALUE errors?
    By Enigmafish14 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 11-22-2013, 08:12 PM
  5. Summing to avoid #N/A errors
    By saad3000 in forum Excel - New Users/Basics
    Replies: 5
    Last Post: 02-28-2008, 02:35 PM
  6. How to Avoid Rounding Errors
    By John Pritchard in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 01-30-2006, 08:45 AM
  7. How to avoid counting blanks in a list
    By Frank in forum Excel Programming / VBA / Macros
    Replies: 10
    Last Post: 10-03-2005, 09:05 AM

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