ACC2000: Sample Function to Return a Random Record from a Field

ID: q210468


The information in this article applies to:

This article applies only to a Microsoft Access database (.mdb).

Moderate: Requires basic macro, coding, and interoperability skills.


SUMMARY

Microsoft Access does not have a built-in mechanism for returning a random record from a set of records. This article describes a sample user-defined function that you can use to return a random record.

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 professionals 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 a Microsoft Certified Solution Provider or the Microsoft fee-based consulting line at (800) 936-5200. For more information about Microsoft Certified Solution Providers, please see the following page on the World Wide Web:

http://www.microsoft.com/mcsp/
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/overview/overview.asp


MORE INFORMATION

The following sample function will return a random record using the recordset name and the field name that you provide.

NOTE: The sample code in this article uses Microsoft Data Access Objects. For this code to run properly, you need to reference the Microsoft DAO 3.6 Object Library.

Create a module and type the following line in the Declarations section if it is not already there:


Option Explicit 
Type the following procedure:

Function FindRandom (RecordSetName As String, Fieldname As String)

   Dim MyDB As Database
   Dim MyRS As Recordset
   Dim SpecificRecord As Long, i As Long, NumOfRecords As Long

   Set MyDB = CurrentDB()
   Set MyRS = MyDB.OpenRecordset(RecordSetName, dbOpenDynaset)
   On Error GoTo NoRecords
   MyRS.MoveLast
   NumOfRecords = MyRS.RecordCount
   SpecificRecord = Int(NumOfRecords * Rnd)
   If SpecificRecord = NumOfRecords Then
      SpecificRecord = SpecificRecord - 1
   End If
   MyRS.MoveFirst
   For i = 1 To SpecificRecord
      MyRS.MoveNext
   Next i
   FindRandom = MyRS(Fieldname)
   Exit Function

NoRecords:
   If Err = 3021 Then
      MsgBox "There Are No Records In The Dynaset", 16, "Error"
   Else
      MsgBox "Error - " & Err & Chr$(13) & Chr$(10) & Error, _
         16, "Error"
   End If
   FindRandom = "No Records"
   Exit Function

End Function 
To test this function, type the following line in the Immediate window, and then press ENTER:
?FindRandom("<RecordSetName>", "<FieldName>")
where <RecordSetName> is the name of a table or query or a SQL statement and <FieldName> is the name of a field in your recordset.

Note that each time that you run the function, a different record is returned.


REFERENCES

For additional information about using a query to return random records, please see the following articles in the Microsoft Knowledge Base:

Q208855 ACC2000: Find N Records in Random Order

Additional query words: inf


Keywords          : kbprg kbdta AccCon 
Version           : WINDOWS:2000
Platform          : WINDOWS 
Issue type        : kbhowto 

Last Reviewed: July 6, 1999