Provided by Allen Browne. Last updated: April 2010.
There is a very simple way to number records sequentially on a report. It always works regardless how the report is sorted or filtered.
With your report open in Design View:
Control Source | =1 | |
Running Sum | Over Group |
That's it! This text box will automatically increment with each record.
Casual users sometimes want to number records in a form as well, e.g. to save the number of a record so as to return there later. Don't do it! Although Access does show "Record xx of yy" in the lower left ofthe form, this number can change for any number of reasons, such as:
In relational database theory, the records in a table cannot have any physical order, so record numbers represent faulty thinking. In place of record numbers, Access uses the Primary Key of the table, or the Bookmark of a recordset. If you are accustomed from another database and find it difficult to conceive of life without record numbers, check out What, no record numbers?
You still want to refer to the number of a record in a form as currently filtered and sorted? There are ways to do so. In Access 97 or later, use the form's CurrentRecord property, by adding a text box with this expression in the ControlSource property:
=[Form].[CurrentRecord]
In Access 2, open your form in Design View in design view and follow these steps:
On Error GoTo Err_Form_Current
Dim rst As Recordset
Set rst = Me.RecordsetClone
rst.Bookmark = Me.Bookmark
Me.txtPosition = rst.AbsolutePosition + 1
Exit_Form_Current:
Set rst = Nothing
Exit Sub
Err_Form_Current:
If Err = 3021 Then 'No current record
Me.txtPosition = rst.RecordCount + 1
Else
MsgBox Error$, 16, "Error in Form_Current()"
End If
Resume Exit_Form_Current
The text box will now show a number matching the one between the NavigationButtons on your form.
For details of how to rank records in a query, see Ranking in a Query
Home | Index of tips | Top |