Swap ranges, rows and columns in Excel

VBA Code Snippets

Copying, pasting and moving cells are simple everyday tasks for an Excel user.  But what if something already occupies the area we want to paste to?  We have to move things into temporary locations before putting them into their final destination.  Wouldn’t it be better if there were a simple way to swap ranges, rows and columns?  Wouldn’t it be better if we could just select the ranges and click one button?  Yes, it would, and that is why I created the macro in this post.

Download the example file
I recommend you download the files which support this post, as you’ll be able to work along with examples.  This is the best way to learn.  You’ll be able to see the solutions in action, plus the file will be useful for future reference.  The support files are available for FREE to newsletter subscribers.

Click below to subscribe and gain access to the subscriber area.  You will also receive:

  • My favorite tips and tricks direct to your inbox
  • Exclusive content (which is only available to subscribers)
  • FREE tools and downloads

Download Icon

If you’re already a subscriber, click here to log-in to the subscriber downloads area.

The filename for this post is 0011 Swap ranges.zip.

WARNING! – Macros cannot be undone.  Before using the code in this post, test it to make sure it works as you expect.

When to use the macro

Here is a scenario that I’m sure you can identify with.  You’ve received a workbook, which is to be used within a presentation.  However, you (or your manager) want to present the items in a different order.

Ranges swapped - example

Let the dragging, or copying and pasting begin.  Alternatively, if you have the following macro available, you can simply select the ranges and click.

VBA code

Here is the VBA code; paste it into a standard module and it will be available for use.  To make the code more reusable, your Personal Macro Workbook is the best place to save it.  Add a custom button to your ribbon, and it’s just one click away 🙂

Sub SwapSelectedRanges()

'Create variables to hold the ranges
Dim rng As Range
Dim tempRng As Variant
Dim areaCount As Long
Dim areaRows As Long
Dim areaCols As Long
Dim i As Integer
Dim j As Integer

Set rng = Selection
areaCount = rng.Areas.Count

'There must be at least two areas selected
If areaCount < 2 Then
    MsgBox "Please select atleast two ranges."
    Exit Sub
End If

'All areas must be the same shape
areaRows = rng.Areas(1).Rows.Count
areaCols = rng.Areas(1).Columns.Count
For i = 2 To areaCount
    If rng.Areas(i).Rows.Count <> areaRows Or _
        rng.Areas(i).Columns.Count <> areaCols Then
        MsgBox "All ranges must have the same number of rows and columns."    
        Exit Sub
    End If
Next i

'Check that ranges don't intersect with each other
For j = 1 To areaCount - 1
    For i = 1 + j To areaCount
        If Not Intersect(rng.Areas(i), rng.Areas(j)) Is Nothing Then
            MsgBox "Selected areas must not overlap."
        End If
    Next i
Next j

'Switch the ranges
tempRng = rng.Areas(areaCount).Cells.Formula
For i = areaCount To 2 Step -1
rng.Areas(i).Cells.Formula = rng.Areas(i - 1).Cells.Formula
Next i
rng.Areas(1).Cells.Formula = tempRng

End Sub

Generate accurate VBA code in seconds with AutoMacro

AutoMacroExample

AutoMacro is a powerful VBA code generator that comes loaded with an extensive code library and many other time-saving tools and utilities.

Whether you’re an experienced coder looking to save time, or a newbie just trying to get things to work, AutoMacro is the tool for you.

Using the VBA code

The macro is simple to use:

  1. Select the first range
  2. Hold the Ctrl key, select the second range
  3. Run the macro

Done!  That’s it – how easy was that!

When using the macro, there are a few things to be aware of:

  • The individual ranges must be the same size (i.e., containing the same number of rows and columns).
  • The macro will include any hidden columns or rows
  • Cell references are maintained.  So, if a range contains a reference to cell A2, after clicking the macro, the range (which has now been moved) still references cell A2
  • Ranges cannot cross over with each other
  • Formatting does not move when the ranges are swapped
  • The code works on ranges which exist in the same worksheet
  • The macro will work with complete columns or rows, but will take longer than selecting a specific cell range.

Using with three or more ranges

Technically, the macro does not swap ranges, but rotates them.  When there are two ranges, rotating and swapping has the same result.

If we select more than two ranges, the macro will rotate them.  The first range moves to the second, the second moves to the third, etc.  Finally, the last range moves into the position initially occupied by the first range.

As before, select each individual range (holding the Ctrl key to select more ranges), then run the macro.

Don’t forget:

If you’ve found this post useful, or if you have a better approach, then please leave a comment below.

Do you need help adapting this to your needs?

I’m guessing the examples in this post didn’t exactly meet your situation.  We all use Excel differently, so it’s impossible to write a post that will meet everybody’s needs.  By taking the time to understand the techniques and principles in this post (and elsewhere on this site) you should be able to adapt it to your needs.

But, if you’re still struggling you should:

  1. Read other blogs, or watch YouTube videos on the same topic.  You will benefit much more by discovering your own solutions.
  2. Ask the ‘Excel Ninja’ in your office.  It’s amazing what things other people know.
  3. Ask a question in a forum like Mr Excel, or the Microsoft Answers Community.  Remember, the people on these forums are generally giving their time for free.  So take care to craft your question, make sure it’s clear and concise.  List all the things you’ve tried, and provide screenshots, code segments and example workbooks.
  4. Use Excel Rescue, who are my consultancy partner.   They help by providing solutions to smaller Excel problems.

What next?
Don’t go yet, there is plenty more to learn on Excel Off The Grid.  Check out the latest posts:

 

Leave a Reply

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