1
0
mirror of https://github.com/postgres/postgres.git synced 2025-05-02 11:44:50 +03:00

Fix extraction of week and quarter fields from intervals.

"EXTRACT(WEEK FROM interval_value)" formerly threw an error.
Define it as "tm->tm_mday / 7".  (With C99 division semantics,
this gives consistent results for negative intervals.)

"EXTRACT(QUARTER FROM interval_value)" has been implemented
all along, but it formerly gave extremely strange results for
negative intervals.  Fix it so that the output for -N months
is the negative of the output for N months.

Per bug #18348 from Michael Bondarenko and subsequent discussion.

Discussion: https://postgr.es/m/18348-b097a3587dfde8a4@postgresql.org
This commit is contained in:
Tom Lane 2024-08-16 12:35:50 -04:00
parent 108d2adb9e
commit 6be39d77a7
4 changed files with 94 additions and 16 deletions

View File

@ -10432,12 +10432,16 @@ SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
<term><literal>quarter</literal></term>
<listitem>
<para>
The quarter of the year (1&ndash;4) that the date is in
The quarter of the year (1&ndash;4) that the date is in;
for <type>interval</type> values, the month field divided by 3
plus 1
</para>
<screen>
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
SELECT EXTRACT(QUARTER FROM INTERVAL '1 year 6 months');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
</screen>
</listitem>
</varlistentry>
@ -10508,9 +10512,16 @@ SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
<literal>week</literal> to get consistent results.
</para>
<para>
For <type>interval</type> values, the week field is simply the number
of integral days divided by 7.
</para>
<screen>
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
SELECT EXTRACT(WEEK FROM INTERVAL '13 days 24 hours');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
</listitem>
</varlistentry>

View File

@ -5899,6 +5899,7 @@ NonFiniteIntervalPart(int type, int unit, char *lowunits, bool isNegative)
case DTK_MILLISEC:
case DTK_SECOND:
case DTK_MINUTE:
case DTK_WEEK:
case DTK_MONTH:
case DTK_QUARTER:
return 0.0;
@ -6018,12 +6019,27 @@ interval_part_common(PG_FUNCTION_ARGS, bool retnumeric)
intresult = tm->tm_mday;
break;
case DTK_WEEK:
intresult = tm->tm_mday / 7;
break;
case DTK_MONTH:
intresult = tm->tm_mon;
break;
case DTK_QUARTER:
intresult = (tm->tm_mon / 3) + 1;
/*
* We want to maintain the rule that a field extracted from a
* negative interval is the negative of the field's value for
* the sign-reversed interval. The broken-down tm_year and
* tm_mon aren't very helpful for that, so work from
* interval->month.
*/
if (interval->month >= 0)
intresult = (tm->tm_mon / 3) + 1;
else
intresult = -(((-interval->month % MONTHS_PER_YEAR) / 3) + 1);
break;
case DTK_YEAR:

View File

