A few weeks back Jhouz asked a question in the Chandoo.org Forums “Is is possible to create a doughnut chart like this one in excel?”
This post will examine how to make it
Alert: It isn’t as straight forward as you may first think!
A couple of users responded with a Doughnut Chart
Which at first glance looks quite similar.
But the original author wanted round ends on the ends of the Doughnut segment. He also wanted a smooth chart.
A quick scan through the properties of a Doughnut Chart reveals there is no optionality to control the ends of the Doughnuts Segments. An alternative approach was required.
A Solution
Before starting, if you want to you can follow along using a sample file with the worked examples shown below: Download Here
The solution I posed was to use an X-Y Scatter chart for the line segments and apply a thick Line style.
The part of this approach that makes it work is that Line Styles have a property for the Lines End including an option for a round end.
The solution chart above consists of 2 lines
The first is the Background (Grey) line, which is a complete circle
The second line is the green line, which is a segment of the circle equal to in this case 45% of a circle or 162 Degrees (0.45 x 360). It is in front of the Grey line.
To apply this technique I used a number of Named Formula, and based the chart on these named formula:
First for the Background Grey chart segment
To define the Grey segment I applied 3 Named Formula:
c1_Rad | =RADIANS(-(ROW(OFFSET(Sheet1!$A$1,,,360+1,1))-91)) |
_x1 | =COS(c1_Rad) |
_y1 | =SIN(c1_Rad) |
The Grey circle is defined by an Array of Radians of each degree between 0 and 360 of a circle.
C1_Rad =RADIANS(-(ROW(OFFSET(Sheet1!$A$1,,,360+1,1))-91))
This works by using the Excel Row() and Offset() function to generate an array of Degrees from 0 to 360
The formula ROW(OFFSET(Sheet1!$A$1,,,360+1,1))
Will return ={1;2;3;4;5;6; …. ;358;359;360;361}
Note that we have taken the array 1 degree past 360 because the Row’s lowest value is Row 1, not row 0.
We then subtract 91 degrees from this to allow the Chart to start at the top of the circle.
The adjusted formula ROW(OFFSET(Sheet1!$A$1,,,360+1,1))-91
Returns: ={-90;-89;-88;-87; … ;268;269;270}
Finally the – in front of the array changes the direction of the circle from Anticlockwise to clockwise.
Returns: ={90;89;88;87; … ;-268;-269;-270}
The Radians() function is used to convert the array of Degrees into an array of Radians
Returns: ={1.57;1.55;1.53; … ;-1.22;-1.23;-1.25}
The Radians above were rounded to 2 decimals places for display on this post, but Excel internally is using the full 15 decimal place precision.
We can now use this array of Radians to draw the background circle
To do this setup 2 new Named Formula
_x1: =COS(c1_Rad)
_y1: =SIN(c1_Rad)
Each of these will return an array of the X and Y values corresponding to each of the Radians from the previous c1_Rad array. The X and Y values will vary between -1 and 1. You may need these for Chart Scaling later.
If you want a circle of different radius simply multiply the x and y formulas like
_x1: =COS(c1_Rad)*5 for a radius of 5 and the same for the _y1 named formula
To plot these we add a X-Y Scatter Chart.
Select a single cell. Then goto the Insert, Chart, Scatter Chart menu and select a Scatter Chart with Smooth lines. This will give you a blank chart.
With the Chart Selected, Right click on the chart area and choose Select Data…
Add a Series using the Add button. Use the Worksheet Name Sheet1 and Named Formula _x1 & _y1 for the X and Y values
You can leave the Series Name blank or enter a value like “Background Circle”.
Note that you must enter the Sheet Name including the ! preceding the Named Formula name. Once you have accepted the inputs, if you return to the Edit Series dialog, notice that Excel now displays the Workbooks name instead of the Worksheets name. That’s quite ok.
You will now have a chart which looks like:
Finally Right click on the first series and select Format Data Series.
Set the Line Color to a Light Grey and set the Line Width to 12 . Check that Markers are set to None
Next the Foreground Green chart segment
To draw the front arc of the circle we add a few more Named Formula
_pct | =Sheet1!$C$6 |
c2_Rad | =RADIANS(-(ROW(OFFSET(Sheet1!$A$1,,,_pct*360+1,1))-91)) |
_x2 | =COS(c2_Rad) |
_y2 | =SIN(c2_Rad) |
_pct stores the value of the percentage of the circle directly from the reference cell on the worksheet eg: 45%
To draw an arc we only need to factor the 360 Degrees for a full circle back to the percentage required for the arc: ie: from 0 to 45% x 360 degrees = 162 Degrees. Hence drawing an Arc from 0 degrees to 162 Degrees.
To do this we use the same formula as before except that we set the range to the 45% of 360 degrees using the Named Formula:
C2_Rad: =RADIANS(-(ROW(OFFSET(Sheet1!$A$1,,,_pct*360+1,1))-91))
Add another series to the chart using.
With the Chart Selected, Right click on the chart area and choose Select Data…
X values: =Sheet1!_x2
Y values: =Sheet1!_y2
Next select the chart and ensure that the 45% circle is in front of the full circle
Select the Chart’s 2nd series and change the line width and line color to suit the impact you want.
Finally select the 45% line
Goto the Lines properties and set the Cap type to Round
Add the Measurement
With the Chart selected, goto the Insert, Text Box dialog and select a text box style and insert it.
With the text box selected, goto the Formula Bar and enter the Formula =_pct and press Enter or click the Tick icon to accept.
Finally with the text box selected, Change the Font Size to suit eg: 64 and Format the Text using an appropriate style from the Drawing Tools, Format Menu
Ensure the Text box is wide enough to display up to 100% include the percentage sign
The Final Chart
and with another value…
Other line type endings
Experiment with other Line Ends and see what you can make?
and Line Styles and Thicknesses?
Multiple Series
By careful use of chart series you can add multiple measurements to the same chart and use a combination of display properties to enhance your chart
Conclusion
In conclusion I have demonstrated a successful solution to Jhouz’s original post and then extended it a bit further.
The Author acknowledges that there is limited use for doughnut charts and only recommends them in limited circumstances.
I hope these enhancements allow you to better use and emphasise your data in your situation as well as add another Excel technique to your arsenal.