Non-volatile "permanent" cell/range reference

mrblister

Board Regular
Joined
Nov 20, 2016
Messages
191
Office Version
  1. 2019
Platform
  1. Windows
Let's say I have numbers in range A1:A3
And I have a formula in B1: =A1
And I have a formula in C1: =sum(A1:A3)

How do I make the cell references in B1 and C1 "permanent", AND non-volatile? For example, if I move and drag cell A1 (or the range A1:A3), then the references in the formulas B1 or C1 will change (which could be bad if the formulas in column B and C are copied down, and there are other formulas dependent on the formulas in column B or C).
I can prevent this by using (for example) "Indirect" or "Offset", but those are volatile, and I am searching for simple non-volatile alternatives to those (if such a thing exists).

Thanks in advance!
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
Format your data as a structured table?

Without using tables you can use =INDEX(1:3,0,1) to stop the range changing when you drag it left or right, you can use =INDEX(A:A,1):INDEX(A:A,3) to stop it changing when you drag down.

Other than that, you will need to use the volatile functions.
 
Upvote 0
Its not clear to me what you are looking for.

You have =A1 in B1. If you want that formula to be unchanged when dragged down, use absolute referencing =$A$1

The formula in B1 will change to follow A1 if one Cuts and pastes A1 elsewhere, COPY pasting A1 will not change the formula in B1.

=INDEX(A:A, 1, 1) or =INDEX(1:1, 1, 1) will always return the cell in A1, even after the (old) A1 is copy pasted. But inserting/deleting whole rows or columns could effect that
 
Upvote 0
Its not clear to me what you are looking for.
The way that I understood it was that the OP doesn't want a formula that refers to A1 to follow the cell if it is moved (click, hold and drag).
 
Upvote 0
Format your data as a structured table?

Without using tables you can use =INDEX(1:3,0,1) to stop the range changing when you drag it left or right, you can use =INDEX(A:A,1):INDEX(A:A,3) to stop it changing when you drag down.

Other than that, you will need to use the volatile functions.
Thanks, I'll try that out. I'm trying to increase efficiency on the sheet, and having too many volatiles will cause too much unnecessary calculation each time anything changes. This should help.
 
Upvote 0
I'm all for removing volatile functions, but there are times when they are a necessary evil. There may be other things in your sheet that are less efficient than simple volatile formulas.
 
Upvote 0
Its not clear to me what you are looking for.

You have =A1 in B1. If you want that formula to be unchanged when dragged down, use absolute referencing =$A$1

The formula in B1 will change to follow A1 if one Cuts and pastes A1 elsewhere, COPY pasting A1 will not change the formula in B1.

=INDEX(A:A, 1, 1) or =INDEX(1:1, 1, 1) will always return the cell in A1, even after the (old) A1 is copy pasted. But inserting/deleting whole rows or columns could effect that
Hi Mike. To follow-up with what Jason said, sometimes I drag stuff around. But if there's formulae referencing those cells, it's possible to create hard-to-catch cascading errors. These "permanent" references are an attempt to reduce those errors (even though they come with their own set of disadvantages).
 
Upvote 0

Forum statistics

Threads
1,213,484
Messages
6,113,923
Members
448,533
Latest member
thietbibeboiwasaco

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top