15.00 - MONTHS_BETWEEN - Teradata Database

Teradata Database SQL Functions, Operators, Expressions, and Predicates

Product
Teradata Database
Release Number
15.00
Content Type
Programming Reference
Publication ID
B035-1145-015K
Language
English (United States)

MONTHS_BETWEEN

Purpose  

Returns the number of months between date_timestamp_value1 and date_timestamp_value2.

Syntax  

where:

 

Syntax element …

Specifies …

TD_SYSFNLIB

the name of the database where the function is located.

date_timestamp_value1

a date or timestamp argument.

If data_timestamp_value1 is NULL, NULL is returned.

date_timestamp_value2

a date or timestamp argument.

If data_timestamp_value2 is NULL, NULL is returned.

ANSI Compliance

This is a Teradata extension to the ANSI SQL:2011 standard.

Invocation

MONTHS_BETWEEN is an embedded services system function. For information on activating and invoking embedded services functions, see “Embedded Services System Functions” on page 24.

Argument Types and Rules

Expressions passed to this function must have one of the following data types:

DATE, TIMESTAMP, or TIMESTAMP WITH TIME ZONE

The two argument to MONTHS_BETWEEN can be one of the above three data types, but the two arguments must be the same data type. For example, you cannot pass a DATE as the first parameter and a TIMESTAMP as the second parameter.

Since TIMESTAMP values are stored in UTC time within the database and lack a time zone, the session time zone is used to interpret the time stamp value within the function. For TIMESTAMP WITH TIME ZONE values, the time zone component is used to interpret the time stamp value within the function.

If date_timestamp_value2 is:

  • Later than date_timestamp_value1, the result is negative.
  • Earlier than date_timestamp_value1, the result is positive.
  • If date_timestamp_value1 and date_timestamp_value2 are either the same days of the month or both last days of months, the result is always an integer. Otherwise, MONTHS_BETWEEN calculates the fractional portion of the result based on a 31-day month and considers the difference in time components of date_timestamp_value1 and date_timestamp_value2. The Gregorian calendar is supported.

    Timestamps without a time zone are compared in the local time zone. This matters solely for the purpose of determining if two timestamps reside on the same day or are both the last day of a month. Timestamps with a time zone are converted to UTC before being compared in order to ensure the times are in the same zone.

    Result Type

    The return data type is NUMBER.

    Example  

    The following query:

    SELECT MONTHS_BETWEEN(DATE'1995-02-02', DATE'1995-01-01'); 

    returns the result 1.03225806451612903225806451612903225806. The MONTHS_BETWEEN function calculates the fractional portion of the result based on a 31-day month and considers the difference in time components of date_timestamp_value1 and date_timestamp_value2.

    Example  

    The following query:

    SELECT MONTHS_BETWEEN(DATE'2008-09-25', DATE'2008-09-25');

    returns the result 0.0 since date_timestamp_value1 and date_timestamp_value2 are both the same date.