VB Code to Automatically Set Min and Max Scale for Y- Axis

Article translations Article translations
Article ID: 141363 - View products that this article applies to.
This article was previously published under Q141363
Expand all | Collapse all

On This Page

SUMMARY

In Microsoft Excel, you can set the Minimum and Maximum properties of the y-axis scale to any value. The example in this article shows the steps necessary to create a Microsoft Visual Basic for Applications procedure that determines the minimum and maximum values contained in your data and sets the scale based on these values.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. The following Visual Basic macro sets the minimum and maximum values for the y-axis scale in a chart to the maximum and minimum values of the data used to create the chart.

Type the following in a Visual Basic module sheet:
   Sub SetScaleToMinAndMaxValues()
      Dim ValuesArray(), SeriesValues As Variant
      Dim Ctr As Integer, TotCtr As Integer

      ' Uses the first chart on the active worksheet.
      With ActiveSheet.ChartObjects(1).Chart

         ' Note: Instead of the preceding line, you could use this line:
         '
         '    With ActiveChart
         '
         ' if you wanted to be able to run this macro on a chart sheet.

         ' Loops through all of the Series and retrieves the values
         ' and places them into an array named ValuesArray.
         For Each X In .SeriesCollection
            SeriesValues = X.Values
            ReDim Preserve ValuesArray(1 To TotCtr + UBound(SeriesValues))
            For Ctr = 1 To UBound(SeriesValues)
               ValuesArray(Ctr + TotCtr) = SeriesValues(Ctr, 1)

               ' In Excel 97 for Windows and Excel 98 Macintosh Edition,
               ' change the preceding line of code to read as follows:
               '
               '    ValuesArray(Ctr + TotCtr) = SeriesValues(Ctr)

            Next
            TotCtr = TotCtr + UBound(SeriesValues)
         Next

         ' Reset the minimum and maximum scale to the minimum and
         ' maximum values in the ValuesArray.
         .Axes(xlValue).MinimumScaleIsAuto = True
         .Axes(xlValue).MaximumScaleIsAuto = True
         .Axes(xlValue).MinimumScale = Application.Min(ValuesArray)
         .Axes(xlValue).MaximumScale = Application.Max(ValuesArray)
      End With
   End Sub
				

Using the Macro

  1. Select the worksheet that contains your chart.
  2. To activate the macro, click Macro on the Tools menu, and run the SetScaleToMinAndMaxValues macro.

    In Excel 97 and Excel 98, click Tools, point to Macro, and then click Macros. Click SetScaleToMinAndMaxValues, and then click Run.
The minimum and maximum values of the y-axis should now be equal to the minimum and maximum values of the data.

REFERENCES

"Visual Basic User's Guide," version 5.0, pages 145-146

Properties

Article ID: 141363 - Last Review: October 11, 2006 - Revision: 2.3
APPLIES TO
  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 95 Standard Edition
  • Microsoft Excel 5.0 Standard Edition
  • Microsoft Excel 98 for Macintosh
Keywords: 
kbdtacode kbhowto kbprogramming KB141363
Retired KB Content Disclaimer
This article was written about products for which Microsoft no longer offers support. Therefore, this article is offered "as is" and will no longer be updated.

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com