• Login
  • Courses
  • Books
  • Cheat Sheets
  • Tutorials Archive
  • VBA Code Generator
  • Contact

Power Spreadsheets

Excel and VBA tutorials and training. Learn how to use Microsoft Excel and Visual Basic for Applications now.

Excel VBA Merge Cells: Step-by-Step Guide and 6 Code Examples to Merge or Unmerge Cells with Macros

Excel VBA Tutorial about to merge and unmerge cells with macrosIn this VBA Tutorial, you learn how to merge cells and unmerge cells in a variety of ways.

This VBA Tutorial is accompanied by Excel workbooks containing the data and macros I use in the examples below. You can get immediate free access to these example workbooks by subscribing to the Power Spreadsheets Newsletter.

Use the following Table of Contents to navigate to the section you're interested in.

Table of Contents

  • Related VBA and Macro Tutorials
  • #1: Merge Cells
    • VBA Code to Merge Cells
    • Process Followed by VBA Code
    • VBA Statement Explanation
    • Macro Example
    • Effects of Executing Macro Example
  • #2: Unmerge Cells
    • VBA Code to Unmerge Cells
    • Process Followed by VBA Code
    • VBA Statement Explanation
    • Macro Example
    • Effects of Executing Macro Example
  • #3: Merge Cells and Center
    • VBA Code to Merge Cells and Center
    • Process Followed by VBA Code
    • VBA Statement Explanation
    • Macro Example
    • Effects of Executing Macro Example
  • #4: Merge Cells Across
    • VBA Code to Merge Cells Across
    • Process Followed by VBA Code
    • VBA Statement Explanation
    • Macro Example
    • Effects of Executing Macro Example
  • #5: Merge Cells Based on Cell Value
    • VBA Code to Merge Cells Based on Cell Value
    • Process Followed by VBA Code
    • VBA Statement Explanation
    • Macro Example
    • Effects of Executing Macro Example
  • #6: Merge Cells Within a Row Based on Cell Value
    • VBA Code to Merge Cells Within a Row Based on Cell Value
    • Process Followed by VBA Code
    • VBA Statement Explanation
    • Macro Example
    • Effects of Executing Macro Example
  • References to VBA Constructs Used in this VBA Tutorial

Related VBA and Macro Tutorials

The following VBA and Macro Tutorials may help you better understand and implement the contents below:

  • General VBA constructs and structures:

    • Learn about using variables here.

    • Learn about VBA data types here.

    • Learn about R1C1 and A1 style references here.

  • Practical VBA applications and macro examples:

    • Learn how to work with worksheets here.

You can find additional VBA and Macro Tutorials in the Archives.

#1: Merge Cells

VBA Code to Merge Cells

To merge cells with VBA, use a statement with the following structure:


Worksheet.Range("FirstCell:LastCell").Merge

Process Followed by VBA Code

Identify cell range > merge cells

VBA Statement Explanation

  1. Item: Worksheet.

    • VBA Construct: Workbook.Worksheets property.

    • Description: Returns a Worksheet object representing the worksheet you work with.

  2. Item: Range(“FirstCell:LastCell”).

    • VBA Construct: Worksheet.Range property.

    • Description: Returns a Range object representing the cell range between FirstCell and LastCell. This is the cell range you merge.

      Specify FirstCell and LastCell using an A1-style cell reference. Separate FirstCell and LastCell using the range operator, a colon (:). Enclose the entire cell range address within quotations (“”).

  3. Item: Merge.

    • VBA Construct: Range.Merge method.

    • Description: Merges the cells represented by the Range object you specify in item #2 above to create a merged cell.

Macro Example

The following macro merges cells A5 to E6 of the worksheet named “Merge Cells”.

Sub mergeCells()

    Worksheets("Merge Cells").Range("A5:E6").Merge

End Sub

Effects of Executing Macro Example

The following GIF illustrates the results of executing this macro example. As expected, cells A5 to E6 are merged.

Macro merges cells

#2: Unmerge Cells

VBA Code to Unmerge Cells

To unmerge cells with VBA, use a statement with the following structure:

Worksheet.Range("A1CellReference").UnMerge

Process Followed by VBA Code

