Sorting Allen Browne's Search Form

A

ablatnik

I am using Allen Browne's Search Form ---
http://allenbrowne.com/ser-62.html modified to my wishes and it works fine.
I want to have it sort numberically by it's ID Number. Currently it does not.


I can understand the concept of VBA instructions but not very good at writing
it.

What I'm asking is where would I put the Order by command? Will this be
nested within the Event Procedure that defines the search criteria or will
this be its own Event Procedure and if so where would I put it.?

I'm putting the code below.

'Purpose: This module illustrates how to create a search form, _
where the user can enter as many or few criteria as they wish, _
and results are shown one per line.
'Note: Only records matching ALL of the criteria are returned.
'Author: Allen Browne ([email protected]), June 2006.

Private Sub cmdFilter_Click()
'Purpose: Build up the criteria string form the non-blank search boxes,
and apply to the form's Filter.
'Notes: 1. We tack " AND " on the end of each condition so you can
easily add more search boxes; _
we remove the trailing " AND " at the end.
' 2. The date range works like this: _
Both dates = only dates between (both inclusive.
_
Start date only = all dates from this one onwards; _
End date only = all dates up to (and including this
one).
Dim strWhere As String 'The criteria string.
Dim lngLen As Long 'Length of the criteria string to
append to.
Const conJetDate = "\#mm\/dd\/yyyy\#" 'The format expected for dates in
a JET query string.

'***********************************************************************
'Look at each search box, and build up the criteria string from the non-
blank ones.
'***********************************************************************
'Text field example. Use quotes around the value in the string.
If Not IsNull(Me.txtFilterRoomLocation) Then
strWhere = strWhere & "([Room_Location] = """ & Me.
txtFilterRoomLocation & """) AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Task) Then
strWhere = strWhere & "([Requested Task] Like ""*" & Me.Task & "*"")
AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Buildings) Then
strWhere = strWhere & "([Building_Name] Like ""*" & Me.Buildings &
"*"") AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Department) Then
strWhere = strWhere & "([Department_Department] Like ""*" & Me.
Department & "*"") AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Status) Then
strWhere = strWhere & "([Status_Status] Like ""*" & Me.Status & "*"")
AND "
End If


'Date field example. Use the format string to add the # delimiters and
get the right international format.
If Not IsNull(Me.txtStartDate) Then
strWhere = strWhere & "([Date Opened] >= " & Format(Me.txtStartDate,
conJetDate) & ") AND "
End If

'Another date field example. Use "less than the next day" since this
field has times as well as dates.
If Not IsNull(Me.txtEndDate) Then 'Less than the next day.
strWhere = strWhere & "([Date Opened] < " & Format(Me.txtEndDate + 1,
conJetDate) & ") AND "
End If

'***********************************************************************
'Chop off the trailing " AND ", and use the string as the form's Filter.
'***********************************************************************
'See if the string has more than 5 characters (a trailng " AND ") to
remove.
lngLen = Len(strWhere) - 5
If lngLen <= 0 Then 'Nah: there was nothing in the string.
MsgBox "No criteria", vbInformation, "Nothing to do."
Else 'Yep: there is something there, so remove the "
AND " at the end.
strWhere = Left$(strWhere, lngLen)
'For debugging, remove the leading quote on the next line. Prints to
Immediate Window (Ctrl+G).
'Debug.Print strWhere

'Finally, apply the string as the form's Filter.
Me.Filter = strWhere
Me.FilterOn = True
End If
End Sub
 
A

Allen Browne

Couple of options:

a) Assign the form's OrderBy clause, like this:
Dim strOrderBy As String
strOrderBy = "SomeField, [Another Field]"
Me.OrderBy = strOrderBy
Me.OrderByOn = True

b) Build both the WHERE clause and the ORDER BY clause, and assign the whole
thing to to the form's RecordSource property instead of setting the Filter:
Const strcStub = "SELECT * FROM Table1 "
'build the strWhere and strOrderBy clauses here.
Me.RecordSource = strcStub & strWhere & strOrderBy

--
Allen Browne - Microsoft MVP. Perth, Western Australia

Reply to group, rather than allenbrowne at mvps dot org.

ablatnik said:
I am using Allen Browne's Search Form ---
http://allenbrowne.com/ser-62.html modified to my wishes and it works
fine.
I want to have it sort numberically by it's ID Number. Currently it does
not.


I can understand the concept of VBA instructions but not very good at
writing
it.

What I'm asking is where would I put the Order by command? Will this be
nested within the Event Procedure that defines the search criteria or will
this be its own Event Procedure and if so where would I put it.?

I'm putting the code below.

'Purpose: This module illustrates how to create a search form, _
where the user can enter as many or few criteria as they wish,
_
and results are shown one per line.
'Note: Only records matching ALL of the criteria are returned.
'Author: Allen Browne ([email protected]), June 2006.

Private Sub cmdFilter_Click()
'Purpose: Build up the criteria string form the non-blank search
boxes,
and apply to the form's Filter.
'Notes: 1. We tack " AND " on the end of each condition so you can
easily add more search boxes; _
we remove the trailing " AND " at the end.
' 2. The date range works like this: _
Both dates = only dates between (both
inclusive.
_
Start date only = all dates from this one onwards;
_
End date only = all dates up to (and including
this
one).
Dim strWhere As String 'The criteria string.
Dim lngLen As Long 'Length of the criteria string
to
append to.
Const conJetDate = "\#mm\/dd\/yyyy\#" 'The format expected for dates
in
a JET query string.


'***********************************************************************
'Look at each search box, and build up the criteria string from the
non-
blank ones.

'***********************************************************************
'Text field example. Use quotes around the value in the string.
If Not IsNull(Me.txtFilterRoomLocation) Then
strWhere = strWhere & "([Room_Location] = """ & Me.
txtFilterRoomLocation & """) AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Task) Then
strWhere = strWhere & "([Requested Task] Like ""*" & Me.Task &
"*"")
AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Buildings) Then
strWhere = strWhere & "([Building_Name] Like ""*" & Me.Buildings &
"*"") AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Department) Then
strWhere = strWhere & "([Department_Department] Like ""*" & Me.
Department & "*"") AND "
End If

'Another text field example. Use Like to find anywhere in the field.
If Not IsNull(Me.Status) Then
strWhere = strWhere & "([Status_Status] Like ""*" & Me.Status &
"*"")
AND "
End If


'Date field example. Use the format string to add the # delimiters and
get the right international format.
If Not IsNull(Me.txtStartDate) Then
strWhere = strWhere & "([Date Opened] >= " &
Format(Me.txtStartDate,
conJetDate) & ") AND "
End If

'Another date field example. Use "less than the next day" since this
field has times as well as dates.
If Not IsNull(Me.txtEndDate) Then 'Less than the next day.
strWhere = strWhere & "([Date Opened] < " & Format(Me.txtEndDate +
1,
conJetDate) & ") AND "
End If


'***********************************************************************
'Chop off the trailing " AND ", and use the string as the form's
Filter.

'***********************************************************************
'See if the string has more than 5 characters (a trailng " AND ") to
remove.
lngLen = Len(strWhere) - 5
If lngLen <= 0 Then 'Nah: there was nothing in the string.
MsgBox "No criteria", vbInformation, "Nothing to do."
Else 'Yep: there is something there, so remove the "
AND " at the end.
strWhere = Left$(strWhere, lngLen)
'For debugging, remove the leading quote on the next line. Prints
to
Immediate Window (Ctrl+G).
'Debug.Print strWhere

'Finally, apply the string as the form's Filter.
Me.Filter = strWhere
Me.FilterOn = True
End If
End Sub
 
A

ablatnik via AccessMonster.com

Thank you once again. I used the 1st option.

Allen said:
Couple of options:

a) Assign the form's OrderBy clause, like this:
Dim strOrderBy As String
strOrderBy = "SomeField, [Another Field]"
Me.OrderBy = strOrderBy
Me.OrderByOn = True

b) Build both the WHERE clause and the ORDER BY clause, and assign the whole
thing to to the form's RecordSource property instead of setting the Filter:
Const strcStub = "SELECT * FROM Table1 "
'build the strWhere and strOrderBy clauses here.
Me.RecordSource = strcStub & strWhere & strOrderBy
I am using Allen Browne's Search Form ---
http://allenbrowne.com/ser-62.html modified to my wishes and it works
[quoted text clipped - 120 lines]
End If
End Sub
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top