Notice: This website is an unofficial Microsoft Knowledge Base (hereinafter KB) archive and is intended to provide a reliable access to deleted content from Microsoft KB. All KB articles are owned by Microsoft Corporation. Read full disclaimer for more details.

How to use code to derive a statistical median


View products that this article applies to.

Summary

This article shows you how to create a Visual Basic for Applications procedure to open a table, read the data, and find the statistical median. The median is a measure of central tendency, another "middle" measurement of a data set, like the mean or average). The data set consisting of the numbers 1, 2, 3, 6, and 100 has a median of 3, the middle of the set. The data set consisting of the numbers 1, 2, 6, and 10 has a median of 4, the middle of the set [(2 + 6) / 2 = 4].

↑ Back to the top


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. However, they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. Note The sample code in this article uses Microsoft Data Access Objects. For this code to run correctly, you must reference the Microsoft DAO 3.6 Object Library. To do so, click References on the Tools menu in the Visual Basic Editor, and make sure that the Microsoft DAO 3.6 Object Library check box is selected. To create a procedure that determines the statistical median of a set of numbers, follow these steps:
  1. Create a module and type the following line in the Declarations section:
    Option Explicit
  2. Type or paste the following procedure.
    Function Median (tName As String, fldName As String) As Single
      Dim MedianDB As DAO.Database
      Dim ssMedian As DAO.Recordset
      Dim RCount As Integer, i As Integer, x As Double, y As Double, _
          OffSet As Integer
      Set MedianDB = CurrentDB()
      Set ssMedian = MedianDB.Openrecordset("SELECT [" & fldName & _
                "] FROM [" & tName & "] WHERE [" & fldName & _ 
                "] IS NOT NULL ORDER BY [" & fldName  & "];")
      'NOTE: To include nulls when calculating the median value, omit
      'WHERE [" & fldName & "] IS NOT NULL from the example.
      ssMedian.MoveLast
      RCount% = ssMedian.RecordCount
      x = RCount Mod 2
      If x <> 0 Then
         OffSet = ((RCount + 1) / 2) - 2
         For i% = 0 To OffSet
            ssMedian.MovePrevious
         Next i
         Median = ssMedian(fldName)
      Else
         OffSet = (RCount / 2) - 2
         For i = 0 To OffSet
            ssMedian.MovePrevious
         Next i
         x = ssMedian(fldName)
         ssMedian.MovePrevious
         y = ssMedian(fldName)
         Median = (x + y) / 2
      End If
      If Not ssMedian Is Nothing Then
         ssMedian.Close
         Set ssMedian = Nothing
      End If
      Set MedianDB = Nothing
    End Function
    

How to Use the Median() Function

Create a form and add a text box control where you want to display the median values of a data set. Set the ControlSource property of the text box control to the following:
=Median("<TableName>", "<FieldName>")
				
The value of this control is the median of the data set. Another way to use this function is to call it from within another function that compares the median from different data sets. For example:
   Function CompareMedians()
      Dim MyDB as Database
      .
      .
      .
      X = Median("<TableName>", "<FieldName>")
      Y = Median("<TableName>", "<FieldName>")
      If X > Y Then Debug.Print "The median for X is greatest."
   End Function
				

↑ Back to the top


Keywords: KB210581, kbprogramming, kbhowto

↑ Back to the top

Article Info
Article ID : 210581
Revision : 4
Created on : 12/12/2007
Published on : 12/12/2007
Exists online : False
Views : 332