• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Cell Ref Tab name instead of Direct Tab ref? |General Excel Questions & Answers|Excel Forum|My Online Training Hub

You are here: Home / Cell Ref Tab name instead of Direct Tab ref? |General Excel Questions & Answers|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumGeneral Excel Questions & Answe…Cell Ref Tab name instead of Direct…
sp_PrintTopic sp_TopicIcon
Cell Ref Tab name instead of Direct Tab ref?
Avatar
stephanrs
England/Humberside/Hull
Member
Members
Level 0
Forum Posts: 41
Member Since:
February 28, 2017
sp_UserOfflineSmall Offline
1
June 9, 2020 - 5:56 am
sp_Permalink sp_Print

Cell Ref > TAB, instead of typed TAB NAME?

File: DieselEditYearRef.xls

Tab: Total

Example: ROW 6, COLS: B-M & AL-BC

Formulas in Cells above quote '2020'! as tab.

However want to ref TAB NAME from Cell A6 not '2020'! but for info to compare with that TAB & CELL , the reason, so no INDIVIDUAL EDIT will be needed for Cols
B-M & AL-BC, for future year Rows.

B6 =IF(A6<=$BG$2,'2020'!$Y$29,"")

Hence for each YEAR ROW want to make it a copy & paste Row job instead of lots of editing.  

Year tab is prepared template, same as 2021, just blank awaiting entries.

Cheers Stephan

sp_AnswersTopicSeeAnswer See Answer
Avatar
Philip Treacy
Admin
Level 10
Forum Posts: 1518
Member Since:
October 5, 2010
sp_UserOfflineSmall Offline
2
June 9, 2020 - 9:41 am
sp_Permalink sp_Print

Hi Stephan,

You can use INDIRECT to reference the year in Column A, for example in D6 you could have

=INDIRECT(TEXT(A6,"yyyy")&"!$V$32")

So this way you only need to enter the year in ColA and the formulae in that row will pick up that year.  But if you ever move the value you want out of cell V32 then this formula will break.

The ideal layout for data like this is a tabular format where everything is on 1 sheet.  This does away with the issue you have where you have to update formula references as you create more sheets to store more data.

Regards

Phil

sp_AnswersTopicAnswer
Answers Post
Avatar
stephanrs
England/Humberside/Hull
Member
Members
Level 0
Forum Posts: 41
Member Since:
February 28, 2017
sp_UserOfflineSmall Offline
3
June 10, 2020 - 7:09 am
sp_Permalink sp_Print sp_EditHistory

D6
=INDIRECT(TEXT(A6,"yyyy")&"!$V$32")

Thanks this worked for Columns B-L, few things:

1. If no data, how to change FALSE to nothing?

2. Columns AL-BC unable to construct working edit for A6 Ref instead of Direct Tab ref.  A
lso these are ARRAY FORMULAS that require CTRL, SHIFT & ENTER:

Example in Cell AL6:
=MIN(IF(('2020'!$A$1:'2020'!$A$284="MPG"),('2020'!$B$1:'2020'!$B$284)))

Example in Cell AP6:
=MAX(IF(('2020'!$A$1:'2020'!$A$284="MPG"),('2020'!$B$1:'2020'!$B$284)))

Cheers

Avatar
Philip Treacy
Admin
Level 10
Forum Posts: 1518
Member Since:
October 5, 2010
sp_UserOfflineSmall Offline
4
June 10, 2020 - 8:41 am
sp_Permalink sp_Print

Hi Stephan,

The answers are:

1. Complete the IF statement by providing an answer if false, which is just an empty string "", so in C7

=IF(A7<=$BG$2,INDIRECT(TEXT($A7,"yyyy")&"!$Y$34"),"")

 

2. Use INDIRECT again, for example in AL6:

=MIN(IF(INDIRECT(TEXT($A6,"yyyy")&"!$A$1:$A$284")="MPG",INDIRECT(TEXT($A6,"yyyy")&"!$b$1:$b$284")))

 

I can tell that you've invested a lot of time into this workbook but unless you redo the layout into a tabular format you will keep coming up against issues like this and have to write monstrous formulae to get the data you want.

Regards

Phil

