How to Stack Data from Multiple Columns into One Column in Excel

In previous article, I have shown you the method to split data from one long column to multiple columns by VBA and Index function. This time if we want to stack data from multiple columns to one column, how can we do? Actually, we can still use VBA script or formula of Index function to make it come true. This article will introduce you the two methods. After reading the article below, you will find the two ways are verify simple and convenient to operate in excel.

For example, see the initial table below:

Stack Data 1

And we want reverse data into one column and make it looks like:

Stack Data 2

Now we can follow below two methods to make it possible.

Method 1: Stack Data in Multiple Columns into One Column by Formula


Step 1: Select range A1 to F2 (you want to do stack), in Name Box, enter a valid name like Range, then click Enter.

Stack Data 3

Step 2: In any cell you want to locate the first cell of destination column, enter the formula =INDEX(Range,1+INT((ROW(A1)-1)/COLUMNS(Range)),MOD(ROW(A1)-1+COLUMNS(Range),COLUMNS(Range))+1).

Please be aware that you have to replace ‘Range’ in this formula to your defined name in Name Box.

Stack Data 4

Step 3: Click Enter. Verify that ‘ID’ (the value in the first cell of selected range) is displayed properly.

Stack Data 5

Step 4: Drag the fill handle to fill I column. Verify that data in previous initial location is reversed to one column properly.

Stack Data 6

Note:

If you drag the fill handle to cells extend selected range cell number, error will be displayed in redundant cell.

Stack Data 7

Method 2: Stack Data in Multiple Columns into One Column by VBA


Step 1: On current visible worksheet, right click on sheet name tab to load Sheet management menu. Select View Code, Microsoft Visual Basic for Applications window pops up.

Or you can enter Microsoft Visual Basic for Applications window via Developer->Visual Basic.

Step 2: In Microsoft Visual Basic for Applications window, click Insert->Module, enter below code in Module1:

Sub StackDataToOneColumn()


Dim Rng1 As Range, Rng2 As Range, Rng As Range

Dim RowIndex As Integer

Set Rng1 = Application.Selection

Set Rng1 = Application.InputBox("Select Range:", "StackDataToOneColumn", Rng1.Address, Type:=8)

Set Rng2 = Application.InputBox("Destination Column:", "StackDataToOneColumn", Type:=8)

RowIndex = 0

Application.ScreenUpdating = False



For Each Rng In Rng1.Rows

    Rng.Copy

    Rng2.Offset(RowIndex, 0).PasteSpecial Paste:=xlPasteAll, Transpose:=True

    RowIndex = RowIndex + Rng.Columns.Count

Next

Application.CutCopyMode = False

Application.ScreenUpdating = True


End Sub

Step 3: Save the codes, see screenshot below. And then quit Microsoft Visual Basic for Applications.

Step 4: Click Developer->Macros to run Macro. Select ‘StackDataToOneColumn’ and click Run.

Stack Data 9

Step 5: Stack Data to One Column dialog pops up. Enter Select Range $A$1:$F$2. Click OK. In this step you can select the range you want to do stack.

Stack Data 10

Step 6: On Stack Data to One Column, enter Destination Column $I$1. Click OK. In this step you can select the first cell from destination range you want to save data.

Stack Data 11

Step 7: Click OK and check the result. Verify that data is displayed in one column properly. The behavior is as same as the result in method 1 step# 4.

Stack Data 12

Related Functions


  • Excel INDEX function
    The Excel INDEX function returns a value from a table based on the index (row number and column number)The INDEX function is a build-in function in Microsoft Excel and it is categorized as a Lookup and Reference Function.The syntax of the INDEX function is as below:= INDEX (array, row_num,[column_num])…
  • Excel ROW function
    The Excel ROW function returns the row number of a cell reference.The ROW function is a build-in function in Microsoft Excel and it is categorized as a Lookup and Reference Function.The syntax of the ROW function is as below:= ROW ([reference])….
  • Excel MOD function
    he Excel MOD function returns the remainder of two numbers after division. So you can use the MOD function to get the remainder after a number is divided by a divisor in Excel. The syntax of the MOD function is as below:=MOD (number, divisor)….
  • Excel INT function
    The Excel INT function returns the integer portion of a given number. And it will rounds a given number down to the nearest integer.The syntax of the INT function is as below:= INT (number)…
  • Excel COLUMNS function
    The Excel COLUMNS function returns the number of columns in an Array or a reference.The syntax of the COLUMNS function is as below:=COLUMNS (array)….

You might also like:

Sidebar