ACC2000: How to Get the Fiscal Year or Month of a Particular Date

ID: q210249


The information in this article applies to:

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

This article applies to a Microsoft Access database (.mdb) and a Microsoft Access project (.adp).


SUMMARY

This article shows you how to get the fiscal year or fiscal month of a particular date by using an expression or a user-defined function.


MORE INFORMATION

Using an Expression to Get the Fiscal Year or Fiscal Month

NOTE: This section applies only to a Microsoft Access database (.mdb).

To get the fiscal year or fiscal month of a particular date by using an expression, follow these steps:
  1. Open the sample database Northwind.mdb.


  2. Create the following new query based on the Orders table.

    NOTE: In the following sample expressions, an underscore (_) at the end of a line is used as a line-continuation character. Remove the underscore from the end of the line when re-creating these sample expressions.


  3. 
       Query: GetFiscalDates
       -------------------------------------------------------------------
       Field: OrderDate
          Table: Orders
          Criteria: DatePart("yyyy",[OrderDate])=1997
       Field: FYear: Year([OrderDate])-IIf([OrderDate]< _
                DateSerial(Year([OrderDate]),6,16),1,0)
       Field: FMonth: (Month([OrderDate])+IIf(Day([OrderDate])<16,6,7)-1) _
                      Mod 12+1 
  4. Run the query, and then scroll through the query datasheet. Note that the fiscal year and fiscal month appear for each record in the Orders table.


You can use the FYear and FMonth expressions in your database by modifying the Date field, the day and the month, to the appropriate values for your fiscal year. For example, if the fiscal year begins on 9/15 of the current calendar year, you can modify the previous expressions as follows:

   Field: FYear: Year([FieldName])-IIf([FieldName]< _
            DateSerial(Year([FieldName]),9,15),1,0)

   Field: FMonth: (Month([FieldName])+IIf(Day([FieldName])<15,9,10)-1) _
            Mod 12+1 
If the fiscal year begins on 9/15 of the previous calendar year, you can modify the FYear expression as follows:

   Field: FYear: Year([FieldName])-IIf([FieldName]< _
            DateSerial(Year([FieldName]),9,15),1,0)+1 

Using Sample Functions to Get the Fiscal Year or Fiscal Month

NOTE: This section applies to a Microsoft Access database (.mdb) and a Microsoft Access project (.adp).

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
To get the fiscal year or fiscal month of a particular date by using user defined functions, follow these steps:
  1. Create a module and type the following lines in the Declarations section:


  2. 
    Option Explicit
    Const FMonthStart = 6   ' Numeric value representing the first month
                            ' of the fiscal year.
    Const FDayStart = 16    ' Numeric value representing the first day of
                            ' the fiscal year.
    Const FYearOffset = -1  ' 0 means the fiscal year starts in the
                            ' current calendar year.
                            ' -1 means the fiscal year starts in the
                            ' previous calendar year. 
  3. Type the following two procedures:


  4. 
    Function GetFiscalYear(ByVal x As Variant)
       If x < DateSerial(Year(x), FMonthStart, FDayStart) Then
          GetFiscalYear = Year(x) - FYearOffset - 1
       Else
          GetFiscalYear = Year(x) - FYearOffset
       End If
    End Function 
    
    Function GetFiscalMonth(ByVal x As Variant)
       Dim m
       m = Month(x) - FMonthStart + 1
       If Day(x) < FDayStart Then m = m - 1
       If m < 1 Then m = m + 12
       GetFiscalMonth = m
    End Function 
  5. To test these functions, type each of the following lines in the Immediate window, and then press ENTER after each one:
    
    ?GetFiscalYear(#7/1/1999#) 
    Note that this line returns the year 2000.
    
    ?GetFiscalMonth(#8/1/1999#) 
    Note that this line returns the number 2. The 2 represents the second month in the fiscal year.



REFERENCES

For more information about the DateSerial function, click Microsoft Access Help on the Help menu, type "DateSerial, Day, Month, and Year function examples" in the Office Assistant or the Answer Wizard, and then click Search to view the topic.

Additional query words:


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

Last Reviewed: July 6, 1999