8.4. Date and Time Functions
8.4.1. CURRENT_DATE
Documented in Section 11.2, “CURRENT_DATE”.
8.4.2. CURRENT_TIME
Documented in Section 11.4, “CURRENT_TIME”.
8.4.3. CURRENT_TIMESTAMP
Documented in Section 11.5, “CURRENT_TIMESTAMP”.
8.4.4. DATEADD()
Available inDSQL, PSQL
Result typeDATE, TIME or TIMESTAMP
Syntax
DATEADD (<args>)
<args> ::=
<amount> <unit> TO <datetime>
| <unit>, <amount>, <datetime>
<amount> ::= an integer expression (negative to subtract)
<unit> ::=
YEAR | MONTH | WEEK | DAY
| HOUR | MINUTE | SECOND | MILLISECOND
<datetime> ::= a DATE, TIME or TIMESTAMP expression
DATEADD Function Parameters| Parameter | Description |
|---|---|
amount | An integer expression of the |
unit | Date/time unit |
datetime | An expression of the |
Adds the specified number of years, months, weeks, days, hours, minutes, seconds or milliseconds to a date/time value.
The result type is determined by the third argument.
With
TIMESTAMPandDATEarguments, all units can be used.With
TIMEarguments, onlyHOUR,MINUTE,SECONDandMILLISECONDcan be used.
8.4.4.1. Examples of DATEADD
dateadd (28 day to current_date)dateadd (-6 hour to current_time)dateadd (month, 9, DateOfConception)dateadd (-38 week to DateOfBirth)dateadd (minute, 90, time 'now')dateadd (? year to date '11-Sep-1973')
selectcast(dateadd(-1 * extract(millisecond from ts) millisecond to ts) as varchar(30)) as t,extract(millisecond from ts) as msfrom (select timestamp '2014-06-09 13:50:17.4971' as tsfrom rdb$database) a
T MS------------------------ ------2014-06-09 13:50:17.0000 497.1
See alsoSection 8.4.5, “DATEDIFF()”, Operations Using Date and Time Values
8.4.5. DATEDIFF()
Available inDSQL, PSQL
Result typeBIGINT, or — since Firebird 3.0.8 — NUMERIC(18,1) for MILLISECOND
Syntax
DATEDIFF (<args>)
<args> ::=
<unit> FROM <moment1> TO <moment2>
| <unit>, <moment1>, <moment2>
<unit> ::=
YEAR | MONTH | WEEK | DAY
| HOUR | MINUTE | SECOND | MILLISECOND
<momentN> ::= a DATE, TIME or TIMESTAMP expression
DATEDIFF Function Parameters| Parameter | Description |
|---|---|
unit | Date/time unit |
moment1 | An expression of the |
moment2 | An expression of the |
Returns the number of years, months, weeks, days, hours, minutes, seconds or milliseconds elapsed between two date/time values.
(The WEEK unit is new in 2.5.)
DATEandTIMESTAMParguments can be combined. No other mixes are allowed.With
TIMESTAMPandDATEarguments, all units can be used. (Prior to Firebird 2.5, units smaller thanDAYwere disallowed forDATEs.)With
TIMEarguments, onlyHOUR,MINUTE,SECONDandMILLISECONDcan be used.
DATEDIFFdoesn’t look at any smaller units than the one specified in the first argument. As a result,datediff (year, date '1-Jan-2009', date '31-Dec-2009')returns 0, butdatediff (year, date '31-Dec-2009', date '1-Jan-2010')returns 1
It does, however, look at all the bigger units. So:
datediff (day, date '26-Jun-1908', date '11-Sep-1973')returns 23818
A negative result value indicates that moment2 lies before moment1.
8.4.5.1. DATEDIFF Examples
datediff (hour from current_timestamp to timestamp '12-Jun-2059 06:00')datediff (minute from time '0:00' to current_time)datediff (month, current_date, date '1-1-1900')datediff (day from current_date to cast(? as date))
See alsoSection 8.4.4, “DATEADD()”, Operations Using Date and Time Values
8.4.6. EXTRACT()
Available inDSQL, ESQL, PSQL
Result typeSMALLINT or NUMERIC
Syntax
EXTRACT (<part> FROM <datetime>)
<part> ::=
YEAR | MONTH | WEEK
| DAY | WEEKDAY | YEARDAY
| HOUR | MINUTE | SECOND | MILLISECOND
<datetime> ::= a DATE, TIME or TIMESTAMP expression
EXTRACT Function Parameters| Parameter | Description |
|---|---|
part | Date/time unit |
datetime | An expression of the |
Extracts and returns an element from a DATE, TIME or TIMESTAMP expression.
This function was already added in InterBase 6, but not documented in the Language Reference at the time.
8.4.6.1. Returned Data Types and Ranges
The returned data types and possible ranges are shown in the table below.
If you try to extract a part that isn’t present in the date/time argument (e.g. SECOND from a DATE or YEAR from a TIME), an error occurs.
EXTRACT results| Part | Type | Range | Comment |
|---|---|---|---|
|
| 1-9999 |
|
|
| 1-12 |
|
|
| 1-53 |
|
|
| 1-31 |
|
|
| 0-6 | 0 = Sunday |
|
| 0-365 | 0 = January 1 |
|
| 0-23 |
|
|
| 0-59 |
|
|
| 0.0000-59.9999 | includes millisecond as fraction |
|
| 0.0-999.9 | broken in 2.1, 2.1.1 |
8.4.6.2. MILLISECOND
Firebird 2.1 and up support extraction of the millisecond from a TIME or TIMESTAMP.
The datatype returned is NUMERIC(9,1).
If you extract the millisecond from Section 11.4, “CURRENT_TIME”, be aware that this variable defaults to seconds precision, so the result will always be 0.
Extract from CURRENT_TIME(3) or Section 11.5, “CURRENT_TIMESTAMP” to get milliseconds precision.
8.4.6.3. WEEK
Firebird 2.1 and up support extraction of the ISO-8601 week number from a DATE or TIMESTAMP.
ISO-8601 weeks start on a Monday and always have the full seven days.
Week 1 is the first week that has a majority (at least 4) of its days in the new year.
The first 1-3 days of the year may belong to the last week (52 or 53) of the previous year.
Likewise, a year’s final 1-3 days may belong to week 1 of the following year.
Be careful when combining WEEK and YEAR results.
For instance, 30 December 2008 lies in week 1 of 2009, so extract(week from date '30 Dec 2008') returns 1.
However, extracting YEAR always gives the calendar year, which is 2008.
In this case, WEEK and YEAR are at odds with each other.
The same happens when the first days of January belong to the last week of the previous year.
Please also notice that WEEKDAY is not ISO-8601 compliant: it returns 0 for Sunday, whereas ISO-8601 specifies 7.
See alsoData Types for Dates and Times
8.4.7. LOCALTIME
Documented in Section 11.11, “LOCALTIME”.
8.4.8. LOCALTIMESTAMP
Documented in Section 11.12, “LOCALTIMESTAMP”.