Ignore X axis labels for zero values

omicron79

New Member
Joined
Jun 3, 2010
Messages
11
How to ignore X axis labels for data series that have zero values in charts (XL 2010)?
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
You can apply a custom number format of 0;-0;;@ to the labels in the options
 
Upvote 0
Thanks Dave, its only useful for data labels. What I want is to ignore the data series completely if data is zero? the data in current format is a below:


ABCDE
X02302
Y02303
Z00201
W02300
sum061106

<tbody>
</tbody>

This will be a stacked column chart where X,Y,Z, W, Sum form the columns. A,B,C,D,E are the x axis. I would like to not plot A and D series since sum is Zero. I have a TRUE/FALSE flag to indicate the same. How can I dynamically create this chart. There might be instances in future where A will be populated with numbers but C or E will all zeros. There will no new addition of columns or rows.
 
Last edited:
Upvote 0
SO you need a dynamic charts, I adapted this from Dynamic Charts | Peltier Tech Blog | Excel Charts

Firstly you'll need some helper columns to plot


Excel 2007
ABCDEFGHIJ
1XYZWsumHelperLabelsValues
2A00000 1B6
3B2202612C11
4C33231123E6
5D00000
6E231063
Sheet1
Cell Formulas
RangeFormula
F2=SUM(B2:E2)
G2=IF(F2=0, "", COUNTIF($F$2:F2, "<>0"))
H2=IFERROR(SMALL($G$2:$G$6, ROW()-1), "")
I2=IF(H2="", "", INDEX($A$2:$A$6, MATCH(H2, $G$2:$G$6, 0)))
J2=IF(I2="", "", VLOOKUP(I2, $A$2:$F$6, 6, 0))


You'll then need two named ranges

xvals - =OFFSET(Sheet1!$I$2,,,COUNT(Sheet1!$J$2:$J$6), 1)
yvals - =OFFSET(xvals,,1)

Plot a chart and click on the data series, in the formula bar you will see a SERIES function, I chnaged this to - =SERIES(Sheet1!$J$1,Sheet1!xvals,Sheet1!yvals,1)

Now you have fully dynamic chart that will only display non-zero series.

Hope this helps
 
Upvote 0

Forum statistics

Threads
1,213,561
Messages
6,114,317
Members
448,564
Latest member
ED38

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