VBA-Copy & Paste Merged Cell into Merged Cell

BigBeachBananas

Active Member
Joined
Jul 13, 2021
Messages
450
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
I'm trying to copy and paste cells from sourceSheet to destSheet. The macro works fine if it's not a merged cell, however, when it comes to merged cells it doesn't paste in the values. Can someone help me with the merged cell block below?
It's fine to assume if the sourceCell is a merged cell, then the destCell will also be a merged cell of same size and address.
T.I.A

VBA Code:
                For Each sourceCell In sourceSheet.UsedRange
                        ' Check if the cell's background color matches the specified RGB color
                        If sourceCell.Interior.Color = RGB(189, 218, 129) Then
                            ' Determine the destination cell
                            If sourceCell.MergeCells Then
                                'ISSUE STARTS FROM HERE-----------------------------------------------------------------------------------------------
                                ' If merged, find the first cell in the merged range
                                Set destCell = destSheet.Cells(sourceCell.mergeArea.Cells(1, 1).Row, sourceCell.mergeArea.Cells(1, 1).Column)
                              
                                ' Merge the destination cell to match the source cell's merged state
                                destCell.Resize(sourceCell.mergeArea.Rows.Count, sourceCell.mergeArea.Columns.Count).Merge
                              
                                ' Copy the source cell's formatting
                                'sourceCell.Copy
                                destCell.value = sourceCell.value
                               'ISSUE ENDS HERE--------------------------------------------------------------------------------------------------------
                            Else
                                ' If not merged, find the corresponding cell in the destination sheet
                                Set destCell = destSheet.Cells(sourceCell.Row, sourceCell.Column)
              
                                ' Copy and paste as values only
                                destCell.value = sourceCell.value
                            End If
                            Debug.Print destCell.value
                            Debug.Print destCell.Address
                        End If
                Next sourceCell
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
this happen becase your destCell always is "MergeArea.cells(1)" so when you loop for condition "sourceCell.Interior.Color = RGB(189, 218, 129)", only "sourceCell.MergeArea.cells(1)" have value
<> Empty, all the cells remaning in that merge area is Empty will replace "sourceCell.MergeArea.cells(1).value" when you copy that to destCell. So i think this will work:
VBA Code:
    For Each sourceCell In sourceSheet.UsedRange
        If Not IsEmpty(sourceCell) Then 'this condition will skip when sourcell is empty include that cell is merged
            If sourceCell.Interior.Color = RGB(189, 218, 129) Then
                If sourceCell.MergeCells Then
                    Set destCell = destSheet.Cells(sourceCell.MergeArea.Cells(1, 1).Row, sourceCell.MergeArea.Cells(1, 1).Column)
                    destCell.Resize(sourceCell.MergeArea.Rows.Count, sourceCell.MergeArea.Columns.Count).Merge
                    destCell.Value = sourceCell.Value
                Else
                    Set destCell = destSheet.Cells(sourceCell.Row, sourceCell.Column)
                    destCell.Value = sourceCell.Value
    
                End If
                Debug.Print destCell.Value
                Debug.Print destCell.Address
            End If
        End If
    Next sourceCell
 
Upvote 1
Solution
this happen becase your destCell always is "MergeArea.cells(1)" so when you loop for condition "sourceCell.Interior.Color = RGB(189, 218, 129)", only "sourceCell.MergeArea.cells(1)" have value
<> Empty, all the cells remaning in that merge area is Empty will replace "sourceCell.MergeArea.cells(1).value" when you copy that to destCell. So i think this will work:
VBA Code:
    For Each sourceCell In sourceSheet.UsedRange
        If Not IsEmpty(sourceCell) Then 'this condition will skip when sourcell is empty include that cell is merged
            If sourceCell.Interior.Color = RGB(189, 218, 129) Then
                If sourceCell.MergeCells Then
                    Set destCell = destSheet.Cells(sourceCell.MergeArea.Cells(1, 1).Row, sourceCell.MergeArea.Cells(1, 1).Column)
                    destCell.Resize(sourceCell.MergeArea.Rows.Count, sourceCell.MergeArea.Columns.Count).Merge
                    destCell.Value = sourceCell.Value
                Else
                    Set destCell = destSheet.Cells(sourceCell.Row, sourceCell.Column)
                    destCell.Value = sourceCell.Value
   
                End If
                Debug.Print destCell.Value
                Debug.Print destCell.Address
            End If
        End If
    Next sourceCell
if you need copy all the cells include blank cell except cells in merge area you can move "isEmpty(sourceCell)" condition to after "sourceCell.MergeCells"condition
 
Upvote 0

Forum statistics

Threads
1,215,069
Messages
6,122,958
Members
449,096
Latest member
Anshu121

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