Identify cell within merged cell > Unmerge cells

VBA Statement Explanation

  • Item: Worksheet.

    • VBA Construct: Workbook.Worksheets property.

    • Description: Returns a Worksheet object representing the worksheet you work with.

  • Item: Range(“A1CellReference”).

    • VBA Construct: Worksheet.Range property.

    • Description: Returns a Range object representing a cell within the merged cell you unmerge. Specify the cell using an A1-style cell reference (A1CellReference) enclosed within quotations (“”).

  • Item: UnMerge.

    • VBA Construct: Range.UnMerge method.

    • Description: Separates the merged cell containing the cell you specify in item #2 above into individual regular cells.

Macro Example

The following macro unmerges the merged cell containing cell C6 of the worksheet named “Merge Cells”.

Sub unmergeCells()

    Worksheets("Merge Cells").Range("C6").UnMerge

End Sub

Effects of Executing Macro Example

The following GIF illustrates the results of executing this macro example. As expected, the merged cell containing cell C6 is unmerged into individual regular cells.

The merged cell range (A5 to E6) was originally merged using the macro example #1 above.

Macro unmerges cells

#3: Merge Cells and Center

VBA Code to Merge Cells and Center

To merge cells and center the contents with VBA, use a macro with the following statement structure:

With Worksheet.Range("FirstCell:LastCell")
    .HorizontalAlignment = xlCenter
    .VerticalAlignment = xlCenter
    .Merge
End With

Process Followed by VBA Code

Identify cell range > center contents of cell range > merge cells

VBA Statement Explanation

