To create a query that returns the data from the previous month based on
the current date, use the
Between...And operator with the
DateSerial() function in the
Criteria of the Date field. The
DateSerial() function returns a date for a specified year, month, and day. The syntax of the
DateSerial() function is:
DateSerial(year, month, day)
The following example returns all records from the Orders table of the
sample database Northwind.mdb in which the value in the ShippedDate field
falls within the previous month.
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.
- Start Microsoft Access and open the sample database, Northwind.mdb.
- Open the Orders table in Datasheet view.
- Click in the ShippedDate field.
- On the Records menu, point to Sort and click Sort Ascending.
- In several of the records in which the ShippedDate field is empty,
enter dates that fall within the previous month.
- Close the Orders table.
- Create the following query based on the Orders table:
Query: qryLastMonth
---------------------------------------------------------
Type: Select Query
Field: OrderID
Table: Orders
Field: OrderDate
Table: Orders
Field: RequiredDate
Table: Orders
Field: ShippedDate
Table: Orders
Criteria: Between DateSerial(Year(Date()),Month(Date())-1,1) And
DateSerial(Year(Date()),Month(Date()),0)
- Save the query as qryLastMonth.
- Run the qryLastMonth query. Note that it returns only the records that you changed in step 5.
In this example, the
DateSerial() function automatically handles the
change in the year. In the expression in the
Criteria of the ShippedDate field, the second instance of the
DateSerial() function sets the
day argument to zero. Therefore, the expression returns the last day of the previous month. For example:
DateSerial(97,1,0)
returns
12/31/96.