ACC2000: Functions for Calculating and Displaying Date/Time Values

ID: Q210604


The information in this article applies to:
  • Microsoft Access 2000

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


SUMMARY

Because a Date/Time value is stored as a double-precision number, you may receive incorrect formatting results when you try to manipulate Date/Time values in an expression. This article demonstrates how to create expressions and custom functions for displaying specific dates and for calculating time intervals.

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

Displaying Specific Dates

To display specific dates, you can use the DateSerial() function to manipulate the day, month, and year portions of a date. For example, you can use the following expressions in the ControlSource property of a text box or in the Immediate window to return specific dates:
  • The current month:


  • DateSerial(Year(Date()), Month(Date()), 1)
  • The next month:


  • DateSerial(Year(Date()), Month(Date()) + 1, 1)
  • The last day of the current month:


  • DateSerial(Year(Date()), Month(Date()) + 1, 0)
  • The last day of the next month:


  • DateSerial(Year(Date()), Month(Date()) + 2, 0)
  • The first day of the previous month:


  • DateSerial(Year(Date()), Month(Date())-1,1)
  • The last day of the previous month:


  • DateSerial(Year(Date()), Month(Date()),0)
  • The first day of the current quarter:


  • DateSerial(Year(Date()), Int((Month(Date()) - 1) / 3) * 3 + 1, 1)
  • The last day of the current quarter:


  • DateSerial(Year(Date()), Int((Month(Date()) - 1) / 3) * 3 + 4, 0)
  • The first day of the current week (assuming Sunday = day 1):


  • Date() - WeekDay(Date()) + 1
  • The last day of the current week:


  • Date() - WeekDay(Date()) + 7
  • The first day of the current week (using settings in Options dialog box):


  • Date() - WeekDay(Date(), 0) + 1
  • The last day of the current week:


  • Date() - WeekDay(Date(), 0) + 7
For additional information about calculating the fiscal year or fiscal month, please see the following article in the Microsoft Knowledge Base:
Q210249 ACC2000: How to Get the Fiscal Year/Month of a Particular Date
CAUTION: Following the steps in this example will modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and perform these steps on a copy of the database.

Calculating Time Intervals

Because a time value is stored as a fraction of a 24-hour day, you may receive incorrect formatting results when you try to add, subtract, multiply or divide time data greater than 24 hours.

For example, if you try to find the number of hours elapsed between two dates by subtracting the values in Visual Basic, you may receive an incorrect number. To demonstrate this, type the following code in the Immediate window and note that it returns a value of 05:00 hours rather than the correct value of 53:00 hours:

   StartDate=#6/1/93 8:00AM#
   EndDate=#6/3/93 1:00PM#
   ?Format(EndDate-StartDate,"hh:mm") 

To resolve formatting problems caused by time values greater than 24 hours, you can use the Int() and CSng() functions in Visual Basic to separate a calculated time value into different variables for days, hours, minutes, and seconds. For example, you can include the following code fragment in a custom function to create separate time variables:

 '-------------------------------------------------------------------
 ' This sample code separates a time interval into seven variables for
 ' the following values: days, hours, minutes, seconds, total time in
 ' hours, total time in minutes, and total time in seconds.
 '
 ' The interval argument is flexible; it can be a single value, an
 ' expression, or a field reference.
 '-------------------------------------------------------------------

 Dim totalhours As Long, totalminutes As Long, totalseconds As Long
 Dim days As Long, hours As Long, minutes As Long, seconds As Long
 Dim interval As Variant

 days = Int(CSng(interval))
 totalhours = Int(CSng(interval * 24))
 totalminutes = Int(CSng(interval * 1440))
 totalseconds = Int(CSng(interval * 86400))
 hours = totalhours Mod 24
 minutes = totalminutes Mod 60
 seconds = totalseconds Mod 60 

You can use the totalhours, totalminutes, and totalseconds variables to display a time value as a single unit of time. The days, hours, minutes, and seconds variables enable you to break down a time value into portions of time. To display time values in different formats, you can concatenate these variables as demonstrated in the following sample functions:
  • The GetElapsedDays() function calculates the elapsed time between two date/time values and displays the result in days.


  • The GetElapsedTime() function calculates the elapsed time between time values and displays the result in days, hours, minutes, and seconds.


  • The GetTimeCardTotal() function sums a field of time values in a table and displays the total in hours and minutes.


GetElapsedDays() Sample Function

