• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Excel VSTACK and HSTACK Functions

You are here: Home / Excel Formulas / Excel VSTACK and HSTACK Functions
September 1, 2022 by Mynda Treacy

Excel VSTACK and HSTACK functions are just two of a raft of new text manipulation functions available to Microsoft 365 users. I wrote about text splitting functions, TEXTSPLIT, TEXTBEFORE and TEXTAFTER a while back. The new VSTACK and HSTACK functions work to combine arrays arranged vertically (VSTACK) or horizontally (HSTACK) into a new single array.

Watch the Excel VSTACK and HSTACK Functions Video

Subscribe YouTube

Download Workbook

Enter your email address below to download the sample workbook.

By submitting your email address you agree that we can email you our Excel newsletter.
Please enter a valid email address.

Download the Excel Workbook and follow along. Note: This is a .xlsx file please ensure your browser doesn't change the file extension on download.

VSTACK Function Syntax

Syntax: =VSTACK(array1,[array2],...)
array     The arrays (cell ranges) you want to append.

HSTACK Function Syntax

Syntax: =HSTACK(array1,[array2],...)

array     The arrays (cell ranges) you want to append.

The syntax is fairly straight forward, but there are some clever techniques we can use to enable stacking data from multiple sheets, sorting, specify headers, filters, handle errors and more.

Example 1: VSTACK Two Arrays

In its simplest form, VSTACK combines multiple arrays of the same number of columns:

Excel VSTACK and HSTACK Functions

Example 2: VSTACK with Headers

Column headers can be added to the stack by entering them in the first array argument as shown below, or referencing an array that contains the labels:

Excel VSTACK with headers

Example 3: VSTACK Sorted Data with Headers

We can nest VSTACK functions inside one another to enable sorting of the data using the SORT function separate to the headers:

Excel VSTACK sorted data with headers

Example 4: VSTACK Handling Errors with IFNA

If the arrays being stacked are different sizes, VSTACK will return #N/A! errors in place of the missing data:

Excel VSTACK errors

Wrapping the formula in IFNA enables you to specify something else in place of the errors. In the example below I’ve used two double quotes so the cell appears empty, but you could also enter some text in here like, “Missing Data”:

handling VSTACK errors

Example 5: VSTACK Unique Rows Only

Omitting duplicates from the final array is easy with the UNIQUE function:

Excel VSTACK unique rows

Example 6: VSTACK 3D Range

You can stack data spread across multiple sheets. In the images below you can see I have data containing the same number of columns, but a different number of rows on 3 separate sheets:

Excel VSTACK 3D Range source data

I can use VSTACK with a 3D reference to stack them all into one array. Now, because I need to allow for the table containing the largest number of rows in my range it results in zeros being returned for the tables that don’t contain data on rows 5 and 6. We’ll look at hiding these blanks in the next example.

Excel VSTACK 3D Range

Tip: If your data is formatted in an Excel Table, you could simply reference the 3 table names separately e.g.:

=VSTACK(Sales_20,Sales_21,Sales_22)

If the data grows, the formula will automatically include the new data.

Example 7: VSTACK Ignore Empty Rows

The previous example contained some empty rows which resulted in zeros throughout the final array. We can use the FILTER function to exclude those rows from our stack:

Excel VSTACK ignore empty rows

Example 8: VSTACK Filtered for Criteria

Similar, to the previous example, we can filter for specific criteria. In the example below I’ve used VSTACK three times:

  1. For the headings
  2. For the range being stacked
  3. For the column containing my criteria used by filter

Excel VSTACK filtered for criteria

Example 9: HSTACK

HSTACK is the horizontal stacking equivalent of VSTACK, so we’ll just look at one scenario for completeness. The example below shows how we can combine two vertically arranged sets of data into a horizontal array. Notice the use of the two double quotes in the middle HSTACK argument to allow for a blank column between the two groups of data:

Excel HSTACK

VSTACK and HSTACK 3D Reference Limitations

One of the advantages of the ‘STACK’ functions is they can be used to make 3D references work with any function that doesn’t have support, except those functions that require a range as an input.

Remember, a 3D reference is one that references multiple sheets, like we looked at in example 6:

Excel VSTACK 3D Range source data

Here we used VSTACK to append it together into one array with the following formula:

=VSTACK('2020:2022'!A2:D6)

Another common 3D formula is to sum the data on those three sheets like so:

=SUM('2020:2022'!D2:D6)

We can do this because the SUM function supports 3D references. Here’s list of all functions that support 3D references.

However, what if you wanted to sum the data for the Clothing category on those three sheets? You might try to write this SUMIF formula:

