Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Transferring Data between Worksheets Using a Macro.
Written by Allen Wyatt (last updated November 19, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Leonard is writing a macro to copy data from one worksheet to another. Both worksheets are in the same workbook. The data he wants to copy is on the first worksheet and uses a named range: "SourceData". It consists of a single row of data. Leonard wants to, within the macro, copy this data from the first worksheet to the first empty row on the second worksheet, but he's not quite sure how to go about this.
There are actually several ways you can do it, but all of the methods have two prerequisites: The identification of the source range and the identification of the target range. The source range is easy because it is named. You can specify the source range in your macro in this manner:
Set rngSource = Worksheets("Sheet1").Range("SourceData")
Figuring out the first empty row in the target worksheet is a bit trickier. Here's a relatively easy way to do it:
iRow = Worksheets("Sheet2").Cells(Rows.Count,1).End(xlUp).Row + 1 Set rngTarget = Worksheets("Sheet2").Range("A" & iRow)
When completed, the rngTarget variable points toward the range of cell A in whatever the first empty row is. (In this case, an empty row is defined as any row that doesn't have something in column A.)
Now all you need to do is put these source and target ranges to use with the Copy method:
Sub CopySource() Dim rngSource As Range Dim rngTarget As Range Dim iRow As Integer Set rngSource = Worksheets("Sheet1").Range("SourceData") iRow = Worksheets("Sheet2").Cells(Rows.Count,1).End(xlUp).Row + 1 Set rngTarget = Worksheets("Sheet2").Range("A" & iRow) rngSource.Copy Destination:=rngTarget End Sub
Note that with the ranges defined, all you need to do is use the Copy method on the source range and specify the target range as the destination for the operation. When completed, the original data is still in the source range, but has been copied to the target.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6131) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Transferring Data between Worksheets Using a Macro.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Disabling function keys is rather easy to do when you rely on the OnKey method in a macro. This tip looks at how you can ...
Discover MoreWhen reading information from a text file, your macro may need to start reading at a place other than the beginning of ...
Discover MoreYou may need to automatically generate unique numbers when you create new worksheets in a workbook. Here are a couple of ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-12-31 11:10:26
J. Woolley
Re. my previous comment below, I have discovered the expressions for LastNonBlankRow and LastNonBlankCol do not properly account for dynamic array formulas. Replace both instances of LookIn:=xlFormulas with LookIn:=xlValues to correct them.
2022-11-21 10:54:15
J. Woolley
Does Leonard want "the first empty row on the second worksheet" or the row below the last non-blank row?
Although poorly described in the Tip, rngTarget is intended to be the cell below the last non-blank cell in column A. A non-blank cell is one that contains data (constant or formula). But non-blank cells in hidden rows are ignored in this expression:
iRow = Worksheets("Sheet2").Cells(Rows.Count,1).End(xlUp).Row + 1
Therefore, rngTarget might point to such a cell or even a blank cell above such a cell. (Formatted cells with no data are also ignored by that expression, which is probably appropriate.) At any rate, rngTarget is not necessarily the first cell of an empty row because it only considers column A. (The Tip resolves this by defining an empty row as "any row that doesn't have something in column A.")
Here is a better expression for the row below the last non-blank row:
With Worksheets("Sheet2").UsedRange
iRow = .Row + .Rows.Count
End With
This also counts hidden rows (blank or non-blank) plus formatted cells with no data, so iRow will be below any of those (which might not be appropriate).
As stated above, a blank cell contains neither a formula nor a constant. (A cell containing a constant apostrophe or space character looks blank but is not.) Although Leonard is only interested in rows, here are several useful VBA expressions for both rows and columns:
With ActiveSheet ' (assuming Leonard's "Sheet2" is active)
With .UsedRange
LastUsedRow = .Row - 1 + .Rows.Count
LastUsedCol = .Column - 1 + .Columns.Count
End With
LastUsedCell = .Cells(LastUsedRow, LastUsedCol).Address
Set R = .Cells.Find(What:="*", After:=.Cells(1), _
LookAt:=xlPart, LookIn:=xlFormulas, MatchCase:=False, _
SearchOrder:=xlByRows, SearchDirection:=xlPrevious)
If R Is Nothing Then LastNonBlankRow = 0 _
Else LastNonBlankRow = R.Row
Set R = .Cells.Find(What:="*", After:=.Cells(1), _
LookAt:=xlPart, LookIn:=xlFormulas, MatchCase:=False, _
SearchOrder:=xlByColumns, SearchDirection:=xlPrevious)
If R Is Nothing Then LastNonBlankCol = 0 _
Else LastNonBlankCol = R.Column
If LastNonBlankRow <> 0 And LastNonBlankCol <> 0 Then _
LastNonBlankCell = _
.Cells(LastNonBlankRow, LastNonBlankCol).Address
End With
LastUsed... and LastNonBlank... expressions count cells (including hidden cells) that contain a formula or a constant.
LastUsed... expressions also count formatted cells that are blank. But if you select and format an entire blank row (like $15:$15) or blank column (like $H:$H), this does not imply that all blank cells in that row or column are counted; they are not. The actual result is as if only the first cell in the blank row or column was formatted; i.e., the blank row or column is considered used, but not all blank cells in that row or column.
LastUsedRow includes blank resized rows, but LastUsedCol does not include blank resized columns.
LastUsedRow includes blank hidden rows, but not after unhidden.
LastUsedCol includes blank hidden columns only if they were resized or adjacent to a resized column or a non-blank or formatted cell before hidden; in this case, they continue to be counted after unhidden until the workbook is closed and reopened. But if they remain hidden when the workbook is closed, they will be counted when the workbook is reopened.
If all cells are blank, LastUsedCell is "$A$1" and LastNonBlankCell is "" (default null string). Ctrl+End jumps to LastUsedCell.
LastNonBlank... expressions exclude blank cells even if hidden, formatted, or resized.
Considering all of the above, the best expression for Leonard's iRow might be
iRow = LastNonBlankRow + 1
However, this could be a blank row that is hidden. To make sure iRow is unhidden:
Worksheets("Sheet2").Rows(iRow).Hidden = False
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments