XL: Using a Visual Basic Macro to Sort Arrays in Microsoft Excel

Last reviewed: February 3, 1998
Article ID: Q133135
The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition

SUMMARY

In Microsoft Excel, there is no direct method for sorting an array of values with a Microsoft Visual Basic for Applications macro or procedure. This article discusses two different algorithms that you can use to sort arrays: Selection Sort and Bubble Sort.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and 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 needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

   http://www.microsoft.com/support/supportnet/refguide/default.asp

Method 1: Selection Sort

To perform a Selection Sort of an array with 1...n elements, locate the largest element from 1...n. If this is not element n, then exchange the largest element with element n. Then, locate the largest element from 1...n-1 and, if this is not element n-1, exchange the largest element with element n-1. Next, locate the largest element from 1...n-2 and, if this is not element n-2, exchange the largest element with element n-2, and so on. Below is an example of a Selection Sort with a Visual Basic Variant type array.

  1. Type the following in a module sheet:

          Option Base 1
    

          Function SelectionSort(TempArray As Variant)
    
              Dim MaxVal As Variant
              Dim MaxIndex As Integer
              Dim i, j As Integer
    
              ' Step through the elements in the array starting with the
              ' last element in the array.
              For i = UBound(TempArray) To 1 Step -1
    
                  ' Set MaxVal to the element in the array and save the
                  ' index of this element as MaxIndex.
                  MaxVal = TempArray(i)
                  MaxIndex = i
    
                  ' Loop through the remaining elements to see if any is
                  ' larger than MaxVal. If it is then set this element
                  ' to be the new MaxVal.
                  For j = 1 To i
                      If TempArray(j) > MaxVal Then
                          MaxVal = TempArray(j)
                          MaxIndex = j
                      End If
                  Next j
    
                  ' If the index of the largest element is not i, then
                  ' exchange this element with element i.
                  If MaxIndex < i Then
                      TempArray(MaxIndex) = TempArray(i)
                      TempArray(i) = MaxVal
                  End If
              Next i
    
          End Function
    
          Sub SelectionSortMyArray()
              Dim TheArray As Variant
    
              ' Create the array.
              TheArray = Array("one", "two", "three", "four", "five", "six", _
                  "seven", "eight", "nine", "ten")
    
              ' Sort the Array and display the values in order.
              SelectionSort TheArray
              For i = 1 To UBound(TheArray)
                  MsgBox TheArray(i)
              Next i
    
          End Sub
    
    

  2. To run the macro, click Macro on the Tools menu. (In Microsoft Excel 97 or Microsoft Excel 98, click the Tools menu, point to Macro, and then click Macros.)

  3. Select the SelectionSortMyArray macro, and click Run.

Method 2: Bubble Sort

To perform a Bubble Sort, evaluate 1...n-1 elements in the array where you compare each element with the one after it (element 1 is compared to element 2, element 2 is compared to element 3, and so on). If an element is larger than the element after it, then those two elements are exchanged. Continue this process until there are no more exchanges of elements. Below is an example of a Bubble Sort with a Visual Basic Variant type array.

  1. Type the following in a module sheet:

          Option Base 1
    

          Function BubbleSort(TempArray As Variant)
    
              Dim Temp As Variant
              Dim i As Integer
              Dim NoExchanges As Integer
    
              ' Loop until no more "exchanges" are made.
              Do
                  NoExchanges = True
    
                  ' Loop through each element in the array.
                  For i = 1 To UBound(TempArray) - 1
    
                      ' If the element is greater than the element
                      ' following it, exchange the two elements.
                      If TempArray(i) > TempArray(i + 1) Then
                          NoExchanges = False
                          Temp = TempArray(i)
                          TempArray(i) = TempArray(i + 1)
                          TempArray(i + 1) = Temp
                      End If
                  Next i
              Loop While Not (NoExchanges)
    
          End Function
    
          Sub BubbleSortMyArray()
              Dim TheArray As Variant
    
              ' Create the array.
              TheArray = Array(15, 8, 11, 7, 33, 4, 46, 19, 20, 27, 43, 25, 36)
    
              ' Sort the Array and display the values in order.
              BubbleSort TheArray
              For i = 1 To UBound(TheArray)
                  MsgBox TheArray(i)
              Next i
          End Sub
    
    

  2. To run the macro, click Macro on the Tools menu. (In Microsoft Excel 97 or Microsoft Excel 98, click the Tools menu, point to Macro, and then click Macros.)

  3. Select the SelectionSortMyArray macro, and click Run.

MORE INFORMATION

NOTE: Both of these examples sort in ascending order. To perform a Selection Sort in descending order, change ">" to "<" in the following line of the SelectionSort function:

   If TempArray(j) > MaxVal Then

To perform a Bubble Sort in descending order, change ">" to a "<" in the following line of the BubbleSort function:

   If TempArray(i) > TempArray(i + 1) Then


Additional query words: 5.00 5.00a 5.00c 7.00 8.00 XL98 XL97 XL7 XL5
Keywords : kbcode kbprg PgmHowto
Version : WINDOWS:5.0,5.0c,7.0,97; MACINTOSH:5.0,5.0a,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.