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: Relative Worksheet References.

Relative Worksheet References

Written by Allen Wyatt (last updated February 4, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


2

Suppose you have a workbook with three worksheets, Sheet1, Sheet2 and Sheet3. In column A1 of worksheet Sheet2 you have the formula =Sheet1!A1. When you copy that formula from Sheet2 to cell A1 of Sheet3, the formula still references Sheet1. How can that be, though? Why doesn't Excel adjust the sheet reference, like it does the cell references?

Like named ranges, Excel treats worksheet names as absolute. Each worksheet object is independent of all other worksheets in the workbook. When you paste a formula that includes a sheet reference, that sheet reference is left unchanged in what is pasted.

There are a couple of things you can do. One is to simply modify the formula reference after it is pasted so that it references the correct sheet. If you have many of them to change, then you can select all the formulas in the target worksheet (F5 | Special | Formulas) and then use Find and Replace to replace the original worksheet name (Sheet1) with the correct worksheet name (Sheet2).

If your referencing needs are not complex, then you can use a macro approach. For instance, if you want a formula in a particular cell to refer to a cell on the sheet previous to the current sheet, then you can do that by macro rather easily. Consider the following macro:

Function PrevSheet(rCell As Range)
    Application.Volatile
    Dim i As Integer
    i = rCell.Cells(1).Parent.Index
    PrevSheet = Sheets(i - 1).Range(rCell.Address)
End Function

The macro looks at the current worksheet and then figures out which worksheet is before it. The reference is then made for that worksheet. Once you've created the PrevSheet macro, here's one way the function can be used in a cell:

=PrevSheet(A1)

This returns the value of cell A1 from the previous worksheet. If you have Sheet1, Sheet2, and Sheet3, and you use this formula on Sheet3, then it returns the value of Sheet2!A1. If the previous sheet is the first sheet of the workbook or it is not a worksheet, then the function returns a #Value error.

If you later copy this formula to a different sheet (say to Sheet 5), then it pulls up the value relative to its new location, which means it pulls up the value from Sheet4!A1.

You can also include a sheet name and the function will work just fine:

=PrevSheet(Sheet3!A5)

This version will always return Sheet2!A5 since Sheet2 is the previous sheet of Sheet3.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12141) 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: Relative Worksheet References.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Determining the Current Directory

When you use a macro to do file operations, it works (by default) within the current directory. If you want to know which ...

Discover More

Making Banners in Word

Word can be used for printing a variety of document types. You may want to use the program to print a festive banner for ...

Discover More

Moving and Selecting Rows

If you need to move down a row and then select that row, you may wonder if there is a shortcut to handle such a ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Generating Random Testing Data

Need to test your formulas? Then you need some testing data that you can use to see if the formulas function as you ...

Discover More

Creating New Windows

If you need to look at different parts of the same worksheet at the same time, the answer is to create windows for your ...

Discover More

Monitoring the Number of Formats Defined

The number of formats used in a workbook can become a problem if you run up against the limit Microsoft hard-coded into ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 9 + 3?

2024-02-12 11:57:03

J. Woolley

The Tip's macro does not work as intended when more than one workbook is open; locate the following statement
    PrevSheet = Sheets(i - 1).Range(rCell.Address)
and replace it with this statement
    PrevSheet = rCell.Parent.Parent.Sheets(i - 1).Range(rCell.Address)
so Sheets(i - 1) applies to the workbook referenced by rCell.
My Excel Toolbox includes the following function to return a range on any worksheet in the workbook:
    =RangeOnSheet(Target, [Position], [Absolute])
Target is the range to be returned on a worksheet determined by Position and Absolute (Sheet!Target). Position is the location of the required sheet in the workbook or 0 (default) for the formula's worksheet. If Absolute is FALSE (default), Position is relative to the formula's worksheet. If Absolute is TRUE, Position is the absolute location of the sheet in the workbook (base-1). Absolute is ignored if Position is 0 (the formula's worksheet). Chart sheets and worksheets plus hidden and very hidden sheets are included when determining location. The required sheet must be a worksheet; otherwise, Sheet!Target would be invalid.
The following examples are equivalent to the Tip's two examples:
    =RangeOnSheet(A1, -1)
    =RangeOnSheet(Sheet3!A5, (SHEET(Sheet3!A5) - 1), TRUE)
Only the cell range of Target applies; Target's worksheet does not apply.
Notice Excel's SHEET function returns the absolute position of a sheet; the SHEETS function returns the number of sheets (including hidden or very hidden).
This example will sum the cells in A1:A5 of the workbook's 3rd sheet:
    =SUM(RangeOnSheet(A1:A5, 3, TRUE))
If Target is not contiguous it must be surrounded by parentheses; for example, (A1,A5). Notice Target might move if rows or columns are added, deleted, or moved on the formula's sheet or on Position's sheet; a named range will automatically adjust, but its scope must be either the workbook or the formula's sheet.
The result of RangeOnSheet can be verified as text using the following function available in My Excel Toolbox:
    =RangeAddress(Range, [RowAbsolute], [ColumnAbsolute],
        [ReferenceStyle], [External], [RelativeTo])
with Range replaced by RangeOnSheet(...). The optional arguments are described in Excel VBA's explanation of the Range.Address property.
My Excel Toolbox also includes the following function to return a sheet's name (text) based on its location (even if it is hidden or very hidden):
    =NameOfSheet([Position], [Absolute])
Position and Absolute are the same as previously described.
See https://sites.google.com/view/MyExcelToolbox


2023-02-04 15:57:20

Tomek

If you omit the name of the sheet in the formula, i.e., use just =A1 then after copying the formula to another sheet will always reference to the sheet it is pasted on.

I am not aware of relative sheet addressing other than maybe using an =INDIRECT(...) function taking the referred-to sheet name from a cell on the same sheet.
    -----------------------
On a positive note, if you rename a sheet, that change is carried to the formulas that reference that sheet.


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.