Dynamic dropdowns are a handy way to get your users to make choices based on what they’ve previously chosen, while steering them away from making invalid choices. Today we’re going to look at one that easily handles multiple levels, and we’ll take a look at what could go wrong. Let’s see one in action, shall we?
Right, what’s on the (dropdown) menu?
*BING!*
Cool…check it out…as you can see from the above, the user gets prompted with “Choose…” whenever a subsequent choice must be made.
Ok, what kind of fruit should I have? Hmmm, let me see….eeny, meeny, miny, STRAWBERRIES!!!…MO!
Ok, so what delights does Sub Category 2 have in store for me?
Earliglow? Never heard of it. Sounds delicious…I’ll have those, please.
There, all done. Pretty nifty eh…users only get to see valid choices depending on what they chose last. So users simply can’t screw up! Or can they?
[Evil user, determined to prove me wrong]: Wait a minute…I just remembered that mother expects me to eat my vegetables first, before I move on to dessert. So I better change that initial selection:
*BING!*
What the…Strawberries are vegetables???
Damn…changing upstream dropdowns later on means those downstream choices can be flat out wrong! So how can we make this bulletproof?
Macros to the rescue
Yep, we’ll use some code to clear out any ‘downstream’ choices if anything ‘upstream’ changes. Let’s go back to that original strawberry fest:
Now watch what happens when our user subsequently decides they better vege out first:
Ahh…look at that: the code realized that all those downstream choices are no longer valid. So it deleted them, and prompted the user to choose again. There. Now that IS bulletproof.
So let’s see…hmmm…for an appetizer, I’ll have baby carrots:
And I already decided on Strawberries for pudding…
But what about my main course. Ah, yes, of course…
MEAT! Yummy. BURP!
What’s the recipe?
My approach draws on Roger Govier’s excellent sample file on the Contextures website. Be sure to check out that link to see Roger’s in-depth discussion of the formula magic behind this puppy…It’s genius.
In my Dynamic-Dependent-dropdowns-20140214, you’ll see that all the different categories used by the dropdowns are hosted in an Excel Table, that has the initial categories down the left hand side, and subsequent categories across the top:
So how do these categories get used by the data validation dropdowns? Roger’s approach uses two dynamic named ranges to feed the data validation lists, one called MainList and one called SubList:
Here’s the MainList formula:
=INDEX(Table1[[Choose…]],1):INDEX(Table1[[Choose…]],COUNTA(Table1[[Choose…]]))
…and here’s the SubList formula:
=IF(OR(Sheet1!B8="Choose…",Sheet1!B8=""),"",INDEX(Table1,1,MATCH(Sheet1!B8,Table1[#Headers],0)):INDEX(
Table1,COUNTA(INDEX(Table1,,MATCH(Sheet1!B8,Table1[#Headers],0))),MATCH(Sheet1!B8,Table1[#Headers],0)))
The SubList formula has a relative reference in it: whatever cell you use it in, it retrieves the value of the cell to the immediate left, and then it scans the column headers of our validations table (Table1) looking for the heading that matches that value. Once it’s found it, it simply uses the items listed underneath that heading.
Because this formula is relative, before you enter it into the Name Manager, you will need to first select cell C8, because the above relative formula refers to B8 – the cell to the left. (Note that it doesn’t matter what is in C8 or where your actual dropdown are…rather it’s just that the above formula happens to refer to B8, and because we want our formula to always reference the cell on the immediate left, then we’ve got to select the cell to the immediate right before we enter this relative formula into the Name Manager.
Also note that my version of Roger’s approach uses Excel Tables and the associated Structured References that Table functionality allows. My table is called Table1. Your validation lists MUST be held within an Excel Table (which requires Excel 2007 or greater) and you MUST change the Table1 references in the above formula to match the name of your table.
Excel Tables – known as ListObjects to VBA developers – were introduced in Excel 2007, and are a very powerful and simple way to store things like lists, chart data, and PivotTable data…especially if you might need to add more data to your spreadsheet at a later date, and want to avoid having to repoint all your formulas to include the additional data. If you’re not familiar with Excel Tables – or you don’t know what that Table1[#Headers] guff above means – then I strongly suggest you check out Chandoo’s Introduction to Structural References and this great video he did with MrExcel.
The way these two formulas work is very clever. That MainList named range only gets used by dropdowns in that very first ‘Main Category’ column:
…and all other ‘downstream’ dropdowns – no matter what level they are – are fed by the SubList named range:
The beauty of Roger’s approach is that it can handle any number of cascading levels, provided all the category names are unique. All you need to do is simply add the new subcategories to the right hand side of our validations table (Table1).
Let’s look at an example. If you look at the below screenshot, you’ll see that users can choose from a number of different kinds of meat:
Let’s add a further level that would give meat eaters some further choices relating to how their meat is prepared.
To set this up, all we need to do is take the individual items from that ‘Meat’ column and add each one as a new column header:
Then we simply list the new options for each type of meat below the relevant header:
Now here’s the magic: as soon as we add another column to our input table and set it up with data validation – which I did simply by clicking on the bottom right corner of the cell with the word ‘Human’ and dragging it across – then Excel picks up on the fact that there’s a sub-subcategory, and serves it up to us. *BING!* Order up!
Add code, and stir-fry for 10 milliseconds
As mentioned earlier, in addition to Roger’s great method, I’ve written some code that clears out any downstream entries in the event that an upstream entry is changed. It’s in the sample workbook already, all set to go. But here’s the actual code, for you VBA nerds. (Special thanks to Gabor Madacs for some enhancement suggestions)
Option Explicit Const CHOOSE = "Choose…" Private Sub Worksheet_Change(ByVal Target As Range) On Error GoTo ErrorHandler Dim targetCell As Range Dim nextCell As Range Dim oldCalc As Excel.XlCalculation If Not Intersect(Target, [DataEntryTable]) Is Nothing Then If [Radio_Choice] = 1 Then With Application .EnableEvents = False .ScreenUpdating = False oldCalc = .Calculation .Calculation = xlCalculationManual End With For Each targetCell In Target 'Clear any cells that use 'SubList' to the right of targetCell in the current table. If targetCell.Column < (targetCell.ListObject.ListColumns.Count + targetCell.ListObject.Range.Column - 1) Then 'there are table cells to the right For Each nextCell In targetCell.Offset(, 1).Resize(, targetCell.ListObject.ListColumns.Count + targetCell.ListObject.Range.Column - targetCell.Column - 1) If HasValidationFormula(nextCell) Then If nextCell.Validation.Formula1 = "=SubList" Then nextCell.Value = "" End If Next nextCell End If 'Perform different action depeding on whether we're dealing with a 'MainList' dropdown ' or a 'SubList' dropdown If HasValidationFormula(targetCell) Then Select Case targetCell.Validation.Formula1 Case "=MainList" If targetCell.Value = "" Then targetCell.Value = CHOOSE ElseIf targetCell.Value = CHOOSE Then 'Do nothing. Else targetCell.Offset(, 1).Value = CHOOSE End If Case "=SubList" If targetCell.Value = "" Then targetCell.Value = CHOOSE ElseIf targetCell.Offset(, -1).Value = CHOOSE Then targetCell.Value = "" ElseIf targetCell.Value = CHOOSE Then 'Do nothing Else Set nextCell = targetCell.Offset(, 1) If HasValidationFormula(nextCell) Then If nextCell.Validation.Formula1 = "=SubList" Then nextCell.Value = CHOOSE End If End If End Select End If Next targetCell With Application .EnableEvents = True .ScreenUpdating = True .Calculation = oldCalc End With End If End If Exit Sub ErrorHandler: With Application .EnableEvents = True .ScreenUpdating = True If oldCalc <> 0 Then .Calculation = oldCalc End With MsgBox Err.Description, vbCritical, Name & ".Worksheet_Change()" End Sub Private Function HasValidationFormula(cell As Range) As Boolean On Error GoTo ValidationNotExistsError If cell.Validation.Formula1 <> "" Then HasValidationFormula = True Else HasValidationFormula = False End If Exit Function ValidationNotExistsError: HasValidationFormula = False End Function
Hungry for more?
Here’s some related Posts at Chandoo.org:
Download the file
To see how this is done, download this file and enable macros:
Dynamic-Dependent-dropdowns-20140214
About the Author.
Jeff Weir – a local of Galactic North up there in Windy Wellington, New Zealand – is more volatile than INDIRECT and more random than RAND. In fact, his state of mind can be pretty much summed up by this:
=NOT(EVEN(PROPER(OR(RIGHT(TODAY())))))
That’s right, pure #VALUE!
Find out more at http:www.heavydutydecisions.co.nz
63 Responses to “Custom Chart Axis Formating – Part 2.”
Hui, these are cool little tricks. Not one I need today, but well worth remembering for future dashboards
I recently learned what I thought was a really simple but useful number format. A custom format followed by ;;; will not display 0 values. Example format #,##0.00,,;;; will display 12,570,000 as 12.57 and display 0 as blank. I found that this really helped me reduce some of the clutter on dynamic charts. Thanks for another good article.
Like! 🙂
hi Hui,
Once I have created a custom format, how do I remove/delete it from the list again? I tried a few methods such as right click (no option to remove). I tried hi-lighting the custom format and hit the delete key. Nothing works.
@Fred,
Unlike the Custom Number format dialog for cells they don't have a Delete Button on the Chart Number Formats dialog, Maybe next version?
.
If you don't want to use your Custom Format select one of the built in formats.
hi chandoo and all,
great tips on the formatting.
1 curious answer: Is it possible to highlight Sat/Sun for DATES on x-axis?
assuming i have 1 month of daily product sales, x-axis = dates, y-axies = sum of sales.
thanks!
@Davidlim
.
You have limited options here as you can only use 3 conditional ranges in the [ ] brackets
So you can do something like
[Green][<40787]ddd;[Blue][>40788]ddd;[Red]ddd
This will make:
Dates earlier than September 2011 Green
Dates after September 2nd 2011 Blue
Dates on September 1 or 2nd, 2011 Red
.
Otherwise you can use the techniques where you use a Combination chart and color the weekend column a highlight color to emphasize them
Have a look at: http://chandoo.org/wp/2009/08/26/combo-charts-to-group-times/
Download the file just below:
Download this excel combo chart and play with it to learn more
Select the hidden bars and apply a fill
Great post,
I would like to know a way to apply custom formatting to the horizontal axis.
Suppose, I want to highlight F,G & H in Red
@Fowmy
As far as I'm aware it can't be done using Custom Formats
You can of course use cells lined up under the chart and do the Conditional Formatting in those cells
@Hui:
How do I get the number formats to work on a Dynamic Chart.i.e: Chart with different scaling based on different data sources. For example, if I have five KPI and each have a Target, how do I get the chart to dynamically change number format based on the data selected?
@Donald
Have a read of this Forum and my comments and see if that helps you
http://chandoo.org/forums/topic/making-vlookup-recieve-multiple-formats-of-data
@Hui: Thanx for the speedy comment, I've checked the link and your last comment is almost what I need but I can't get it right for my application. See below my problems. Data below is displayed on the dynamic graph. The Graph only shows two data lines Target and the actual KPI data. on the data line I won't to highlight the numbers based on the info below relative to the Target line.
KPI Target GREEN ORANGE RED
DCR 1 and 1.2
BSS Setup 99 >99 95> and <99 <95
TCH BLK 0.5 and 1
SD BLK 0.5 and 1
UL_TBF S_Rate 90 >85 85> and <90 85 85> and <90 <85
@Donald
Do you want to email me this file
I'm struggling to visualise this
add instructions please
I remember seeing a blog post some time ago about the number format colors. The default green color is ugly, and there was some neat trick to change that into more dark green version. I think it had to do with assigning some code instead of [green].
@Hui: I just forward you a mail now. I've also noticed that the custom only allows two conditions and I struggling to put more custom for same chart. As indicated, the graph has different target format i.e 1% and 95%.
@Donald: I'm not sure what do you want to get in your case, here is what I've used in my dashboard for different KPI values:
[50000]$#,K;0
I have %'s, monthly sales amounts (all > $50000) and invoice counts. However I didn't apply this formatting to the axis number format - it will always have 0 as 0.00% - any ideas how to avoid this?
Formatting in my comment above should be as following: [50000]$#,K;0
one more time:
[50000]$#,K;0
@Oleksiy: Follow link on Hui comment (11). Looks like it might address your problem.
@Donald: I have done similar for series values already, just for some reason Chandoo's website modified my comment from "/<1/0.00%; /50000/$#,K;0" where / - [ and ]. 🙂
Problem is that I can't apply this to the axis format as it always has zero.
Thanks, Hui.
Hello Hui, Please suggest how can I highlight ( making it bold or colored) a particular month among 12 months that I put in X axis.
You can use the same technique with Dates that are Dates, but not when they are Text.
That is if your X-Axis has dates, apply a custom number format like
[Red][<=40790]d-mmm;[Black]d-mmm
that is Dates <= 4 Sept 2011 will be Red, others will be Black where 40790 is the serial number for 4 Sept 2011 You can change the Date Format d-mmm to whatever suits you . [Red][<=40790]d-mmm;[Black][<40798]d-mmm;[Green]d-mmm
Red <=4 Sep Black < 12 Sep Green >= 12 Sep
.
The Date fomats can change as well
[Red][<=40790]d mm;[Black][<40798]d-mmm;[Green]d mmmm yy
Red <= 4 Sept; displayed as 4 09 Black < 12 Sept; displayed as 12-Sep Green >= 12 Sept; displayed as 12 September 11
Thanks a lot Hui for your great suggestion. So it is only possible for months not for any other texts!
@Tamoghna
Its possible for any Numbers, %, $, Dates or Times,
Which are all numbers anyway.
It is not possible for Text
If you need to do text, you can consider using Text Boxes or cells behind the chart where you can apply conditional formats to.
So instead of using the Built In axis labels, make the chart transparent and place a number of Columns behind the chart with the approriate text and Conditional Formats in it
A similar approach can be done using Text Boxes linked to cells
Hui,
This is great and very timely because I suddenly have a need for lables that change format according to the values - so thank you.
A quick question however, on a slightly different issue. Is it possible to format the markers so they don't show for a zero value but do show for any value above or below zero.
Thanks,
Linda
@Linda
try a format like
[red]0;[green]-2;;
.
Note the custom format layout is
Positive;Negative;0;Text
.
so by having a third parameter of ;;
you get no format when it is 0
Hui,
Thanks for the quick response. However, I don't seem to know where to type the format. I can see how to do this for the Labels but not for the actual graph marker itself. Esentially I want the marker to show if there is a value, but not if it is 0.
Appreciate your help.
Linda
@Linda
Sorry, I'd misread your requirements
Where your data is, change the formula to be
=if(my formula=0, na(), my Formula)
.
You may have to change the settings
Select chart
Right Click, Select data
Hidden & Empty cells
Adjust to suit
Hui,
Thank you so much that worked well. I had a couple of problems at first because I had the graph type set as a line and the #NA had no effect. However, once I changed it to XY scatter, your suggestion worked like a treat!
Thanks so much for your help
Linda
@Linda
You may want to also have a read of
http://chandoo.org/wp/2010/11/11/highlight-data-points-scatter-line-charts/
Hello Hui,
I have a data validation cell (A1) with a dropdown list for "Qty" and "$$$".
My data set is values that I plot asa Pie Chart (In Column B1).
These values are conditionally read from 2 different tables depending on the drop down list selection for $$$$ or Qty.
I have conditionlly formatted all cells in B1 to display number format as Number (0 decimal places) or Currency $ again dependent on selection made in A1.
Now my pie chart is updating correctly based on my selections and data but the labels do not get formatted to Number or Currency automatically.
How can I conditionally format the labels based on selection in A1?
@Aashtee
You can't conditionally format chart objects against another cell only against there own values.
If the values for Qty and price are different
ie: Price $100-200
Qty 1-20
you can use a Custom Number format like
[Blue][>=100]$#,###.00 ;[Red][<100]#,###;
.
But if they overlap it can't be done
[...] http://chandoo.org/wp/2011/08/22/custom-chart-axis-formating-part-2/ [...]
Hi Hui,
I'm trying to customize the x-axis from 0,1,2,3,4,5 to read: 0, KG, 1, 2, 3, 4, 5. How can I do this?
Also, the x-axis figures are currently on top of my chart, how can I move these to be on the bottom?
Thanks!
@Annie
Try the following Custom Number Format
#;-#;0" Kg";@
Thanks! This almost works perfectly, except that the "0" and the "KG" are labels for the same point (0). I need the "0" at 0 and then "KG" then 1, 2, 3,...
Thank you for your help with this!
Select the X Axis
Ctrl 1
Axis Options Tab
Vertical Axis Crosses
Axis Value: 0.0
That didn't change anything.
To clarify, I'm trying to get the x-axis to read: 0 KG 1 2 3 4 5 (evenly spaced). The problem may be in trying to put "KG" in the "1" place, "1" in the "2" place, and so on.
Annie
What type of Chart is this ?
It's a clustered bar chart that I'm using to show when curriculum was developed for different subjects. The y-axis indicates the year the curriculum was developed and the x-axis corresponds to the grade level (KG is short for kindergarten, followed by Class 1, 2, 3, 4 and 5).
@Annie
I'm struggling with an easy solution for this one
One way would be to delete the axis altogether or use a Custom Number format like ;;;
Then setup a manual set of cells with the 0 K 1 2 3 4 etc which would be located behind the chart and then resemble the Axis Labels
or
Setup a Text Box/es with the same Sequence 0 K 1 2 3 4 etc and place that where the axis would be
Once properly located and sized, The Text Box could be grouped with the chart so that they remain fixed to each other.
Hi Annie,
I think this might work for you...basically what Hui said but a couple small tweaks.
use this custom format
General;[<0]"0";"KG"
It will make negatives appear as 0 and 0 appear as KG, positive numbers will remain as they are.
Then select the x-axis and ctrl+1 to go to format axis.
Axis Options
1/Set Minimum to -1 (Fixed)
2/Set Maximum to 5 (Fixed, optional)
3/Vertical axis crosses; Axis Value = -1
In your data, make sure that all data points relating to KG are 0.
Your clustered bar chart should have 0 KG 1 2 3 4 5 for the x-axis labels.
Kyle
THANK YOU SO MUCH!
This worked perfectly. I really appreciate all of your help.
Phew!
Annie
minor note on the customer format I posted...it doesn't need the [<0] in General;[<0]"0";"KG". You can just use General;"0";"KG"
hi drea,
thank you so much !
i am from iran.
this site is very good for me.
this site has very good information from excel.
by
I need to do something like your highlight thousands as K, but to this degree:
1? 0.000001
10? 0.00001 100? 0.0001 1m 0.001 10m 0.010 100m 0.100
1 1.000
10 10.000
100 100.000
1k 1000.000 10k 10000.000 100k 100000.000 1M 1000000.000 10M 10000000.000 100M 100000000.000 1G 1000000000.000 10G 10000000000.000
100G 100000000000.000
From what i've been told i can not express all of that as a chart label number format, so i was looking at other options.
Within VBA and Excel, how can i apply a NumberFormat like this to a chart?
Any help is greatly appreciated!
Russ
Actually the numbers ghot screwed up when i pasted.
They should be like
1K 1000.0
10K 10000.0
100K 100000.0
etc.
If it is just "k"s that you want to add, then using the format #,"k" should work.
My y axis goes from 0 to 1 with increments of 0.1
I want it do be displayed in terms of p10,p20 all the way to p100
For ex instead of 0.1 i want p90 and instead of 0.2 i want p80 all the waiy to p0. Is this possible?
@Yousuf
You can't do maths in Number Formatting apart from the Power of 10 tricks discussed here: http://chandoo.org/wp/2012/01/31/custom-number-formats-multiply-divide-by-any-power-of-10/
However you can still do what you want
Setup your chart
Select the Y Axis and set Max to 1, Min to 0 and Major Unit to 0.1
With the Chart selected Add text boxes and type the text you want for each Axis Point eg: p10, p20 etc
Locate the text boxes in the correct locations using the Axis as a guide
Set the text size, font, Bold etc to suit
Select all the text boxes and group them
Select the axis and set the text color to None
How can I use an image instead of a text on chart axes? I would like to use companies logos instead of using the names on x-axis. Is it possible?
@lonchas
With the chart selected
Select the axis
Set the Custom Number format to "";"";""
This will display the axis without labels
Then paste the pictures in, rescale and position as appropriate
Is it not possible to insert the picture automatically, just associating each label with a picture?
I am trying to do something like that:
http://www.ricaperrone.com.br/2012/09/br12-publico-e-renda/
(pls, see the third image).
I though the images had been inserted directly from cells through a formule.
I have data labels in percentage format. which custom format i should use to have green color fornt if more then 100% and red color font if less then 100%.
@Bisal
try:
[>1][Green]0%;[<=1][Red]0%
I'm hoping you can help. I have a dynamic chart for financial data. Most of the charts have a y axis based on $ with a couple charts that are a %. I can not use a option mentioned above since some of the $s have a negative value. I tried conditional formatting the source, but the 'Link to source' does not pick up the conditional formatting. Is there a way to have the y axis dynamically change from $ to %. I am using a combo box to change the data on the chart.
@Shelley
Can you post or email me a sample file ?
I emailed the file. Did you receive it?
I need this question to be answered for me too. My "linked" data is conditional formatted to be red given some criteria. I want my axis to be red too, but it only picks up the number format, not the conditional formatting.
The “linked” data from my table is conditional formatted to be red based off of some criteria. I want my chart axis to be red too, but it only picks up the number format, not the conditional formatting.
Is there any way to link conditional formatting of sourced data to axis labels?
You are awesome chandoo. Thanks
Hi Chandoo,
Your posts are very helpful.
Is there a way to conditionally format the data label position/location (in addition color, as you have shown in this post)?
I have some line charts with markers showing the same measure from year to year. Each chart has two lines. One of the lines is an average of participants in the group and stays the same. The other line is for each participant and gets updated dynamically to produce about 50 unique charts total. If I put the data labels "above" or "below," they look good for about half the participants, then overlap or are confusing next to each other for the remaining half of the participants (given that the one line is the average of all participants). Right, left, and center do not look good, as they overlap the lines. I tried using the Chart Tools---> Design---> Style 2, which makes the markers bigger and places the data label inside the marker. However, for the 3-4 participants per year who have about average values, the marker for the participant overlaps with that for the average and makes the labels unreadable.
Thank you for any help you can offer!