Exceljet

Quick, clean, and to the point

Unique values from multiple ranges

Excel formula: Unique values from multiple ranges
Generic formula 
=UNIQUE(VSTACK(range1,range2,range3))
Summary 

To extract unique values from more than one range at the same time, you can use the UNIQUE function with the VSTACK function. In the example shown, the formula in cell H5 is:

=UNIQUE(VSTACK(range1,range2,range3))

Where range1 (C5:C16), range2 (D5:D15), and range3 (F5:F13) are named ranges.

Explanation 

In this example, the goal is to extract unique values from three separate ranges at the same time: range1 (C5:C16), range2 (D5:D15), and range3 (F5:F13). At one time, this was a difficult problem, since UNIQUE is programmed to accept only one array and there is no obvious way to provide another range.  However, with the introduction of the VSTACK function, the solution is straightforward. 

UNIQUE function

The UNIQUE function makes it very easy to extract unique values from a range. Just give UNIQUE a range, and it will give you back the unique values:

=UNIQUE(range) // extract unique

Like other dynamic array formulas, the results from UNIQUE will spill onto the worksheet into multiple cells.

The challenge in this example is to provide more than one range to UNIQUE at the same time. The solution is to use the VSTACK function to combine ranges first, before invoking UNIQUE. This is done with the VSTACK function.

VSTACK function

The VSTACK function combines arrays or ranges vertically into a single array. For example, the formula below joins range1 and range2:

=VSTACK(range1,range2) // combines ranges

Each additional array is appended to the bottom of the previous array. The result from VSTACK is a single array with range1 at the top. To combine more arrays, simply provide more arrays to VSTACK.

Note: VSTACK is currently a Beta function available only through the Beta channel of Office Insiders. The Office Insiders program is free to join in Excel 365. Without VSTACK, it is still possible to combine ranges in a formula, but it is a more complicated formula.

UNIQUE with VSTACK

To solve the problem in this example, we simply need to nest the VSTACK function inside the UNIQUE function like this:

=UNIQUE(VSTACK(range1,range2,range3))

Working from the inside out, the VSTACK function combines all three ranges vertically into a single range:

VSTACK(range1,range2,range3) // combine ranges into one

The combined array has  range1 on top, range2 in the middle, and range3 at the bottom:

range1
range2
range3

This array is then delivered to the UNIQUE function, which returns the unique values in the combined range. The result is a list of unique values in all three ranges taken together.

Empty cells

If any of the ranges to be combined contain empty cells, a zero (0) will appear as a unique value in the final result. To prevent empty cells from being evaluated by UNIQUE, you can use the FILTER function like this:

=LET(
    data,VSTACK(range1,range2,range3),
    UNIQUE(FILTER(data,data<>""))
)

In this formula, the LET function is used to store the result from VSTACK in the variable data so that it can be used twice inside the FILTER function without another call to VSTACK. For more details on the operation of FILTER with UNIQUE, see this example.

Legacy Excel

In Legacy Excel, there is no UNIQUE function or VSTACK function, so the formula on this page is not possible. In simple scenarios, you can use a formula based on INDEX and MATCH to extract unique values. See Alternatives to Dynamic Array Functions for a more general discussion.

If you open the attached workbook in an older version of Excel without UNIQUE and/or VSTACK. You will see an xlfn prefix before the function name. The original result will still be displayed, but the formula will not update if source data changes.

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.

Download 100+ Important Excel Functions

Get over 100 Excel Functions you should know in one handy PDF.