@ -1834,6 +1834,7 @@ SELECT f1,
EXTRACT(MINUTE FROM f1) AS MINUTE,
EXTRACT(HOUR FROM f1) AS HOUR,
EXTRACT(DAY FROM f1) AS DAY,
EXTRACT(WEEK FROM f1) AS WEEK,
EXTRACT(MONTH FROM f1) AS MONTH,
EXTRACT(QUARTER FROM f1) AS QUARTER,
EXTRACT(YEAR FROM f1) AS YEAR,
@ -1842,20 +1843,52 @@ SELECT f1,
EXTRACT(MILLENNIUM FROM f1) AS MILLENNIUM,
EXTRACT(EPOCH FROM f1) AS EPOCH
FROM INTERVAL_TBL;
f1 | microsecond | millisecond | second | minute | hour | day | month | quarter | year | decade | century | millennium | epoch
-------------------------------+-------------+-------------+------------+--------+-----------+-----------+-------+---------+-----------+-----------+-----------+------------+-------------------
@ 1 min | 0 | 0.000 | 0.000000 | 1 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 60.000000
@ 5 hours | 0 | 0.000 | 0.000000 | 0 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 18000.000000
@ 10 days | 0 | 0.000 | 0.000000 | 0 | 0 | 10 | 0 | 1 | 0 | 0 | 0 | 0 | 864000.000000
@ 34 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 1 | 34 | 3 | 0 | 0 | 1072958400.000000
@ 3 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 3 | 2 | 0 | 0 | 0 | 0 | 7776000.000000
@ 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.000 | 4.000000 | 3 | 2 | 1 | 0 | 1 | 0 | 0 | 0 | 0 | 93784.000000
@ 6 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 1 | 6 | 0 | 0 | 0 | 189345600.000000
@ 5 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 12960000.000000
@ 5 mons 12 hours | 0 | 0.000 | 0.000000 | 0 | 12 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 13003200.000000
infinity | | | | | Infinity | Infinity | | | Infinity | Infinity | Infinity | Infinity | Infinity
-infinity | | | | | -Infinity | -Infinity | | | -Infinity | -Infinity | -Infinity | -Infinity | -Infinity
f1 | microsecond | millisecond | second | minute | hour | day | week | month | quarter | year | decade | century | millennium | epoch
-------------------------------+-------------+-------------+------------+--------+-----------+-----------+------+-------+---------+-----------+-----------+-----------+------------+-------------------
@ 1 min | 0 | 0.000 | 0.000000 | 1 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 60.000000
@ 5 hours | 0 | 0.000 | 0.000000 | 0 | 5 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 18000.000000
@ 10 days | 0 | 0.000 | 0.000000 | 0 | 0 | 10 | 1 | 0 | 1 | 0 | 0 | 0 | 0 | 864000.000000
@ 34 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 1 | 34 | 3 | 0 | 0 | 1072958400.000000
@ 3 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 3 | 2 | 0 | 0 | 0 | 0 | 7776000.000000
@ 14 secs ago | -14000000 | -14000.000 | -14.000000 | 0 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -14.000000
@ 1 day 2 hours 3 mins 4 secs | 4000000 | 4000.000 | 4.000000 | 3 | 2 | 1 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 93784.000000
@ 6 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 1 | 6 | 0 | 0 | 0 | 189345600.000000
@ 5 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 12960000.000000
@ 5 mons 12 hours | 0 | 0.000 | 0.000000 | 0 | 12 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 13003200.000000
infinity | | | | | Infinity | Infinity | | | | Infinity | Infinity | Infinity | Infinity | Infinity
-infinity | | | | | -Infinity | -Infinity | | | | -Infinity | -Infinity | -Infinity | -Infinity | -Infinity
(12 rows)
SELECT -f1,
EXTRACT(MICROSECOND FROM -f1) AS MICROSECOND,
EXTRACT(MILLISECOND FROM -f1) AS MILLISECOND,
EXTRACT(SECOND FROM -f1) AS SECOND,
EXTRACT(MINUTE FROM -f1) AS MINUTE,
EXTRACT(HOUR FROM -f1) AS HOUR,
EXTRACT(DAY FROM -f1) AS DAY,
EXTRACT(WEEK FROM -f1) AS WEEK,
EXTRACT(MONTH FROM -f1) AS MONTH,
EXTRACT(QUARTER FROM -f1) AS QUARTER,
EXTRACT(YEAR FROM -f1) AS YEAR,
EXTRACT(DECADE FROM -f1) AS DECADE,
EXTRACT(CENTURY FROM -f1) AS CENTURY,
EXTRACT(MILLENNIUM FROM -f1) AS MILLENNIUM,
EXTRACT(EPOCH FROM -f1) AS EPOCH
FROM INTERVAL_TBL;
?column? | microsecond | millisecond | second | minute | hour | day | week | month | quarter | year | decade | century | millennium | epoch
-----------------------------------+-------------+-------------+-----------+--------+-----------+-----------+------+-------+---------+-----------+-----------+-----------+------------+--------------------
@ 1 min ago | 0 | 0.000 | 0.000000 | -1 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -60.000000
@ 5 hours ago | 0 | 0.000 | 0.000000 | 0 | -5 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -18000.000000
@ 10 days ago | 0 | 0.000 | 0.000000 | 0 | 0 | -10 | -1 | 0 | 1 | 0 | 0 | 0 | 0 | -864000.000000
@ 34 years ago | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | -1 | -34 | -3 | 0 | 0 | -1072958400.000000
@ 3 mons ago | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | -3 | -2 | 0 | 0 | 0 | 0 | -7776000.000000
@ 14 secs | 14000000 | 14000.000 | 14.000000 | 0 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 14.000000
@ 1 day 2 hours 3 mins 4 secs ago | -4000000 | -4000.000 | -4.000000 | -3 | -2 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -93784.000000
@ 6 years ago | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | -1 | -6 | 0 | 0 | 0 | -189345600.000000
@ 5 mons ago | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | -5 | -2 | 0 | 0 | 0 | 0 | -12960000.000000
@ 5 mons 12 hours ago | 0 | 0.000 | 0.000000 | 0 | -12 | 0 | 0 | -5 | -2 | 0 | 0 | 0 | 0 | -13003200.000000
-infinity | | | | | -Infinity | -Infinity | | | | -Infinity | -Infinity | -Infinity | -Infinity | -Infinity
infinity | | | | | Infinity | Infinity | | | | Infinity | Infinity | Infinity | Infinity | Infinity
(12 rows)
SELECT EXTRACT(FORTNIGHT FROM INTERVAL '2 days'); -- error

View File

@ -592,6 +592,7 @@ SELECT f1,
EXTRACT(MINUTE FROM f1) AS MINUTE,
EXTRACT(HOUR FROM f1) AS HOUR,
EXTRACT(DAY FROM f1) AS DAY,
EXTRACT(WEEK FROM f1) AS WEEK,
EXTRACT(MONTH FROM f1) AS MONTH,
EXTRACT(QUARTER FROM f1) AS QUARTER,
EXTRACT(YEAR FROM f1) AS YEAR,
@ -601,6 +602,23 @@ SELECT f1,
EXTRACT(EPOCH FROM f1) AS EPOCH
FROM INTERVAL_TBL;
SELECT -f1,
EXTRACT(MICROSECOND FROM -f1) AS MICROSECOND,
EXTRACT(MILLISECOND FROM -f1) AS MILLISECOND,
EXTRACT(SECOND FROM -f1) AS SECOND,
EXTRACT(MINUTE FROM -f1) AS MINUTE,
EXTRACT(HOUR FROM -f1) AS HOUR,
EXTRACT(DAY FROM -f1) AS DAY,
EXTRACT(WEEK FROM -f1) AS WEEK,
EXTRACT(MONTH FROM -f1) AS MONTH,
EXTRACT(QUARTER FROM -f1) AS QUARTER,
EXTRACT(YEAR FROM -f1) AS YEAR,
EXTRACT(DECADE FROM -f1) AS DECADE,
EXTRACT(CENTURY FROM -f1) AS CENTURY,
EXTRACT(MILLENNIUM FROM -f1) AS MILLENNIUM,
EXTRACT(EPOCH FROM -f1) AS EPOCH
FROM INTERVAL_TBL;
SELECT EXTRACT(FORTNIGHT FROM INTERVAL '2 days'); -- error
SELECT EXTRACT(TIMEZONE FROM INTERVAL '2 days'); -- error