Re: [HACKERS] Date conversion using day of week - Mailing list pgsql-general

From Bruce Momjian
Subject Re: [HACKERS] Date conversion using day of week
Date
Msg-id 20120901211123.GA13618@momjian.us
Whole thread Raw
In response to Re: [HACKERS] Date conversion using day of week  (Brendan Jurd <direvus@gmail.com>)
List pgsql-general
On Fri, Apr  1, 2011 at 02:27:02AM +1100, Brendan Jurd wrote:
> On 1 April 2011 02:00, Adrian Klaver <adrian.klaver@gmail.com> wrote:
> > On Wednesday, March 30, 2011 8:39:25 pm Brendan Jurd wrote:
> >> If we wanted to make it "work", then I think the thing to do would be
> >> to add a new set of formatting tokens IDY, IDAY etc.  I don't like the
> >> idea of interpreting DY and co. differently depending on whether the
> >> other tokens happen to be ISO week or Gregorian.
> >
> > Just to play Devils advocate here, but why not? The day name is the same either
> > way, it is the index that changes. I am not sure why that could not be context
> > specific?
> >
>
> To be perfectly honest, it's mostly because I was hoping not to spend
> very much more of my time in formatting.c.  Every time I go in there I
> come out a little bit less sane.  I'm concerned that if I do anything
  -------------------------------

Agreed!

> further to it, I might inadvertently summon Chattur'gha or something.
> But since you went to the trouble of calling me on my laziness, let's
> take a look at the problem.
>
> At the time when the day-of-week token gets converted into a numeric
> value and put into the TmFromChar.d field, the code has no knowledge
> of whether the overall pattern is Gregorian or ISO (the DY field could
> well be at the front of the pattern, for example).
>
> Later on, in do_to_timestamp, the code expects the 'd' value to make
> sense given the mode (it should be zero-based on Sunday for Gregorian,
> or one-based on Monday for ISO).  That's all well and good *except* in
> the totally bizarre case raised by the OP.
>
> To resolve it, we could make TmFromChar.d always stored using the ISO
> convention (because zero then has the useful property of meaning "not
> set") and converted to the Gregorian convention as necessary in
> do_to_timestamp.

I did quite a bit if study on this and have a fix in the attached patch.
Brendan above is correct about the cause of the problems.  Basically,
'd' was sometimes numbered 1-7 with Monday as week start, and 'd' was at
other times 0-6 with Sunday as start.  Plus, zero was used to designate
"not supplied" in ISO tests.  Obviously the number and the start value
both caused problems.

The attached patch fixes this by using Gregorian 1-7 (Sunday=7) format
throughout, allowing any mix of Gregorian and ISO week designations.  It
is converted to ISO (or Unix format 0-6, Sunday=0) as needed.

Sample output:

    test=> select to_date('2011-13-MON', 'IYYY-IW-DY');
      to_date
    ------------
     2011-03-28
    (1 row)

    test=> select to_date('2011-13-SUN', 'IYYY-IW-DY');
      to_date
    ------------
     2011-04-03
    (1 row)

    test=> select to_date('2011-13-SAT', 'IYYY-IW-DY');
      to_date
    ------------
     2011-04-02
    (1 row)

    test=> select to_date('2011-13-1', 'IYYY-IW-ID');
      to_date
    ------------
     2011-03-28
    (1 row)

    test=> select to_date('2011-13-7', 'IYYY-IW-ID');
      to_date
    ------------
     2011-04-03
    (1 row)

    test=> select to_date('2011-13-0', 'IYYY-IW-ID');
      to_date
    ------------
     2011-04-03
    (1 row)

--
  Bruce Momjian  <bruce@momjian.us>        http://momjian.us
  EnterpriseDB                             http://enterprisedb.com

  + It's impossible for everything to be true. +

Attachment

pgsql-general by date:

Previous
From: Stefan Kaltenbrunner
Date:
Subject: Re: "Too far out of the mainstream"
Next
From: Bruce Momjian
Date:
Subject: Re: [HACKERS] Date conversion using day of week