Written by Allen Wyatt (last updated June 3, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Chris has a workbook that contains a lot of small, identical charts. He wants to change some of the attributes of elements in each chart—such as color or font size—all at one time.
If you find yourself using a "non-default" chart often (which means changing the appearance of certain chart elements after the chart is created), then a great approach is to create a custom chart and save that format in Excel. You can then use the saved format to create all your new charts, thereby minimizing the amount of later formatting you need to do. How you save custom chart formats has been covered in other issues of ExcelTips.
Custom chart formats may be great for the future, but it doesn't help if you already have a whole bunch of charts in an existing workbook. In that case, the best solution is to use a macro which can step through all the charts in a workbook and make a desired change. You just need to decide up front which items you wish to change, and then program the macro to specifically change those items.
For example, the following macro changes the font color and size of the Y-axis labels. It loops through all the charts in the workbook, both sheets and embedded charts.
Sub ChangeAllCharts1() Dim cht As Chart Dim sht Dim ChtObj As ChartObject For Each cht In ActiveWorkbook.Charts With cht.Axes(xlValue).TickLabels.Font .Size = 20 .Color = vbRed End With Next For Each sht In ActiveWorkbook.Sheets For Each ChtObj In sht.ChartObjects With ChtObj.Chart.Axes(xlValue).TickLabels.Font .Size = 20 .Color = vbRed End With Next Next End Sub
As written here, the macro changes the font size to 20 and the color to red. If you want the macro to change other elements, all you need to do is change the With statements to reflect the elements you want changed, or you could use a For...Next loop to step through all the chart elements. The following macro exhibits this technique, changing the background color of the charts in a workbook.
Sub ChangeAllCharts2() On Error Resume Next NewChartAreaColor = 34 For J = 1 To ActiveWorkbook.Charts.Count ActiveWorkbook.Charts(J).Select 'The pairs of line code indicate desired changes ActiveChart.ChartArea.Select Selection.Interior.ColorIndex = NewChartAreaColor Next J For J = 1 To ActiveWorkbook.Sheets.Count For K = 1 To Sheets(J).ChartObjects.Count Sheets(J).Select Sheets(J).ChartObjects(K).Activate 'The pairs of line code indicate desired changes ActiveChart.ChartArea.Select Selection.Interior.ColorIndex = NewChartAreaColor Next K Next J End Sub
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7734) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Changing Elements in Lots of Charts at One Time.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
Got a chart created from your worksheet? You can plot times of day in the chart if you apply the simple techniques in ...
Discover MoreNeed a chart that uses two lines for axis labels? It's easy to do if you know how to set up your data in the worksheet, ...
Discover MoreOne type of chart that Excel allows you to create is one that occupies an entire worksheet. When it comes time to print ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments