Automatically update formula using reference to sheet not present

johnbrownbaby

New Member
Joined
Dec 9, 2015
Messages
38
Hello,

I would like to firstly check if a specific sheet exists, then if TRUE, extract a value from that sheet.

I do this in two stages:
Step1:- Cell B3 - If sheet "JAN2018" exist, then return 0, else FALSE -

=IFERROR(INDIRECT("JAN2018"&"!A1"),"FALSE")

Step 2:- Cell B5 - If cell B3 = 0, then get value from Sheet

=IF(B3=0,0,'JAN2018'!B3)

I use this 'JAN2018' in a lot of other formulas.

How to go about making the sheet name 'JAN2018' in the formulas above dynamic, so that if I update the sheet name to say 'JAN2019', I don't have to go and change the formulas in a bunch of the other places where the "JAN2018!..." was used?

Thanks!
 

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.
I do this in two stages:
Step1:- Cell B3 - If sheet "JAN2018" exist, then return 0, else FALSE -

Step 2:- Cell B5 - If cell B3 = 0, then get value from Sheet
This doesn't seem consistent to me, False in one place and 0 in the other.



How to go about making the sheet name 'JAN2018' in the formulas above dynamic, ...
See if this works for you. Take another empty cell (I've used cell C1) and format it as Text. In that cell enter JAN2018
Then ..
B3: =IFERROR(INDIRECT("'"&C1&"'!A1"),0)

B5: =IF(B3=0,0,INDIRECT("'"&C1&"'!B3"))

Then you can just change the text in cell C1
 
Last edited:
Upvote 0

Forum statistics

Threads
1,225,768
Messages
6,186,924
Members
453,387
Latest member
uzairkhan

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