UNMERGE and CENTER ACROSS

erik.van.geit

MrExcel MVP
Joined
Feb 1, 2003
Messages
17,832
"Get rid of merged cells!"
You can read it often on this Board.
I will not open any debate on the subject, but just want to provide a solution to get rid of them automatically. Anybody who likes can refer to this thread.
As always I am open to suggestions to improve this feature.

WARNING
This code is changing layout.
1. Could take a while when you have sheets with large used range or a lot of merged cells. You can follow the status and can interrupt it if you want.
2. Save before executing. I'm quite sure it works good, but the result might be something else then you had in mind, especially when you are quite new to this.

Code:
Option Explicit
 
Sub Unmerge_CenterAcross()
'Erik Van Geit
'080808
 
'merged cells will be unmerged
'contents will be centered across merged area
 
Dim LR As Long      'Last Row
Dim LC As Integer   'Last Column
Dim i As Long
Dim j As Long
 
Dim cntUnmerged As Long
Dim cntMerged As Long
Dim mergeRng As Range
Dim checkmerged As Boolean
Dim LastMerged As String
 
Dim AppSetCalc As Integer
Dim StatusBarVisible As Boolean
 
Dim msg As String
Dim MaxRc As Long
Dim ColorMe As Boolean
 
 
    If ActiveWorkbook.Saved = False Then
    msg = "Your workbook is not saved." & vbNewLine
    msg = msg & "Code checks last used cell, which is only updated when saved" & vbNewLine & vbNewLine
    msg = msg & "Do want to save now?"
 
        If MsgBox(msg, 292, "SAVE?") = vbYes Then
        On Error Resume Next
        ActiveWorkbook.Save
            If Err Then
            MsgBox Err.Description, vbCritical, "ERROR " & Err.Number
            Exit Sub
            End If
        End If
 
    End If
 
    With ActiveSheet
    'needing xlCellTypeLastCell: else if last cell is merged wrong area will be found
    LR = .Cells.SpecialCells(xlCellTypeLastCell).Row
    LC = .Cells.SpecialCells(xlCellTypeLastCell).Column
        With .Cells(LR, LC)
            If .MergeCells Then
            LR = LR + .MergeArea.Rows.Count - 1
            LC = LC + .MergeArea.Columns.Count - 1
            End If
        End With
    If .Range(.Cells(1, 1), .Cells(LR, LC)).MergeCells = False Then
    MsgBox "no merged cells on this sheet", 48, "EXIT"
    Exit Sub
    End If
 
    msg = "Please define max # of rows a merged area may contain"
    msg = msg & "EXAMPLE" & vbNewLine & "If you type ""5"" then A1:A5 or A1:B5 will be unmerged, but not A1:A6"
    MaxRc = Application.InputBox(msg, "", 1, , , , , 1)
    If MaxRc = 0 Then Exit Sub
 
    msg = "Do you want to color the unmerged cells to check out the result?"
    ColorMe = MsgBox(msg, 292, "Color") = vbYes
 
    With Application
    .ScreenUpdating = False
    AppSetCalc = .Calculation
    .Calculation = xlCalculationManual
    StatusBarVisible = .DisplayStatusBar
    .DisplayStatusBar = True
    .EnableCancelKey = xlErrorHandler
    End With
 
    For i = 1 To LR
    On Error Resume Next
    checkmerged = .Range(.Cells(i, 1), .Cells(i, LC)).MergeCells
    'error occurs when MergeArea intersects row and contains more rows
    'checkmerged is TRUE when MergeArea is in one row
        If Err Or checkmerged Then
        Err.Clear
            For j = 1 To LC
                With .Cells(i, j)
                    If .Resize(1, 1).MergeCells Then
                    cntMerged = cntMerged + 1
                        On Error GoTo stopit
                        With .MergeArea
                            If .Rows.Count <= MaxRc Then
                            cntUnmerged = cntUnmerged + 1
                            .Unmerge
                            .HorizontalAlignment = xlCenterAcrossSelection
                            If ColorMe Then .Interior.ColorIndex = 3
                            Else
                            LastMerged = .Address(0, 0)
                            End If
                        End With
                    End If
                End With
            Next j
        End If
    Application.StatusBar = "rows checked: " & Round(i / LR, 2) * 100 & "%"
    Next i
 
    End With
 
