OSDN Git Service

> After all that about numbering centuries and millenia correctly,
authorBruce Momjian <bruce@momjian.us>
Fri, 20 Aug 2004 03:45:14 +0000 (03:45 +0000)
committerBruce Momjian <bruce@momjian.us>
Fri, 20 Aug 2004 03:45:14 +0000 (03:45 +0000)
> why does CVS tip still give me
>
> regression=# select extract(century from now());
>  date_part
> -----------
>         20
> (1 row)
> [ ... looks in code ... ]
>
> Apparently it's because you fixed only timestamp_part, and not
> timestamptz_part.  I'm not too sure about what timestamp_trunc or
> timestamptz_trunc should do, but they may be wrong as well.

Sigh... as usual, what is not tested does not work:-(

> Could we have a more complete patch?

Please find a submission attached. I hope it really fixes all decade,
century and millenium issues for extract and *_trunc functions on
interval
and other timestamp types. If someone could check that the results
are reasonnable, it would be great.

I indeed overlooked the fact that there were two functions. The patch
fixes the code so that both variants agree.

I added comments to interval extractions, because it relies on the C
division to have a negative remainder: -7/10 = 0 and remains -7.

As for *_trunc functions, I have chosen to put the first year of the
century or millennium: -100, 1, 101... 1001 2001 etc. Indeed, I don't
think it would make sense to put 2000 (last year of the 2nd millennium)
for rounding all years of the third millenium.

I also fixed the code so that all decades last 10 years and decade 199
means the 1990's.

I have added some tests that are relevant to deal with tricky cases. The
formula may be simplified, but all these cases must pass. Please keep
them.

Fabien Coelho

src/backend/utils/adt/timestamp.c
src/test/regress/expected/date.out
src/test/regress/sql/date.sql

index 3f6d431..a38bbda 100644 (file)
@@ -8,7 +8,7 @@
  *
  *
  * IDENTIFICATION
- *       $PostgreSQL: pgsql/src/backend/utils/adt/timestamp.c,v 1.109 2004/06/03 17:57:09 tgl Exp $
+ *       $PostgreSQL: pgsql/src/backend/utils/adt/timestamp.c,v 1.110 2004/08/20 03:45:13 momjian Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -2727,11 +2727,26 @@ timestamp_trunc(PG_FUNCTION_ARGS)
                                fsec = 0;
                                break;
                        case DTK_MILLENNIUM:
-                               tm->tm_year = (tm->tm_year / 1000) * 1000;
+                               /* see comments in timestamptz_trunc */
+                               if (tm->tm_year > 0)
+                                       tm->tm_year = ((tm->tm_year+999) / 1000) * 1000 - 999;
+                               else
+                                       tm->tm_year = - ((999 - (tm->tm_year-1))/1000) * 1000 + 1;
                        case DTK_CENTURY:
-                               tm->tm_year = (tm->tm_year / 100) * 100;
+                               /* see comments in timestamptz_trunc */
+                               if (tm->tm_year > 0)
+                                       tm->tm_year = ((tm->tm_year+99) / 100) * 100 - 99;
+                               else
+                                       tm->tm_year = - ((99 - (tm->tm_year-1))/100) * 100 + 1;
                        case DTK_DECADE:
-                               tm->tm_year = (tm->tm_year / 10) * 10;
+                               /* see comments in timestamptz_trunc */
+                               if (val != DTK_MILLENNIUM && val != DTK_CENTURY)
+                               {
+                                       if (tm->tm_year > 0)
+                                               tm->tm_year = (tm->tm_year / 10) * 10;
+                                       else
+                                               tm->tm_year = - ((8-(tm->tm_year-1)) / 10) * 10;
+                               }
                        case DTK_YEAR:
                                tm->tm_mon = 1;
                        case DTK_QUARTER:
@@ -2830,12 +2845,33 @@ timestamptz_trunc(PG_FUNCTION_ARGS)
                                tm->tm_sec = 0;
                                fsec = 0;
                                break;
+                               /* one may consider DTK_THOUSAND and DTK_HUNDRED... */
                        case DTK_MILLENNIUM:
-                               tm->tm_year = (tm->tm_year / 1000) * 1000;
+                               /* truncating to the millennium? what is this supposed to mean?
+                                * let us put the first year of the millennium... 
+                                * i.e. -1000, 1, 1001, 2001...
+                                */
+                               if (tm->tm_year > 0)
+                                       tm->tm_year = ((tm->tm_year+999) / 1000) * 1000 - 999;
+                               else
+                                       tm->tm_year = - ((999 - (tm->tm_year-1))/1000) * 1000 + 1;
                        case DTK_CENTURY:
-                               tm->tm_year = (tm->tm_year / 100) * 100;
+                               /* truncating to the century? as above: -100, 1, 101... */
+                               if (tm->tm_year > 0)
+                                       tm->tm_year = ((tm->tm_year+99) / 100) * 100 - 99 ;
+                               else
+                                       tm->tm_year = - ((99 - (tm->tm_year-1))/100) * 100 + 1;
                        case DTK_DECADE:
-                               tm->tm_year = (tm->tm_year / 10) * 10;
+                               /* truncating to the decade? first year of the decade.
+                                * must not be applied if year was truncated before!
+                                */
+                               if (val != DTK_MILLENNIUM && val != DTK_CENTURY)
+                               {
+                                       if (tm->tm_year > 0)
+                                               tm->tm_year = (tm->tm_year / 10) * 10;
+                                       else
+                                               tm->tm_year = - ((8-(tm->tm_year-1)) / 10) * 10;
+                               }
                        case DTK_YEAR:
                                tm->tm_mon = 1;
                        case DTK_QUARTER:
@@ -2923,10 +2959,13 @@ interval_trunc(PG_FUNCTION_ARGS)
                        switch (val)
                        {
                                case DTK_MILLENNIUM:
+                                       /* caution: C division may have negative remainder */
                                        tm->tm_year = (tm->tm_year / 1000) * 1000;
                                case DTK_CENTURY:
+                                       /* caution: C division may have negative remainder */
                                        tm->tm_year = (tm->tm_year / 100) * 100;
                                case DTK_DECADE:
+                                       /* caution: C division may have negative remainder */
                                        tm->tm_year = (tm->tm_year / 10) * 10;
                                case DTK_YEAR:
                                        tm->tm_mon = 0;
@@ -3221,7 +3260,14 @@ timestamp_part(PG_FUNCTION_ARGS)
                                break;
 
                        case DTK_DECADE:
-                               result = (tm->tm_year / 10);
+                               /* what is a decade wrt dates?
+                                * let us assume that decade 199 is 1990 thru 1999...
+                                * decade 0 starts on year 1 BC, and -1 is 11 BC thru 2 BC...
+                                */
+                               if (tm->tm_year>=0)
+                                       result = (tm->tm_year / 10);
+                               else
+                                       result = -((8-(tm->tm_year-1)) / 10);
                                break;
 
                        case DTK_CENTURY:
@@ -3232,7 +3278,7 @@ timestamp_part(PG_FUNCTION_ARGS)
                                if (tm->tm_year > 0)
                                        result = ((tm->tm_year+99) / 100);
                                else
-                                       /* caution: C division may yave negative remainder */
+                                       /* caution: C division may have negative remainder */
                                        result = - ((99 - (tm->tm_year-1))/100);
                                break;
 
@@ -3445,15 +3491,27 @@ timestamptz_part(PG_FUNCTION_ARGS)
                                break;
 
                        case DTK_DECADE:
-                               result = (tm->tm_year / 10);
+                               /* see comments in timestamp_part */
+                               if (tm->tm_year>0)
+                                       result = (tm->tm_year / 10);
+                               else
+                                       result = - ((8-(tm->tm_year-1)) / 10);
                                break;
 
                        case DTK_CENTURY:
-                               result = (tm->tm_year / 100);
+                               /* see comments in timestamp_part */
+                               if (tm->tm_year > 0)
+                                       result = ((tm->tm_year+99) / 100);
+                               else
+                                       result = - ((99 - (tm->tm_year-1))/100);
                                break;
 
                        case DTK_MILLENNIUM:
-                               result = (tm->tm_year / 1000);
+                               /* see comments in timestamp_part */
+                               if (tm->tm_year > 0)
+                                       result = ((tm->tm_year+999) / 1000);
+                               else
+                                       result = - ((999 - (tm->tm_year-1))/1000);
                                break;
 
                        case DTK_JULIAN:
@@ -3606,14 +3664,17 @@ interval_part(PG_FUNCTION_ARGS)
                                        break;
 
                                case DTK_DECADE:
+                                       /* caution: C division may have negative remainder */
                                        result = (tm->tm_year / 10);
                                        break;
 
                                case DTK_CENTURY:
+                                       /* caution: C division may have negative remainder */
                                        result = (tm->tm_year / 100);
                                        break;
 
                                case DTK_MILLENNIUM:
+                                       /* caution: C division may have negative remainder */
                                        result = (tm->tm_year / 1000);
                                        break;
 
index 77bbdb9..24018de 100644 (file)
@@ -930,3 +930,152 @@ SELECT EXTRACT(MILLENNIUM FROM CURRENT_DATE);         --  3
          3
 (1 row)
 
+--
+-- decade
+--
+SELECT EXTRACT(DECADE FROM DATE '1994-12-25');    -- 199
+ date_part 
+-----------
+       199
+(1 row)
+
+SELECT EXTRACT(DECADE FROM DATE '0010-01-01');    --   1
+ date_part 
+-----------
+         1
+(1 row)
+
+SELECT EXTRACT(DECADE FROM DATE '0009-12-31');    --   0
+ date_part 
+-----------
+         0
+(1 row)
+
+SELECT EXTRACT(DECADE FROM DATE '0001-01-01 BC'); --   0
+ date_part 
+-----------
+         0
+(1 row)
+
+SELECT EXTRACT(DECADE FROM DATE '0002-12-31 BC'); --  -1
+ date_part 
+-----------
+        -1
+(1 row)
+
+SELECT EXTRACT(DECADE FROM DATE '0011-01-01 BC'); --  -1
+ date_part 
+-----------
+        -1
+(1 row)
+
+SELECT EXTRACT(DECADE FROM DATE '0012-12-31 BC'); --  -2
+ date_part 
+-----------
+        -2
+(1 row)
+
+--
+-- some other types:
+--
+-- on a timestamp.
+SELECT EXTRACT(CENTURY FROM NOW())>=21 AS True;       -- true
+ true 
+------
+ t
+(1 row)
+
+SELECT EXTRACT(CENTURY FROM TIMESTAMP '1970-03-20 04:30:00.00000'); -- 20
+ date_part 
+-----------
+        20
+(1 row)
+
+-- on an interval
+SELECT EXTRACT(CENTURY FROM INTERVAL '100 y');  -- 1
+ date_part 
+-----------
+         1
+(1 row)
+
+SELECT EXTRACT(CENTURY FROM INTERVAL '99 y');   -- 0
+ date_part 
+-----------
+         0
+(1 row)
+
+SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y');  -- 0
+ date_part 
+-----------
+         0
+(1 row)
+
+SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y'); -- -1
+ date_part 
+-----------
+        -1
+(1 row)
+
+--
+-- test trunc function!
+--
+SELECT DATE_TRUNC('MILLENNIUM', TIMESTAMP '1970-03-20 04:30:00.00000'); -- 1001
+        date_trunc        
+--------------------------
+ Thu Jan 01 00:00:00 1001
+(1 row)
+
+SELECT DATE_TRUNC('MILLENNIUM', DATE '1970-03-20'); -- 1001-01-01
+          date_trunc          
+------------------------------
+ Thu Jan 01 00:00:00 1001 PST
+(1 row)
+
+SELECT DATE_TRUNC('CENTURY', TIMESTAMP '1970-03-20 04:30:00.00000'); -- 1901
+        date_trunc        
+--------------------------
+ Tue Jan 01 00:00:00 1901
+(1 row)
+
+SELECT DATE_TRUNC('CENTURY', DATE '1970-03-20'); -- 1901
+          date_trunc          
+------------------------------
+ Tue Jan 01 00:00:00 1901 PST
+(1 row)
+
+SELECT DATE_TRUNC('CENTURY', DATE '2004-08-10'); -- 2001-01-01
+          date_trunc          
+------------------------------
+ Mon Jan 01 00:00:00 2001 PST
+(1 row)
+
+SELECT DATE_TRUNC('CENTURY', DATE '0002-02-04'); -- 0001-01-01
+          date_trunc          
+------------------------------
+ Mon Jan 01 00:00:00 0001 PST
+(1 row)
+
+SELECT DATE_TRUNC('CENTURY', DATE '0055-08-10 BC'); -- 0100-01-01 BC
+           date_trunc            
+---------------------------------
+ Tue Jan 01 00:00:00 0100 PST BC
+(1 row)
+
+SELECT DATE_TRUNC('DECADE', DATE '1993-12-25'); -- 1990-01-01
+          date_trunc          
+------------------------------
+ Mon Jan 01 00:00:00 1990 PST
+(1 row)
+
+SELECT DATE_TRUNC('DECADE', DATE '0004-12-25'); -- 0001-01-01 BC
+           date_trunc            
+---------------------------------
+ Sat Jan 01 00:00:00 0001 PST BC
+(1 row)
+
+SELECT DATE_TRUNC('DECADE', DATE '0002-12-31 BC'); -- 0011-01-01 BC
+           date_trunc            
+---------------------------------
+ Mon Jan 01 00:00:00 0011 PST BC
+(1 row)
+
index a3cad66..97ddbe9 100644 (file)
@@ -235,3 +235,37 @@ SELECT EXTRACT(MILLENNIUM FROM DATE '2000-12-31');    --  2
 SELECT EXTRACT(MILLENNIUM FROM DATE '2001-01-01');    --  3
 -- next test to be fixed on the turn of the next millennium;-)
 SELECT EXTRACT(MILLENNIUM FROM CURRENT_DATE);         --  3
+--
+-- decade
+--
+SELECT EXTRACT(DECADE FROM DATE '1994-12-25');    -- 199
+SELECT EXTRACT(DECADE FROM DATE '0010-01-01');    --   1
+SELECT EXTRACT(DECADE FROM DATE '0009-12-31');    --   0
+SELECT EXTRACT(DECADE FROM DATE '0001-01-01 BC'); --   0
+SELECT EXTRACT(DECADE FROM DATE '0002-12-31 BC'); --  -1
+SELECT EXTRACT(DECADE FROM DATE '0011-01-01 BC'); --  -1
+SELECT EXTRACT(DECADE FROM DATE '0012-12-31 BC'); --  -2
+--
+-- some other types:
+--
+-- on a timestamp.
+SELECT EXTRACT(CENTURY FROM NOW())>=21 AS True;       -- true
+SELECT EXTRACT(CENTURY FROM TIMESTAMP '1970-03-20 04:30:00.00000'); -- 20
+-- on an interval
+SELECT EXTRACT(CENTURY FROM INTERVAL '100 y');  -- 1
+SELECT EXTRACT(CENTURY FROM INTERVAL '99 y');   -- 0
+SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y');  -- 0
+SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y'); -- -1
+--
+-- test trunc function!
+--
+SELECT DATE_TRUNC('MILLENNIUM', TIMESTAMP '1970-03-20 04:30:00.00000'); -- 1001
+SELECT DATE_TRUNC('MILLENNIUM', DATE '1970-03-20'); -- 1001-01-01
+SELECT DATE_TRUNC('CENTURY', TIMESTAMP '1970-03-20 04:30:00.00000'); -- 1901
+SELECT DATE_TRUNC('CENTURY', DATE '1970-03-20'); -- 1901
+SELECT DATE_TRUNC('CENTURY', DATE '2004-08-10'); -- 2001-01-01
+SELECT DATE_TRUNC('CENTURY', DATE '0002-02-04'); -- 0001-01-01
+SELECT DATE_TRUNC('CENTURY', DATE '0055-08-10 BC'); -- 0100-01-01 BC
+SELECT DATE_TRUNC('DECADE', DATE '1993-12-25'); -- 1990-01-01
+SELECT DATE_TRUNC('DECADE', DATE '0004-12-25'); -- 0001-01-01 BC
+SELECT DATE_TRUNC('DECADE', DATE '0002-12-31 BC'); -- 0011-01-01 BC