=SUMIF('2020:2022'!D2:D6,'2020:2022'!B2:B6="Clothing",'2020:2022'!D2:D6)

And you’d find it returns the #VALUE! error because the SUMIF function requires a range as the first argument. And because of this you can’t use VSTACK for the range argument because VSTACK returns an array, not a range. Instead, you could use one of the following formulas:

=SUMPRODUCT(--(VSTACK('2020:2022'!B2:B6)="Clothing")*VSTACK('2020:2022'!D2:D6))

Or

=SUM(--(VSTACK('2020:2022'!B2:B6)="Clothing")*(VSTACK('2020:2022'!D2:D6)))

VLOOKUP and XLOOKUP on the other hand do accept VSTACK in the array arguments. For example, say I want to lookup the sales for socks, I can write:

=VLOOKUP("Socks",VSTACK('2020:2022'!C2:D6),2,0)

Or

=XLOOKUP("Socks",VSTACK('2020:2022'!C2:C6),VSTACK('2020:2022'!D2:D6))

More Excel Formulas Posts

ai-aided excel formula editor

AI Aided Excel Formula Editor

Save time with this free AI Excel formula editor add-in that writes, edits, improves and interprets formulas for you!
top excel functions for data analysts

Top Excel Functions for Data Analysts

Must know Excel Functions for Data Analysts and what functions you don’t have to waste time learning and why.
excel advanced formula environment

Excel Advanced Formula Environment

Excel Advanced Formula Environment is a long awaited, new improved way to write, name and store Excel formulas.
Pro Excel Formula Writing Tips

Pro Excel Formula Writing Tips

Must know Excel formula writing tips, tricks and tools to make you an Excel formula ninja, including a new formula editor.
excel shaping arrays

New Array Shaping Excel Functions

The Excel Shaping Array Functions makes it easier than ever to reshape arrays and ranges using these purpose built functions
excel nested if functions what not to do

Excel IF Formulas and What Not To Do

Excel IF formulas can get out of hand when you nest too many IFs. Not only do they become unwieldy they’re difficult for anyone to understand
excel image function

Excel IMAGE Function

The Excel IMAGE Function enables you to embed images in a cell using a formula. It supports BMP, JPG/JPEG, GIF, TIFF, PNG, ICO, and WEBP files
identify overlapping dates and times in excel

Identify overlapping dates and times in Excel

How to identify overlapping dates and times in Excel with a formula that checks a range of cells. Works with Dates and Times.
New Excel Text Functions

TEXTSPLIT, TEXTBEFORE and TEXTAFTER Functions

TEXTAFTER, TEXTBEFORE and TEXTSPLIT are exciting new Excel Text functions. They’re fairly self-explanatory, however TEXTSPLIT has some cool features.

Top 10 Intermediate Excel Functions

Take your Excel skills to the next level with this top 10 intermediate Excel functions. These are must know functions for all Excel users.


Category: Excel Formulas
Previous Post:Excel S Curve ChartsExcel S-Curve Charts
Next Post:Excel IMAGE Functionexcel image function

Reader Interactions

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Current ye@r *

Leave this field empty

Sidebar

More results...

Featured Content

  • 10 Common Excel Mistakes to Avoid
  • Top Excel Functions for Data Analysts
  • Secrets to Building Excel Dashboards in Less Than 15 Minutes
  • Pro Excel Formula Writing Tips
  • Hidden Excel Double-Click Shortcuts
  • Top 10 Intermediate Excel Functions
  • 5 Pro Excel Dashboard Design Tips
  • 5 Excel SUM Function Tricks
  • 239 Excel Keyboard Shortcuts

100 Excel Tips and Tricks eBook

Download Free Tips & Tricks

Subscribe to Our Newsletter

Receive weekly tutorials on Excel, Power Query, Power Pivot, Power BI and More.

We respect your email privacy

Guides and Resources

  • Excel Keyboard Shortcuts
  • Excel Functions
  • Excel Formulas
  • Excel Custom Number Formatting
  • ALT Codes
  • Pivot Tables
  • VLOOKUP
  • VBA
  • Excel Userforms
  • Free Downloads

239 Excel Keyboard Shortcuts

Download Free PDF

Free Webinars

Excel Dashboards Webinar

Watch our free webinars and learn to create Interactive Dashboard Reports in Excel or Power BI

Click Here to Watch Now

mynda treacy microsoft mvpHi, I'm Mynda Treacy and I run MOTH with my husband, Phil. Through our blog, webinars, YouTube channel and courses we hope we can help you learn Excel, Power Pivot and DAX, Power Query, Power BI, and Excel Dashboards.

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk – For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.