stopit:
    With Application
    .EnableCancelKey = xlDisabled
    .ScreenUpdating = True
    .Calculation = AppSetCalc
    .StatusBar = False
    .DisplayStatusBar = StatusBarVisible
    End With
 
    If i > 0 Then
    msg = IIf(i = LR + 1, "All rows checked", "Last row checked: " & vbTab & i) & vbNewLine
    msg = msg & "Found areas: " & vbTab & cntMerged & vbNewLine
    msg = msg & "Unmerged areas: " & vbTab & cntUnmerged & vbNewLine
        If cntMerged <> cntUnmerged Then
        msg = msg & "Still merged: " & vbTab & cntMerged - cntUnmerged & vbNewLine & vbNewLine
        msg = msg & "Last area: " & LastMerged
        End If
    End If
 
    If Err Then msg = msg & Err.Description
    MsgBox msg, IIf(Err, vbCritical, vbOKOnly), IIf(Err, "ERROR " & Err.Number, "Done")
 
End Sub

Good luck!

kind regards,
Erik
 
Last edited:

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
Holy cow Erik. Let me toss this into a spreadsheet that has a lot of random merged cells and I will get back with you on how well this works.

THANK YOU for this code also!
 
Upvote 0
Erik,

Tested your code and it looks pretty nice. I see a few small things here and there that could be cleaned up... such as in the Input Box where you have the EXAMPLE, there needs to be a space or a carriage return before the Example.

Also, is the macro supposed to catch 100% of all of the merged cells and center them across, or all but one. I made 5 sets of merged cells on my spreadsheet in completely random placed. First one was a 4x1, second was 4x2, third was 3x1, fourth was 6x2, and fifth was 7x15. It caught everything except the 7x15. I even tried putting 8 in for the "Maximum" number just to see if there was an error in my counting cells, but it remains unchanged.
 
Upvote 0
Also, the 7x15 set of cells was the merged area that was the furthest down and to the right on the spreadsheet, so it would have been the defining factor in LR and LC
 
Upvote 0
Ah-Ha. I found my error in what I was doing.

Might want to redo that input box to say "Maximum number or rows or columns" The fact it read just rows was kinda confusing at first... but I didn't look at the example well enough.
 
Upvote 0
Little fix to your code that makes a bit more sense, your example was an example for columns instead of rows:

Code:
    msg = "Please define max # of rows a merged area may contain, whichever is bigger."
    msg = msg & vbNewLine & "EXAMPLE:" & vbNewLine & "If you type ""5"" then A1:A5 or A1:E5 will be unmerged, but not A1:A6 or A1:E6."
    MaxRc = Application.InputBox(msg, "", 1, , , , , 1)
    If MaxRc = 0 Then Exit Sub
 
Upvote 0
I do not agree with your comments and do not feel interested to discuss them.

Fact is that you copied the code, tested and wrote 5 replies in less then half an hour. It took me more time to think about all this.
 
Upvote 0
Well Eric,
I know very little about code,, but hey,,, you are 1 special kind of clever excel dude!

I'm having problems with some merged cells.

I was pointed to this link.

I've just tried your macro,,, so so cool.

I love not just how you can highlight,, but also the pop data at the end,,,,

Some special code going on here ninja stylee,,
:-)
Nice 1,,,
For what it's worth,, I give this a 5 star rating :-)
regards
John Caines
 
Upvote 0
Thank you for your nice words.
I had another play with it for a few minutes; the message which comes at the end is not really correct; it's talking about cells within the areas: only the "unmerged areas" count is always correct.

But there is a lot to do here and I'm married ... Don't know when I will be tempted to look at this again.

kind regards,
Erik
 
Upvote 0

Forum statistics

Threads
1,223,912
Messages
6,175,340
Members
452,638
Latest member
Oluwabukunmi

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top