This post may contain affiliate links. Please read my disclosure for more info.

Convert Merged cells to Centre Across Selection with VBA

VBA Code Snippets

To merge or not to merge?  That is the question.  And it’s a questions which divides the Excel community.  We find the Merge & Center button is on the Ribbon, so it appears to be the only option.  But soon we are greeted by these types of annoying error messages:

Merged Cell Error

Excel has a secret alternative option called Center Across Selection, which once you’ve found it, you’ll never return to merging cells again.

Visually the two options look very similar

Merged vs Center Across Selection

Functionally they are very different, the lack of annoying error messages for starters.

Applying center across selection manually

Center Across Selection is available form the Format Cells window.

Select the cells you wish to center across, click Home -> Alignment Settings.

Home Alignment Settings

The Format Cells window will open. On the Alignment tab.  From the Horizontal drop-down select Center Across Selection.

Format Cells Center Across Selection

Finally, click OK to close the window.

If you do use this method a lot, you can save some time by adding the icon to the QAT or using an Add-in.

What happens if you already have a workbook with lots of merged cells?  Are you really going to go through cell by cell to change them all?  Thankfully, you don’t have to, I have written a macro which will do the conversion for you 🙂

Convert all Merged cells to Center Across Selection

As you might be using this macro a lot, I suggest you add it to your Personal Macrobook for fast access.

Sub ConvertMergedCellsToCenterAcross()

Dim c As Range
Dim mergedRange As Range

'Check active sheet is a worksheet
If TypeName(ActiveSheet) <> "Worksheet" Then Exit Sub

'Loop through all cells in Used range
For Each c In ActiveSheet.UsedRange

    'If merged and single row
    If c.MergeCells = True And c.MergeArea.Rows.Count = 1 Then

        'Set variable for the merged range
        Set mergedRange = c.MergeArea

        'Unmerge the cell and apply Centre Across Selection
        mergedRange.UnMerge
        mergedRange.HorizontalAlignment = xlCenterAcrossSelection

    End If

Next

End Sub

Center Across Selection does not work across rows, it only centers across columns.  We want to maintain the integrity of the spreadsheet, therefore, this macro has been specifically designed to not remove any merged cells which cover more than one row.  To select all the remaning merged cell you can follow the code in my VBA to select merged cells post.



Want to Learn VBA & Macros?

If you want to automate Excel and save time, my recommended resouces for learning VBA Macros are:

3 thoughts on “Convert Merged cells to Centre Across Selection with VBA

  1. Jon Peltier says:

    You can go to Excel UserVoice and vote for Microsoft to add Center Across Selection to the ribbon, so it’s easier to access:
    https://excel.uservoice.com/forums/304921-excel-for-windows-desktop-application/suggestions/31663255-add-center-across-selection-to-the-merge-center
    You can also use MVP Chris Newman’s add-in to add a Center Across button before Microsoft gets around to it:
    https://www.thespreadsheetguru.com/blog/add-center-across-selection-button-to-excel-home-tab

  2. Nick says:

    I never take the time to write replies like this but I have to say, this write up along with the one on inserting comments are the best I’ve read in a long time. If there’s anything I can do to help promote the site please let me know.

    • Excel Off The Grid says:

      Thank you for your kind comments. I appreciate the support.

      In terms of helping me promote the site, the best compliment you could give would be to recommend the site to friends and co-workers.

Leave a Reply

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