Commit a2da77cd authored by Peter Eisentraut's avatar Peter Eisentraut

Change return type of EXTRACT to numeric

The previous implementation of EXTRACT mapped internally to
date_part(), which returned type double precision (since it was
implemented long before the numeric type existed).  This can lead to
imprecise output in some cases, so returning numeric would be
preferrable.  Changing the return type of an existing function is a
bit risky, so instead we do the following:  We implement a new set of
functions, which are now called "extract", in parallel to the existing
date_part functions.  They work the same way internally but use
numeric instead of float8.  The EXTRACT construct is now mapped by the
parser to these new extract functions.  That way, dumps of views
etc. from old versions (which would use date_part) continue to work
unchanged, but new uses will map to the new extract functions.

Additionally, the reverse compilation of EXTRACT now reproduces the
original syntax, using the new mechanism introduced in
40c24bfe.

The following minor changes of behavior result from the new
implementation:

- The column name from an isolated EXTRACT call is now "extract"
  instead of "date_part".

- Extract from date now rejects inappropriate field names such as
  HOUR.  It was previously mapped internally to extract from
  timestamp, so it would silently accept everything appropriate for
  timestamp.

- Return values when extracting fields with possibly fractional
  values, such as second and epoch, now have the full scale that the
  value has internally (so, for example, '1.000000' instead of just
  '1').