Avatar
stephanrs
England/Humberside/Hull
Member
Members
Level 0
Forum Posts: 41
Member Since:
February 28, 2017
sp_UserOfflineSmall Offline
5
June 11, 2020 - 3:16 am
sp_Permalink sp_Print sp_EditHistory

Many thanks Philip those suggestions worked!

1 other question: when answer is zero = 0, for these Calcs how to display blank space?

O7
=MIN(IF(A7<=$BG$2,IF(AL7:AO7>0,AL7:AO7,"")))

AL7 (ARRAY CALC)
=(MIN(IF(INDIRECT(TEXT($A7,"yyyy")&"!$A$1:$A$284")="MPG",INDIRECT(TEXT($A7,"yyyy")&"!$B$1:$B$284")))

Realise 1 non formula alternative:
Tools > Options > View > Zero Values

Did manage to make few working formulas of division on my own!:
BB6
=IF(INDIRECT(TEXT($A6,"yyyy")&"!$A$330")>0,INDIRECT(TEXT($A6,"yyyy")&"!$A$306")/INDIRECT(TEXT($A6,"yyyy")&"!$A$307"),"")

Also spreadsheet my approach is Data sheet then seperate Summary sheet.
I like this Dashboard approach, keeping all the individual data seperate from the summaries of it all, it may not be formula/speed efficient, but it is the only way I know!  I need working examples to start with, I don't know formulas in my head, except something simple like IF or SUM Formula.

Also Slicers & other newer features may automate many aspects, but versions tried to use, just didn't work as intended, so in terms of Data Validation etc I just continue to use what I can get to work!

Time invested?  It is good to be organised, & I realise many people don't have to be concerned about trivial things, so instead of having my time deliberately wasted it is nice to know what MILEAGE or MPG I did in a year, because years later it will all be forgotten.

Cheers

Avatar
Philip Treacy
Admin
Level 10
Forum Posts: 1518
Member Since:
October 5, 2010
sp_UserOfflineSmall Offline
6
June 11, 2020 - 10:42 am
sp_Permalink sp_Print

Hi Stephan,

You could wrap the function that produces a 0 in an IF and display an empty string

=IF(MIN(IF(A7<=$BG$2,IF(AL7:AO7>0,AL7:AO7,"")))=0,"",MIN(IF(A7<=$BG$2,IF(AL7:AO7>0,AL7:AO7,""))))

but a much easier way is to apply a custom number format to the cell(s) so that they don't display the 0

#,##0.00;-#,##0.00;;

I realise that reworking your data will take some considerable effort but the benefits in the long run would be simpler formulae and the ability to use tools like Pivot Tables and Power Query to get the insights you are after.

Regards

Phil

Avatar
stephanrs
England/Humberside/Hull
Member
Members
Level 0
Forum Posts: 41
Member Since:
February 28, 2017
sp_UserOfflineSmall Offline
7
June 14, 2020 - 4:54 am
sp_Permalink sp_Print

Thanks for those Formulas, workbook completed!

Appreciate new Excel features may save time, but older versions then 2016, seem to be less obvious with unobvious menus, and features that look simple but just don't work as intended like trying to drive a car away in neutral or pulling up to stop in gear. ...

Hence seperate tabs & totals with seperate summary page will be my approach, but yes some formulas to get desired calc sometimes feels like trying to make something simple into onerousity & time consuming.

Avatar
stephanrs
England/Humberside/Hull
Member
Members
Level 0
Forum Posts: 41
Member Since:
February 28, 2017
sp_UserOfflineSmall Offline
8
June 21, 2020 - 2:45 am
sp_Permalink sp_Print

So I know Autofilter suits my purposes often too!

But if the later functions actually work for me the individual, I doubt that.

But in that I know there is a bunch of empty Cells just waiting imminently for me, and colouring/shading cells is such a treat too.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online:
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 871
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
Jessica Stewart: 205
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
stuart burge
Bruce Tang Nian
Scot C
Othman AL MUTAIRI
Misael Gutierrez Sr.
Attif Ihsan
Kieran Fee
Murat Hasanoglu
Brett Dryland
Saeed Aldousari
Forum Stats:
Groups: 3
Forums: 24
Topics: 6223
Posts: 27295

 

Member Stats:
Guest Posters: 49
Members: 31920
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.