ACC2000: How to Find Minimum or Maximum Value Across Fields of Record (209857)



The information in this article applies to:

  • Microsoft Access 2000

This article was previously published under Q209857
Advanced: Requires expert coding, interoperability, and multiuser skills.

SUMMARY

Microsoft Access has no built-in functions that find the maximum or minimum values of numbers across the fields of a record. This article provides two custom functions that cycle through the values across fields and return the minimum or maximum values of each record.

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. CAUTION: If you follow the steps in this example, you modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and follow these steps on a copy of the database.

Follow these steps to create and implement Visual Basic for Applications procedures that find the minimum or maximum values:

  1. Open the sample database Northwind.mdb.
  2. Create a new module and enter the following two functions:
    Function Minimum(ParamArray FieldArray() As Variant)
       ' Declare the two local variables.
       Dim I As Integer
       Dim currentVal As Variant
    
       ' Set the variable currentVal equal to the array of values.
       currentVal = FieldArray(0)
    
       ' Cycle through each value from the row to find the smallest.
       For I = 0 To UBound(FieldArray)
          If FieldArray(I) < currentVal  Then
             currentVal = FieldArray(I)
          End If
       Next I
    
       ' Return the minimum value found.
       Minimum = currentVal
    
    End Function
    
    Function Maximum(ParamArray FieldArray() As Variant)
       ' Declare the two local variables.
       Dim I As Integer
       Dim currentVal As Variant
    
       ' Set the variable currentVal equal to the array of values.
       currentVal = FieldArray(0)
    
       ' Cycle through each value from the row to find the largest.
    
       For I = 0 To UBound(FieldArray)
          If FieldArray(I) > currentVal Then
             currentVal = FieldArray(I)
          End If
       Next I
    
       ' Return the maximum value found.
       Maximum = currentVal
    
    End Function
    					
  3. On the Debug menu, click Compile Northwind.
  4. On the File menu, click Close and Return to Microsoft Access.
  5. Create the following table named tblMinMax:
       Table: tblMinMax
       ---------------------------
       Field Name: Field1
       Data Type: Number
       Field Size: Long Integer
    
       Field Name: Field2
       Data Type: Number
       Field Size: Long Integer
    
       Field Name: Field3
       Data Type: Number
       Field Size: Long Integer
    					
  6. Save the table as tblMinMax. When prompted to create a primary key, click No.
  7. Switch the tblMinMax table to Datasheet view and enter the following values:
       Field1    Field2    Field3
       ------    ------    ------
       50        30        40
       40        50        30
       30        40        50
    					
  8. Create a new query based on the tblMinMax table and drag Field1, Field2, and Field3 to the query grid.
  9. In the fourth column of the query grid, enter the following:

    Minimum Value: Minimum([Field1],[Field2],[Field3])

  10. In the fifth column of the query grid, enter the following:

    Maximum Value: Maximum([Field1],[Field2],[Field3])

  11. Run the query. Note that the fourth and fifth columns contain the minimum and maximum values.

REFERENCES

For more information about creating custom functions, in the Visual Basic Editor, click Microsoft Visual Basic Help on the Help menu, type custom functions in the Office Assistant or the Answer Wizard, and then click Search to view the topic.

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto kbProgramming KB209857