Written by Allen Wyatt (last updated January 30, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
David has a workbook that contains 53 worksheets. The first worksheet is named "Master," and it contains data in the range B1:B52. He would like, under macro control, to copy cell B1 to cell A2 on Sheet2, cell B2 to cell A2 on Sheet3, cell B3 to cell A2 on Sheet4, etc. David can't seem to wrap his head around the best way to accomplish this.
In order to best understand how to approach this task, it is helpful (nay, critical) that you understand how individual worksheets are handled in VBA. The critical part is that each worksheet is part of a Worksheets collection. This means that each worksheet has a name and each has an index value that denotes its position within the Worksheets collection. There is an initial correspondence between the worksheet name and the index position within the Worksheets collection, but this can easily get out of whack.
For instance, when you first create a workbook, it will typically contain one or more worksheets named, generically enough, Sheet1, Sheet2, Sheet3, and so on. These will correspond to index numbers 1, 2, 3, and so on in the Worksheets collection. It is this initial correspondence between worksheet name (Sheet1) and index value (1) that can lead to confusion. This is because as you rename worksheets and, more importantly, change the worksheet order, the relationship between worksheet name and index value can seem, well, capricious.
Let's say that David's workbook was created with Sheet1, Sheet2, and Sheet3. Right off the bat, he adds a worksheet before Sheet1 (to the left of Sheet1 in the worksheet tabs) and names it Master. At this point, Master has an Worksheets collection index value of 1, Sheet1 has an index value of 2, Sheet2 has an index value of 3, and Sheet3 has an index value of 4. The index values in the Worksheets collection always correspond to the order of the worksheets as shown in the worksheet tabs.
Why is this important? Because when you reference a worksheet in a macro, you can do so using either the index value for the Worksheets collection or you can do so using the actual name assigned to the worksheet. For instance, you could refer to the Master worksheet using the following:
Worksheets("Master")
Or, if you didn't want to refer to it by name, you could refer to it using the index value in the Worksheets collection. Assuming that the Master worksheet is the first one in the workbook (the Master tab is to the left of all other worksheet tabs), then this also refers to the Master worksheet:
Worksheets(1)
With all this in mind, if your Master worksheet is the first one in the workbook and you want to put the values into the next 52 worksheets, from left to right in the workbook, you could use this very simple macro:
Sub CopyData1() Dim J As Integer For J = 1 To 52 Worksheets(J + 1).Range("A2") = Worksheets("Master").Cells(J, 2) Next J End Sub
The macro uses both the index value method of referencing sheets along with the name method, for the Master worksheet. You could easily have used the index value method for both references:
Sub CopyData2() Dim J As Integer For J = 1 To 52 Worksheets(J + 1).Range("A2") = Worksheets(1).Cells(J, 2) Next J End Sub
Or, if you prefer, you could have gotten a bit trickier and just stepped through the cells on the Master worksheet and used that as a way to determine where to place the information:
Sub CopyData3() Dim c As Range For Each c In Worksheets("Master").Range("B1:B52") Worksheets(c.Row + 1).Range("A2") = c.Value Next c End Sub
Finally, you might want to consider if you really want to take the approaches discussed so far. The problem is that the values copied to cell A2 in each of the other worksheets are static—they don't change. In order to update the values (if the values in B1:B52 on the Master worksheet change), you'll need to remember to re-run the macro.
The solution, of course, is to place formulas into cell A2 on each of the non-Master worksheets. The formulas on each of the first three worksheets would look like this:
=Master!B1 =Master!B2 =Master!B3
Of course, putting those formulas on all 52 of the worksheets could be tedious, time-consuming, and prone to error. Thus, you could use a macro to place all the formulas, using a variation of the macros discussed already:
Sub CopyData4() Dim J As Integer For J = 1 To 52 Worksheets(J + 1).Range("A2").Formula = "=Master!B" & J Next J End Sub
The result is all of the formulas are where you expect them, and the results displayed in A2 on each worksheet are no longer static.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12414) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Excel provides a little-known way to copy worksheets simply by clicking and dragging. Here's how to do it.
Discover MoreAs you develop worksheets, it is not unusual to end up with two that are essentially the same. At some point you may want ...
Discover MoreIf you want to set the color of a worksheet tab based on some conditions within the worksheet, you'll need to resort to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-02-01 07:06:20
Mike D.
I love macros and enjoy writing them, however; in this case the formulas, to me, is the most elegant solution.
With the add-on of the formula placement macro it is made even better.
One thing I would most likely do is to shift the data in the master sheet down one row so the row number would match the sheet number. This would eliminate the need for the (J + 1) in the macro formula. Reduce the math, reduce the chance of error, but that is how my brain works.
"Measure twice, cut once but don't measure if you don't have to", Norm Abrams
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