×

Copy/Paste A Dynamic Formula Spill Range With VBA

By Chris Newman •  Updated: 04/28/21 •  5 min read
VBA code snippet to copy and paste a dynamic formula spill range.

What This VBA Code Does

There are a plethora of new Dynamic Array functions being released in Excel that produce something called a Spill Range. This is a range that changes in size depending on its output at any given time. So how do we reference these dynamic Spill Ranges if we want to transfer the data via copy/paste with VBA code? Let’s find out!

KEY: Referencing The Spill Parent Cell:

The very first cell in the Spill Range is where the actual formula sits and is called the Parent Cell. If you know this cell’s location, you can reference it by simply adding a “#” symbol after the reference. There is a validation function called HasSpill you can utilize to verify your reference is valid (discussed briefly at the end of this article).

EXAMPLE 1: Below is an example of how you can copy a Spill Range with a Spill Parent in cell B2 to another location within your spreadsheet:

Sub CopySpillRange()

'Copy Spill Range with Spill Parent Reference
  ActiveSheet.Range("B2#").Copy

'Paste Spill Range into Sheet2
  Worksheets("Sheet2").Range("F2").PasteSpecial xlPasteValues

'Clear Clipboard
  Application.CutCopyMode = False
  
End Sub

EXAMPLE 2: If you don’t want to deal with the burden of copy/pasting, you could send the values directly to a range (of the exact same size) utilizing the following code:

Sub TransferSpillRange()

'Transfer Spill Range into Sheet2
  With ActiveSheet.Range("B2#")
    Worksheets("Sheet2").Range("F2").Resize(.Rows.Count, .Columns.Count) = .Value
  End With

End Sub

EXAMPLE 3: If you don’t want to mess around with the # symbol, you could alternatively utilize something like this:

Sub TransferSpillRange()

'Transfer Spill Range into Sheet2
  With ActiveSheet.Range("B2").SpillingToRange
    Worksheets("Sheet2").Range("F2").Resize(.Rows.Count, .Columns.Count) = .Value
  End With

End Sub

Other VBA Spill Range Properties

HasSpill

What It Does: Tells you whether a range/cell has a spill range within it. This can serve as a test prior to utilizing SpillingToRange or SpillParent.

Range(“A1:D1”).HasSpill would result in either a True or False

SpillingToRange

What It Does: References a range object of the entire Spill Range associated with a given cell

Range(“A1”).SpillingToRange.Address would result with a reference to the entire range address

Range(“A1”).SpillingToRange.Count would output the number of cells in the Spill Range

SpillParent

What It Does: References the Spill Parent cell object associated with a given cell

Range(“A10”).SpillParent.Address would result with the cell address of the Spill Parent (ie “A$1$”)


Using VBA Code Found On The Internet

Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.

Getting Started Automating Excel

Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.

Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!

How Do I Modify This To Fit My Specific Needs?

Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it

I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).

I wish you the best of luck and I hope this tutorial gets you heading in the right direction!

Keep Learning

Chris Newman

Chris Newman

Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.

[FREE Training] 10 Amazing Excel Efficiency Tricks. Why Don't People Know These?!

X