Oracle® Database SQL Reference 10g Release 2 (10.2) Part Number B14200-01 |
|
|
View PDF |
Syntax
extract_datetime::=
Purpose
EXTRACT
extracts and returns the value of a specified datetime field from a datetime or interval value expression. When you extract a TIMEZONE_REGION
or TIMEZONE_ABBR
(abbreviation), the value returned is a string containing the appropriate time zone name or abbreviation. When you extract any of the other values, the value returned is in the Gregorian calendar. When extracting from a datetime with a time zone value, the value returned is in UTC. For a listing of time zone names and their corresponding abbreviations, query the V$TIMEZONE_NAMES
dynamic performance view.
This function can be very useful for manipulating datetime field values in very large tables, as shown in the first example below.
Note: Timezone region names are needed by the daylight savings feature. The region names are stored in two time zone files. The default time zone file is a small file containing only the most common time zones to maximize performance. If your time zone is not in the default file, then you will not have daylight savings support until you provide a path to the complete (larger) file by way of theORA_TZFILE environment variable. |
Some combinations of datetime field and datetime or interval value expression result in ambiguity. In these cases, Oracle Database returns UNKNOWN
(see the examples that follow for additional information).
The field you are extracting must be a field of the datetime_value_expr
or interval_value_expr
. For example, you can extract only YEAR
, MONTH
, and DAY
from a DATE
value. Likewise, you can extract TIMEZONE_HOUR
and TIMEZONE_MINUTE
only from the TIMESTAMP
WITH
TIME
ZONE
datatype.
See Also:
|
Examples
The following example returns from the oe.orders
table the number of orders placed in each month:
SELECT EXTRACT(month FROM order_date) "Month", COUNT(order_date) "No. of Orders" FROM orders GROUP BY EXTRACT(month FROM order_date) ORDER BY "No. of Orders" DESC; Month No. of Orders ---------- ------------- 11 15 7 14 6 14 3 11 5 10 9 9 2 9 8 7 10 6 1 5 12 4 4 1 12 rows selected.
The following example returns the year 1998.
SELECT EXTRACT(YEAR FROM DATE '1998-03-07') FROM DUAL; EXTRACT(YEARFROMDATE'1998-03-07') --------------------------------- 1998
The following example selects from the sample table hr.employees
all employees who were hired after 1998:
SELECT last_name, employee_id, hire_date FROM employees WHERE EXTRACT(YEAR FROM TO_DATE(hire_date, 'DD-MON-RR')) > 1998 ORDER BY hire_date; LAST_NAME EMPLOYEE_ID HIRE_DATE ------------------------- ----------- --------- Landry 127 14-JAN-99 Lorentz 107 07-FEB-99 Cabrio 187 07-FEB-99 . . .
The following example results in ambiguity, so Oracle returns UNKNOWN
:
SELECT EXTRACT(TIMEZONE_REGION FROM TIMESTAMP '1999-01-01 10:00:00 -08:00') FROM DUAL; EXTRACT(TIMEZONE_REGIONFROMTIMESTAMP'1999-01-0110:00:00-08:00') ---------------------------------------------------------------- UNKNOWN
The ambiguity arises because the time zone numerical offset is provided in the expression, and that numerical offset may map to more than one time zone region.