Reported-by: default avatarPetr Fedorov <petr.fedorov@phystech.edu>
Reviewed-by: default avatarTom Lane <tgl@sss.pgh.pa.us>
Discussion: https://www.postgresql.org/message-id/flat/42b73d2d-da12-ba9f-570a-420e0cce19d9@phystech.edu
parent f5d94e40
...@@ -8872,7 +8872,7 @@ SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}'); ...@@ -8872,7 +8872,7 @@ SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
<primary>extract</primary> <primary>extract</primary>
</indexterm> </indexterm>
<function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> ) <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> )
<returnvalue>double precision</returnvalue> <returnvalue>numeric</returnvalue>
</para> </para>
<para> <para>
Get timestamp subfield; see <xref linkend="functions-datetime-extract"/> Get timestamp subfield; see <xref linkend="functions-datetime-extract"/>
...@@ -8886,7 +8886,7 @@ SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}'); ...@@ -8886,7 +8886,7 @@ SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
<row> <row>
<entry role="func_table_entry"><para role="func_signature"> <entry role="func_table_entry"><para role="func_signature">
<function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> ) <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> )
<returnvalue>double precision</returnvalue> <returnvalue>numeric</returnvalue>
</para> </para>
<para> <para>
Get interval subfield; see <xref linkend="functions-datetime-extract"/> Get interval subfield; see <xref linkend="functions-datetime-extract"/>
...@@ -9401,7 +9401,7 @@ EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>) ...@@ -9401,7 +9401,7 @@ EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
well.) <replaceable>field</replaceable> is an identifier or well.) <replaceable>field</replaceable> is an identifier or
string that selects what field to extract from the source value. string that selects what field to extract from the source value.
The <function>extract</function> function returns values of type The <function>extract</function> function returns values of type
<type>double precision</type>. <type>numeric</type>.
The following are valid field names: The following are valid field names:
<!-- alphabetical --> <!-- alphabetical -->
...@@ -9825,6 +9825,10 @@ date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>) ...@@ -9825,6 +9825,10 @@ date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
be a string value, not a name. The valid field names for be a string value, not a name. The valid field names for
<function>date_part</function> are the same as for <function>date_part</function> are the same as for
<function>extract</function>. <function>extract</function>.
For historical reasons, the <function>date_part</function> function
returns values of type <type>double precision</type>. This can result in
a loss of precision in certain uses. Using <function>extract</function>
is recommended instead.
</para> </para>
<screen> <screen>
......
...@@ -14020,7 +14020,7 @@ func_expr_common_subexpr: ...@@ -14020,7 +14020,7 @@ func_expr_common_subexpr:
{ $$ = makeTypeCast($3, $5, @1); } { $$ = makeTypeCast($3, $5, @1); }
| EXTRACT '(' extract_list ')' | EXTRACT '(' extract_list ')'
{ {
$$ = (Node *) makeFuncCall(SystemFuncName("date_part"), $$ = (Node *) makeFuncCall(SystemFuncName("extract"),
$3, $3,
COERCE_SQL_SYNTAX, COERCE_SQL_SYNTAX,
@1); @1);
......
This diff is collapsed.
...@@ -4092,6 +4092,67 @@ int64_to_numeric(int64 val) ...@@ -4092,6 +4092,67 @@ int64_to_numeric(int64 val)
return res; return res;
} }
/*
* Convert val1/(10**val2) to numeric. This is much faster than normal
* numeric division.
*/
Numeric
int64_div_fast_to_numeric(int64 val1, int log10val2)
{
Numeric res;
NumericVar result;
int64 saved_val1 = val1;
int w;
int m;
/* how much to decrease the weight by */
w = log10val2 / DEC_DIGITS;
/* how much is left */
m = log10val2 % DEC_DIGITS;
/*
* If there is anything left, multiply the dividend by what's left, then
* shift the weight by one more.
*/
if (m > 0)
{
static int pow10[] = {1, 10, 100, 1000};
StaticAssertStmt(lengthof(pow10) == DEC_DIGITS, "mismatch with DEC_DIGITS");
if (unlikely(pg_mul_s64_overflow(val1, pow10[DEC_DIGITS - m], &val1)))
{
/*
* If it doesn't fit, do the whole computation in numeric the slow
* way. Note that va1l may have been overwritten, so use
* saved_val1 instead.
*/
int val2 = 1;
for (int i = 0; i < log10val2; i++)
val2 *= 10;
res = numeric_div_opt_error(int64_to_numeric(saved_val1), int64_to_numeric(val2), NULL);
res = DatumGetNumeric(DirectFunctionCall2(numeric_round,
NumericGetDatum(res),
Int32GetDatum(log10val2)));
return res;
}
w++;
}
init_var(&result);
int64_to_numericvar(val1, &result);
result.weight -= w;
result.dscale += w * DEC_DIGITS - (DEC_DIGITS - m);
res = make_result(&result);
free_var(&result);
return res;
}
Datum Datum
int4_numeric(PG_FUNCTION_ARGS) int4_numeric(PG_FUNCTION_ARGS)
{ {
......
...@@ -9782,6 +9782,27 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context) ...@@ -9782,6 +9782,27 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
appendStringInfoString(buf, "))"); appendStringInfoString(buf, "))");
return true; return true;
case F_EXTRACT_TEXT_DATE:
case F_EXTRACT_TEXT_TIME:
case F_EXTRACT_TEXT_TIMETZ:
case F_EXTRACT_TEXT_TIMESTAMP:
case F_EXTRACT_TEXT_TIMESTAMPTZ:
case F_EXTRACT_TEXT_INTERVAL:
/* EXTRACT (x FROM y) */
appendStringInfoString(buf, "EXTRACT(");
{
Const *con = (Const *) linitial(expr->args);
Assert(IsA(con, Const) &&
con->consttype == TEXTOID &&
!con->constisnull);
appendStringInfoString(buf, TextDatumGetCString(con->constvalue));
}
appendStringInfoString(buf, " FROM ");
get_rule_expr((Node *) lsecond(expr->args), context, false);
appendStringInfoChar(buf, ')');
return true;
case F_IS_NORMALIZED: case F_IS_NORMALIZED:
/* IS xxx NORMALIZED */ /* IS xxx NORMALIZED */
appendStringInfoString(buf, "(("); appendStringInfoString(buf, "((");
......
This diff is collapsed.
...@@ -53,6 +53,6 @@ ...@@ -53,6 +53,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 202104061 #define CATALOG_VERSION_NO 202104062
#endif #endif
...@@ -2339,9 +2339,15 @@ ...@@ -2339,9 +2339,15 @@
{ oid => '1171', descr => 'extract field from timestamp with time zone', { oid => '1171', descr => 'extract field from timestamp with time zone',
proname => 'date_part', provolatile => 's', prorettype => 'float8', proname => 'date_part', provolatile => 's', prorettype => 'float8',
proargtypes => 'text timestamptz', prosrc => 'timestamptz_part' }, proargtypes => 'text timestamptz', prosrc => 'timestamptz_part' },
{ oid => '9983', descr => 'extract field from timestamp with time zone',
proname => 'extract', provolatile => 's', prorettype => 'numeric',
proargtypes => 'text timestamptz', prosrc => 'extract_timestamptz' },
{ oid => '1172', descr => 'extract field from interval', { oid => '1172', descr => 'extract field from interval',
proname => 'date_part', prorettype => 'float8', proname => 'date_part', prorettype => 'float8',
proargtypes => 'text interval', prosrc => 'interval_part' }, proargtypes => 'text interval', prosrc => 'interval_part' },
{ oid => '9984', descr => 'extract field from interval',
proname => 'extract', prorettype => 'numeric', proargtypes => 'text interval',
prosrc => 'extract_interval' },
{ oid => '1174', descr => 'convert date to timestamp with time zone', { oid => '1174', descr => 'convert date to timestamp with time zone',
proname => 'timestamptz', provolatile => 's', prorettype => 'timestamptz', proname => 'timestamptz', provolatile => 's', prorettype => 'timestamptz',
proargtypes => 'date', prosrc => 'date_timestamptz' }, proargtypes => 'date', prosrc => 'date_timestamptz' },
...@@ -2489,6 +2495,9 @@ ...@@ -2489,6 +2495,9 @@
{ oid => '1273', descr => 'extract field from time with time zone', { oid => '1273', descr => 'extract field from time with time zone',
proname => 'date_part', prorettype => 'float8', proargtypes => 'text timetz', proname => 'date_part', prorettype => 'float8', proargtypes => 'text timetz',
prosrc => 'timetz_part' }, prosrc => 'timetz_part' },
{ oid => '9981', descr => 'extract field from time with time zone',
proname => 'extract', prorettype => 'numeric', proargtypes => 'text timetz',
prosrc => 'extract_timetz' },
{ oid => '1274', { oid => '1274',
proname => 'int84pl', prorettype => 'int8', proargtypes => 'int8 int4', proname => 'int84pl', prorettype => 'int8', proargtypes => 'int8 int4',
prosrc => 'int84pl' }, prosrc => 'int84pl' },
...@@ -2834,9 +2843,15 @@ ...@@ -2834,9 +2843,15 @@
proname => 'date_part', prolang => 'sql', prorettype => 'float8', proname => 'date_part', prolang => 'sql', prorettype => 'float8',
proargtypes => 'text date', proargtypes => 'text date',
prosrc => 'select pg_catalog.date_part($1, cast($2 as timestamp without time zone))' }, prosrc => 'select pg_catalog.date_part($1, cast($2 as timestamp without time zone))' },
{ oid => '9979', descr => 'extract field from date',
proname => 'extract', prorettype => 'numeric', proargtypes => 'text date',
prosrc => 'extract_date' },
{ oid => '1385', descr => 'extract field from time', { oid => '1385', descr => 'extract field from time',
proname => 'date_part', prorettype => 'float8', proargtypes => 'text time', proname => 'date_part', prorettype => 'float8', proargtypes => 'text time',
prosrc => 'time_part' }, prosrc => 'time_part' },
{ oid => '9980', descr => 'extract field from time',
proname => 'extract', prorettype => 'numeric', proargtypes => 'text time',
prosrc => 'extract_time' },
{ oid => '1386', { oid => '1386',
descr => 'date difference from today preserving months and years', descr => 'date difference from today preserving months and years',
proname => 'age', prolang => 'sql', provolatile => 's', proname => 'age', prolang => 'sql', provolatile => 's',
...@@ -5835,6 +5850,9 @@ ...@@ -5835,6 +5850,9 @@
{ oid => '2021', descr => 'extract field from timestamp', { oid => '2021', descr => 'extract field from timestamp',
proname => 'date_part', prorettype => 'float8', proname => 'date_part', prorettype => 'float8',
proargtypes => 'text timestamp', prosrc => 'timestamp_part' }, proargtypes => 'text timestamp', prosrc => 'timestamp_part' },
{ oid => '9982', descr => 'extract field from timestamp',
proname => 'extract', prorettype => 'numeric',
proargtypes => 'text timestamp', prosrc => 'extract_timestamp' },
{ oid => '2024', descr => 'convert date to timestamp', { oid => '2024', descr => 'convert date to timestamp',
proname => 'timestamp', prorettype => 'timestamp', proargtypes => 'date', proname => 'timestamp', prorettype => 'timestamp', proargtypes => 'date',
prosrc => 'date_timestamp' }, prosrc => 'date_timestamp' },
......
...@@ -63,6 +63,7 @@ extern char *numeric_out_sci(Numeric num, int scale); ...@@ -63,6 +63,7 @@ extern char *numeric_out_sci(Numeric num, int scale);
extern char *numeric_normalize(Numeric num); extern char *numeric_normalize(Numeric num);
extern Numeric int64_to_numeric(int64 val); extern Numeric int64_to_numeric(int64 val);
extern Numeric int64_div_fast_to_numeric(int64 val1, int log10val2);
extern Numeric numeric_add_opt_error(Numeric num1, Numeric num2, extern Numeric numeric_add_opt_error(Numeric num1, Numeric num2,
bool *have_error); bool *have_error);
......
...@@ -1787,7 +1787,7 @@ select ...@@ -1787,7 +1787,7 @@ select
select pg_get_viewdef('tt201v', true); select pg_get_viewdef('tt201v', true);
pg_get_viewdef pg_get_viewdef
----------------------------------------------------------------------------------------------- -----------------------------------------------------------------------------------------------
SELECT date_part('day'::text, now()) AS extr, + SELECT EXTRACT(day FROM now()) AS extr, +
((now(), '@ 1 day'::interval) OVERLAPS (CURRENT_TIMESTAMP(2), '@ 1 day'::interval)) AS o,+ ((now(), '@ 1 day'::interval) OVERLAPS (CURRENT_TIMESTAMP(2), '@ 1 day'::interval)) AS o,+
(('foo'::text) IS NORMALIZED) AS isn, + (('foo'::text) IS NORMALIZED) AS isn, +
(('foo'::text) IS NFKC NORMALIZED) AS isnn, + (('foo'::text) IS NFKC NORMALIZED) AS isnn, +
......
This diff is collapsed.
...@@ -948,18 +948,18 @@ SELECT f1, ...@@ -948,18 +948,18 @@ SELECT f1,
EXTRACT(MILLENNIUM FROM f1) AS MILLENNIUM, EXTRACT(MILLENNIUM FROM f1) AS MILLENNIUM,
EXTRACT(EPOCH FROM f1) AS EPOCH EXTRACT(EPOCH FROM f1) AS EPOCH
FROM INTERVAL_TBL; FROM INTERVAL_TBL;
f1 | microsecond | millisecond | second | minute | hour | day | month | quarter | year | decade | century | millennium | epoch f1 | microsecond | millisecond | second | minute | hour | day | month | quarter | year | decade | century | millennium | epoch
-------------------------------+-------------+-------------+--------+--------+------+-----+-------+---------+------+--------+---------+------------+------------ -------------------------------+-------------+-------------+------------+--------+------+-----+-------+---------+------+--------+---------+------------+-------------------
@ 1 min | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 60 @ 1 min | 0 | 0.000 | 0.000000 | 1 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 60.000000
@ 5 hours | 0 | 0 | 0 | 0 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 18000 @ 5 hours | 0 | 0.000 | 0.000000 | 0 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 18000.000000
@ 10 days | 0 | 0 | 0 | 0 | 0 | 10 | 0 | 1 | 0 | 0 | 0 | 0 | 864000 @ 10 days | 0 | 0.000 | 0.000000 | 0 | 0 | 10 | 0 | 1 | 0 | 0 | 0 | 0 | 864000.000000
@ 34 years | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 1 | 34 | 3 | 0 | 0 | 1072958400 @ 34 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 1 | 34 | 3 | 0 | 0 | 1072224000.000000
@ 3 mons | 0 | 0 | 0 | 0 | 0 | 0 | 3 | 2 | 0 | 0 | 0 | 0 | 7776000 @ 3 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 3 | 2 | 0 | 0 | 0 | 0 | 7776000.000000
@ 14 secs ago | -14000000 | -14000 | -14 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -14 @ 14 secs ago | -14000000 | -14000.000 | -14.000000 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -14.000000
@ 1 day 2 hours 3 mins 4 secs | 4000000 | 4000 | 4 | 3 | 2 | 1 | 0 | 1 | 0 | 0 | 0 | 0 | 93784 @ 1 day 2 hours 3 mins 4 secs | 4000000 | 4000.000 | 4.000000 | 3 | 2 | 1 | 0 | 1 | 0 | 0 | 0 | 0 | 93784.000000
@ 6 years | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 1 | 6 | 0 | 0 | 0 | 189345600 @ 6 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 1 | 6 | 0 | 0 | 0 | 189216000.000000
@ 5 mons | 0 | 0 | 0 | 0 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 12960000 @ 5 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 12960000.000000
@ 5 mons 12 hours | 0 | 0 | 0 | 0 | 12 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 13003200 @ 5 mons 12 hours | 0 | 0.000 | 0.000000 | 0 | 12 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 13003200.000000
(10 rows) (10 rows)
SELECT EXTRACT(FORTNIGHT FROM INTERVAL '2 days'); -- error SELECT EXTRACT(FORTNIGHT FROM INTERVAL '2 days'); -- error
...@@ -967,50 +967,79 @@ ERROR: interval units "fortnight" not recognized ...@@ -967,50 +967,79 @@ ERROR: interval units "fortnight" not recognized
SELECT EXTRACT(TIMEZONE FROM INTERVAL '2 days'); -- error SELECT EXTRACT(TIMEZONE FROM INTERVAL '2 days'); -- error
ERROR: interval units "timezone" not supported ERROR: interval units "timezone" not supported
SELECT EXTRACT(DECADE FROM INTERVAL '100 y'); SELECT EXTRACT(DECADE FROM INTERVAL '100 y');
date_part extract
----------- ---------
10 10
(1 row) (1 row)
SELECT EXTRACT(DECADE FROM INTERVAL '99 y'); SELECT EXTRACT(DECADE FROM INTERVAL '99 y');
date_part extract
----------- ---------
9 9
(1 row) (1 row)
SELECT EXTRACT(DECADE FROM INTERVAL '-99 y'); SELECT EXTRACT(DECADE FROM INTERVAL '-99 y');
date_part extract
----------- ---------
-9 -9
(1 row) (1 row)
SELECT EXTRACT(DECADE FROM INTERVAL '-100 y'); SELECT EXTRACT(DECADE FROM INTERVAL '-100 y');
date_part extract
----------- ---------
-10 -10
(1 row) (1 row)
SELECT EXTRACT(CENTURY FROM INTERVAL '100 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '100 y');
date_part extract
----------- ---------
1 1
(1 row) (1 row)
SELECT EXTRACT(CENTURY FROM INTERVAL '99 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '99 y');
date_part extract
----------- ---------
0 0
(1 row) (1 row)
SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y');
date_part extract
----------- ---------
0 0
(1 row) (1 row)
SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y');
date_part extract
----------- ---------
-1 -1
(1 row)
-- date_part implementation is mostly the same as extract, so only
-- test a few cases for additional coverage.
SELECT f1,
date_part('microsecond', f1) AS microsecond,
date_part('millisecond', f1) AS millisecond,
date_part('second', f1) AS second,
date_part('epoch', f1) AS epoch
FROM INTERVAL_TBL;
f1 | microsecond | millisecond | second | epoch
-------------------------------+-------------+-------------+--------+------------
@ 1 min | 0 | 0 | 0 | 60
@ 5 hours | 0 | 0 | 0 | 18000
@ 10 days | 0 | 0 | 0 | 864000
@ 34 years | 0 | 0 | 0 | 1072958400
@ 3 mons | 0 | 0 | 0 | 7776000
@ 14 secs ago | -14000000 | -14000 | -14 | -14
@ 1 day 2 hours 3 mins 4 secs | 4000000 | 4000 | 4 | 93784
@ 6 years | 0 | 0 | 0 | 189345600
@ 5 mons | 0 | 0 | 0 | 12960000
@ 5 mons 12 hours | 0 | 0 | 0 | 13003200
(10 rows)
-- internal overflow test case
SELECT extract(epoch from interval '1000000000 days');
extract
-----------------------
86400000000000.000000
(1 row) (1 row)
...@@ -17,12 +17,12 @@ SELECT v, EXTRACT(year FROM d), count(*) ...@@ -17,12 +17,12 @@ SELECT v, EXTRACT(year FROM d), count(*)
FROM ctv_data FROM ctv_data
GROUP BY 1, 2 GROUP BY 1, 2
ORDER BY 1, 2; ORDER BY 1, 2;
v | date_part | count v | extract | count
----+-----------+------- ----+---------+-------
v0 | 2014 | 2 v0 | 2014 | 2
v0 | 2015 | 1 v0 | 2015 | 1
v1 | 2015 | 3 v1 | 2015 | 3
v2 | 2015 | 1 v2 | 2015 | 1
(4 rows) (4 rows)
-- basic usage with 3 columns -- basic usage with 3 columns
......
...@@ -131,33 +131,33 @@ HINT: Could not choose a best candidate operator. You might need to add explici ...@@ -131,33 +131,33 @@ HINT: Could not choose a best candidate operator. You might need to add explici
-- test EXTRACT -- test EXTRACT
-- --
SELECT EXTRACT(MICROSECOND FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(MICROSECOND FROM TIME '2020-05-26 13:30:25.575401');
date_part extract
----------- ----------
25575401 25575401
(1 row) (1 row)
SELECT EXTRACT(MILLISECOND FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(MILLISECOND FROM TIME '2020-05-26 13:30:25.575401');
date_part extract
----------- -----------
25575.401 25575.401
(1 row) (1 row)
SELECT EXTRACT(SECOND FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(SECOND FROM TIME '2020-05-26 13:30:25.575401');
date_part extract
----------- -----------
25.575401 25.575401
(1 row) (1 row)
SELECT EXTRACT(MINUTE FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(MINUTE FROM TIME '2020-05-26 13:30:25.575401');
date_part extract
----------- ---------
30 30
(1 row) (1 row)
SELECT EXTRACT(HOUR FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(HOUR FROM TIME '2020-05-26 13:30:25.575401');
date_part extract
----------- ---------
13 13
(1 row) (1 row)
SELECT EXTRACT(DAY FROM TIME '2020-05-26 13:30:25.575401'); -- error SELECT EXTRACT(DAY FROM TIME '2020-05-26 13:30:25.575401'); -- error
...@@ -167,6 +167,32 @@ ERROR: "time" units "fortnight" not recognized ...@@ -167,6 +167,32 @@ ERROR: "time" units "fortnight" not recognized
SELECT EXTRACT(TIMEZONE FROM TIME '2020-05-26 13:30:25.575401'); -- error SELECT EXTRACT(TIMEZONE FROM TIME '2020-05-26 13:30:25.575401'); -- error
ERROR: "time" units "timezone" not recognized ERROR: "time" units "timezone" not recognized
SELECT EXTRACT(EPOCH FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(EPOCH FROM TIME '2020-05-26 13:30:25.575401');
extract
--------------
48625.575401
(1 row)
-- date_part implementation is mostly the same as extract, so only
-- test a few cases for additional coverage.
SELECT date_part('microsecond', TIME '2020-05-26 13:30:25.575401');
date_part
-----------
25575401
(1 row)
SELECT date_part('millisecond', TIME '2020-05-26 13:30:25.575401');
date_part
-----------
25575.401
(1 row)
SELECT date_part('second', TIME '2020-05-26 13:30:25.575401');
date_part
-----------
25.575401
(1 row)
SELECT date_part('epoch', TIME '2020-05-26 13:30:25.575401');
date_part date_part
-------------- --------------
48625.575401 48625.575401
......
...@@ -1012,6 +1012,84 @@ SELECT d1 as "timestamp", ...@@ -1012,6 +1012,84 @@ SELECT d1 as "timestamp",
Mon Jan 01 17:32:01 2001 | 200 | 21 | 3 | 2451912 | 978370321 Mon Jan 01 17:32:01 2001 | 200 | 21 | 3 | 2451912 | 978370321
(65 rows) (65 rows)
-- extract implementation is mostly the same as date_part, so only
-- test a few cases for additional coverage.
SELECT d1 as "timestamp",
extract(microseconds from d1) AS microseconds,
extract(milliseconds from d1) AS milliseconds,
extract(seconds from d1) AS seconds,
round(extract(julian from d1)) AS julian,
extract(epoch from d1) AS epoch
FROM TIMESTAMP_TBL;
timestamp | microseconds | milliseconds | seconds | julian | epoch
-----------------------------+--------------+--------------+-----------+-----------+---------------------
-infinity | | | | -Infinity | -Infinity
infinity | | | | Infinity | Infinity
Thu Jan 01 00:00:00 1970 | 0 | 0.000 | 0.000000 | 2440588 | 0.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:02 1997 | 2000000 | 2000.000 | 2.000000 | 2450491 | 855595922.000000
Mon Feb 10 17:32:01.4 1997 | 1400000 | 1400.000 | 1.400000 | 2450491 | 855595921.400000
Mon Feb 10 17:32:01.5 1997 | 1500000 | 1500.000 | 1.500000 | 2450491 | 855595921.500000
Mon Feb 10 17:32:01.6 1997 | 1600000 | 1600.000 | 1.600000 | 2450491 | 855595921.600000
Thu Jan 02 00:00:00 1997 | 0 | 0.000 | 0.000000 | 2450451 | 852163200.000000
Thu Jan 02 03:04:05 1997 | 5000000 | 5000.000 | 5.000000 | 2450451 | 852174245.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Tue Jun 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450611 | 865963921.000000
Sat Sep 22 18:19:20 2001 | 20000000 | 20000.000 | 20.000000 | 2452176 | 1001182760.000000
Wed Mar 15 08:14:01 2000 | 1000000 | 1000.000 | 1.000000 | 2451619 | 953108041.000000
Wed Mar 15 13:14:02 2000 | 2000000 | 2000.000 | 2.000000 | 2451620 | 953126042.000000
Wed Mar 15 12:14:03 2000 | 3000000 | 3000.000 | 3.000000 | 2451620 | 953122443.000000
Wed Mar 15 03:14:04 2000 | 4000000 | 4000.000 | 4.000000 | 2451619 | 953090044.000000
Wed Mar 15 02:14:05 2000 | 5000000 | 5000.000 | 5.000000 | 2451619 | 953086445.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:00 1997 | 0 | 0.000 | 0.000000 | 2450491 | 855595920.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Tue Jun 10 18:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450611 | 865967521.000000
Mon Feb 10 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450491 | 855595921.000000
Tue Feb 11 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450492 | 855682321.000000
Wed Feb 12 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450493 | 855768721.000000
Thu Feb 13 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450494 | 855855121.000000
Fri Feb 14 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450495 | 855941521.000000
Sat Feb 15 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450496 | 856027921.000000
Sun Feb 16 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450497 | 856114321.000000
Tue Feb 16 17:32:01 0097 BC | 1000000 | 1000.000 | 1.000000 | 1686043 | -65192711279.000000
Sat Feb 16 17:32:01 0097 | 1000000 | 1000.000 | 1.000000 | 1756537 | -59102029679.000000
Thu Feb 16 17:32:01 0597 | 1000000 | 1000.000 | 1.000000 | 1939158 | -43323575279.000000
Tue Feb 16 17:32:01 1097 | 1000000 | 1000.000 | 1.000000 | 2121779 | -27545120879.000000
Sat Feb 16 17:32:01 1697 | 1000000 | 1000.000 | 1.000000 | 2340925 | -8610906479.000000
Thu Feb 16 17:32:01 1797 | 1000000 | 1000.000 | 1.000000 | 2377449 | -5455232879.000000
Tue Feb 16 17:32:01 1897 | 1000000 | 1000.000 | 1.000000 | 2413973 | -2299559279.000000
Sun Feb 16 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450497 | 856114321.000000
Sat Feb 16 17:32:01 2097 | 1000000 | 1000.000 | 1.000000 | 2487022 | 4011874321.000000
Wed Feb 28 17:32:01 1996 | 1000000 | 1000.000 | 1.000000 | 2450143 | 825528721.000000
Thu Feb 29 17:32:01 1996 | 1000000 | 1000.000 | 1.000000 | 2450144 | 825615121.000000
Fri Mar 01 17:32:01 1996 | 1000000 | 1000.000 | 1.000000 | 2450145 | 825701521.000000
Mon Dec 30 17:32:01 1996 | 1000000 | 1000.000 | 1.000000 | 2450449 | 851967121.000000
Tue Dec 31 17:32:01 1996 | 1000000 | 1000.000 | 1.000000 | 2450450 | 852053521.000000
Wed Jan 01 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450451 | 852139921.000000
Fri Feb 28 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450509 | 857151121.000000
Sat Mar 01 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450510 | 857237521.000000
Tue Dec 30 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450814 | 883503121.000000
Wed Dec 31 17:32:01 1997 | 1000000 | 1000.000 | 1.000000 | 2450815 | 883589521.000000
Fri Dec 31 17:32:01 1999 | 1000000 | 1000.000 | 1.000000 | 2451545 | 946661521.000000
Sat Jan 01 17:32:01 2000 | 1000000 | 1000.000 | 1.000000 | 2451546 | 946747921.000000
Sun Dec 31 17:32:01 2000 | 1000000 | 1000.000 | 1.000000 | 2451911 | 978283921.000000
Mon Jan 01 17:32:01 2001 | 1000000 | 1000.000 | 1.000000 | 2451912 | 978370321.000000
(65 rows)
-- value near upper bound uses special case in code -- value near upper bound uses special case in code
SELECT date_part('epoch', '294270-01-01 00:00:00'::timestamp); SELECT date_part('epoch', '294270-01-01 00:00:00'::timestamp);
date_part date_part
...@@ -1019,6 +1097,19 @@ SELECT date_part('epoch', '294270-01-01 00:00:00'::timestamp); ...@@ -1019,6 +1097,19 @@ SELECT date_part('epoch', '294270-01-01 00:00:00'::timestamp);
9224097091200 9224097091200
(1 row) (1 row)
SELECT extract(epoch from '294270-01-01 00:00:00'::timestamp);
extract
----------------------
9224097091200.000000
(1 row)
-- another internal overflow test case
SELECT extract(epoch from '5000-01-01 00:00:00'::timestamp);
extract
--------------------
95617584000.000000
(1 row)
-- TO_CHAR() -- TO_CHAR()
SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon') SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
FROM TIMESTAMP_TBL; FROM TIMESTAMP_TBL;
......
...@@ -1189,6 +1189,85 @@ SELECT d1 as timestamptz, ...@@ -1189,6 +1189,85 @@ SELECT d1 as timestamptz,
Mon Jan 01 17:32:01 2001 PST | -28800 | -8 | 0 Mon Jan 01 17:32:01 2001 PST | -28800 | -8 | 0
(66 rows) (66 rows)
-- extract implementation is mostly the same as date_part, so only
-- test a few cases for additional coverage.
SELECT d1 as "timestamp",
extract(microseconds from d1) AS microseconds,
extract(milliseconds from d1) AS milliseconds,
extract(seconds from d1) AS seconds,
round(extract(julian from d1)) AS julian,
extract(epoch from d1) AS epoch
FROM TIMESTAMPTZ_TBL;
timestamp | microseconds | milliseconds | seconds | julian | epoch
---------------------------------+--------------+--------------+-----------+-----------+---------------------
-infinity | | | | -Infinity | -Infinity
infinity | | | | Infinity | Infinity
Wed Dec 31 16:00:00 1969 PST | 0 | 0.000 | 0.000000 | 2440588 | 0.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:02 1997 PST | 2000000 | 2000.000 | 2.000000 | 2450491 | 855624722.000000
Mon Feb 10 17:32:01.4 1997 PST | 1400000 | 1400.000 | 1.400000 | 2450491 | 855624721.400000
Mon Feb 10 17:32:01.5 1997 PST | 1500000 | 1500.000 | 1.500000 | 2450491 | 855624721.500000
Mon Feb 10 17:32:01.6 1997 PST | 1600000 | 1600.000 | 1.600000 | 2450491 | 855624721.600000
Thu Jan 02 00:00:00 1997 PST | 0 | 0.000 | 0.000000 | 2450451 | 852192000.000000
Thu Jan 02 03:04:05 1997 PST | 5000000 | 5000.000 | 5.000000 | 2450451 | 852203045.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Tue Jun 10 17:32:01 1997 PDT | 1000000 | 1000.000 | 1.000000 | 2450611 | 865989121.000000
Sat Sep 22 18:19:20 2001 PDT | 20000000 | 20000.000 | 20.000000 | 2452176 | 1001207960.000000
Wed Mar 15 08:14:01 2000 PST | 1000000 | 1000.000 | 1.000000 | 2451619 | 953136841.000000
Wed Mar 15 04:14:02 2000 PST | 2000000 | 2000.000 | 2.000000 | 2451619 | 953122442.000000
Wed Mar 15 02:14:03 2000 PST | 3000000 | 3000.000 | 3.000000 | 2451619 | 953115243.000000
Wed Mar 15 03:14:04 2000 PST | 4000000 | 4000.000 | 4.000000 | 2451619 | 953118844.000000
Wed Mar 15 01:14:05 2000 PST | 5000000 | 5000.000 | 5.000000 | 2451619 | 953111645.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:00 1997 PST | 0 | 0.000 | 0.000000 | 2450491 | 855624720.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Mon Feb 10 09:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450490 | 855595921.000000
Mon Feb 10 09:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450490 | 855595921.000000
Mon Feb 10 09:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450490 | 855595921.000000
Mon Feb 10 14:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855613921.000000
Thu Jul 10 14:32:01 1997 PDT | 1000000 | 1000.000 | 1.000000 | 2450641 | 868570321.000000
Tue Jun 10 18:32:01 1997 PDT | 1000000 | 1000.000 | 1.000000 | 2450611 | 865992721.000000
Mon Feb 10 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450491 | 855624721.000000
Tue Feb 11 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450492 | 855711121.000000
Wed Feb 12 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450493 | 855797521.000000
Thu Feb 13 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450494 | 855883921.000000
Fri Feb 14 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450495 | 855970321.000000
Sat Feb 15 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450496 | 856056721.000000
Sun Feb 16 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450497 | 856143121.000000
Tue Feb 16 17:32:01 0097 PST BC | 1000000 | 1000.000 | 1.000000 | 1686043 | -65192682479.000000
Sat Feb 16 17:32:01 0097 PST | 1000000 | 1000.000 | 1.000000 | 1756537 | -59102000879.000000
Thu Feb 16 17:32:01 0597 PST | 1000000 | 1000.000 | 1.000000 | 1939158 | -43323546479.000000
Tue Feb 16 17:32:01 1097 PST | 1000000 | 1000.000 | 1.000000 | 2121779 | -27545092079.000000
Sat Feb 16 17:32:01 1697 PST | 1000000 | 1000.000 | 1.000000 | 2340925 | -8610877679.000000
Thu Feb 16 17:32:01 1797 PST | 1000000 | 1000.000 | 1.000000 | 2377449 | -5455204079.000000
Tue Feb 16 17:32:01 1897 PST | 1000000 | 1000.000 | 1.000000 | 2413973 | -2299530479.000000
Sun Feb 16 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450497 | 856143121.000000
Sat Feb 16 17:32:01 2097 PST | 1000000 | 1000.000 | 1.000000 | 2487022 | 4011903121.000000
Wed Feb 28 17:32:01 1996 PST | 1000000 | 1000.000 | 1.000000 | 2450143 | 825557521.000000
Thu Feb 29 17:32:01 1996 PST | 1000000 | 1000.000 | 1.000000 | 2450144 | 825643921.000000
Fri Mar 01 17:32:01 1996 PST | 1000000 | 1000.000 | 1.000000 | 2450145 | 825730321.000000
Mon Dec 30 17:32:01 1996 PST | 1000000 | 1000.000 | 1.000000 | 2450449 | 851995921.000000
Tue Dec 31 17:32:01 1996 PST | 1000000 | 1000.000 | 1.000000 | 2450450 | 852082321.000000
Wed Jan 01 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450451 | 852168721.000000
Fri Feb 28 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450509 | 857179921.000000
Sat Mar 01 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450510 | 857266321.000000
Tue Dec 30 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450814 | 883531921.000000
Wed Dec 31 17:32:01 1997 PST | 1000000 | 1000.000 | 1.000000 | 2450815 | 883618321.000000
Fri Dec 31 17:32:01 1999 PST | 1000000 | 1000.000 | 1.000000 | 2451545 | 946690321.000000
Sat Jan 01 17:32:01 2000 PST | 1000000 | 1000.000 | 1.000000 | 2451546 | 946776721.000000
Sun Dec 31 17:32:01 2000 PST | 1000000 | 1000.000 | 1.000000 | 2451911 | 978312721.000000
Mon Jan 01 17:32:01 2001 PST | 1000000 | 1000.000 | 1.000000 | 2451912 | 978399121.000000
(66 rows)
-- value near upper bound uses special case in code -- value near upper bound uses special case in code
SELECT date_part('epoch', '294270-01-01 00:00:00+00'::timestamptz); SELECT date_part('epoch', '294270-01-01 00:00:00+00'::timestamptz);
date_part date_part
...@@ -1196,6 +1275,19 @@ SELECT date_part('epoch', '294270-01-01 00:00:00+00'::timestamptz); ...@@ -1196,6 +1275,19 @@ SELECT date_part('epoch', '294270-01-01 00:00:00+00'::timestamptz);
9224097091200 9224097091200
(1 row) (1 row)
SELECT extract(epoch from '294270-01-01 00:00:00+00'::timestamptz);
extract
----------------------
9224097091200.000000
(1 row)
-- another internal overflow test case
SELECT extract(epoch from '5000-01-01 00:00:00+00'::timestamptz);
extract
--------------------
95617584000.000000
(1 row)
-- TO_CHAR() -- TO_CHAR()
SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon') SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
FROM TIMESTAMPTZ_TBL; FROM TIMESTAMPTZ_TBL;
......
...@@ -148,33 +148,33 @@ HINT: No operator matches the given name and argument types. You might need to ...@@ -148,33 +148,33 @@ HINT: No operator matches the given name and argument types. You might need to
-- test EXTRACT -- test EXTRACT
-- --
SELECT EXTRACT(MICROSECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT EXTRACT(MICROSECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part extract
----------- ----------
25575401 25575401
(1 row) (1 row)
SELECT EXTRACT(MILLISECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT EXTRACT(MILLISECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part extract
----------- -----------
25575.401 25575.401
(1 row) (1 row)
SELECT EXTRACT(SECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT EXTRACT(SECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part extract
----------- -----------
25.575401 25.575401
(1 row) (1 row)
SELECT EXTRACT(MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT EXTRACT(MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part extract
----------- ---------
30 30
(1 row) (1 row)
SELECT EXTRACT(HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT EXTRACT(HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part extract
----------- ---------
13 13
(1 row) (1 row)
SELECT EXTRACT(DAY FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); -- error SELECT EXTRACT(DAY FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); -- error
...@@ -182,24 +182,50 @@ ERROR: "time with time zone" units "day" not recognized ...@@ -182,24 +182,50 @@ ERROR: "time with time zone" units "day" not recognized
SELECT EXTRACT(FORTNIGHT FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); -- error SELECT EXTRACT(FORTNIGHT FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); -- error
ERROR: "time with time zone" units "fortnight" not recognized ERROR: "time with time zone" units "fortnight" not recognized
SELECT EXTRACT(TIMEZONE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30'); SELECT EXTRACT(TIMEZONE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30');
extract
---------
-16200
(1 row)
SELECT EXTRACT(TIMEZONE_HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30');
extract
---------
-4
(1 row)
SELECT EXTRACT(TIMEZONE_MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30');
extract
---------
-30
(1 row)
SELECT EXTRACT(EPOCH FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
extract
--------------
63025.575401
(1 row)
-- date_part implementation is mostly the same as extract, so only
-- test a few cases for additional coverage.
SELECT date_part('microsecond', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part date_part
----------- -----------
-16200 25575401
(1 row) (1 row)
SELECT EXTRACT(TIMEZONE_HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30'); SELECT date_part('millisecond', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part date_part
----------- -----------
-4 25575.401
(1 row) (1 row)
SELECT EXTRACT(TIMEZONE_MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30'); SELECT date_part('second', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part date_part
----------- -----------
-30 25.575401
(1 row) (1 row)
SELECT EXTRACT(EPOCH FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT date_part('epoch', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
date_part date_part
-------------- --------------
63025.575401 63025.575401
......
...@@ -284,14 +284,18 @@ SELECT EXTRACT(HOUR FROM DATE '2020-08-11'); ...@@ -284,14 +284,18 @@ SELECT EXTRACT(HOUR FROM DATE '2020-08-11');
SELECT EXTRACT(DAY FROM DATE '2020-08-11'); SELECT EXTRACT(DAY FROM DATE '2020-08-11');
SELECT EXTRACT(MONTH FROM DATE '2020-08-11'); SELECT EXTRACT(MONTH FROM DATE '2020-08-11');
SELECT EXTRACT(YEAR FROM DATE '2020-08-11'); SELECT EXTRACT(YEAR FROM DATE '2020-08-11');
SELECT EXTRACT(YEAR FROM DATE '2020-08-11 BC');
SELECT EXTRACT(DECADE FROM DATE '2020-08-11'); SELECT EXTRACT(DECADE FROM DATE '2020-08-11');
SELECT EXTRACT(CENTURY FROM DATE '2020-08-11'); SELECT EXTRACT(CENTURY FROM DATE '2020-08-11');
SELECT EXTRACT(MILLENNIUM FROM DATE '2020-08-11'); SELECT EXTRACT(MILLENNIUM FROM DATE '2020-08-11');
SELECT EXTRACT(ISOYEAR FROM DATE '2020-08-11'); SELECT EXTRACT(ISOYEAR FROM DATE '2020-08-11');
SELECT EXTRACT(ISOYEAR FROM DATE '2020-08-11 BC');
SELECT EXTRACT(QUARTER FROM DATE '2020-08-11'); SELECT EXTRACT(QUARTER FROM DATE '2020-08-11');
SELECT EXTRACT(WEEK FROM DATE '2020-08-11'); SELECT EXTRACT(WEEK FROM DATE '2020-08-11');
SELECT EXTRACT(DOW FROM DATE '2020-08-11'); SELECT EXTRACT(DOW FROM DATE '2020-08-11');
SELECT EXTRACT(DOW FROM DATE '2020-08-16');
SELECT EXTRACT(ISODOW FROM DATE '2020-08-11'); SELECT EXTRACT(ISODOW FROM DATE '2020-08-11');
SELECT EXTRACT(ISODOW FROM DATE '2020-08-16');
SELECT EXTRACT(DOY FROM DATE '2020-08-11'); SELECT EXTRACT(DOY FROM DATE '2020-08-11');
SELECT EXTRACT(TIMEZONE FROM DATE '2020-08-11'); SELECT EXTRACT(TIMEZONE FROM DATE '2020-08-11');
SELECT EXTRACT(TIMEZONE_M FROM DATE '2020-08-11'); SELECT EXTRACT(TIMEZONE_M FROM DATE '2020-08-11');
...@@ -321,14 +325,9 @@ select isfinite('infinity'::date), isfinite('-infinity'::date), isfinite('today' ...@@ -321,14 +325,9 @@ select isfinite('infinity'::date), isfinite('-infinity'::date), isfinite('today'
-- --
-- oscillating fields from non-finite date: -- oscillating fields from non-finite date:
-- --
SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(HOUR FROM DATE '-infinity'); -- NULL SELECT EXTRACT(DAY FROM DATE '-infinity'); -- NULL
-- all possible fields -- all supported fields
SELECT EXTRACT(MICROSECONDS FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(MILLISECONDS FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(SECOND FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(MINUTE FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(MONTH FROM DATE 'infinity'); -- NULL SELECT EXTRACT(MONTH FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(QUARTER FROM DATE 'infinity'); -- NULL SELECT EXTRACT(QUARTER FROM DATE 'infinity'); -- NULL
...@@ -336,15 +335,12 @@ SELECT EXTRACT(WEEK FROM DATE 'infinity'); -- NULL ...@@ -336,15 +335,12 @@ SELECT EXTRACT(WEEK FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(DOW FROM DATE 'infinity'); -- NULL SELECT EXTRACT(DOW FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(ISODOW FROM DATE 'infinity'); -- NULL SELECT EXTRACT(ISODOW FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(DOY FROM DATE 'infinity'); -- NULL SELECT EXTRACT(DOY FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(TIMEZONE FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(TIMEZONE_M FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(TIMEZONE_H FROM DATE 'infinity'); -- NULL
-- --
-- monotonic fields from non-finite date: -- monotonic fields from non-finite date:
-- --
SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(EPOCH FROM DATE '-infinity'); -- -Infinity SELECT EXTRACT(EPOCH FROM DATE '-infinity'); -- -Infinity
-- all supported fields
SELECT EXTRACT(YEAR FROM DATE 'infinity'); -- Infinity SELECT EXTRACT(YEAR FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(DECADE FROM DATE 'infinity'); -- Infinity SELECT EXTRACT(DECADE FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(CENTURY FROM DATE 'infinity'); -- Infinity SELECT EXTRACT(CENTURY FROM DATE 'infinity'); -- Infinity
...@@ -355,7 +351,7 @@ SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity ...@@ -355,7 +351,7 @@ SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity
-- --
-- wrong fields from non-finite date: -- wrong fields from non-finite date:
-- --
SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- ERROR: timestamp units "microsec" not recognized SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- error
-- test constructors -- test constructors
select make_date(2013, 7, 15); select make_date(2013, 7, 15);
......
...@@ -343,3 +343,15 @@ SELECT EXTRACT(CENTURY FROM INTERVAL '100 y'); ...@@ -343,3 +343,15 @@ SELECT EXTRACT(CENTURY FROM INTERVAL '100 y');
SELECT EXTRACT(CENTURY FROM INTERVAL '99 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '99 y');
SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y');
SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y'); SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y');
-- date_part implementation is mostly the same as extract, so only
-- test a few cases for additional coverage.
SELECT f1,
date_part('microsecond', f1) AS microsecond,
date_part('millisecond', f1) AS millisecond,
date_part('second', f1) AS second,
date_part('epoch', f1) AS epoch
FROM INTERVAL_TBL;
-- internal overflow test case
SELECT extract(epoch from interval '1000000000 days');
...@@ -63,3 +63,10 @@ SELECT EXTRACT(DAY FROM TIME '2020-05-26 13:30:25.575401'); -- error ...@@ -63,3 +63,10 @@ SELECT EXTRACT(DAY FROM TIME '2020-05-26 13:30:25.575401'); -- error
SELECT EXTRACT(FORTNIGHT FROM TIME '2020-05-26 13:30:25.575401'); -- error SELECT EXTRACT(FORTNIGHT FROM TIME '2020-05-26 13:30:25.575401'); -- error
SELECT EXTRACT(TIMEZONE FROM TIME '2020-05-26 13:30:25.575401'); -- error SELECT EXTRACT(TIMEZONE FROM TIME '2020-05-26 13:30:25.575401'); -- error
SELECT EXTRACT(EPOCH FROM TIME '2020-05-26 13:30:25.575401'); SELECT EXTRACT(EPOCH FROM TIME '2020-05-26 13:30:25.575401');
-- date_part implementation is mostly the same as extract, so only
-- test a few cases for additional coverage.
SELECT date_part('microsecond', TIME '2020-05-26 13:30:25.575401');
SELECT date_part('millisecond', TIME '2020-05-26 13:30:25.575401');
SELECT date_part('second', TIME '2020-05-26 13:30:25.575401');
SELECT date_part('epoch', TIME '2020-05-26 13:30:25.575401');
...@@ -261,8 +261,21 @@ SELECT d1 as "timestamp", ...@@ -261,8 +261,21 @@ SELECT d1 as "timestamp",
date_part( 'epoch', d1) AS epoch date_part( 'epoch', d1) AS epoch
FROM TIMESTAMP_TBL; FROM TIMESTAMP_TBL;
-- extract implementation is mostly the same as date_part, so only
-- test a few cases for additional coverage.
SELECT d1 as "timestamp",
extract(microseconds from d1) AS microseconds,
extract(milliseconds from d1) AS milliseconds,
extract(seconds from d1) AS seconds,
round(extract(julian from d1)) AS julian,
extract(epoch from d1) AS epoch
FROM TIMESTAMP_TBL;
-- value near upper bound uses special case in code -- value near upper bound uses special case in code
SELECT date_part('epoch', '294270-01-01 00:00:00'::timestamp); SELECT date_part('epoch', '294270-01-01 00:00:00'::timestamp);
SELECT extract(epoch from '294270-01-01 00:00:00'::timestamp);
-- another internal overflow test case
SELECT extract(epoch from '5000-01-01 00:00:00'::timestamp);
-- TO_CHAR() -- TO_CHAR()
SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon') SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
......
...@@ -275,8 +275,21 @@ SELECT d1 as timestamptz, ...@@ -275,8 +275,21 @@ SELECT d1 as timestamptz,
date_part( 'timezone_minute', d1) AS timezone_minute date_part( 'timezone_minute', d1) AS timezone_minute
FROM TIMESTAMPTZ_TBL; FROM TIMESTAMPTZ_TBL;
-- extract implementation is mostly the same as date_part, so only
-- test a few cases for additional coverage.
SELECT d1 as "timestamp",
extract(microseconds from d1) AS microseconds,
extract(milliseconds from d1) AS milliseconds,
extract(seconds from d1) AS seconds,
round(extract(julian from d1)) AS julian,
extract(epoch from d1) AS epoch
FROM TIMESTAMPTZ_TBL;
-- value near upper bound uses special case in code -- value near upper bound uses special case in code
SELECT date_part('epoch', '294270-01-01 00:00:00+00'::timestamptz); SELECT date_part('epoch', '294270-01-01 00:00:00+00'::timestamptz);
SELECT extract(epoch from '294270-01-01 00:00:00+00'::timestamptz);
-- another internal overflow test case
SELECT extract(epoch from '5000-01-01 00:00:00+00'::timestamptz);
-- TO_CHAR() -- TO_CHAR()
SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon') SELECT to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
......
...@@ -70,3 +70,10 @@ SELECT EXTRACT(TIMEZONE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401- ...@@ -70,3 +70,10 @@ SELECT EXTRACT(TIMEZONE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-
SELECT EXTRACT(TIMEZONE_HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30'); SELECT EXTRACT(TIMEZONE_HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30');
SELECT EXTRACT(TIMEZONE_MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30'); SELECT EXTRACT(TIMEZONE_MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04:30');
SELECT EXTRACT(EPOCH FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT EXTRACT(EPOCH FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
-- date_part implementation is mostly the same as extract, so only
-- test a few cases for additional coverage.
SELECT date_part('microsecond', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
SELECT date_part('millisecond', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
SELECT date_part('second', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
SELECT date_part('epoch', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04');
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment