• 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
    • 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
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Charts with Dynamic Arrays without Offset|Dashboards & Charts|Excel Forum|My Online Training Hub

You are here: Home / Charts with Dynamic Arrays without Offset|Dashboards & Charts|Excel Forum|My Online Training Hub

Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search
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 ForumDashboards & ChartsCharts with Dynamic Arrays without …
sp_PrintTopic sp_TopicIcon
Charts with Dynamic Arrays without Offset
Avatar
Yvonne Love

Active Member
Members

Dashboards

Power Query
Level 0
Forum Posts: 4
Member Since:
April 24, 2015
sp_UserOfflineSmall Offline
1
January 7, 2023 - 9:35 am
sp_Permalink sp_Print

Hi everyone! Long time listener, first time caller...and big fan!

I create charts reflecting top 10 clients for a period of 3 years, and I use a specific format for all the charts I create. I've attached a sample spreadsheet showing a screenshot containing the chart and series data. Due to the size of this spreadsheet and the complexity of the columns/data sets/spill ranges, I didn't try to create a sample spreadsheet with the visible formulas. But I'm hoping it'll be easy enough to talk through the process and that my question will be easy to understand.

Columns V, W, X, AA, AB, AC, AD, and AE are all dynamic array spill ranges; the percentage series on the graph pulls from spill ranges in columns AB and AC, both of which have defined names and the chart references those named ranges. Columns Y and Z make up the horizontal axis labels (combos of columns V, AD, and W), but they are not dynamic array spill ranges. Currently I copy the formula in these columns down further than the spill ranges in the other columns (down to column 44, resulting in #N/A) so I use this offset formula to define this range: =OFFSET(ATTORNEY!$Y$2,0,0,COUNTIF(ATTORNEY!$Y$2:$Y$44,"#N/A"),2). It works perfectly fine, but what I would really like to do is be able to make those two columns a single spill range so I don't have to use offset. I'm not even sure if this is possible, but I've shifted most of my thinking/work/processes to using many dynamic arrays (though I know I'm still scratching the surface), so I wanted to see if anyone knows if this is possible with DAs.

Hopefully that makes sense!
Thank you!
Yvonne

sp_AnswersTopicSeeAnswer See Answer
Avatar
Riny van Eekelen
Örnsköldsvik, Sweden
Moderator
Members


Trusted Members

Moderators

Power BI
Level 0
Forum Posts: 384
Member Since:
January 31, 2022
sp_UserOfflineSmall Offline
2
January 7, 2023 - 9:07 pm
sp_Permalink sp_Print

Tried to replicate your data with spilled arrays and constructed a single (rather ugly) formula that spills columns Y:Z, based on columns V, W and AD.

=HSTACK(V2#&" : "&TEXT(IF(V2#VSTACK(0,INDEX(V2#,SEQUENCE(ROWS(V2#)-1,,2)-1)),AD2#,""),"(0.00)"),W2#)

See if it works for you.

sp_AnswersTopicAnswer
Answers Post
Avatar
Yvonne Love

Active Member
Members

Dashboards

Power Query
Level 0
Forum Posts: 4
Member Since:
April 24, 2015
sp_UserOfflineSmall Offline
3
January 12, 2023 - 8:11 am
sp_Permalink sp_Print

Thank you Riny! This was nearly perfect, and I was able to modify the formula a bit to make it exactly what I needed. Since I wanted both the year and the amount to only appear once, I modified it as follows: =HSTACK(IF(V2#VSTACK(0,INDEX(V2#,SEQUENCE(ROWS(V2#)-1,,2)-1)),V2#,"")&" "&TEXT(IF(V2#VSTACK(0,INDEX(V2#,SEQUENCE(ROWS(V2#)-1,,2)-1)),AD2#,""),"(0.00)"),W2#).

Now I will go through and analyze the formula so I understand exactly what it is doing and be able to use it going forward!! This was incredibly helpful. Thank you so very much for taking the time to look at this!!

Yvonne

Avatar
Yvonne Love

Active Member
Members

Dashboards

Power Query
Level 0
Forum Posts: 4
Member Since:
April 24, 2015
sp_UserOfflineSmall Offline
4
January 12, 2023 - 9:11 am
sp_Permalink sp_Print

One quick follow up on this - while it does spill into two columns, the chart doesn't seem to recognize it as being two separate columns so it doesn't display "correctly". But I also know that a feature that just came out is the chart's ability to work with dynamic arrays without having to have named ranges - so once I have that update, it might work the way that I want. Just wanted to post a follow up in case anyone uses charts in the same format that I do.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 170
Currently Online: Norilina Harvel, Brenda Krol
Guest(s) 44
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1431
Anders Sehlstedt: 848
Velouria: 574
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 213
A.Maurizio: 202
Aye Mu: 201
Jessica Stewart: 185
Newest Members:
David Collins
Andras Marsi
Orimoloye Funsho
YUSUF IMAM KAGARA
PRADEEP PRADHAN
Vicky Otosnika
Abhishek Singh
Kevin Sojourner
Kara Weiss
And Woox
Forum Stats:
Groups: 3
Forums: 24
Topics: 6047
Posts: 26543

 

Member Stats:
Guest Posters: 49
Members: 31497
Moderators: 2
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Riny van Eekelen
© Simple:Press —sp_Information
  • 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
 
  • About My Online Training Hub
  • Contact
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

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.

Download A Free Copy of 100 Excel Tips & Tricks

excel tips and tricks ebook

We respect your privacy. We won’t spam you.

x