Lines #1 and #5: With Worksheet.Range(“FirstCell:LastCell”) | End With

  1. Item: With… End With.

    • VBA Construct: With… End With statement.

    • Description: Statements within the With… End With statement (lines #2 through #4 below) are executed on the Range object returned by item #3 below.

  2. Item: Worksheet.

    • VBA Construct: Workbook.Worksheets property.

    • Description: Returns a Worksheet object representing the worksheet you work with.

  3. Item: Range(“FirstCell:LastCell”).

    • VBA Construct: Worksheet.Range property.

    • Description: Returns a Range object representing the cell range between FirstCell and LastCell. This is the cell range you merge.

      Specify FirstCell and LastCell using an A1-style cell reference. Separate FirstCell and LastCell using the range operator, a colon (:). Enclose the entire cell range address within quotations (“”).

Line #2: .HorizontalAlignment = xlCenter

  1. Item: HorizontalAlignment = xlCenter.

    • VBA Construct: Range.HorizontalAlignment property.

    • Description: Horizontally centers the contents of the cell range you specify in line #1 above by setting the HorizontalAlignment property to xlCenter.

Line #3: VerticalAlignment = xlCenter

  1. Item: VerticalAlignment = xlCenter.

    • VBA Construct: Range.VerticalAlignment property.

    • Description: Vertically centers the contents of the cell range you specify in line #1 above by setting the VerticalAlignment property to xlCenter.

Line #4: Merge

  1. Item: Merge.

    • VBA Construct: Range.Merge method.

    • Description: Merges the cells represented by the Range object you specify in line #1 above to create a merged cell.

Macro Example

The following macro (i) centers the contents in cells A8 to E9 of the worksheet named “Merge Cells”, and (ii) merges those cells.

Sub mergeCellsAndCenter()

    With Worksheets("Merge Cells").Range("A8:E9")
        .HorizontalAlignment = xlCenter
        .VerticalAlignment = xlCenter
        .Merge
    End With

End Sub

Effects of Executing Macro Example

The following GIF illustrates the results of executing this macro example. As expected, VBA merges cells A8 to E9 and centers the contents.

Macro merges cells and centers contents

#4: Merge Cells Across

VBA Code to Merge Cells Across

To merge cells across (in the same row) with VBA, use a statement with the following structure:

Worksheet.Range("FirstCell:LastCell").Merge Across:=True

Process Followed by VBA Code

Identify cell range > merge cells across

VBA Statement Explanation

  1. Item: Worksheet.

    • VBA Construct: Workbook.Worksheets property.

    • Description: Returns a Worksheet object representing the worksheet you work with.

  2. Item: Range(“FirstCell:LastCell”).

    • VBA Construct: Worksheet.Range property.

    • Description: Returns a Range object representing the cell range between FirstCell and LastCell. This is the cell range you merge.

      Specify FirstCell and LastCell using an A1-style cell reference. Separate FirstCell and LastCell using the range operator, a colon (:). Enclose the entire cell range address within quotations (“”).

  3. Item: Merge.

    • VBA Construct: Range.Merge method.

    • Description: Merges the cells in each row of the cell range you specify in item #2 above to create separate merged cells. For these purposes, considers the Across parameter (item #4 below).

  4. Item: Across:=True.

    • VBA Construct: Across parameter of the Range.Merge method.

    • Description: Specifies that the cells in each row of the cell range you specify in item #2 above are merged separately. In other words, the cells in each row are merged into separate merged cells (vs. a single merged cell covering the entire cell range).

      The default value of the Across parameter is False. In such case, all cells within the cell range you specify are merged into a single cell. This is the equivalent of simply merging cells (operation #1 above).

Macro Example

The following macro merges cells A11 to E15 of the worksheet named “Merge Cells” across. Therefore, the cells in each row from row 11 to row 15 are merged into separate merged cells.

Sub mergeCellsAcross()

    Worksheets("Merge Cells").Range("A11:E15").Merge Across:=True

End Sub

Effects of Executing Macro Example

The following GIF illustrates the results of executing this macro example. As expected, VBA merges cells A11 to E15 across.

Macro merges cells across

#5: Merge Cells Based on Cell Value

VBA Code to Merge Cells Based on Cell Value

To merge cells based on a cell value (whether it meets certain criteria), use a macro with the following statement structure:

With Worksheet
    For Counter = LastRow To FirstRow Step -1
        If .Cells(Counter, CriteriaColumn).Value = Criteria Then .Range(.Cells(Counter, FirstColumn), .Cells(Counter, LastColumn)).Merge
    Next Counter 
End With

Process Followed by VBA Code

Does row meet criteria? > Identify cell range in row > merge cells > go to previous row

VBA Statement Explanation

Lines #1 and #5: With Worksheet | End With

  1. Item: With… End With.

    • VBA Construct: With… End With statement.

    • Description: Statements within the With… End With statement (lines #2 through #4 below) are executed on the Worksheet object returned by item #2 below.

  2. Item: Worksheet.

    • VBA Construct: Workbook.Worksheets property.

    • Description: Returns a Worksheet object representing the worksheet you work with.

Lines #2 and #4: For Counter = LastRow To FirstRow Step -1 | Next Counter

  1. Item: For… Next Counter.

    • VBA Construct: For… Next statement.

    • Description: Repeats the statements within the loop (line #3 below) for each row between FirstRow (item #4 below) and LastRow (item #3 below).

  2. Item: Counter.

    • VBA Construct: Counter of For… Next statement.

    • Description: Loop counter. If you explicitly declare a variable to represent the loop counter, use the Long data type.

  3. Item: LastRow.

    • VBA Construct: Counter Start of For… Next statement.

    • Description: Number of the last row (further down the worksheet) you want the macro to consider when identifying rows to merge cells. The number of the last row is also the initial value of Counter (item #2 above).

      If you explicitly declare a variable to represent the number of the last row to consider, use the Long data type.

  4. Item: FirstRow.

    • VBA Construct: Counter End of For… Next statement.

    • Description: Number of the first row (closer to the top of the worksheet) you want the macro to consider when identifying rows to merge cells. The number of the first row is also the final value of Counter (item (#2 above).

      If you explicitly declare a variable to represent the number of the first row to consider, use the Long data type.

  5. Item: Step -1.

    • VBA Construct: Step of For… Next statement.

    • Description: Amount by which Counter (item #2 above) changes every time a loop iteration occurs.

      In this scenario, you loop backwards: from LastRow (item #3 above) to FirstRow (item #4 above). Therefore, step is -1.

Line #3: If .Cells(Counter, CriteriaColumn).Value = Criteria Then .Range(.Cells(Counter, FirstColumn), .Cells(Counter, LastColumn)).Merge

  1. Item: If… Then.

    • VBA Construct: If… Then… Else statement.

    • Description: Conditionally executes the statement at the end of the line of code (items #5 through #8 below) if the condition specified in item #4 below is met.

  2. Item: .Cells(Counter, CriteriaColumn).

    • VBA Construct: Worksheet.Cells property and Range.Item property.

    • Description: Returns a Range object representing the cell at the intersection of row number Counter and column number CriteriaColumn.

      At any given time, the value of the loop counter (Counter) is the same as that of the row through which the macro is currently looping. CriteriaColumn is the number of the column containing the cells you consider for purposes of determining whether to merge cells in the row through which the macro is currently looping.

  3. Item: Value.

    • VBA Construct: Range.Value property.

    • Description: Returns the value of the cell represented by the Range object returned by item #2 above.

  4. Item: .Cells(Counter, CriteriaColumn).Value = Criteria.

    • VBA Construct: Condition of If… Then… Else statement.

    • Description: This condition is an expression that evaluates to True or False, as follows:

        • True: When the value of the cell represented by the Range object returned by item #2 above is equal to the criteria you specify (Criteria).

        • False: When the value of the cell represented by the Range object returned by item #2 above isn't equal to the criteria you specify (Criteria).

      If you explicitly declare a variable to represent value, ensure that the data type you use can handle the value you use as criteria.

  5. Item: .Range.

    • VBA Construct: Worksheet.Range property.

    • Description: Returns a Range object representing a cell range specified as follows:

      • Leftmost cell: Range object returned by item #6 below.

      • Rightmost cell: Range object returned by item #7 below.

  6. Item: .Cells(Counter, FirstColumn).

    • VBA Construct: Worksheet.Cells property and Range.Item property.

    • Description: Returns a Range object representing the cell at the intersection of row number Counter and column number FirstColumn.

      At any given time, the value of the loop counter (Counter) is the same as that of the row through which the macro is currently looping. FirstColumn is the number of the first column in the cell range you want the macro to merge. If you explicitly declare a variable to represent FirstColumn, use the Long data type.

  7. Item: .Cells(Counter, LastColumn).

    • VBA Construct: Worksheet.Cells property and Range.Item property.

    • Description: Returns a Range object representing the cell at the intersection of row number Counter and column number LastColumn.

      At any given time, the value of the loop counter (Counter) is the same as that of the row through which the macro is currently looping. LastColumn is the number of the last column in the cell range you want the macro to merge. If you explicitly declare a variable to represent LastColumn, use the Long data type.

  8. Item: Merge.

    • VBA Construct: Range.Merge method.

    • Description: Merges the cells represented by the Range object returned by items #5 through #7 above to create a merged cell.

Macro Example

The following macro merges cells in columns myFirstColumn through myLastColumn in each row between myFirstRow and myLastRow where the value stored in column myCriteriaColumn is the string held by the myCriteria variable.

  • myFirstRow is set to 5.

  • myLastRow is set to the number of the last row with data in the worksheet named “Merge Cells Based on Criteria”. The constructs used by the statement that finds the last row with data in the worksheet are the Worksheet.Cells property, the Range.Find method, and the Range.Row property.

  • Both myCriteriaColumn and myFirstColumn are set to 1 (column A).

  • myLastColumn is set to 5 (column E).

  • myCriteria holds the string “Merge cells”
Sub mergeCellsBasedOnCriteria()

    Dim myFirstRow As Long
    Dim myLastRow As Long
    Dim myCriteriaColumn As Long
    Dim myFirstColumn As Long
    Dim myLastColumn As Long
    Dim myWorksheet As Worksheet
    Dim myCriteria As String
    Dim iCounter As Long

    myFirstRow = 5
    myCriteriaColumn = 1
    myFirstColumn = 1
    myLastColumn = 5
    myCriteria = "Merge cells"

    Set myWorksheet = Worksheets("Merge Cells Based on Criteria")

    With myWorksheet

        myLastRow = .Cells.Find(What:="*", LookIn:=xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row

        For iCounter = myLastRow To myFirstRow Step -1
            If .Cells(iCounter, myCriteriaColumn).Value = myCriteria Then .Range(.Cells(iCounter, myFirstColumn), .Cells(iCounter, myLastColumn)).Merge
        Next iCounter

    End With

End Sub

Effects of Executing Macro Example

The following GIF illustrates the results of executing this macro example. As expected, VBA merges cells in columns A through E in each row where the value stored in column A is the string “Merge Cells”.

Macro merges cells according to criteria

#6: Merge Cells Within a Row Based on Cell Value

VBA Code to Merge Cells Within a Row Based on Cell Value

To merge cells within a row based on a cell value (the cell value determines the number of cells to merge), use a macro with the following statement structure:

With Worksheet
    For Counter = LastRow To FirstRow Step -1
        .Cells(Counter, BaseColumn).Resize(ColumnSize:=.Cells(Counter, SizeColumn).Value).Merge
    Next iCounter
End With

Process Followed by VBA Code

Identify base cell > resize cell range > merge cells > go to previous row

VBA Statement Explanation

Lines #1 and #5: With Worksheet | End With

  1. Item: With… End With.

    • VBA Construct: With… End With statement.

    • Description: Statements within the With… End With statement (lines #2 through #4 below) are executed on the Worksheet object returned by item #2 below.

  2. Item: Worksheet.

    • VBA Construct: Workbook.Worksheets property.

    • Description: Returns a Worksheet object representing the worksheet you work with.

Lines #2 and #4: For Counter = LastRow To FirstRow Step -1 | Next Counter

  1. Item: For… Next Counter.

    • VBA Construct: For… Next statement.

    • Description: Repeats the statements within the loop (line #3 below) for each row between FirstRow (item #4 below) and LastRow (item #3 below).

  2. Item: Counter.

    • VBA Construct: Counter of For… Next statement.

    • Description: Loop counter. If you explicitly declare a variable to represent the loop counter, use the Long data type.

  3. Item: LastRow.

    • VBA Construct: Counter Start of For… Next statement.

    • Description: Number of the last row (further down the worksheet) you want the macro to consider when identifying rows to merge cells. The number of the last row is also the initial value of Counter (item #2 above).

      If you explicitly declare a variable to represent the number of the last row to consider, use the Long data type.

  4. Item: FirstRow.

    • VBA Construct: Counter End of For… Next statement.

    • Description: Number of the first row (closer to the top of the worksheet) you want the macro to consider when identifying rows to merge cells. The number of the first row is also the final value of Counter (item (#2 above).

      If you explicitly declare a variable to represent the number of the first row to consider, use the Long data type.

  5. Item: Step -1.

    • VBA Construct: Step of For… Next statement.

    • Description: Amount by which Counter (item #2 above) changes every time a loop iteration occurs.

      In this scenario, you loop backwards: from LastRow (item #3 above) to FirstRow (item #4 above). Therefore, step is -1.

Line #3: .Cells(Counter, BaseColumn).Resize(ColumnSize:=.Cells(Counter, SizeColumn).Value).Merge

  1. Item: .Cells(Counter, BaseColumn).

    • VBA Construct: Worksheet.Cells property and Range.Item property.

    • Description: Returns a Range object representing the cell at the intersection of row number Counter and column number BaseColumn.

      At any given time, the value of the loop counter (Counter) is the same as that of the row through which the macro is currently looping. BaseColumn is the number of the column you use as base for purposes of merging cells within the row through which the macro is currently looping.

  2. Item: Resize(ColumnSize:=.Cells(Counter, SizeColumn).Value).

    • VBA Construct: Range.Resize property.

    • Description: Returns a Range object representing a resized cell range. The Range object returned by Range.Resize is determined as follows:

      • Base Cell Range: The base Range object (prior to resizing) is that returned by item #1 above.

      • Row Size: The number of rows in the cell range returned by Range.Resize remain the same. In other words, the cell range where cells are merged is 1 row tall.

        This is because the first parameter of Resize (known as RowSize) is omitted. Therefore, the number of rows in the cell range remains the same.

      • Column Size: The number of columns in the cell range returned by Range.Resize is determined by item #3 below.

  3. Item: ColumnSize:=.Cells(Counter, SizeColumn).Value.

    • VBA Constructs: ColumnSize parameter of Range.Resize property and Range.Value property.

    • Description: Specifies the number of columns in the Range object returned by the Range.Resize property. The number of columns in this cell range is equal to the value within the cell at the intersection of row number Counter and column number SizeColumn (.Cells(Counter, SizeColumn).Value).

      At any given time, the value of the loop counter (Counter) is the same as that of the row through which the macro is currently looping. SizeColumn is the number of the column containing the number of cells you want to merge within the row through which the macro is currently looping.

  4. Item: Merge.

    • VBA Construct: Range.Merge method.

    • Description: Merges the cells represented by the Range object returned by items #1 through #3 above.

Macro Example

The following macro merges a certain number of cells, starting with the cell in column myBaseColumn, in each row between myFirstRow and myLastRow. The number of merged cells is equal to the value stored in mySizeColumn. If that value is 1, no cells are merged.

In other words, the macro merges the cells between column number mySizeColumn and the column whose number is equal to that stored within the cell in myBaseColumn.

  • myFirstRow is set to 5.

  • myLastRow is set to the number of the last row with data in the worksheet named “Merge Cells Based on Cell Value”. The constructs used by the statement that finds the last row with data in the worksheet are the Worksheet.Cells property, the Range.Find method, and the Range.Row property.

  • Both myBaseColumn and mySizeColumn are set to 1 (column A).

Sub mergeCellsBasedOnCellValue()

    Dim myFirstRow As Long
    Dim myLastRow As Long
    Dim myBaseColumn As Long
    Dim mySizeColumn As Long
    Dim myWorksheet As Worksheet
    Dim iCounter As Long

    myFirstRow = 5
    myBaseColumn = 1
    mySizeColumn = 1

    Set myWorksheet = Worksheets("Merge Cells Based on Cell Value")

    With myWorksheet

        myLastRow = .Cells.Find(What:="*", LookIn:=xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row

        For iCounter = myLastRow To myFirstRow Step -1
            .Cells(iCounter, myBaseColumn).Resize(ColumnSize:=.Cells(iCounter, mySizeColumn).Value).Merge
        Next iCounter

End With

End Sub

Effects of Executing Macro Example

The following GIF illustrates the results of executing this macro example. As expected, for each row with data, the macro merges the cells between column A and the column whose number is specified in column A.

Macro merges cells according to value in row

References to VBA Constructs Used in this VBA Tutorial

Use the following links to visit the appropriate webpage within the Microsoft Office Dev Center:

  1. Identify the worksheet you work with:

    • Workbook.Worksheets property.

  2. Return a Range object representing the cells you merge:

    • Worksheet.Range property.

    • Worksheet.Cells property.

    • Range.Resize property.

  3. Merge cells:

    • Range.Merge method.

  4. Unmerge cells:

    • Range.UnMerge method.

  5. Center the contents of a cell range horizontally or vertically:

    • Range.HorizontalAlignment property.

    • Range.VerticalAlignment property.

  6. Identify last row with data in a worksheet:

    • Range.Find method.

    • Range.Row property.

  7. Loop through rows:

    • For… Next statement.

  8. Identify the value stored in a cell to specify criteria for merging cells.

    • Range.Value property.

  9. Test if cells meet criteria for merging:

    • If… Then… Else statement.

  10. Work with variables:

    • Dim statement.

    • Set statement.

    • Data types:

      • Long data type.

      • String data type.

  11. Simplify object references:

    • With… End With statement.
guest
guest
0 Comments
Inline Feedbacks
View all comments

I publish a lot of Tutorials and Training Resources about Microsoft Excel and VBA. Here are some of my most popular Excel Training Resources:

  1. Free Excel VBA Email Course
  2. Excel Macro Tutorial for Beginners
  3. Excel Power Query (Get and Transform) Tutorial for Beginners
  4. Excel Keyboard Shortcut Cheat Sheet
  5. Excel Resources
Terms and Conditions

Privacy Policy

Limit of Liability and Disclaimer of Warranty

Affiliate Disclosure

Copyright © 2015–2023 PDS Intelligence Pte. Ltd. All rights reserved.
Excel ® is a registered trademark of the Microsoft Corporation. Power Spreadsheets is not affiliated with the Microsoft Corporation.