• 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

Use of Formulas to Define X-Axis in a Chart|General Excel Questions & Answers|Excel Forum|My Online Training Hub

You are here: Home / Use of Formulas to Define X-Axis in a Chart|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…Use of Formulas to Define X-Axis in…
sp_PrintTopic sp_TopicIcon
Use of Formulas to Define X-Axis in a Chart
Avatar
Bob Abrams
Member
Members
Level 0
Forum Posts: 17
Member Since:
October 14, 2015
sp_UserOfflineSmall Offline
1
February 7, 2019 - 5:05 am
sp_Permalink sp_Print

I'm having a problem defining the x-axis on a chart

Failed Approach 1:

I tried using the following formula:

=OFFSET(INDIRECT(ADDRESS(Sheet4!$K$2,1)),0,0,Sheet4!$L$2,1)

However, I get the error message:  "Excel found a problem with one or more formula references in this worksheet"

I've successfully use OFFSET formulas to define chart axes before, so I'm wondering if perhaps the INDIRECT or ADDRESS formulas are not allowed in the SERIES formula defining a chart?

Failed Approach 2:

I have the addresses of the beginning and the end of the desired x-axis range in two separate cells, but can't figure out how to create a range reference that the SERIES function will accept.  Can this be done?

Thanks!

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4443
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
February 7, 2019 - 12:24 pm
sp_Permalink sp_Print

Hi Bob,

I'm wondering why you can't just use OFFSET to derive the range. You've managed to get the cell addresses of the beginning and end cells, but I don't know how you've done this or if it can be skipped altogether.

Looking at your formula, if cell L2 contains a cell address then this isn't what OFFSET needs in this argument. It wants to know how many cells in the range.

Can you please upload your file as it will help answer these questions and more?

Mynda

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 613
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
3
February 7, 2019 - 6:03 pm
sp_Permalink sp_Print

You have to include a sheet name in the INDIRECT part, otherwise there's no context as to what range you actually want.

Avatar
Bob Abrams
Member
Members
Level 0
Forum Posts: 17
Member Since:
October 14, 2015
sp_UserOfflineSmall Offline
4
February 8, 2019 - 7:41 am
sp_Permalink sp_Print

Please see attached file.

The original data is in columns A, C and D.  What I'm trying to do is create up to 7 charts to plot the daily cumulative totals of C & D (as a 2-line line chart).

I added column B as a helper column to make it easier to see when dates change.  I added E and F to show the daily cumulative total of C & D.  The original file was too large to update, so I changed columns B, C and D from (simple) formulas to values to reduce the file size.

The chart on the page was built by using the actual numeric data for day 1.  I then created the table in H1 to N9, figuring that once I had the start and stop addresses, I could create the x-Axis range using "=OFFSET(INDIRECT(ADDRESS($J$2,3)),0,0,$K$2,1)"

That didn't work, so I tried

=INDIRECT(ADDRESS(2,14))&":"&INDIRECT(ADDRESS(2,14))

and

=INDIRECT($M$2)&":"&INDIRECT($N$2)

but neither of these worked either.  I then created range names for each of the three formulas, but that didn't work either.

I did a few other experiments and it looks like I can't use the indirect function in a series function, but I'm not sure if that's really the problem.

Finally I tried the suggestion to add the sheet name, but OFFSET(INDIRECT(ADDRESS(sheet1!$J$2,3)),0,0,Sheet1!$K$2,1) didn't work either.

 I'm obviously stumped, and would appreciate any help the community can offer.

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 613
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
5
February 8, 2019 - 7:46 am
sp_Permalink sp_Print

It needs to be:

 

INDIRECT("Sheet1!"&ADDRESS($J$2,3))

 

to specify the sheet for the returned range.

Avatar
Bob Abrams
Member
Members
Level 0
Forum Posts: 17
Member Since:
October 14, 2015
sp_UserOfflineSmall Offline
6
February 8, 2019 - 10:38 am
sp_Permalink sp_Print

I'm trying to define a range for the x-axis by using =OFFSET([starting cell],0,0,$K$2,1).  The challenge is finding a formula that (in this case) resolves to A2 in place of [starting cell].

Based on the most recent suggestion, I started with "Sheet1!"&ADDRESS($J$2,1), which resolved to $A$2, so I thought I was done.  However, when I put it into the OFFSET function, it resolved to "$A$2", which OFFSET wouldn't accept, since it's text, not a reference.

OK, so I tried to use SUBSTITUTE("Sheet1!"&ADDRESS($J$2,1),CHAR(34),"") to remove the quotes, which worked fine on its own.  However, when I put it into the OFFSET function, it still resolved to "$A$2".  Out of curiosity, I also tried =INDIRECT(SUBSTITUTE("Sheet1!"&ADDRESS($J$2,1),CHAR(34),"")), which worked perfectly, and gave me the contents of A2, as it should have.

Since both OFFSET and INDIRECT require a valid reference as the first parameter, why does INDIRECT accept SUBSTITUTE("Sheet1!"&ADDRESS($J$2,1),CHAR(34),"") as a valid reference, but OFFSET won't????

I feel like I'm overlooking something obvious, but I can't see what it is.

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 613
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
7
February 8, 2019 - 6:26 pm
sp_Permalink sp_Print

INDIRECT expects a text address, not an actual cell reference (which is what it returns). So you can use that to provide the necessary starting cell for OFFSET.

 

You will note that when you define a name, you have to specify a sheet for any cell references you use - if you simply use J2, the name manager will add a reference to the current sheet automatically so that the name has the correct context, no matter where you use it from. The same principle applies to charts - every range you use must be explicitly qualified to a particular sheet.

 

So, if you define a named range for the chart axis, it needs to look something like:

 

=OFFSET(INDIRECT("Sheet1!"&ADDRESS(Sheet1!$J$2,3)),0,0,Sheet1!$K$2,1)

Avatar
Bob Abrams
Member
Members
Level 0
Forum Posts: 17
Member Since:
October 14, 2015
sp_UserOfflineSmall Offline
8
February 10, 2019 - 7:58 am
sp_Permalink sp_Print

I'm afraid I get the same result as before, even using the suggested formula of

=OFFSET(INDIRECT("Sheet1!"&ADDRESS(Sheet1!$J$2,3)),0,0,Sheet1!$K$2,1)

Namely, if I enter that formula into a cell, it evaluates properly; if I try to use it to specify the X-Axis for a chart, I get an error message.

 

It occurred to me to look back at previous projects where I had been able to use OFFSET to successfully define an X-Axis.  I found 4 examples, and noticed that in each case, the first parameter (starting point) of the OFFSET function was a direct reference, not a formula.  Could that possibly be the reason I can't get the formula above to work?  I know I'm grasping at straws, but it seems that that's all that's left....

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 613
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
9
February 11, 2019 - 8:49 pm
sp_Permalink sp_Print

Interestingly, it seems to be the combination of INDIRECT with ADDRESS. INDIRECT on its own works fine.

As it happens, you can avoid both here by using INDEX:

 

=OFFSET(INDEX(Sheet1!$C:$C,Sheet1!$J$2),0,0,Sheet1!$K$2,1)

which works fine with a chart.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Brian Pham, Chandler Davis
Guest(s) 9
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
drsven
Annie Witbrod
wahab tunde
Cong Le Duc
Faisal Bashir
Ivica Cvetkovski
Blaine Cox
Shankar Srinivasan
riyepa fdgf
Hannah Cave
Forum Stats:
Groups: 3
Forums: 24
Topics: 6205
Posts: 27212

 

Member Stats:
Guest Posters: 49
Members: 31880
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.