To create the GetElapsedDays() function, follow these steps:
  1. Open the sample database Northwind.mdb.


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


  3. 
     Option Explicit 
  4. Type the following function:


  5. 
     Function GetElapsedDays (interval)
        Dim days As Long
    
        days = Int(CSng(interval))
        GetElapsedDays = days & " Days "
     End Function 
  6. To test this function, create a new query based on the Orders table.


  7. In the QBE grid, add the following fields.


  8. 
        Field: ShippedDate
        Show: True
    
        Field: OrderDate
        Show: True
    
        Field: ElapsedTime: GetElapsedDays([ShippedDate]-[OrderDate])
        Show: True 
  9. Run the query. Note that the ElapsedTime column displays the number of days between the ShippedDate field and OrderDate field for each record in the Orders table.


GetElapsedTime() Sample Function

To create the GetElapsedTime() function, follow these steps:
  1. Create a new table with the following structure and save it as TimeLog.


  2. 
        Table: TimeLog
        -----------------------
        Field Name: StartTime
        Data Type: Date/Time
        Format: General Date
    
        Field Name: EndTime
        Data Type: Date/Time
        Format: General Date 
  3. View the TimeLog table in Datasheet view, enter the following three records, and then close the table:


  4. 
        StartTime                 EndTime
        --------------------------------------------
        5/10/95 4:57:00  PM       5/15/95 2:38:00 AM
        5/11/95 10:17:31 AM       5/24/95 6:05:00 PM
        5/18/95 9:16:43  AM       5/19/95 5:03:00 PM 
  5. Create a module and type the following line in the Declarations section:


  6. 
     Option Explicit 
  7. Enter the following function:
    
     Function GetElapsedTime(interval)
    
     Dim totalhours As Long, totalminutes As Long, totalseconds As _
         Long
     Dim days As Long, hours As Long, Minutes As Long, Seconds As Long
    
     days = Int(CSng(interval))
     totalhours = Int(CSng(interval * 24))
     totalminutes = Int(CSng(interval * 1440))
     totalseconds = Int(CSng(interval * 86400))
     hours = totalhours Mod 24
     Minutes = totalminutes Mod 60
     Seconds = totalseconds Mod 60
    
     GetElapsedTime = days & " Days " & hours & " Hours " & Minutes & _
     " Minutes " & Seconds & " Seconds "
    
     End Function 

    NOTE: The GetElapsedTime function requires that you pass it a date and a time.


  8. To test this function, create a new report based on the TimeLog table using the AutoReport Wizard.


  9. View the report in Design view.


  10. Add an unbound text box to the TimeLog table's detail section and set its properties as follows:


  11. 
        Textbox
        ---------------
        Name: ElapsedTime
        ControlSource: =GetElapsedTime([EndTime]-[StartTime])
        Width: 3 inches 
  12. Preview the report. Note that each record displays the total elapsed time in days, hours, minutes, and seconds.


GetTimeCardTotal() Sample Function

To create the GetTimeCardTotal() function, follow these steps:
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.

  1. Create a new table with the following structure and save it as TimeCard.


  2. 
        Table: TimeCard
        -----------------------
        Field Name: Daily Hours
        Data Type: Date/Time
        Format: Short Time 
  3. View the TimeCard table in Datasheet view, enter the following four records, and then close the table:


  4. 
        8:15
        7:37
        8:12
        8:03 
  5. Create a module and type the following line in the Declarations section if it's not already there:


  6. 
     Option Explicit 
  7. Type the following function:


  8. 
     Function GetTimeCardTotal ()
    
     Dim db As DAO.Database, rs As DAO.Recordset
     Dim totalhours As Long, totalminutes As Long
     Dim days As Long, hours As Long, minutes As Long
     Dim interval As Variant, j As Integer
    
     Set db = dbengine.workspaces(0).databases(0)
     Set rs = db.OpenRecordset("timecard")
     interval = #12:00:00 AM#
        While Not rs.EOF
           interval = interval + rs![Daily hours]
           rs.MoveNext
        Wend
     totalhours = Int(CSng(interval * 24))
     totalminutes = Int(CSng(interval * 1440))
     hours = totalhours Mod 24
     minutes = totalminutes Mod 60
    
     GetTimeCardTotal = totalhours & " hours and " & minutes & " minutes"
    
     End Function 
  9. To test this function, type the following line in the Immediate Window, and then press ENTER:
    
     ?GetTimeCardTotal() 

    Note that the Immediate Window displays 32 hours and 7 minutes.



REFERENCES

For additional information about calculating date/time values, please see the following article(s) in the Microsoft Knowledge Base:

Q210276 ACC2000: Storing, Calculating, and Comparing Date/Time Data

Additional query words: fractional

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


Last Reviewed: September 10, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.