Generate chart from highest three values in a table

sogs0707

New Member
Joined
Sep 25, 2014
Messages
13
Hello all,

I have a table which lists categories with percentages which will change every month. I want to have a chart which will automatically pull the highest three values from the table. Is that possible?

Thanks,

Sogs0707
 

Some videos you may like

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.

Momentman

Well-known Member
Joined
Jan 11, 2012
Messages
4,066
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
What you should do is to set up a small table which uses formulas to pick the highest values from your data. Using a function like LARGE

So its the smaller table with the highest 3 values that you then plot,. Once the big table changes, the smaller table('cos it uses formulas to pick) updates as well
 

sogs0707

New Member
Joined
Sep 25, 2014
Messages
13
What you should do is to set up a small table which uses formulas to pick the highest values from your data. Using a function like LARGE

So its the smaller table with the highest 3 values that you then plot,. Once the big table changes, the smaller table('cos it uses formulas to pick) updates as well

A great starting point. I shall give it a try, thank you!
 

ParamRay

Well-known Member
Joined
Aug 6, 2014
Messages
1,195
.
.

Try something like this:

Code:
Sub AddColumnChart()
    
    'Adds a clustered column chart
    'to the active sheet
    'using the 3 largest series values
    'from the specified range
    
    Dim s_vals As Range
    Dim add As String
    Dim cht As Chart
    
    Set s_vals = ActiveSheet.Range("A1:A16")    'change this line
                                                'to the range
                                                'containing your
                                                'series values
    
    add = "=" & _
        LargeAdd(s_vals, 1) & "," & _
        LargeAdd(s_vals, 2) & "," & _
        LargeAdd(s_vals, 3)
    
    Set cht = ActiveSheet.Shapes.AddChart.Chart
    
    With cht
        .ChartType = xlColumnClustered
        .SeriesCollection.NewSeries
        .SeriesCollection(1).Values = add
    End With

End Sub

'--------------------------------------------------------------------------

Private Function LargeAdd(rng As Range, k As Long) As String

    'Returns the address
    'of the k-th largest value
    'in a range
    
    LargeAdd = rng.Parent.Name & "!" & _
        rng.Find(WorksheetFunction.Large(rng, k)).Address

End Function
 

Watch MrExcel Video

Forum statistics

Threads
1,122,207
Messages
5,594,839
Members
413,943
Latest member
Dhornsby21

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
Top