Thread: Proposed patch: make SQL interval-literal syntax work per spec
Over in that TPC-H thread, I was bemoaning once again the never-finished support for SQL-spec interval literals. I decided to go look at exactly how unfinished it was, and it turns out that it's actually pretty close. Hence the attached proposed patch ;-) The main gating factor is that coerce_type doesn't want to pass typmod through to the datatype input function when converting a literal constant. This is necessary for certain types like char and varchar but loses badly for interval. I have a feeling that we changed that behavior after Tom Lockhart left the project, which may mean that interval wasn't quite as broken when he left it as it is today. Anyway, the attached patch simply hardwires a special case for INTERVAL. Given that this is reflective of a special case in the standard, and that there's no very good reason for anyone else to design a datatype that acts this way, I don't feel too bad about such a hack; but has anyone got a better idea? After that it's just a matter of getting DecodeInterval to do the right things; and it turns out that about half the logic for SQL-spec input syntax was there already. Almost the only thing I had to change was the code to decide what a plain integer field at the right end of the input means. The patch includes regression test changes that illustrate what it does. I am not sure about some of the corner cases --- anyone want to see if their understanding of the spec for <interval string> is different? There is still some unfinished business if anyone wants to make it really exactly 100% spec compliant. In particular the spec seems to allow a minus sign *outside* the string literal, and if I'm reading it right, a precision spec in combination with field restrictions ought to look like INTERVAL '...' DAY TO SECOND(3) not INTERVAL(3) '...' DAY TO SECOND. However, for these you'll get a syntax error instead of silently wrong answers if you try to use the other syntax, so it's not quite as pernicious as the matters addressed here. regards, tom lane Index: src/backend/parser/parse_coerce.c =================================================================== RCS file: /cvsroot/pgsql/src/backend/parser/parse_coerce.c,v retrieving revision 2.166 diff -c -r2.166 parse_coerce.c *** src/backend/parser/parse_coerce.c 1 Sep 2008 20:42:44 -0000 2.166 --- src/backend/parser/parse_coerce.c 9 Sep 2008 23:47:59 -0000 *************** *** 179,184 **** --- 179,185 ---- Const *newcon = makeNode(Const); Oid baseTypeId; int32 baseTypeMod; + int32 inputTypeMod; Type targetType; ParseCallbackState pcbstate; *************** *** 190,202 **** * what we want here. The needed check will be applied properly * inside coerce_to_domain(). */ ! baseTypeMod = -1; baseTypeId = getBaseTypeAndTypmod(targetTypeId, &baseTypeMod); targetType = typeidType(baseTypeId); newcon->consttype = baseTypeId; ! newcon->consttypmod = -1; newcon->constlen = typeLen(targetType); newcon->constbyval = typeByVal(targetType); newcon->constisnull = con->constisnull; --- 191,217 ---- * what we want here. The needed check will be applied properly * inside coerce_to_domain(). */ ! baseTypeMod = targetTypeMod; baseTypeId = getBaseTypeAndTypmod(targetTypeId, &baseTypeMod); + /* + * For most types we pass typmod -1 to the input routine, because + * existing input routines follow implicit-coercion semantics for + * length checks, which is not always what we want here. Any length + * constraint will be applied later by our caller. An exception + * however is the INTERVAL type, for which we *must* pass the typmod + * or it won't be able to obey the bizarre SQL-spec input rules. + * (Ugly as sin, but so is this part of the spec...) + */ + if (baseTypeId == INTERVALOID) + inputTypeMod = baseTypeMod; + else + inputTypeMod = -1; + targetType = typeidType(baseTypeId); newcon->consttype = baseTypeId; ! newcon->consttypmod = inputTypeMod; newcon->constlen = typeLen(targetType); newcon->constbyval = typeByVal(targetType); newcon->constisnull = con->constisnull; *************** *** 215,234 **** setup_parser_errposition_callback(&pcbstate, pstate, con->location); /* - * We pass typmod -1 to the input routine, primarily because existing - * input routines follow implicit-coercion semantics for length - * checks, which is not always what we want here. Any length - * constraint will be applied later by our caller. - * * We assume here that UNKNOWN's internal representation is the same * as CSTRING. */ if (!con->constisnull) newcon->constvalue = stringTypeDatum(targetType, DatumGetCString(con->constvalue), ! -1); else ! newcon->constvalue = stringTypeDatum(targetType, NULL, -1); cancel_parser_errposition_callback(&pcbstate); --- 230,246 ---- setup_parser_errposition_callback(&pcbstate, pstate, con->location); /* * We assume here that UNKNOWN's internal representation is the same * as CSTRING. */ if (!con->constisnull) newcon->constvalue = stringTypeDatum(targetType, DatumGetCString(con->constvalue), ! inputTypeMod); else ! newcon->constvalue = stringTypeDatum(targetType, ! NULL, ! inputTypeMod); cancel_parser_errposition_callback(&pcbstate); Index: src/backend/utils/adt/datetime.c =================================================================== RCS file: /cvsroot/pgsql/src/backend/utils/adt/datetime.c,v retrieving revision 1.190 diff -c -r1.190 datetime.c *** src/backend/utils/adt/datetime.c 9 Jun 2008 19:34:02 -0000 1.190 --- src/backend/utils/adt/datetime.c 9 Sep 2008 23:48:00 -0000 *************** *** 35,42 **** static int DecodeNumberField(int len, char *str, int fmask, int *tmask, struct pg_tm * tm, fsec_t *fsec, bool *is2digits); ! static int DecodeTime(char *str, int fmask, int *tmask, ! struct pg_tm * tm, fsec_t *fsec); static int DecodeTimezone(char *str, int *tzp); static const datetkn *datebsearch(const char *key, const datetkn *base, int nel); static int DecodeDate(char *str, int fmask, int *tmask, bool *is2digits, --- 35,42 ---- static int DecodeNumberField(int len, char *str, int fmask, int *tmask, struct pg_tm * tm, fsec_t *fsec, bool *is2digits); ! static int DecodeTime(char *str, int fmask, int range, ! int *tmask, struct pg_tm * tm, fsec_t *fsec); static int DecodeTimezone(char *str, int *tzp); static const datetkn *datebsearch(const char *key, const datetkn *base, int nel); static int DecodeDate(char *str, int fmask, int *tmask, bool *is2digits, *************** *** 832,838 **** break; case DTK_TIME: ! dterr = DecodeTime(field[i], fmask, &tmask, tm, fsec); if (dterr) return dterr; --- 832,839 ---- break; case DTK_TIME: ! dterr = DecodeTime(field[i], fmask, INTERVAL_FULL_RANGE, ! &tmask, tm, fsec); if (dterr) return dterr; *************** *** 1563,1568 **** --- 1564,1570 ---- case DTK_TIME: dterr = DecodeTime(field[i], (fmask | DTK_DATE_M), + INTERVAL_FULL_RANGE, &tmask, tm, fsec); if (dterr) return dterr; *************** *** 2224,2230 **** * used to represent time spans. */ static int ! DecodeTime(char *str, int fmask, int *tmask, struct pg_tm * tm, fsec_t *fsec) { char *cp; --- 2226,2233 ---- * used to represent time spans. */ static int ! DecodeTime(char *str, int fmask, int range, ! int *tmask, struct pg_tm * tm, fsec_t *fsec) { char *cp; *************** *** 2245,2250 **** --- 2248,2260 ---- { tm->tm_sec = 0; *fsec = 0; + /* If it's a MINUTE TO SECOND interval, take 2 fields as being mm:ss */ + if (range == (INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND))) + { + tm->tm_sec = tm->tm_min; + tm->tm_min = tm->tm_hour; + tm->tm_hour = 0; + } } else if (*cp != ':') return DTERR_BAD_FORMAT; *************** *** 2705,2711 **** * preceding an hh:mm:ss field. - thomas 1998-04-30 */ int ! DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct pg_tm * tm, fsec_t *fsec) { bool is_before = FALSE; char *cp; --- 2715,2722 ---- * preceding an hh:mm:ss field. - thomas 1998-04-30 */ int ! DecodeInterval(char **field, int *ftype, int nf, int range, ! int *dtype, struct pg_tm * tm, fsec_t *fsec) { bool is_before = FALSE; char *cp; *************** *** 2734,2740 **** switch (ftype[i]) { case DTK_TIME: ! dterr = DecodeTime(field[i], fmask, &tmask, tm, fsec); if (dterr) return dterr; type = DTK_DAY; --- 2745,2752 ---- switch (ftype[i]) { case DTK_TIME: ! dterr = DecodeTime(field[i], fmask, range, ! &tmask, tm, fsec); if (dterr) return dterr; type = DTK_DAY; *************** *** 2757,2763 **** while (*cp != '\0' && *cp != ':' && *cp != '.') cp++; if (*cp == ':' && ! DecodeTime(field[i] + 1, fmask, &tmask, tm, fsec) == 0) { if (*field[i] == '-') { --- 2769,2776 ---- while (*cp != '\0' && *cp != ':' && *cp != '.') cp++; if (*cp == ':' && ! DecodeTime(field[i] + 1, fmask, INTERVAL_FULL_RANGE, ! &tmask, tm, fsec) == 0) { if (*field[i] == '-') { *************** *** 2796,2814 **** type = DTK_HOUR; } } ! /* DROP THROUGH */ case DTK_DATE: case DTK_NUMBER: errno = 0; val = strtoi(field[i], &cp, 10); if (errno == ERANGE) return DTERR_FIELD_OVERFLOW; ! if (type == IGNORE_DTF) ! type = DTK_SECOND; ! if (*cp == '.') { fval = strtod(cp, &cp); if (*cp != '\0') --- 2809,2874 ---- type = DTK_HOUR; } } ! /* FALL THROUGH */ case DTK_DATE: case DTK_NUMBER: + if (type == IGNORE_DTF) + { + /* use typmod to decide what rightmost integer field is */ + switch (range) + { + case INTERVAL_MASK(YEAR): + type = DTK_YEAR; + break; + case INTERVAL_MASK(MONTH): + case INTERVAL_MASK(YEAR) | INTERVAL_MASK(MONTH): + type = DTK_MONTH; + break; + case INTERVAL_MASK(DAY): + type = DTK_DAY; + break; + case INTERVAL_MASK(HOUR): + case INTERVAL_MASK(DAY) | INTERVAL_MASK(HOUR): + case INTERVAL_MASK(DAY) | INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE): + case INTERVAL_MASK(DAY) | INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND): + type = DTK_HOUR; + break; + case INTERVAL_MASK(MINUTE): + case INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE): + type = DTK_MINUTE; + break; + case INTERVAL_MASK(SECOND): + case INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND): + case INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND): + type = DTK_SECOND; + break; + default: + type = DTK_SECOND; + break; + } + } + errno = 0; val = strtoi(field[i], &cp, 10); if (errno == ERANGE) return DTERR_FIELD_OVERFLOW; ! if (*cp == '-') ! { ! /* SQL "years-months" syntax */ ! int val2; ! val2 = strtoi(cp + 1, &cp, 10); ! if (errno == ERANGE || val2 < 0 || val2 >= MONTHS_PER_YEAR) ! return DTERR_FIELD_OVERFLOW; ! if (*cp != '\0') ! return DTERR_BAD_FORMAT; ! type = DTK_MONTH; ! val = val * MONTHS_PER_YEAR + val2; ! fval = 0; ! } ! else if (*cp == '.') { fval = strtod(cp, &cp); if (*cp != '\0') *************** *** 2896,2901 **** --- 2956,2962 ---- #endif } tmask = DTK_M(HOUR); + type = DTK_DAY; break; case DTK_DAY: Index: src/backend/utils/adt/nabstime.c =================================================================== RCS file: /cvsroot/pgsql/src/backend/utils/adt/nabstime.c,v retrieving revision 1.155 diff -c -r1.155 nabstime.c *** src/backend/utils/adt/nabstime.c 25 Mar 2008 22:42:44 -0000 1.155 --- src/backend/utils/adt/nabstime.c 9 Sep 2008 23:48:00 -0000 *************** *** 632,638 **** dterr = ParseDateTime(str, workbuf, sizeof(workbuf), field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) ! dterr = DecodeInterval(field, ftype, nf, &dtype, tm, &fsec); if (dterr != 0) { if (dterr == DTERR_FIELD_OVERFLOW) --- 632,639 ---- dterr = ParseDateTime(str, workbuf, sizeof(workbuf), field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) ! dterr = DecodeInterval(field, ftype, nf, INTERVAL_FULL_RANGE, ! &dtype, tm, &fsec); if (dterr != 0) { if (dterr == DTERR_FIELD_OVERFLOW) Index: src/backend/utils/adt/timestamp.c =================================================================== RCS file: /cvsroot/pgsql/src/backend/utils/adt/timestamp.c,v retrieving revision 1.190 diff -c -r1.190 timestamp.c *** src/backend/utils/adt/timestamp.c 7 Jul 2008 18:09:46 -0000 1.190 --- src/backend/utils/adt/timestamp.c 9 Sep 2008 23:48:00 -0000 *************** *** 604,609 **** --- 604,610 ---- *tm = &tt; int dtype; int nf; + int range; int dterr; char *field[MAXDATEFIELDS]; int ftype[MAXDATEFIELDS]; *************** *** 617,626 **** tm->tm_sec = 0; fsec = 0; dterr = ParseDateTime(str, workbuf, sizeof(workbuf), field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) ! dterr = DecodeInterval(field, ftype, nf, &dtype, tm, &fsec); if (dterr != 0) { if (dterr == DTERR_FIELD_OVERFLOW) --- 618,632 ---- tm->tm_sec = 0; fsec = 0; + if (typmod >= 0) + range = INTERVAL_RANGE(typmod); + else + range = INTERVAL_FULL_RANGE; + dterr = ParseDateTime(str, workbuf, sizeof(workbuf), field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) ! dterr = DecodeInterval(field, ftype, nf, range, &dtype, tm, &fsec); if (dterr != 0) { if (dterr == DTERR_FIELD_OVERFLOW) *************** *** 945,951 **** * Unspecified range and precision? Then not necessary to adjust. Setting * typmod to -1 is the convention for all types. */ ! if (typmod != -1) { int range = INTERVAL_RANGE(typmod); int precision = INTERVAL_PRECISION(typmod); --- 951,957 ---- * Unspecified range and precision? Then not necessary to adjust. Setting * typmod to -1 is the convention for all types. */ ! if (typmod >= 0) { int range = INTERVAL_RANGE(typmod); int precision = INTERVAL_PRECISION(typmod); Index: src/include/utils/datetime.h =================================================================== RCS file: /cvsroot/pgsql/src/include/utils/datetime.h,v retrieving revision 1.69 diff -c -r1.69 datetime.h *** src/include/utils/datetime.h 1 Jan 2008 19:45:59 -0000 1.69 --- src/include/utils/datetime.h 9 Sep 2008 23:48:00 -0000 *************** *** 290,296 **** int nf, int *dtype, struct pg_tm * tm, fsec_t *fsec, int *tzp); extern int DecodeInterval(char **field, int *ftype, ! int nf, int *dtype, struct pg_tm * tm, fsec_t *fsec); extern void DateTimeParseError(int dterr, const char *str, const char *datatype); --- 290,296 ---- int nf, int *dtype, struct pg_tm * tm, fsec_t *fsec, int *tzp); extern int DecodeInterval(char **field, int *ftype, ! int nf, int range, int *dtype, struct pg_tm * tm, fsec_t *fsec); extern void DateTimeParseError(int dterr, const char *str, const char *datatype); Index: src/test/regress/expected/interval.out =================================================================== RCS file: /cvsroot/pgsql/src/test/regress/expected/interval.out,v retrieving revision 1.20 diff -c -r1.20 interval.out *** src/test/regress/expected/interval.out 1 Sep 2008 20:42:46 -0000 1.20 --- src/test/regress/expected/interval.out 9 Sep 2008 23:48:00 -0000 *************** *** 361,363 **** --- 361,520 ---- ERROR: invalid input syntax for type interval: "1:20:05 5 microseconds" LINE 1: SELECT '1:20:05 5 microseconds'::interval; ^ + SELECT interval '1-2'; -- SQL year-month literal + interval + --------------- + 1 year 2 mons + (1 row) + + -- test SQL-spec syntaxes for restricted field sets + SELECT interval '1' year; + interval + ---------- + 1 year + (1 row) + + SELECT interval '2' month; + interval + ---------- + 2 mons + (1 row) + + SELECT interval '3' day; + interval + ---------- + 3 days + (1 row) + + SELECT interval '4' hour; + interval + ---------- + 04:00:00 + (1 row) + + SELECT interval '5' minute; + interval + ---------- + 00:05:00 + (1 row) + + SELECT interval '6' second; + interval + ---------- + 00:00:06 + (1 row) + + SELECT interval '1' year to month; + interval + ---------- + 1 mon + (1 row) + + SELECT interval '1-2' year to month; + interval + --------------- + 1 year 2 mons + (1 row) + + SELECT interval '1 2' day to hour; + interval + ---------------- + 1 day 02:00:00 + (1 row) + + SELECT interval '1 2:03' day to hour; + interval + ---------------- + 1 day 02:00:00 + (1 row) + + SELECT interval '1 2:03:04' day to hour; + interval + ---------------- + 1 day 02:00:00 + (1 row) + + SELECT interval '1 2' day to minute; + interval + ---------------- + 1 day 02:00:00 + (1 row) + + SELECT interval '1 2:03' day to minute; + interval + ---------------- + 1 day 02:03:00 + (1 row) + + SELECT interval '1 2:03:04' day to minute; + interval + ---------------- + 1 day 02:03:00 + (1 row) + + SELECT interval '1 2' day to second; + interval + ---------------- + 1 day 02:00:00 + (1 row) + + SELECT interval '1 2:03' day to second; + interval + ---------------- + 1 day 02:03:00 + (1 row) + + SELECT interval '1 2:03:04' day to second; + interval + ---------------- + 1 day 02:03:04 + (1 row) + + SELECT interval '1 2' hour to minute; + ERROR: invalid input syntax for type interval: "1 2" + LINE 1: SELECT interval '1 2' hour to minute; + ^ + SELECT interval '1 2:03' hour to minute; + interval + ---------- + 02:03:00 + (1 row) + + SELECT interval '1 2:03:04' hour to minute; + interval + ---------- + 02:03:00 + (1 row) + + SELECT interval '1 2' hour to second; + ERROR: invalid input syntax for type interval: "1 2" + LINE 1: SELECT interval '1 2' hour to second; + ^ + SELECT interval '1 2:03' hour to second; + interval + ---------- + 02:03:00 + (1 row) + + SELECT interval '1 2:03:04' hour to second; + interval + ---------- + 02:03:04 + (1 row) + + SELECT interval '1 2' minute to second; + ERROR: invalid input syntax for type interval: "1 2" + LINE 1: SELECT interval '1 2' minute to second; + ^ + SELECT interval '1 2:03' minute to second; + interval + ---------- + 00:02:03 + (1 row) + + SELECT interval '1 2:03:04' minute to second; + interval + ---------- + 00:03:04 + (1 row) + Index: src/test/regress/sql/interval.sql =================================================================== RCS file: /cvsroot/pgsql/src/test/regress/sql/interval.sql,v retrieving revision 1.12 diff -c -r1.12 interval.sql *** src/test/regress/sql/interval.sql 29 May 2007 04:58:43 -0000 1.12 --- src/test/regress/sql/interval.sql 9 Sep 2008 23:48:00 -0000 *************** *** 126,129 **** SELECT '1 second 2 seconds'::interval; -- error SELECT '10 milliseconds 20 milliseconds'::interval; -- error SELECT '5.5 seconds 3 milliseconds'::interval; -- error ! SELECT '1:20:05 5 microseconds'::interval; -- error \ No newline at end of file --- 126,158 ---- SELECT '1 second 2 seconds'::interval; -- error SELECT '10 milliseconds 20 milliseconds'::interval; -- error SELECT '5.5 seconds 3 milliseconds'::interval; -- error ! SELECT '1:20:05 5 microseconds'::interval; -- error ! SELECT interval '1-2'; -- SQL year-month literal ! ! -- test SQL-spec syntaxes for restricted field sets ! SELECT interval '1' year; ! SELECT interval '2' month; ! SELECT interval '3' day; ! SELECT interval '4' hour; ! SELECT interval '5' minute; ! SELECT interval '6' second; ! SELECT interval '1' year to month; ! SELECT interval '1-2' year to month; ! SELECT interval '1 2' day to hour; ! SELECT interval '1 2:03' day to hour; ! SELECT interval '1 2:03:04' day to hour; ! SELECT interval '1 2' day to minute; ! SELECT interval '1 2:03' day to minute; ! SELECT interval '1 2:03:04' day to minute; ! SELECT interval '1 2' day to second; ! SELECT interval '1 2:03' day to second; ! SELECT interval '1 2:03:04' day to second; ! SELECT interval '1 2' hour to minute; ! SELECT interval '1 2:03' hour to minute; ! SELECT interval '1 2:03:04' hour to minute; ! SELECT interval '1 2' hour to second; ! SELECT interval '1 2:03' hour to second; ! SELECT interval '1 2:03:04' hour to second; ! SELECT interval '1 2' minute to second; ! SELECT interval '1 2:03' minute to second; ! SELECT interval '1 2:03:04' minute to second;
>>> Tom Lane <tgl@sss.pgh.pa.us> wrote: > The patch includes regression test changes that illustrate what it does. > I am not sure about some of the corner cases --- anyone want to see if > their understanding of the spec for <interval string> is different? The patch seems to support extensions to the standard. (1) In the spec, an interval value or literal must be either year-month or day-time. (I guess they didn't want to try to deal with the sticky issues of what it means to have an interval of, for example, seven months and three days -- since an interval has no sense of which seven months.) (2) The interval qualifier is not optional in the spec. (3) It seems to me that they were requiring that there be a one-to-one match between the fields specified in the interval qualifier and the fields present in the interval string. (4) I'm not 100% sure on this one, but it seemed to me that they were requiring year to be four digits and other components (except for fractional seconds) to be two digits. So long as they are documented, there's nothing wrong with extensions. Nothing I saw suggests that legal interval literals would be misinterpreted. > There is still some unfinished business if anyone wants to make it > really exactly 100% spec compliant. In particular the spec seems to > allow a minus sign *outside* the string literal, I agree. They go so far as to point out how it should be interpreted if the minus is present in both allowed locations (both inside and outside the quotes): 5) The <sign> in a <signed numeric literal> or an <interval literal> is a monadic arithmetic operator. The monadic arithmetic operators + and * specify monadic plus and monadic minus, respectively. If neither monadic plus nor monadic minus are specified in a <signed numeric literal> or an <interval literal>, or if monadic plus is specified, then the literal is positive. If monadic minus is specified in a <signed numeric literal> or <interval literal>, then the literal is negative. If <sign> is specified in both possible locations in an <interval literal>, then the sign of the literal is determined by normal mathematical interpretation of multiple sign operators. > and if I'm reading it > right, a precision spec in combination with field restrictions ought to > look like INTERVAL '...' DAY TO SECOND(3) not INTERVAL(3) '...' DAY TO > SECOND. Agreed. > However, for these you'll get a syntax error instead of > silently wrong answers if you try to use the other syntax, so it's not > quite as pernicious as the matters addressed here. Agreed. -Kevin
>>> "Kevin Grittner" <Kevin.Grittner@wicourts.gov> wrote: > (4) I'm not 100% sure on this one, but it seemed to me that they were > requiring year to be four digits and other components (except for > fractional seconds) to be two digits. That can't be right. Maybe I saw that in datetime literal specs. Apologies. -Kevin
"Kevin Grittner" <Kevin.Grittner@wicourts.gov> writes: > Tom Lane <tgl@sss.pgh.pa.us> wrote: >> I am not sure about some of the corner cases --- anyone want to see if >> their understanding of the spec for <interval string> is different? > The patch seems to support extensions to the standard. Right. All of these were extensions that already existed in PG. > (3) It seems to me that they were requiring that there be a > one-to-one match between the fields specified in the interval > qualifier and the fields present in the interval string. Yeah. I couldn't actually find any such statement in SQL92, but the SQL:2008 draft has this at 5.3 rule 30: 30)Let N be the number of <primary datetime field>s in the precision of the <interval literal>, as specified by <intervalqualifier>. The <interval literal> being defined shall contain N datetime components. and at rule 34: 34)Within the definition of an <interval literal> that contains a <year-month literal>, the <interval qualifier> shall notspecify DAY, HOUR, MINUTE, or SECOND. Within the definition of an <interval literal> that contains a <day-time literal>,the <interval qualifier> shall not specify YEAR or MONTH. This seems to be requiring that not only do you give the exact number of components, but the formatting must match the expectation. So anything we accept beyond that is gravy. I think that most of the "extension" cases were already being accepted in some form, and I'd be hesitant to take them out for fear of breaking existing applications. >> There is still some unfinished business if anyone wants to make it >> really exactly 100% spec compliant ... > I agree. I committed the patch as presented, and I think I might go take a quick look at the other two issues. What I suspect I'll find is that the minus sign issue isn't fixable without turning INTERVAL into a fully reserved word, which is probably a cure worse than the disease. However it might be fairly easy to get the grammar to allow the precision in either place. (We'd want to keep the old way working for backward compatibility.) regards, tom lane
> (1) In the spec, an interval value or literal must be either > year-month or day-time. (I guess they didn't want to try to deal with > the sticky issues of what it means to have an interval of, for > example, seven months and three days -- since an interval has no sense > of which seven months.) Note that, for usability reasons, Karel some time ago try-partitioned our intervals: year-month|day-week|hour-min-sec. --Josh
Tom Lane wrote: > "Kevin Grittner" <Kevin.Grittner@wicourts.gov> writes: >> Tom Lane <tgl@sss.pgh.pa.us> wrote: >>> I am not sure about some of the corner cases --- anyone want to see if >>> their understanding of the spec for <interval string> is different? > >> The patch seems to support extensions to the standard. > > Right. All of these were extensions that already existed in PG. Back a while ago (2003) there was some talk about replacing some of the non-standard extensions with shorthand forms of intervals with ISO 8601 intervals that have a similar but not-the-same shorthand. Interval ISO Postgres 8601 shorthand ----------------------------------------------------- '1 year 1 minute' 'P1YT1M' '1Y1M' '1year 1 month' 'P1Y1M' N/A http://archives.postgresql.org/pgsql-patches/2003-09/msg00119.php When I proposed we support the ISO-8601 standard shorthand, Tom recommended we rip out the old shorthand at the same time: http://archives.postgresql.org/pgsql-patches/2003-09/msg00134.php I've been maintaining a patch that supports these ISO-8601 intervals for a client. Back in 2003 I recall Peter said he wanted to see SQL standard intervals first. There were also discussions about selecting the output format. My old patch made this depend on datestyle; but it seems Tom preferred a separate GUC? http://archives.postgresql.org/pgsql-patches/2003-12/msg00257.php I see there's a TODO regarding ISO8601 intervals as well. I have a version of this patch for 8.2; but would be happy to bring it up-to-date if people want to re-consider it now.
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Back a while ago (2003) there was some talk about replacing > some of the non-standard extensions with shorthand forms of > intervals with ISO 8601 intervals that have a similar but > not-the-same shorthand. I think *replacement* would be a hard sell, as that would tick off all the existing users ;-). Now it seems like being able to accept either the 8601 syntax or the existing syntaxes on input wouldn't be tough at all, if you insist on the P prefix to distinguish; so that end of it should be easy enough. On the output side, seems like a GUC variable is the standard precedent here. I'd still vote against overloading DateStyle --- it does too much already --- but a separate variable for interval style wouldn't bother me. In fact, given that we are now somewhat SQL-compliant on interval input, a GUC that selected PG traditional, SQL-standard, or ISO 8601 interval output format seems like it could be a good idea. regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Back a while ago (2003) there was some talk about replacing >> some of the non-standard extensions with shorthand forms of >> intervals with ISO 8601 intervals that have a similar but >> not-the-same shorthand. > > I think *replacement* would be a hard sell, as that would tick off all > the existing users ;-). Now it seems like being able to accept either I originally submitted a patch that supported both, and I think you suggested replacing on the grounds that the old one was never documented, http://archives.postgresql.org/pgsql-patches/2003-09/msg00134.php "If we're going to support the real ISO spec, I'd suggestripping out any not-quite-there variant. http://archives.postgresql.org/pgsql-patches/2003-09/msg00121.php "I doubt anyone is using it, because it's completely undocumented." On the other hand, the company I was at was indeed originally using it, so I prefer that it stay in as well. Perhaps if there's a way to mark them as deprecated and post warnings in the log file if they're used. I think they should be removed eventually in a few releases, because they're quite confusing as they stand: Interval ISO Postgres 8601 shorthand ----------------------------------------------------- '1 year 1 minute' 'P1YT1M' '1Y1M' '1 year 1 month' 'P1Y1M' N/A > the 8601 syntax or the existing syntaxes on input wouldn't be tough > at all, if you insist on the P prefix to distinguish; so that end of ISO 8601 seems to me to require the P, so I think we would. > it should be easy enough. On the output side, seems like a GUC variable > is the standard precedent here. I'd still vote against overloading > DateStyle --- it does too much already --- but a separate variable for > interval style wouldn't bother me. In fact, given that we are now > somewhat SQL-compliant on interval input, a GUC that selected > PG traditional, SQL-standard, or ISO 8601 interval output format seems > like it could be a good idea. Great. I'm bringing my patch up-to-date with CVS now and adding the separate GUC.
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Tom Lane wrote: >> I think *replacement* would be a hard sell, as that would tick off all >> the existing users ;-). Now it seems like being able to accept either > I originally submitted a patch that supported both, and I think > you suggested replacing on the grounds that the old one was > never documented, Yeah, but that was five years ago, and someone remedied the oversight since then ... The other problem is that the SQL spec clearly defines an interval literal syntax, and it's not this ISO thing. So even without backward compatibility issues, 8601-only doesn't seem like it would fly. regards, tom lane
Tom Lane wrote: > > The other problem is that the SQL spec clearly defines an interval > literal syntax, and it's not this ISO thing. So even without backward > compatibility issues, 8601-only doesn't seem like it would fly. > Oh. I wasn't proposing 8601-only. Just the one-character shorthands like '1Y1M'::interval that postgresql interprets as "1 year one minute". No standard specifies anything close to that; and any similar standards ask to interpret that M as months instead of minutes.
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Oh. I wasn't proposing 8601-only. Just the one-character > shorthands like '1Y1M'::interval that postgresql interprets > as "1 year one minute". No standard specifies anything close > to that; and any similar standards ask to interpret that M as > months instead of minutes. Hmmm. I would say that the problem with that is not that it's nonstandard but that it's ambiguous. Our documentation about the interval type says: interval values can be written with the following syntax: [@] quantity unit [quantity unit...] [direction] Where: quantity is a number (possibly signed); unit is microsecond, millisecond, second, minute, hour, day, week, month,year, decade, century, millennium, or abbreviations or plurals of these units; direction can be ago or empty. The atsign (@) is optional noise. The amounts of different units are implicitly added up with appropriate sign accounting. agonegates all the fields. There isn't anything there that would suggest to a user that 'm' is well-defined as a unit, much less that it specifically means "minute" rather than one of the other options. What if we just tweak the code to reject ambiguous abbreviations? [ experiments a bit... ] Another interesting point is that "mo", which is a perfectly unique abbreviation, is rejected. Seems like the handling of abbreviations in this code could be improved. regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> '1Y1M'::interval ... minute ... month > Hmmm. I would say that the problem with that is not that it's > nonstandard but that it's ambiguous. Ah yes. > Our documentation...says..."or abbreviations". >...What if we just tweak the code to > reject ambiguous abbreviations? Good idea. I'll try that. > [ experiments a bit... ] Another interesting point is that "mo", > which is a perfectly unique abbreviation, is rejected. Seems like > the handling of abbreviations in this code could be improved. It looks like rather than abbreviations being any shorter form of a unit, it has an explicit list of abbreviations it likes (deltatktbl) in the beginning of datetime.c that forces "m" to "minute"? So losing the ambiguous ones should be very easy.
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> ... ISO 8601 intervals ... > > On the output side, seems like a GUC variable > is the standard precedent here. I'd still vote against overloading > DateStyle --- it does too much already --- but a separate variable for > interval style wouldn't bother me. In fact, given that we are now > somewhat SQL-compliant on interval input, a GUC that selected > PG traditional, SQL-standard, or ISO 8601 interval output format seems > like it could be a good idea. Is it OK that this seems to me it wouldn't be backward compatible with the current interval_out that looks to me to be using the DateStyle GUC? I supposed it could be made backward compatible if the new IntervalStyle GUC defaulted to a value of "guess_from_datestyle", but I fear an option like that might add rather than remove confusion.
Tom Lane wrote: > somewhat SQL-compliant on interval input, a GUC that selected > PG traditional, SQL-standard, or ISO 8601 interval output format seems > like it could be a good idea. Trying to do the SQL-standard output now, and have a question of what to do in the SQL-standard mode when trying to output an interval that as both a YEAR and a DAY component. AFAICT the SQL standard doesn't let you have both, so the "SQL-standard" output actually won't be.
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Trying to do the SQL-standard output now, and have a question > of what to do in the SQL-standard mode when trying to output > an interval that as both a YEAR and a DAY component. > AFAICT the SQL standard doesn't let you have both, so the > "SQL-standard" output actually won't be. The reason it's not SQL-standard is the data value isn't. So not a problem. Someone conforming to the spec limits on what he puts in will see spec-compliant output. I think all you need is 'yyy-mm dd hh:mm:ss' where you omit yyy-mm if zeroes, omit dd if zero, omit hh:mm:ss if zeroes (but maybe only if dd is also 0? otherwise your output is just dd which is uncomfortably ambiguous). regards, tom lane
Tom Lane wrote: > The reason it's not SQL-standard is the data value isn't. > So not a problem. Someone conforming to the spec limits on > what he puts in will see spec-compliant output. I think all > you need is 'yyy-mm dd hh:mm:ss' where you omit yyy-mm if > zeroes, omit dd if zero, omit hh:mm:ss if zeroes (but maybe > only if dd is also 0? otherwise your output is just dd which > is uncomfortably ambiguous). Great. That's what I'll do. Any convention or preference on the naming of the GUC? I assume "intervalstyle" is reasonable? Or thoughts regarding the current EncodeInterval() that's already using the "datestyle" GUC? pg82=# select interval '1'; interval ---------- 00:00:01 (1 row) pg82=# set datestyle='sql'; SET pg82=# select interval '1'; interval ---------- @ 1 sec (1 row)
Ron Mayer wrote: > Tom Lane wrote: >> you need is 'yyy-mm dd hh:mm:ss' where you omit yyy-mm if >> zeroes, omit dd if zero, omit hh:mm:ss if zeroes (but maybe >> only if dd is also 0? otherwise your output is just dd which >> is uncomfortably ambiguous). Oh, and if both parts are 0, I guess we desire the (more comfortable than the alternatives) '0'?
Tom Lane wrote: > I think all > you need is 'yyy-mm dd hh:mm:ss' where you omit yyy-mm if > zeroes, omit dd if zero, omit hh:mm:ss if zeroes (but maybe > only if dd is also 0? otherwise your output is just dd which > is uncomfortably ambiguous). Cool. I think I have it pretty much working with a new GUC "intervalstyle" that can take values of "sql_standard" that I think will output SQL standard interval literals when given a sql standardinterval. "iso_8601" that will output ISO 8601 "Time Intervals" of the "format with time-unit deignators", and "backward_compatible" that will output the same thing that postgres currently does that depends on thevalue of the DateStyle GUC. I'll add the documentation and regression tests and can submit a patch early next week. Oh. One more question is that under ecpg there seems to be a fair amount of near-duplicated code (EncodeDateTime, EncodeInterval) for turning dates and times and intervals to strings. Should those ECPG functions be made identical to the ones in the backend? Could those somehow share code with the backend for some of their work? Anyway - here's a quick test of the SQL Standard and ISO interval output as it stands right now... regression=# drop table test_intervals; DROP TABLE regression=# create temporary table test_intervals (i interval); CREATE TABLE regression=# insert into test_intervals values regression-# ('0 years'), regression-# ('1 year 1 month'), regression-# ('1 day 2 hours 3 minutes 4 seconds'), regression-# ('1 year 1 minute'); INSERT 0 4 regression=# regression=# insert into test_intervals values regression-# ('1-1'), regression-# ('1'), regression-# (interval '1' year), regression-# ('1:00:00'), regression-# ('1 1:02:03'); INSERT 0 5 regression=# regression=# insert into test_intervals values regression-# ('P1Y1M'), regression-# ('P1DT1H1M1S'), regression-# ('PT1S'); INSERT 0 3 regression=# regression=# set intervalstyle to sql_standard; SET regression=# select * from test_intervals; i ------------- 0 1-1 1 2:3:4 1-0 0 0:1:0 1-1 0:0:1 1-0 1:0:0 1 1:2:3 1-1 1 1:1:1 0:0:1 (12 rows) regression=# regression=# set intervalstyle to iso_8601; SET regression=# select * from test_intervals; i ------------ PT0S P1Y1M P1DT2H3M4S P1YT1M P1Y1M PT1S P1Y PT1H P1DT1H2M3S P1Y1M P1DT1H1M1S PT1S (12 rows) regression=# regression=# set intervalstyle to backward_compatible; SET regression=# set datestyle to sql; SET regression=# select * from test_intervals; i ------------------------------- @ 0 @ 1 year 1 mon @ 1 day 2 hours 3 mins 4 secs @ 1 year 1 min @ 1 year 1 mon @ 1 sec @1 year @ 1 hour @ 1 day 1 hour 2 mins 3 secs @ 1 year 1 mon @ 1 day 1 hour 1 min 1 sec @ 1 sec (12 rows) regression=# set datestyle to iso; SET regression=# select * from test_intervals; i ----------------- 00:00:00 1 year 1 mon 1 day 02:03:04 1 year 00:01:00 1 year 1 mon 00:00:01 1 year 01:00:00 1 day 01:02:031 year 1 mon 1 day 01:01:01 00:00:01 (12 rows)
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Cool. I think I have it pretty much working with a new > GUC "intervalstyle" that can take values of > "sql_standard" that I think will output SQL standard > interval literals when given a sql > standard interval. > "iso_8601" that will output ISO 8601 "Time Intervals" of > the "format with time-unit deignators", and > "backward_compatible" that will output the same thing > that postgres currently does that depends > on the value of the DateStyle GUC. Actually, we have never considered that new releases need to preserve the behavior of postgresql.conf settings. So the above seems unnecessarily baroque. How about decoupling interval_out's behavior from DateStyle altogether, and instead providing values of IntervalStyle that match all the previous behaviors? > Should those ECPG functions be made identical to > the ones in the backend? The ECPG situation is a mess :-(. That code was forked off from the backend some time ago, and has not been well maintained at all. If you are brave enough to tackle that mess, more power to you; but I strongly suggest doing it as an independent patch. > Could those somehow share code with the backend for > some of their work? The palloc and elog dependencies seem to be the hard part. regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> interval ... "sql_standard"..."iso_8601"... >> "backward_compatible" ...depends... on ... DateStyle... > > ...How about decoupling interval_out's behavior > from DateStyle altogether, and instead providing values of IntervalStyle > that match all the previous behaviors? Great. That seems much more sane. Any desired names for the existing interval styles? Currently we output intervals in these two styles: '1 year 2 mons 3 days 04:05:06' when the DateStyle is iso. and '@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs' when the DateStyle is sql or postgres, etc. I'm not quite sure where those styles came from so don't know what good names for them might be. >> Should those ECPG functions be made identical ... > ... > The palloc and elog dependencies seem to be the hard part. Interesting. So EncodeDateTime and EncodeInterval, guessing 400 or so lines, seem sharable since at first glance they either already do or easily could make their callers deal with all allocation and logging. Agreed that it's a independent patch that I'll try separately.
Unless I'm compiling stuff wrong, it seems HEAD is giving me slightly different output on Intervals than 8.3 in the roundoff of seconds. 8.3 was rounding to the nearest fraction of a second, HEAD seems to be truncating. In the psql output below it shows 8.3.1 outputting "6.70 secs" while the similar output for head is showing "6.69 secs". At first glance it seems this might be because HEAD defaults to USE_INTEGER_DATETIMES, which leads to HAVE_INT64_TIMESTAMP which leads to sprintf(cp, "%s%d.%02d secs", is_nonzero ? " " : "", tm->tm_sec, ((int) sec) / 10000); in EncodeInterval in datetime.c which doesn't seem to be doing any rounding. Am I interpreting this right? If so, shall I submit a patch that rounds it to hundredths of a second (hundredths seems hardcoded in the sprintf), or perhaps just silently add that fix to the EncodeInterval patch I'm doing any for SQL Standard and ISO intervals? ======================================================================== psql (8.4devel) Type "help" for help. regression=# set datestyle to sql; SET regression=# select '1 year 2 mons 3 days 04:05:06.699999'::interval; interval ------------------------------------------------- @ 1 year 2 mons 3 days 4 hours 5 mins 6.69 secs (1 row) ======================================================================== Welcome to psql 8.3.1, the PostgreSQL interactive terminal. ... pg83=# set datestyle to sql; SET pg83=# select '1 year 2 mons 3 days 04:05:06.699999'::interval; interval ------------------------------------------------- @ 1 year 2 mons 3 days 4 hours 5 mins 6.70 secs (1 row)
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Unless I'm compiling stuff wrong, it seems HEAD is giving me > slightly different output on Intervals than 8.3 in the roundoff > of seconds. 8.3 was rounding to the nearest fraction of a second, > HEAD seems to be truncating. Yeah, that's surely because of the change to integer timestamps. > Am I interpreting this right? If so, shall I submit a patch > that rounds it to hundredths of a second (hundredths seems > hardcoded in the sprintf), or perhaps just silently add that > fix to the EncodeInterval patch I'm doing any for SQL Standard > and ISO intervals? This is not the only place where the float-timestamps code has rounding behavior that doesn't appear in the integer-timestamps code. I don't know if we want to buy into making them act the same ... after all, if they acted exactly the same, we'd not have bothered with writing the integer code. In this example, rounding to hundredths doesn't seem like a particularly good idea; it seems to me it should give you the exact down-to-the-microsecond value. regards, tom lane
>>> On Mon, Sep 15, 2008 at 4:58 PM, in message <20219.1221515913@sss.pgh.pa.us>, Tom Lane <tgl@sss.pgh.pa.us> wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Unless I'm compiling stuff wrong, it seems HEAD is giving me >> slightly different output on Intervals than 8.3 in the roundoff >> of seconds. 8.3 was rounding to the nearest fraction of a second, >> HEAD seems to be truncating. > > Yeah, that's surely because of the change to integer timestamps. > >> Am I interpreting this right? If so, shall I submit a patch >> that rounds it to hundredths of a second (hundredths seems >> hardcoded in the sprintf), or perhaps just silently add that >> fix to the EncodeInterval patch I'm doing any for SQL Standard >> and ISO intervals? > > This is not the only place where the float-timestamps code has rounding > behavior that doesn't appear in the integer-timestamps code. I don't > know if we want to buy into making them act the same ... after all, > if they acted exactly the same, we'd not have bothered with writing the > integer code. In this example, rounding to hundredths doesn't seem like > a particularly good idea; it seems to me it should give you the exact > down-to-the-microsecond value. I find the results on 8.3.3 with integer timestamps surprising: ccdev=# select version(); version ------------------------------------------------------------------------------------------------------------------PostgreSQL 8.3.3on x86_64-unknown-linux-gnu, compiled by GCC gcc (GCC) 4.1.2 20070115 (prerelease) (SUSE Linux) (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval; interval --------------------------------------1 year 2 mons 3 days 04:05:06.699999 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval(1); interval ----------------------------------1 year 2 mons 3 days 04:05:06.70 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval(2); interval ----------------------------------1 year 2 mons 3 days 04:05:06.70 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval(3); interval ----------------------------------1 year 2 mons 3 days 04:05:06.70 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval(4); interval ----------------------------------1 year 2 mons 3 days 04:05:06.70 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval(5); interval ----------------------------------1 year 2 mons 3 days 04:05:06.70 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.699999'::interval(6); interval --------------------------------------1 year 2 mons 3 days 04:05:06.699999 (1 row) -Kevin
>>> "Kevin Grittner" <Kevin.Grittner@wicourts.gov> wrote: > I find the results on 8.3.3 with integer timestamps surprising: Even more surprising is the behavior for interval(1) here: ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval; interval -------------------------------------1 year 2 mons 3 days 04:05:06.64321 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(1); interval ----------------------------------1 year 2 mons 3 days 04:05:06.60 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(2); interval ----------------------------------1 year 2 mons 3 days 04:05:06.64 (1 row) ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(3); interval -----------------------------------1 year 2 mons 3 days 04:05:06.643 (1 row) etc. That trailing zero should be considered a bug. -Kevin
Kevin Grittner wrote: >...not the only place where the float-timestamps code has > rounding behavior that doesn't appear in the integer-timestamps > code. ... > I find the results on 8.3.3 with integer timestamps surprising: Agreed it's surprising and agreed there are more places. Sounds like I should keep that separate and perhaps later submit a separate patch to identify and/or remove surprising rounding behavior.
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Sounds like I should keep that separate and perhaps later > submit a separate patch to identify and/or remove surprising > rounding behavior. Agreed. It's easier to review and get consensus on patches if you keep separate issues separate. regards, tom lane
Unless I'm compiling stuff wrong, it seems HEAD is giving me slightly different output on Intervals than 8.3 in the roundoff of seconds. 8.3 was rounding to the nearest fraction of a second, HEAD seems to be truncating. In the psql output below it shows 8.3.1 outputting "6.70 secs" while the similar output for head is showing "6.69 secs". At first glance it seems this might be because HEAD defaults to USE_INTEGER_DATETIMES, which leads to HAVE_INT64_TIMESTAMP which leads to sprintf(cp, "%s%d.%02d secs", is_nonzero ? " " : "", tm->tm_sec, ((int) sec) / 10000); in EncodeInterval in datetime.c which doesn't seem to be doing any rounding. Am I interpreting this right? If so, shall I submit a patch that rounds it to hundredths of a second (hundredths seems hardcoded in the sprintf), or perhaps just silently add that fix to the EncodeInterval patch I'm doing any for SQL Standard and ISO intervals? ======================================================================== psql (8.4devel) Type "help" for help. regression=# set datestyle to sql; SET regression=# select '1 year 2 mons 3 days 04:05:06.699999'::interval; interval ------------------------------------------------- @ 1 year 2 mons 3 days 4 hours 5 mins 6.69 secs (1 row) ======================================================================== Welcome to psql 8.3.1, the PostgreSQL interactive terminal. ... pg83=# set datestyle to sql; SET pg83=# select '1 year 2 mons 3 days 04:05:06.699999'::interval; interval ------------------------------------------------- @ 1 year 2 mons 3 days 4 hours 5 mins 6.70 secs (1 row)
Tom Lane wrote: > > This is not the only place where the float-timestamps code has rounding > behavior that doesn't appear in the integer-timestamps code. Yeah... For that matter, I find this surprising as well: regression=# select '0.7 secs'::interval, ('7 secs'::interval/10); interval | ?column? -----------------+------------- 00:00:00.699999 | 00:00:00.70 (1 row) I'll start making a list of them for a future patch down the road.
Tom Lane wrote: > support for SQL-spec interval literals. I decided to go look at exactly > how unfinished it was, and it turns out that it's actually pretty close. > Hence the attached proposed patch ;-) Is this code handling negative interval literals right? I think I quote the relevant spec part at the bottom. If I'm reading the spec right, I find this surprising. regression=# select interval '-1-1'; interval ------------------- -1 days -01:00:00 regression=# select interval '1-1'; interval -------------- 1 year 1 mon Also if I read the spec right, ISTM the <sign> should apply to the entire interval literal. But if I compiled the patch right, the negative sign applies only to the first part it encounters? regression=# select interval '-1 2:3:4'; interval ------------------- -1 days +02:03:04 (1 row) If I understand right, this'll add confusion to SQL "standard" output for mixed year-month and day-time intervals that have both negative and positive components too. :( This looks to me like the relevant part of SQL 200N(8?), which seems to me to allow a sign inside the quotes: ==================================================================== <interval literal> ::= INTERVAL [ <sign> ] <interval string> <interval qualifier> <interval string> ::= <quote> <unquoted interval string> <quote> <unquoted interval string> ::= [ <sign> ] { <year-month literal> | <day-time literal> } ====================================================================
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Is this code handling negative interval literals right? > I think I quote the relevant spec part at the bottom. We support independent signs for the different components of the interval. I'm not sure how well the spec copes with that. regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Is this code handling negative interval literals right? >> I think I quote the relevant spec part at the bottom. > > We support independent signs for the different components of the Even so it surprises me that: '-1-1'::interval gives me a day-hour interval while '1-1'::interval gives me a year-month interval. >I'm not sure how well the spec copes with that. If I'm read the spec right, SQL 2008 expects "-1 12:34:56" to be what we'd see as "-1 -12:34:56", and doesn't handle with different signs for different components at all. SQL 92 seems to have been simpler, apparently requiring the negative sign to stay outside the quotes. ==SQL 92=========================================================== <interval literal> ::= INTERVAL [ <sign> ] <interval string> <interval qualifier> <interval string> ::= <quote> { <year-month literal> | <day-time literal> } <quote> =================================================================== SQL 200N seems to allow a sign inside the string: ==SQL 200N========================================================= <interval literal> ::= INTERVAL [ <sign> ] <interval string> <interval qualifier> <interval string> ::= <quote> <unquoted interval string> <quote> <unquoted interval string> ::= [ <sign> ] { <year-month literal> | <day-time literal> } ===================================================================
Tom Lane wrote: > ... SQL-spec interval literals. I decided to go look at exactly > how unfinished it was, and it turns out that it's actually pretty close. > Hence the attached proposed patch ;-) Short summary: I think this patch fixes a bug with sql-spec negative interval literals. Longer. I believe this short (4 lines of code & 1 line of comment) patch (below) fixes the way we handle SQL-standard negative-valued year-month interval strings. In particular, if I read the spec right (relevant excerpts below), the string '-1-1' is a vaild SQL-200N "year-month" interval meaning a negative year and a month - because the spec only allows a <sign> in the beginning of the unquoted interval string: <unquoted interval string> ::= [ <sign> ] { <year-month literal>| <day-time literal> } Current HEAD interprets '-1-1' as "-1 days -1 hours". 8.3 doesn't recognize it at all. Assuming I read the spec right, are there any problems with this, and if not, could I ask that the patch at the end of this email be applied? Ron =============================================================================== == with this patch =============================================================================== regression=# select interval '-1-1'; interval ------------------ -1 years -1 mons (1 row) =============================================================================== == without this patch =============================================================================== regression=# select interval '-1-1'; interval ------------------- -1 days -01:00:00 (1 row) =============================================================================== == 8.3 =============================================================================== regression=# select interval '-1-1'; ERROR: invalid input syntax for type interval: "-1-1" =============================================================================== == I think the relevant part of SQL 200N =============================================================================== <interval string> ::= <quote> <unquoted interval string> <quote> <unquoted interval string> ::= [ <sign> ] { <year-month literal> | <day-time literal> } <year-month literal> ::= <years value> [ <minus sign> <months value> ] | <months value> <years value> ::= <datetime value> <months value> ::= <datetime value> <datetime value> ::= <unsigned integer> ... If SV is a negative interval, then <sign> shall be specified within <unquoted interval string> in the literal Y. =============================================================================== == The patch =============================================================================== *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 609,621 **** ParseDateTime(const char *timestr, char *workbuf, size_t buflen, /* soak up leading whitespace*/ while (isspace((unsigned char) *cp)) cp++; ! /* numeric timezone? */ if (isdigit((unsigned char) *cp)) { ftype[nf]= DTK_TZ; APPEND_CHAR(bufp, bufend, *cp++); while (isdigit((unsigned char) *cp)|| ! *cp == ':' || *cp == '.') APPEND_CHAR(bufp, bufend, *cp++); } /* special? */ --- 609,621 ---- /* soak up leading whitespace */ while (isspace((unsigned char) *cp)) cp++; ! /* numeric timezone? or sql year-month interval?*/ if (isdigit((unsigned char) *cp)) { ftype[nf] = DTK_TZ; APPEND_CHAR(bufp, bufend, *cp++); while (isdigit((unsignedchar) *cp) || ! *cp == ':' || *cp == '.' || *cp == '-') APPEND_CHAR(bufp, bufend, *cp++); } /* special? */ *************** *** 2876,2889 **** DecodeInterval(char **field, int *ftype, int nf, int range, { /*SQL "years-months" syntax */ int val2; ! val2 = strtoi(cp + 1, &cp, 10); if (errno == ERANGE || val2 < 0 || val2 >= MONTHS_PER_YEAR) return DTERR_FIELD_OVERFLOW; if (*cp != '\0') return DTERR_BAD_FORMAT; type = DTK_MONTH; ! val = val * MONTHS_PER_YEAR + val2; fval = 0; } else if (*cp == '.') --- 2876,2890 ---- { /* SQL "years-months" syntax */ int val2; ! int sign; ! sign = val < 0 ? -1 : 1; val2 = strtoi(cp + 1, &cp, 10); if (errno == ERANGE || val2 < 0 || val2 >= MONTHS_PER_YEAR) return DTERR_FIELD_OVERFLOW; if (*cp != '\0') return DTERR_BAD_FORMAT; type = DTK_MONTH; ! val = val * MONTHS_PER_YEAR + val2*sign; fval = 0; } else if (*cp == '.') ================================================================================
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Short summary: > I think this patch fixes a bug with sql-spec negative interval literals. Hmm. I'm a bit concerned about possible side-effects on other cases: what had been seen as two separate tokens will now become one token for *all* datetime types, not just interval. However, I can't immediately think of any likely input formats where this would be a problem. Something else I noticed while poking at it is this inconsistency: regression=# select interval '1';interval ----------00:00:01 (1 row) regression=# select interval '-1';interval ------------01:00:00 (1 row) regression=# select interval '+1';interval ----------01:00:00 (1 row) regression=# select interval '1' day;interval ----------1 day (1 row) regression=# select interval '+1' day;interval ----------00:00:00 (1 row) regression=# select interval '-1' day;interval ----------00:00:00 (1 row) regression=# select interval '1' hour to minute;interval ----------00:01:00 (1 row) regression=# select interval '-1' hour to minute;interval ------------01:00:00 (1 row) regression=# select interval '+1' hour to minute;interval ----------01:00:00 (1 row) As soon as you throw in a sign, it gets wacky :-(. The reason for this bizarreness is this chunk of code at the end of DecodeInterval's DTK_TZ case: else if (type == IGNORE_DTF) { if (*cp == '.') { /* * Got a decimal point? Then assume some sort of * secondsspecification */ type = DTK_SECOND; } else if (*cp == '\0') { /* * Only a signed integer? Thenmust assume a * timezone-like usage */ type = DTK_HOUR; } } which means that a signed integer gets forced to be "hours" if there isn't an explicit unit spec in the literal, while a signed float gets forced to be "seconds". I can't see any reason why that's a good idea, and propose that while we're making incompatible changes in corner cases, we should just drop the code quoted above. regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Short summary: >> I think this patch fixes a bug with sql-spec negative interval literals. > > Hmm. I'm a bit concerned about possible side-effects on other cases: > what had been seen as two separate tokens will now become one token > for *all* datetime types, not just interval. However, I can't If it's a concern, I could make interval_in first look for the SQL-standard patterns before even parsing the string into fields. If we want to handle the SQL standard negative datetime intervals (see below) the way the spec looks to me, > immediately think of any likely input formats where this would be a > problem. > Something else I noticed while poking at it is this inconsistency:... Yes. I saw some of those too (and '-1 1:00:00'); but didn't have a patch ready (yet). I'm happy to work on it. > As soon as you throw in a sign, it gets wacky :-(. Oh. And looking more closely; there's a potential bad incompatibility. If I read SQL 200N's spec correctly select interval '-1 1:00:00'; should mean "-1 days -1 hours", yet 8.3 sees it as "-1 days +1 hours". Scary to touch that one, but since a standard's a standard, I think eventually we should get there. Perhaps we need a GUC to choose standards or backward compatible behavior for that one? Or perhaps keep parsing it the old way but with a WARNING for 8.4 and switch in 8.5? > The reason for this bizarreness is this chunk of code at the end of > DecodeInterval's DTK_TZ case: > > else if (type == IGNORE_DTF) > {...} } > > which means that a signed integer gets forced to be "hours" if there > isn't an explicit unit spec in the literal, while a signed float gets > forced to be "seconds". I can't see any reason why that's a good idea, > and propose that while we're making incompatible changes in corner cases, > we should just drop the code quoted above. +1. Shall I try for a patch that handles those and possibly the (more frightening) SQL 200N signed day-time interval mentioned above.
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Tom Lane wrote: >> Hmm. I'm a bit concerned about possible side-effects on other cases: >> what had been seen as two separate tokens will now become one token >> for *all* datetime types, not just interval. However, I can't > If it's a concern, I could make interval_in first look for the > SQL-standard patterns before even parsing the string into fields. I don't think it's worth the trouble unless someone points out a real-world format that would be broken by the change. We certainly don't document anything that would be. I've applied a patch along these lines and we'll see if anyone complains. > If I read SQL 200N's spec correctly > select interval '-1 1:00:00'; > should mean "-1 days -1 hours", > yet 8.3 sees it as "-1 days +1 hours". I think we are kind of stuck on this one. If we change it, then how would one represent -1 days +1 hours? The spec's format is only sane if you assume all the fields must have the same sign, which is not the case for PG. > Scary to touch that one, but since a standard's a standard, I think > eventually we should get there. The SQL spec's date/time handling is, and always has been, broken enough that I feel no great compulsion to follow every last detail. Especially details that make it impossible to support our extensions... regards, tom lane
Tom Lane wrote: >> If I read SQL 200N's spec correctly >> select interval '-1 1:00:00'; >> should mean "-1 days -1 hours", >> yet 8.3 sees it as "-1 days +1 hours". > > I think we are kind of stuck on this one. If we change it, then how > would one represent -1 days +1 hours? The spec's format is only sane I'm not proposing this, but I could imagine making "-1 -1:00:00" and/or "-1 +1:00:00" mean -1 days +1 hours. I think if it weren't for backward compatibility issues I'd even support such an idea - since now we're oh-so-very-close to accepting to-spec literals. Unfortunately I fear old users might assume the opposite meaning. >> Scary to touch that one, but since a standard's a standard, I think >> eventually we should get there. > > The SQL spec's date/time handling is, and always has been, broken enough > that I feel no great compulsion to follow every last detail. Especially > details that make it impossible to support our extensions... In this case we're so very close to meeting the spec, though. And it's ashame where we accept the to-spec syntax ("-1 1:00:00") but return a different answer. And since it's not quite impossible to support our extensions (force putting the sign on the h:m:s part for mixed sign cases) I feels nice to me to try.
Tom Lane wrote: >Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Tom Lane wrote: >> If I read SQL 200N's spec correctly >> select interval '-1 1:00:00'; >> should mean "-1 days -1 hours", >> yet 8.3 sees it as "-1 days +1 hours". >I think we are kind of stuck on this one. If we change it, then how >would one represent -1 days +1 hours? The spec's format is only sane >if you assume all the fields must have the same sign, which is not >the case for PG. -1 days +1 hours = interval '-0 23:00:00' Intervals are a scalar, not an addition of assorted values, alternating signs between fields would be wrong. -- Sincerely, Stephen R. van den Berg. He did a quarter of the work in *half* the time!
"Stephen R. van den Berg" <srb@cuci.nl> writes: > Intervals are a scalar, not an addition of assorted values, alternating signs > between fields would be wrong. Sorry, you're the one who's wrong on that. We've treated intervals as three independent fields for years now (and before that it was two independent fields). We're not going to throw away that capability. regards, tom lane
Tom Lane wrote: > "Stephen R. van den Berg" <srb@cuci.nl> writes: >> Intervals are a scalar, not an addition of assorted values, alternating signs >> between fields would be wrong. > > Sorry, you're the one who's wrong on that. We've treated intervals as > three independent fields for years now (and before that it was two > independent fields). We're not going to throw away that capability. +1 It's very useful. Currently our terse input format that's similar to the SQL standard rejects more mixed-sign intervals than I'd like. I'd be quite happy if: '1 2:03:-04' gave me '1 day 2 hours 3 minutes -4 seconds' but currently we reject that mixed-sign-literal. I'd just like to find a way to have SQL-standard input produce SQL-standard output in the cases where the input happened to match the standard. If we had a blank slate, my vote would be that '-1 2:03:04' should mean what the SQL standard says it should. '-1 +2:03:04'should mean negative 1 days, plus 2 hours 3 minutes 4 sec '1 2:03:-04' should mean 1 day 2 hours 3 minutes minus4 seconds '-1 2:03:+04' should mean negative 1 day 2 hours 3 minutes plus 4 seconds but I'm aware that there are backward compatibility issues.
Tom Lane wrote: >"Stephen R. van den Berg" <srb@cuci.nl> writes: >> Intervals are a scalar, not an addition of assorted values, alternating signs >> between fields would be wrong. >Sorry, you're the one who's wrong on that. We've treated intervals as >three independent fields for years now (and before that it was two >independent fields). Ok, didn't know that. Let's put it differently then: I can understand that the standard considers it a scalar and not an addition, but apparently the addition characteristic is being used in Postgres code already; that makes it undesirable to change it indeed. -- Sincerely, Stephen R. van den Berg. He did a quarter of the work in *half* the time!
Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > In fact, given that we are now > somewhat SQL-compliant on interval input, a GUC that selected > PG traditional, SQL-standard, or ISO 8601 interval output format seems > like it could be a good idea. Short summary: The attached patch (1) adds a new GUC called "IntervalStyle" that decouples interval output from the "DateStyle" GUC, and (2) adds a new interval style that will match the SQL standards for interval literals when given interval data that meets the sql standard (year-month or date-time only; and no mixed sign). Background: Currently Postgres outputs Intervals in one of two formats depending on DateStyle. When DateStyle is 'ISO', it outputs intervals like '1 year 2 mons 3 days -04:05:06.78' (though I know of no ISO interval standards that look like that). When DateStyle is 'SQL' it outputs intervals like '@ 1 year 2 mons 3 days -4 hours -5 mins -6.78 secs' (though I know of no SQL interval standards that look like that). The feature: The SQL standard only specifies interval literal strings for the two kinds of intervals (year-month and day-time) that are defined by the SQL spec. It also doesn't account for postgres's intervals that can have mixed-sign components. I tried to make the output here be a logical extension of the spec, concatenating the year-month and day-time interval strings and forcing signs in the output that could otherwise have been ambiguous. This little table shows an example of the output of this new style compared to the existing postgres output for (a) a year-month interval, (b) a day-time interval, and (c) a not-quite-standard postgres interval with year-month and day-time components of varying signs. '1-2' | '@ 1 year 2 mons' '3 4:05:06.78' | '@ 3 days 4 hours 5 mins 6.78 secs' '+1-2 -3 +4:05:06.78' | '@ 1 year 2 mons -3 days 4 hours 5 mins 6.78 secs' The patch: Seems to work for me; and I believe I updated the docs. Many regression tests fail, though, because they assume the existing coupling of DateStyle and interval output styles. If people like where this is going I can update those regression tests and add ones to test this new style. *** a/doc/src/sgml/config.sgml --- b/doc/src/sgml/config.sgml *************** *** 4090,4095 **** SET XML OPTION { DOCUMENT | CONTENT }; --- 4090,4117 ---- </listitem> </varlistentry> + <varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle"> + <term><varname>IntervalStyle</varname> (<type>string</type>)</term> + <indexterm> + <primary><varname>IntervalStyle</> configuration parameter</primary> + </indexterm> + <listitem> + <para> + Sets the display format for interval values. + The value <literal>sql_standard</> will output SQL Standard + strings when given intervals that conform to the SQL + standard (either year-month only or date-time only; and no + mixing of positive and negative components). + The value <literal>postgres</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'ISO'</>. + The value <literal>postgres_verbose</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'SQL'</>. + </para> + </listitem> + </varlistentry> + <varlistentry id="guc-timezone" xreflabel="timezone"> <term><varname>timezone</varname> (<type>string</type>)</term> <indexterm> *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 2213,2218 **** January 8 04:05:06 1999 PST --- 2213,2305 ---- </para> </sect2> + <sect2 id="interval-output"> + <title>Interval Output</title> + + <indexterm> + <primary>interval</primary> + <secondary>output format</secondary> + <seealso>formatting</seealso> + </indexterm> + + <para> + The output format of the interval types can be set to one of the four + styles <literal>sql_standard</>, + <literal>postgres</>, or <literal>postgres_verbose</>.The default + is the <literal>postgres</> format. + <xref + linkend="interval-style-output-table"> shows examples of each + output style. + </para> + + <para> + The <literal>sql_standard</> style will output SQL standard + interval literal strings where the value of the interval + value consists of only a year-month component or a datetime + component (as required by the sql standard). For an interval + containing both a year-month and a datetime component, the + output will be a SQL Standard unquoted year-month literal + string joined to a SQL Standard unquoted datetime literal + string with a space in between. + </para> + + <para> + The <literal>postgres</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>ISO</>. + </para> + + <para> + The <literal>postgres_verbose</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>SQL</>. + </para> + + <table id="interval-style-output-table"> + <title>Interval Style Example</title> + <tgroup cols="2"> + <thead> + <row> + <entry>Style Specification</entry> + <entry>Year-Month Interval</entry> + <entry>DateTime Interval</entry> + <entry>Nonstandardrd Extended Interval</entry> + </row> + </thead> + <tbody> + <row> + <entry>sql_standard</entry> + <entry>1-2</entry> + <entry>3 4:05:06</entry> + <entry>-1-2 +3 -4:05:06</entry> + </row> + <row> + <entry>postgres</entry> + <entry>1 year 2 mons</entry> + <entry>3 days 04:05:06</entry> + <entry> -1 years -2 mons +3 days -04:05:06</entry> + </row> + <row> + <entry>postgres_verbose</entry> + <entry>@ 1 year 2 mons</entry> + <entry>@ 3 days 4 hours 5 mins 6 secs</entry> + <entry>@ 1 year 2 mons -3 days 4 hours 5 mins 6 secs ago</entry> + </row> + </tbody> + </tgroup> + </table> + + <para> + Note that <literal>sql_standard</> style will only produce strictly + standards-conforming string sliterals when given a strictly SQL-standard interval + value - meaning that it needs to be a pure year-month or datetime + interval and not mix positive and negative components. + </para> + + </sect2> + + + <sect2 id="datatype-timezones"> <title>Time Zones</title> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 229,234 **** assign_datestyle(const char *value, bool doit, GucSource source) --- 229,271 ---- /* + * assign_intervalstyle: GUC assign_hook for datestyle + */ + const char * + assign_intervalstyle(const char *value, bool doit, GucSource source) + { + int newIntervalStyle = IntervalStyle; + char * result = (char *) malloc(32); + if (pg_strcasecmp(value, "postgres") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES; + } + else if (pg_strcasecmp(value, "postgres_verbose") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES_VERBOSE; + } + else if (pg_strcasecmp(value, "sql_standard") == 0) + { + newIntervalStyle = INTSTYLE_SQL_STANDARD; + } + else + { + ereport(GUC_complaint_elevel(source), + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized \"intervalstyle\" key word: \"%s\"", + value))); + return NULL; + } + if (doit) + { + IntervalStyle = newIntervalStyle; + strcpy(result, "ISO"); + } + return result; + } + + + /* * TIMEZONE */ *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 3605,3610 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3605,3624 ---- return TRUE; } + /* + * small helper funciton to avoid copy&paste of this ifdef below + */ + void + AppendFsec(char * cp,fsec_t fsec) { + if (fsec==0) return; + #ifdef HAVE_INT64_TIMESTAMP + sprintf(cp, ".%06d", Abs(fsec)); + #else + sprintf(cp, ":%012.9f", fabs(fsec)); + #endif + TrimTrailingZeros(cp); + } + /* EncodeInterval() * Interpret time structure as a delta time and convert to string. *************** *** 3613,3618 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3627,3643 ---- * Actually, afaik ISO does not address time interval formatting, * but this looks similar to the spec for absolute date/time. * - thomas 1998-04-30 + * + * Actually, afaik, ISO 8601 does specify formats for "time + * intervals...[of the]...format with time-unit designators", which + * are pretty ugly. The format looks something like + * P1Y1M1DT1H1M1.12345S + * but useful for exchanging data with computers instead of humans. + * - ron 2003-07-14 + * + * And ISO's SQL 2008 standard specifies standards for + * "year-month literal"s (that look like '2-3') and + * "day-time literal"s (that look like ('4 5:6:7') */ int EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) *************** *** 3621,3626 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3646,3658 ---- bool is_nonzero = FALSE; char *cp = str; + int year = tm->tm_year; + int mon = tm->tm_mon; + int mday = tm->tm_mday; + int hour = tm->tm_hour; + int min = tm->tm_min; + int sec = tm->tm_sec; + /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and *************** *** 3628,3635 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) */ switch (style) { ! /* compatible with ISO date formats */ ! case USE_ISO_DATES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", --- 3660,3738 ---- */ switch (style) { ! /* SQL Standard interval literals */ ! case INTSTYLE_SQL_STANDARD: ! { ! bool has_negative = (year < 0) || (mon < 0) || ! (mday < 0) || (hour < 0) || ! (min < 0) || (sec < 0) || (fsec<0); ! bool has_positive = (year > 0) || (mon > 0) || ! (mday > 0) || (hour > 0) || ! (min > 0) || (sec > 0) || (fsec>0); ! bool has_year_month = (year != 0) || (mon != 0); ! bool has_datetime = (hour != 0) || (min != 0) || ! (sec != 0) || (fsec!= 0) || (mday != 0); ! bool has_day = (mday != 0); ! bool sql_standard_value = (!(has_negative && has_positive)) && ! (!(has_year_month && has_datetime)); ! /* ! * SQL Standard wants only 1 "<sign>" preceeding the whole ! * interval. ! */ ! if (has_negative && sql_standard_value) ! { ! sprintf(cp,"-"); ! cp++; ! year = -year; ! mon = -mon; ! mday = -mday; ! hour = -hour; ! min = -min; ! sec = -sec; ! fsec = -fsec; ! } ! if (!has_negative && !has_positive) ! { ! sprintf(cp,"0"); ! } ! else if (!sql_standard_value) ! { ! /* ! * For non sql-standard interval values, ! * force outputting the signs to avoid ! * ambiguities with intervals with mixed ! * sign components. ! */ ! char year_sign = (year<0 || mon<0) ? '-' : '+'; ! char day_sign = (mday<0) ? '-' : '+'; ! char sec_sign = (hour<0 || min<0 || sec<0 || fsec<0) ! ? '-' : '+'; ! sprintf(cp,"%c%d-%d %c%d %c%d:%02d:%02d", ! year_sign,abs(year),abs(mon), ! day_sign,abs(mday), ! sec_sign,abs(hour),abs(min),abs(sec)); ! AppendFsec(cp+strlen(cp),fsec); ! } ! else if (has_year_month) ! { ! sprintf(cp,"%d-%d",year,mon); ! } ! else if (has_day) ! { ! sprintf(cp,"%d %d:%02d:%02d",mday,hour,min,sec); ! AppendFsec(cp+strlen(cp),fsec); ! } ! else ! { ! sprintf(cp,"%d:%02d:%02d",hour,min,sec); ! AppendFsec(cp+strlen(cp),fsec); ! } ! cp += strlen(cp); ! break; ! } ! ! /* compatible with postgresql 8.3 when DateStyle = 'iso' */ ! case INTSTYLE_POSTGRES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", *************** *** 3692,3700 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) cp += strlen(cp); } } break; ! case USE_POSTGRES_DATES: default: strcpy(cp, "@ "); cp += strlen(cp); --- 3795,3809 ---- cp += strlen(cp); } } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } break; ! /* compatible with postgresql 8.3 when DateStyle = 'sql' */ ! case INTSTYLE_POSTGRES_VERBOSE: default: strcpy(cp, "@ "); cp += strlen(cp); *************** *** 3821,3842 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } break; } - /* identically zero? then put in a unitless zero... */ - if (!is_nonzero) - { - strcat(cp, "0"); - cp += strlen(cp); - } - - if (is_before && (style != USE_ISO_DATES)) - { - strcat(cp, " ago"); - cp += strlen(cp); - } - return 0; } /* EncodeInterval() */ --- 3930,3948 ---- is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } + if (is_before) + { + strcat(cp, " ago"); + cp += strlen(cp); + } break; } return 0; } /* EncodeInterval() */ *** a/src/backend/utils/adt/nabstime.c --- b/src/backend/utils/adt/nabstime.c *************** *** 671,677 **** reltimeout(PG_FUNCTION_ARGS) char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, DateStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); --- 671,677 ---- char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, INTSTYLE_POSTGRES, DateStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 677,683 **** interval_out(PG_FUNCTION_ARGS) if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, DateStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); --- 677,683 ---- if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); *** a/src/backend/utils/init/globals.c --- b/src/backend/utils/init/globals.c *************** *** 88,93 **** bool ExitOnAnyError = false; --- 88,94 ---- int DateStyle = USE_ISO_DATES; int DateOrder = DATEORDER_MDY; + int IntervalStyle = INTSTYLE_POSTGRES; bool HasCTZSet = false; int CTimeZone = 0; *** a/src/backend/utils/misc/guc.c --- b/src/backend/utils/misc/guc.c *************** *** 367,372 **** static bool session_auth_is_superuser; --- 367,373 ---- static double phony_random_seed; static char *client_encoding_string; static char *datestyle_string; + static char *intervalstyle_string; static char *locale_collate; static char *locale_ctype; static char *server_encoding_string; *************** *** 2098,2103 **** static struct config_string ConfigureNamesString[] = --- 2099,2113 ---- "ISO, MDY", assign_datestyle, NULL }, + { + {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE, + gettext_noop("Sets the display format for interval values."), + GUC_LIST_INPUT | GUC_REPORT + }, + &intervalstyle_string, + "postgres", assign_intervalstyle, NULL + }, + { {"default_tablespace", PGC_USERSET, CLIENT_CONN_STATEMENT, gettext_noop("Sets the default tablespace to create tables and indexes in."), *** a/src/backend/utils/misc/postgresql.conf.sample --- b/src/backend/utils/misc/postgresql.conf.sample *************** *** 426,431 **** --- 426,432 ---- # - Locale and Formatting - #datestyle = 'iso, mdy' + #intervalstyle = 'postgres' #timezone = unknown # actually, defaults to TZ environment # setting #timezone_abbreviations = 'Default' # Select the set of available time zone *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1953,1958 **** psql_completion(char *text, int start, int end) --- 1953,1965 ---- COMPLETE_WITH_LIST(my_list); } + else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) + { + static const char *const my_list[] = + {"postgres","postgres_verbose", "sql_standard", NULL}; + + COMPLETE_WITH_LIST(my_list); + } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) { static const char *const my_list[] = *** a/src/include/commands/variable.h --- b/src/include/commands/variable.h *************** *** 15,20 **** --- 15,22 ---- extern const char *assign_datestyle(const char *value, bool doit, GucSource source); + extern const char *assign_intervalstyle(const char *value, + bool doit, GucSource source); extern const char *assign_timezone(const char *value, bool doit, GucSource source); extern const char *show_timezone(void); *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 191,196 **** extern PGDLLIMPORT Oid MyDatabaseTableSpace; --- 191,208 ---- extern int DateStyle; extern int DateOrder; + + /* + * IntervalStyles + * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' + * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' + * INTSTYLE_SQL_STANDARD SQL standard interals + */ + #define INTSTYLE_POSTGRES 0 + #define INTSTYLE_POSTGRES_VERBOSE 1 + #define INTSTYLE_SQL_STANDARD 2 + + extern int IntervalStyle; /* * HasCTZSet is true if user has set timezone as a numeric offset from UTC.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Ron Mayer wrote: > Tom Lane wrote: >> ...GUC that selected PG traditional, SQL-standard... interval output >> format seems like it could be a good idea. > This is an update to the earlier SQL-standard-interval-literal output patch that I submitted here: http://archives.postgresql.org/message-id/48D15471.6080305@cheapcomplexdevices.com This version fixes a couple bugs in my last patch related to reltime output and with the new GUC variable, and updated the regression tests to adjust the new IntervalStyle guc to match the output of the previous regression tests where the interval output depended on DateStyle. I've also added it to the Nov CommitFest wiki page. *** a/doc/src/sgml/config.sgml --- b/doc/src/sgml/config.sgml *************** *** 4090,4095 **** SET XML OPTION { DOCUMENT | CONTENT }; --- 4090,4117 ---- </listitem> </varlistentry> + <varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle"> + <term><varname>IntervalStyle</varname> (<type>string</type>)</term> + <indexterm> + <primary><varname>IntervalStyle</> configuration parameter</primary> + </indexterm> + <listitem> + <para> + Sets the display format for interval values. + The value <literal>sql_standard</> will output SQL Standard + strings when given intervals that conform to the SQL + standard (either year-month only or date-time only; and no + mixing of positive and negative components). + The value <literal>postgres</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'ISO'</>. + The value <literal>postgres_verbose</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'SQL'</>. + </para> + </listitem> + </varlistentry> + <varlistentry id="guc-timezone" xreflabel="timezone"> <term><varname>timezone</varname> (<type>string</type>)</term> <indexterm> *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 2213,2218 **** January 8 04:05:06 1999 PST --- 2213,2305 ---- </para> </sect2> + <sect2 id="interval-output"> + <title>Interval Output</title> + + <indexterm> + <primary>interval</primary> + <secondary>output format</secondary> + <seealso>formatting</seealso> + </indexterm> + + <para> + The output format of the interval types can be set to one of the four + styles <literal>sql_standard</>, + <literal>postgres</>, or <literal>postgres_verbose</>.The default + is the <literal>postgres</> format. + <xref + linkend="interval-style-output-table"> shows examples of each + output style. + </para> + + <para> + The <literal>sql_standard</> style will output SQL standard + interval literal strings where the value of the interval + value consists of only a year-month component or a datetime + component (as required by the sql standard). For an interval + containing both a year-month and a datetime component, the + output will be a SQL Standard unquoted year-month literal + string joined to a SQL Standard unquoted datetime literal + string with a space in between. + </para> + + <para> + The <literal>postgres</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>ISO</>. + </para> + + <para> + The <literal>postgres_verbose</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>SQL</>. + </para> + + <table id="interval-style-output-table"> + <title>Interval Style Example</title> + <tgroup cols="2"> + <thead> + <row> + <entry>Style Specification</entry> + <entry>Year-Month Interval</entry> + <entry>DateTime Interval</entry> + <entry>Nonstandardrd Extended Interval</entry> + </row> + </thead> + <tbody> + <row> + <entry>sql_standard</entry> + <entry>1-2</entry> + <entry>3 4:05:06</entry> + <entry>-1-2 +3 -4:05:06</entry> + </row> + <row> + <entry>postgres</entry> + <entry>1 year 2 mons</entry> + <entry>3 days 04:05:06</entry> + <entry> -1 years -2 mons +3 days -04:05:06</entry> + </row> + <row> + <entry>postgres_verbose</entry> + <entry>@ 1 year 2 mons</entry> + <entry>@ 3 days 4 hours 5 mins 6 secs</entry> + <entry>@ 1 year 2 mons -3 days 4 hours 5 mins 6 secs ago</entry> + </row> + </tbody> + </tgroup> + </table> + + <para> + Note that <literal>sql_standard</> style will only produce strictly + standards-conforming string sliterals when given a strictly SQL-standard interval + value - meaning that it needs to be a pure year-month or datetime + interval and not mix positive and negative components. + </para> + + </sect2> + + + <sect2 id="datatype-timezones"> <title>Time Zones</title> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 229,234 **** assign_datestyle(const char *value, bool doit, GucSource source) --- 229,271 ---- /* + * assign_intervalstyle: GUC assign_hook for datestyle + */ + const char * + assign_intervalstyle(const char *value, bool doit, GucSource source) + { + int newIntervalStyle = IntervalStyle; + char * result = (char *) malloc(32); + if (pg_strcasecmp(value, "postgres") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES; + } + else if (pg_strcasecmp(value, "postgres_verbose") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES_VERBOSE; + } + else if (pg_strcasecmp(value, "sql_standard") == 0) + { + newIntervalStyle = INTSTYLE_SQL_STANDARD; + } + else + { + ereport(GUC_complaint_elevel(source), + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized \"intervalstyle\" key word: \"%s\"", + value))); + return NULL; + } + if (doit) + { + IntervalStyle = newIntervalStyle; + strcpy(result, value); + } + return result; + } + + + /* * TIMEZONE */ *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 3605,3610 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3605,3624 ---- return TRUE; } + /* + * small helper funciton to avoid copy&paste of this ifdef below + */ + void + AppendFsec(char * cp,fsec_t fsec) { + if (fsec==0) return; + #ifdef HAVE_INT64_TIMESTAMP + sprintf(cp, ".%06d", Abs(fsec)); + #else + sprintf(cp, ":%012.9f", fabs(fsec)); + #endif + TrimTrailingZeros(cp); + } + /* EncodeInterval() * Interpret time structure as a delta time and convert to string. *************** *** 3613,3618 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3627,3643 ---- * Actually, afaik ISO does not address time interval formatting, * but this looks similar to the spec for absolute date/time. * - thomas 1998-04-30 + * + * Actually, afaik, ISO 8601 does specify formats for "time + * intervals...[of the]...format with time-unit designators", which + * are pretty ugly. The format looks something like + * P1Y1M1DT1H1M1.12345S + * but useful for exchanging data with computers instead of humans. + * - ron 2003-07-14 + * + * And ISO's SQL 2008 standard specifies standards for + * "year-month literal"s (that look like '2-3') and + * "day-time literal"s (that look like ('4 5:6:7') */ int EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) *************** *** 3621,3626 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3646,3658 ---- bool is_nonzero = FALSE; char *cp = str; + int year = tm->tm_year; + int mon = tm->tm_mon; + int mday = tm->tm_mday; + int hour = tm->tm_hour; + int min = tm->tm_min; + int sec = tm->tm_sec; + /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and *************** *** 3628,3635 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) */ switch (style) { ! /* compatible with ISO date formats */ ! case USE_ISO_DATES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", --- 3660,3738 ---- */ switch (style) { ! /* SQL Standard interval literals */ ! case INTSTYLE_SQL_STANDARD: ! { ! bool has_negative = (year < 0) || (mon < 0) || ! (mday < 0) || (hour < 0) || ! (min < 0) || (sec < 0) || (fsec<0); ! bool has_positive = (year > 0) || (mon > 0) || ! (mday > 0) || (hour > 0) || ! (min > 0) || (sec > 0) || (fsec>0); ! bool has_year_month = (year != 0) || (mon != 0); ! bool has_datetime = (hour != 0) || (min != 0) || ! (sec != 0) || (fsec!= 0) || (mday != 0); ! bool has_day = (mday != 0); ! bool sql_standard_value = (!(has_negative && has_positive)) && ! (!(has_year_month && has_datetime)); ! /* ! * SQL Standard wants only 1 "<sign>" preceeding the whole ! * interval. ! */ ! if (has_negative && sql_standard_value) ! { ! sprintf(cp,"-"); ! cp++; ! year = -year; ! mon = -mon; ! mday = -mday; ! hour = -hour; ! min = -min; ! sec = -sec; ! fsec = -fsec; ! } ! if (!has_negative && !has_positive) ! { ! sprintf(cp,"0"); ! } ! else if (!sql_standard_value) ! { ! /* ! * For non sql-standard interval values, ! * force outputting the signs to avoid ! * ambiguities with intervals with mixed ! * sign components. ! */ ! char year_sign = (year<0 || mon<0) ? '-' : '+'; ! char day_sign = (mday<0) ? '-' : '+'; ! char sec_sign = (hour<0 || min<0 || sec<0 || fsec<0) ! ? '-' : '+'; ! sprintf(cp,"%c%d-%d %c%d %c%d:%02d:%02d", ! year_sign,abs(year),abs(mon), ! day_sign,abs(mday), ! sec_sign,abs(hour),abs(min),abs(sec)); ! AppendFsec(cp+strlen(cp),fsec); ! } ! else if (has_year_month) ! { ! sprintf(cp,"%d-%d",year,mon); ! } ! else if (has_day) ! { ! sprintf(cp,"%d %d:%02d:%02d",mday,hour,min,sec); ! AppendFsec(cp+strlen(cp),fsec); ! } ! else ! { ! sprintf(cp,"%d:%02d:%02d",hour,min,sec); ! AppendFsec(cp+strlen(cp),fsec); ! } ! cp += strlen(cp); ! break; ! } ! ! /* compatible with postgresql 8.3 when DateStyle = 'iso' */ ! case INTSTYLE_POSTGRES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", *************** *** 3692,3700 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) cp += strlen(cp); } } break; ! case USE_POSTGRES_DATES: default: strcpy(cp, "@ "); cp += strlen(cp); --- 3795,3809 ---- cp += strlen(cp); } } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } break; ! /* compatible with postgresql 8.3 when DateStyle = 'sql' */ ! case INTSTYLE_POSTGRES_VERBOSE: default: strcpy(cp, "@ "); cp += strlen(cp); *************** *** 3821,3842 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } break; } - /* identically zero? then put in a unitless zero... */ - if (!is_nonzero) - { - strcat(cp, "0"); - cp += strlen(cp); - } - - if (is_before && (style != USE_ISO_DATES)) - { - strcat(cp, " ago"); - cp += strlen(cp); - } - return 0; } /* EncodeInterval() */ --- 3930,3948 ---- is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } + if (is_before) + { + strcat(cp, " ago"); + cp += strlen(cp); + } break; } return 0; } /* EncodeInterval() */ *** a/src/backend/utils/adt/nabstime.c --- b/src/backend/utils/adt/nabstime.c *************** *** 671,677 **** reltimeout(PG_FUNCTION_ARGS) char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, DateStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); --- 671,677 ---- char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, IntervalStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 677,683 **** interval_out(PG_FUNCTION_ARGS) if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, DateStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); --- 677,683 ---- if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); *** a/src/backend/utils/init/globals.c --- b/src/backend/utils/init/globals.c *************** *** 88,93 **** bool ExitOnAnyError = false; --- 88,94 ---- int DateStyle = USE_ISO_DATES; int DateOrder = DATEORDER_MDY; + int IntervalStyle = INTSTYLE_POSTGRES; bool HasCTZSet = false; int CTimeZone = 0; *** a/src/backend/utils/misc/guc.c --- b/src/backend/utils/misc/guc.c *************** *** 367,372 **** static bool session_auth_is_superuser; --- 367,373 ---- static double phony_random_seed; static char *client_encoding_string; static char *datestyle_string; + static char *intervalstyle_string; static char *locale_collate; static char *locale_ctype; static char *server_encoding_string; *************** *** 2098,2103 **** static struct config_string ConfigureNamesString[] = --- 2099,2114 ---- "ISO, MDY", assign_datestyle, NULL }, + { + {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE, + gettext_noop("Sets the display format for interval values."), + gettext_noop(""), + GUC_REPORT + }, + &intervalstyle_string, + "postgres", assign_intervalstyle, NULL + }, + { {"default_tablespace", PGC_USERSET, CLIENT_CONN_STATEMENT, gettext_noop("Sets the default tablespace to create tables and indexes in."), *** a/src/backend/utils/misc/postgresql.conf.sample --- b/src/backend/utils/misc/postgresql.conf.sample *************** *** 426,431 **** --- 426,432 ---- # - Locale and Formatting - #datestyle = 'iso, mdy' + #intervalstyle = 'postgres' #timezone = unknown # actually, defaults to TZ environment # setting #timezone_abbreviations = 'Default' # Select the set of available time zone *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1953,1958 **** psql_completion(char *text, int start, int end) --- 1953,1965 ---- COMPLETE_WITH_LIST(my_list); } + else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) + { + static const char *const my_list[] = + {"postgres","postgres_verbose", "sql_standard", NULL}; + + COMPLETE_WITH_LIST(my_list); + } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) { static const char *const my_list[] = *** a/src/include/commands/variable.h --- b/src/include/commands/variable.h *************** *** 15,20 **** --- 15,22 ---- extern const char *assign_datestyle(const char *value, bool doit, GucSource source); + extern const char *assign_intervalstyle(const char *value, + bool doit, GucSource source); extern const char *assign_timezone(const char *value, bool doit, GucSource source); extern const char *show_timezone(void); *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 191,196 **** extern PGDLLIMPORT Oid MyDatabaseTableSpace; --- 191,208 ---- extern int DateStyle; extern int DateOrder; + + /* + * IntervalStyles + * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' + * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' + * INTSTYLE_SQL_STANDARD SQL standard interals + */ + #define INTSTYLE_POSTGRES 0 + #define INTSTYLE_POSTGRES_VERBOSE 1 + #define INTSTYLE_SQL_STANDARD 2 + + extern int IntervalStyle; /* * HasCTZSet is true if user has set timezone as a numeric offset from UTC. *** a/src/test/regress/sql/alter_table.sql --- b/src/test/regress/sql/alter_table.sql *************** *** 60,65 **** ALTER TABLE tmp ADD COLUMN y float4[]; --- 60,67 ---- ALTER TABLE tmp ADD COLUMN z int2[]; + SET IntervalStyle to postgres_verbose; + INSERT INTO tmp (a, b, c, d, e, f, g, h, i, j, k, l, m, n, p, q, r, s, t, u, v, w, x, y, z) VALUES (4, 'name', 'text', 4.1, 4.1, 2, '(4.1,4.1,3.1,3.1)', *** a/src/test/regress/sql/arrays.sql --- b/src/test/regress/sql/arrays.sql *************** *** 283,288 **** select '{ }}'::text[]; --- 283,289 ---- select array[]; -- none of the above should be accepted + SET intervalstyle to postgres_verbose; -- all of the following should be accepted select '{}'::text[]; select '{{{1,2,3,4},{2,3,4,5}},{{3,4,5,6},{4,5,6,7}}}'::text[]; *** a/src/test/regress/sql/horology.sql --- b/src/test/regress/sql/horology.sql *************** *** 73,79 **** SELECT date '1991-02-03' - time with time zone '04:05:06 UTC' AS "Subtract Time -- -- timestamp, interval arithmetic -- ! SELECT timestamp without time zone '1996-03-01' - interval '1 second' AS "Feb 29"; SELECT timestamp without time zone '1999-03-01' - interval '1 second' AS "Feb 28"; SELECT timestamp without time zone '2000-03-01' - interval '1 second' AS "Feb 29"; --- 73,79 ---- -- -- timestamp, interval arithmetic -- ! set IntervalStyle to postgres_verbose; SELECT timestamp without time zone '1996-03-01' - interval '1 second' AS "Feb 29"; SELECT timestamp without time zone '1999-03-01' - interval '1 second' AS "Feb 28"; SELECT timestamp without time zone '2000-03-01' - interval '1 second' AS "Feb 29"; *** a/src/test/regress/sql/interval.sql --- b/src/test/regress/sql/interval.sql *************** *** 94,99 **** FROM INTERVAL_MULDIV_TBL; --- 94,100 ---- DROP TABLE INTERVAL_MULDIV_TBL; SET DATESTYLE = 'postgres'; + SET INTERVALSTYLE = 'postgres_verbose'; SELECT '' AS ten, * FROM INTERVAL_TBL; *************** *** 118,123 **** SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour"; --- 119,126 ---- -- test fractional second input, and detection of duplicate units SET DATESTYLE = 'ISO'; + SET INTERVALSTYLE = 'postgres'; + SELECT '1 millisecond'::interval, '1 microsecond'::interval, '500 seconds 99 milliseconds 51 microseconds'::interval; SELECT '3 days 5 milliseconds'::interval; *** a/src/test/regress/sql/reltime.sql --- b/src/test/regress/sql/reltime.sql *************** *** 2,7 **** --- 2,10 ---- -- RELTIME -- + -- DateStyle is 'Postgres, MDY' here... + SET intervalstyle to postgres_verbose; + CREATE TABLE RELTIME_TBL (f1 reltime); INSERT INTO RELTIME_TBL (f1) VALUES ('@ 1 minute'); *************** *** 23,29 **** INSERT INTO RELTIME_TBL (f1) VALUES ('badly formatted reltime'); INSERT INTO RELTIME_TBL (f1) VALUES ('@ 30 eons ago'); -- test reltime operators - SELECT '' AS six, * FROM RELTIME_TBL; SELECT '' AS five, * FROM RELTIME_TBL --- 26,31 ---- *** a/src/test/regress/sql/timestamp.sql --- b/src/test/regress/sql/timestamp.sql *************** *** 163,168 **** SELECT '' AS "16", d1 FROM TIMESTAMP_TBL --- 163,171 ---- SELECT '' AS "49", d1 FROM TIMESTAMP_TBL WHERE d1 >= timestamp without time zone '1997-01-02'; + -- DateStyle was 'Postgres, MDY' at this point. + SET intervalstyle to postgres_verbose; + SELECT '' AS "54", d1 - timestamp without time zone '1997-01-02' AS diff FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; *** a/src/test/regress/sql/timestamptz.sql --- b/src/test/regress/sql/timestamptz.sql *************** *** 182,187 **** SELECT '' AS "16", d1 FROM TIMESTAMPTZ_TBL --- 182,190 ---- SELECT '' AS "49", d1 FROM TIMESTAMPTZ_TBL WHERE d1 >= timestamp with time zone '1997-01-02'; + -- Datestyle was Postgres, MDY here + SET intervalstyle TO postgres_verbose; + SELECT '' AS "54", d1 - timestamp with time zone '1997-01-02' AS diff FROM TIMESTAMPTZ_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
Tom Lane wrote: > >> There is still some unfinished business if anyone wants to make it > >> really exactly 100% spec compliant ... > > > I agree. > > I committed the patch as presented, and I think I might go take a quick Tom, which Interval TODO items did you complete with this patch? http://wiki.postgresql.org/wiki/Todo#Dates_and_Times -- Bruce Momjian <bruce@momjian.us> http://momjian.us EnterpriseDB http://enterprisedb.com + If your life is a hard drive, Christ can be your backup. +
Bruce Momjian <bruce@momjian.us> writes: > Tom, which Interval TODO items did you complete with this patch? > http://wiki.postgresql.org/wiki/Todo#Dates_and_Times I think we've at least mostly fixed * Support ISO INTERVAL syntax if units cannot be determined from the string, and are supplied after the string * Add support for year-month syntax, INTERVAL '50-6' YEAR TO MONTH There might be a few glitches left but they are at much smaller grain than the TODO is talking about. ... while I'm looking: I am not sure that I think either of these TODO items are sane or standards-compliant: * Interpret INTERVAL '1 year' MONTH as CAST (INTERVAL '1 year' AS INTERVAL MONTH), and this should return '12 months' * Support precision, CREATE TABLE foo (a INTERVAL MONTH(3)) regards, tom lane
Tom Lane wrote: > Bruce Momjian <bruce@momjian.us> writes: > > Tom, which Interval TODO items did you complete with this patch? > > http://wiki.postgresql.org/wiki/Todo#Dates_and_Times > > I think we've at least mostly fixed > > * Support ISO INTERVAL syntax if units cannot be determined from the string, and are supplied after the string > > * Add support for year-month syntax, INTERVAL '50-6' YEAR TO MONTH > > There might be a few glitches left but they are at much smaller grain > than the TODO is talking about. Thanks, marked as done. > ... while I'm looking: I am not sure that I think either of these TODO > items are sane or standards-compliant: > > * Interpret INTERVAL '1 year' MONTH as CAST (INTERVAL '1 year' AS INTERVAL MONTH), and this should return '12 months' > > * Support precision, CREATE TABLE foo (a INTERVAL MONTH(3)) OK, I have removed the items; we can always re-add them if they are requested. Thanks for the review. -- Bruce Momjian <bruce@momjian.us> http://momjian.us EnterpriseDB http://enterprisedb.com + If your life is a hard drive, Christ can be your backup. +
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Ron Mayer wrote: > Ron Mayer wrote: >> Tom Lane wrote: >>> ...GUC that selected PG traditional, SQL-standard... interval output >>> format seems like it could be a good idea. > This is an update to the earlier SQL-standard-interval-literal output > patch that I submitted here: > http://archives.postgresql.org/message-id/48D15471.6080305@cheapcomplexdevices.com Yet another update - mostly bringing the patch current with HEAD now that the previous commit fest is over; and also posting it again since I have a followup patch (for ISO 8601 interval input and output) that is based on this one and I want the patches lines-of-code to match. Ron *** a/doc/src/sgml/config.sgml --- b/doc/src/sgml/config.sgml *************** *** 4016,4021 **** SET XML OPTION { DOCUMENT | CONTENT }; --- 4016,4043 ---- </listitem> </varlistentry> + <varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle"> + <term><varname>IntervalStyle</varname> (<type>string</type>)</term> + <indexterm> + <primary><varname>IntervalStyle</> configuration parameter</primary> + </indexterm> + <listitem> + <para> + Sets the display format for interval values. + The value <literal>sql_standard</> will output SQL Standard + strings when given intervals that conform to the SQL + standard (either year-month only or date-time only; and no + mixing of positive and negative components). + The value <literal>postgres</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'ISO'</>. + The value <literal>postgres_verbose</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'SQL'</>. + </para> + </listitem> + </varlistentry> + <varlistentry id="guc-timezone" xreflabel="timezone"> <term><varname>timezone</varname> (<type>string</type>)</term> <indexterm> *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 2213,2218 **** January 8 04:05:06 1999 PST --- 2213,2305 ---- </para> </sect2> + <sect2 id="interval-output"> + <title>Interval Output</title> + + <indexterm> + <primary>interval</primary> + <secondary>output format</secondary> + <seealso>formatting</seealso> + </indexterm> + + <para> + The output format of the interval types can be set to one of the four + styles <literal>sql_standard</>, + <literal>postgres</>, or <literal>postgres_verbose</>.The default + is the <literal>postgres</> format. + <xref + linkend="interval-style-output-table"> shows examples of each + output style. + </para> + + <para> + The <literal>sql_standard</> style will output SQL standard + interval literal strings where the value of the interval + value consists of only a year-month component or a datetime + component (as required by the sql standard). For an interval + containing both a year-month and a datetime component, the + output will be a SQL Standard unquoted year-month literal + string joined to a SQL Standard unquoted datetime literal + string with a space in between. + </para> + + <para> + The <literal>postgres</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>ISO</>. + </para> + + <para> + The <literal>postgres_verbose</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>SQL</>. + </para> + + <table id="interval-style-output-table"> + <title>Interval Style Example</title> + <tgroup cols="2"> + <thead> + <row> + <entry>Style Specification</entry> + <entry>Year-Month Interval</entry> + <entry>DateTime Interval</entry> + <entry>Nonstandardrd Extended Interval</entry> + </row> + </thead> + <tbody> + <row> + <entry>sql_standard</entry> + <entry>1-2</entry> + <entry>3 4:05:06</entry> + <entry>-1-2 +3 -4:05:06</entry> + </row> + <row> + <entry>postgres</entry> + <entry>1 year 2 mons</entry> + <entry>3 days 04:05:06</entry> + <entry> -1 years -2 mons +3 days -04:05:06</entry> + </row> + <row> + <entry>postgres_verbose</entry> + <entry>@ 1 year 2 mons</entry> + <entry>@ 3 days 4 hours 5 mins 6 secs</entry> + <entry>@ 1 year 2 mons -3 days 4 hours 5 mins 6 secs ago</entry> + </row> + </tbody> + </tgroup> + </table> + + <para> + Note that <literal>sql_standard</> style will only produce strictly + standards-conforming string sliterals when given a strictly SQL-standard interval + value - meaning that it needs to be a pure year-month or datetime + interval and not mix positive and negative components. + </para> + + </sect2> + + + <sect2 id="datatype-timezones"> <title>Time Zones</title> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 229,234 **** assign_datestyle(const char *value, bool doit, GucSource source) --- 229,271 ---- /* + * assign_intervalstyle: GUC assign_hook for datestyle + */ + const char * + assign_intervalstyle(const char *value, bool doit, GucSource source) + { + int newIntervalStyle = IntervalStyle; + char * result = (char *) malloc(32); + if (pg_strcasecmp(value, "postgres") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES; + } + else if (pg_strcasecmp(value, "postgres_verbose") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES_VERBOSE; + } + else if (pg_strcasecmp(value, "sql_standard") == 0) + { + newIntervalStyle = INTSTYLE_SQL_STANDARD; + } + else + { + ereport(GUC_complaint_elevel(source), + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized \"intervalstyle\" key word: \"%s\"", + value))); + return NULL; + } + if (doit) + { + IntervalStyle = newIntervalStyle; + strcpy(result, value); + } + return result; + } + + + /* * TIMEZONE */ *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 3605,3610 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3605,3625 ---- return TRUE; } + /* + * small helper funciton to avoid copy&paste of this ifdef below + */ + static void + AppendFsec(char * cp,fsec_t fsec) + { + if (fsec==0) return; + #ifdef HAVE_INT64_TIMESTAMP + sprintf(cp, ".%06d", Abs(fsec)); + #else + sprintf(cp, ":%012.9f", fabs(fsec)); + #endif + TrimTrailingZeros(cp); + } + /* EncodeInterval() * Interpret time structure as a delta time and convert to string. *************** *** 3613,3618 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3628,3644 ---- * Actually, afaik ISO does not address time interval formatting, * but this looks similar to the spec for absolute date/time. * - thomas 1998-04-30 + * + * Actually, afaik, ISO 8601 does specify formats for "time + * intervals...[of the]...format with time-unit designators", which + * are pretty ugly. The format looks something like + * P1Y1M1DT1H1M1.12345S + * but useful for exchanging data with computers instead of humans. + * - ron 2003-07-14 + * + * And ISO's SQL 2008 standard specifies standards for + * "year-month literal"s (that look like '2-3') and + * "day-time literal"s (that look like ('4 5:6:7') */ int EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) *************** *** 3621,3626 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3647,3659 ---- bool is_nonzero = FALSE; char *cp = str; + int year = tm->tm_year; + int mon = tm->tm_mon; + int mday = tm->tm_mday; + int hour = tm->tm_hour; + int min = tm->tm_min; + int sec = tm->tm_sec; + /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and *************** *** 3628,3635 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) */ switch (style) { ! /* compatible with ISO date formats */ ! case USE_ISO_DATES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", --- 3661,3738 ---- */ switch (style) { ! /* SQL Standard interval literals */ ! case INTSTYLE_SQL_STANDARD: ! { ! bool has_negative = (year < 0) || (mon < 0) || ! (mday < 0) || (hour < 0) || ! (min < 0) || (sec < 0) || (fsec<0); ! bool has_positive = (year > 0) || (mon > 0) || ! (mday > 0) || (hour > 0) || ! (min > 0) || (sec > 0) || (fsec>0); ! bool has_year_month = (year != 0) || (mon != 0); ! bool has_datetime = (hour != 0) || (min != 0) || ! (sec != 0) || (fsec!= 0) || (mday != 0); ! bool has_day = (mday != 0); ! bool sql_standard_value = (!(has_negative && has_positive)) && ! (!(has_year_month && has_datetime)); ! /* ! * SQL Standard wants only 1 "<sign>" preceeding the whole ! * interval. ! */ ! if (has_negative && sql_standard_value) ! { ! sprintf(cp,"-"); ! cp++; ! year = -year; ! mon = -mon; ! mday = -mday; ! hour = -hour; ! min = -min; ! sec = -sec; ! fsec = -fsec; ! } ! if (!has_negative && !has_positive) ! { ! sprintf(cp,"0"); ! } ! else if (!sql_standard_value) ! { ! /* ! * For non sql-standard interval values, ! * force outputting the signs to avoid ! * ambiguities with intervals with mixed ! * sign components. ! */ ! char year_sign = (year<0 || mon<0) ? '-' : '+'; ! char day_sign = (mday<0) ? '-' : '+'; ! char sec_sign = (hour<0 || min<0 || sec<0 || fsec<0) ! ? '-' : '+'; ! cp += sprintf(cp,"%c%d-%d %c%d %c%d:%02d:%02d", ! year_sign,abs(year),abs(mon), ! day_sign,abs(mday), ! sec_sign,abs(hour),abs(min),abs(sec)); ! AppendFsec(cp,fsec); ! } ! else if (has_year_month) ! { ! sprintf(cp,"%d-%d",year,mon); ! } ! else if (has_day) ! { ! cp += sprintf(cp,"%d %d:%02d:%02d",mday,hour,min,sec); ! AppendFsec(cp,fsec); ! } ! else ! { ! cp += sprintf(cp,"%d:%02d:%02d",hour,min,sec); ! AppendFsec(cp,fsec); ! } ! break; ! } ! ! /* compatible with postgresql 8.3 when DateStyle = 'iso' */ ! case INTSTYLE_POSTGRES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", *************** *** 3692,3700 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) cp += strlen(cp); } } break; ! case USE_POSTGRES_DATES: default: strcpy(cp, "@ "); cp += strlen(cp); --- 3795,3809 ---- cp += strlen(cp); } } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } break; ! /* compatible with postgresql 8.3 when DateStyle = 'sql' */ ! case INTSTYLE_POSTGRES_VERBOSE: default: strcpy(cp, "@ "); cp += strlen(cp); *************** *** 3821,3842 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } break; } - /* identically zero? then put in a unitless zero... */ - if (!is_nonzero) - { - strcat(cp, "0"); - cp += strlen(cp); - } - - if (is_before && (style != USE_ISO_DATES)) - { - strcat(cp, " ago"); - cp += strlen(cp); - } - return 0; } /* EncodeInterval() */ --- 3930,3948 ---- is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } + if (is_before) + { + strcat(cp, " ago"); + cp += strlen(cp); + } break; } return 0; } /* EncodeInterval() */ *** a/src/backend/utils/adt/nabstime.c --- b/src/backend/utils/adt/nabstime.c *************** *** 671,677 **** reltimeout(PG_FUNCTION_ARGS) char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, DateStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); --- 671,677 ---- char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, IntervalStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 677,683 **** interval_out(PG_FUNCTION_ARGS) if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, DateStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); --- 677,683 ---- if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); *** a/src/backend/utils/init/globals.c --- b/src/backend/utils/init/globals.c *************** *** 88,93 **** bool ExitOnAnyError = false; --- 88,94 ---- int DateStyle = USE_ISO_DATES; int DateOrder = DATEORDER_MDY; + int IntervalStyle = INTSTYLE_POSTGRES; bool HasCTZSet = false; int CTimeZone = 0; *** a/src/backend/utils/misc/guc.c --- b/src/backend/utils/misc/guc.c *************** *** 366,371 **** static bool session_auth_is_superuser; --- 366,372 ---- static double phony_random_seed; static char *client_encoding_string; static char *datestyle_string; + static char *intervalstyle_string; static char *locale_collate; static char *locale_ctype; static char *server_encoding_string; *************** *** 2078,2083 **** static struct config_string ConfigureNamesString[] = --- 2079,2094 ---- "ISO, MDY", assign_datestyle, NULL }, + { + {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE, + gettext_noop("Sets the display format for interval values."), + gettext_noop(""), + GUC_REPORT + }, + &intervalstyle_string, + "postgres", assign_intervalstyle, NULL + }, + { {"default_tablespace", PGC_USERSET, CLIENT_CONN_STATEMENT, gettext_noop("Sets the default tablespace to create tables and indexes in."), *** a/src/backend/utils/misc/postgresql.conf.sample --- b/src/backend/utils/misc/postgresql.conf.sample *************** *** 419,424 **** --- 419,425 ---- # - Locale and Formatting - #datestyle = 'iso, mdy' + #intervalstyle = 'postgres' #timezone = unknown # actually, defaults to TZ environment # setting #timezone_abbreviations = 'Default' # Select the set of available time zone *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1953,1958 **** psql_completion(char *text, int start, int end) --- 1953,1965 ---- COMPLETE_WITH_LIST(my_list); } + else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) + { + static const char *const my_list[] = + {"postgres","postgres_verbose", "sql_standard", NULL}; + + COMPLETE_WITH_LIST(my_list); + } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) { static const char *const my_list[] = *** a/src/include/commands/variable.h --- b/src/include/commands/variable.h *************** *** 15,20 **** --- 15,22 ---- extern const char *assign_datestyle(const char *value, bool doit, GucSource source); + extern const char *assign_intervalstyle(const char *value, + bool doit, GucSource source); extern const char *assign_timezone(const char *value, bool doit, GucSource source); extern const char *show_timezone(void); *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 191,196 **** extern PGDLLIMPORT Oid MyDatabaseTableSpace; --- 191,208 ---- extern int DateStyle; extern int DateOrder; + + /* + * IntervalStyles + * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' + * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' + * INTSTYLE_SQL_STANDARD SQL standard interval literals + */ + #define INTSTYLE_POSTGRES 0 + #define INTSTYLE_POSTGRES_VERBOSE 1 + #define INTSTYLE_SQL_STANDARD 2 + + extern int IntervalStyle; /* * HasCTZSet is true if user has set timezone as a numeric offset from UTC. *** a/src/test/regress/sql/alter_table.sql --- b/src/test/regress/sql/alter_table.sql *************** *** 60,65 **** ALTER TABLE tmp ADD COLUMN y float4[]; --- 60,67 ---- ALTER TABLE tmp ADD COLUMN z int2[]; + SET IntervalStyle to postgres_verbose; + INSERT INTO tmp (a, b, c, d, e, f, g, h, i, j, k, l, m, n, p, q, r, s, t, u, v, w, x, y, z) VALUES (4, 'name', 'text', 4.1, 4.1, 2, '(4.1,4.1,3.1,3.1)', *** a/src/test/regress/sql/arrays.sql --- b/src/test/regress/sql/arrays.sql *************** *** 283,288 **** select '{ }}'::text[]; --- 283,289 ---- select array[]; -- none of the above should be accepted + SET intervalstyle to postgres_verbose; -- all of the following should be accepted select '{}'::text[]; select '{{{1,2,3,4},{2,3,4,5}},{{3,4,5,6},{4,5,6,7}}}'::text[]; *** a/src/test/regress/sql/horology.sql --- b/src/test/regress/sql/horology.sql *************** *** 73,79 **** SELECT date '1991-02-03' - time with time zone '04:05:06 UTC' AS "Subtract Time -- -- timestamp, interval arithmetic -- ! SELECT timestamp without time zone '1996-03-01' - interval '1 second' AS "Feb 29"; SELECT timestamp without time zone '1999-03-01' - interval '1 second' AS "Feb 28"; SELECT timestamp without time zone '2000-03-01' - interval '1 second' AS "Feb 29"; --- 73,79 ---- -- -- timestamp, interval arithmetic -- ! set IntervalStyle to postgres_verbose; SELECT timestamp without time zone '1996-03-01' - interval '1 second' AS "Feb 29"; SELECT timestamp without time zone '1999-03-01' - interval '1 second' AS "Feb 28"; SELECT timestamp without time zone '2000-03-01' - interval '1 second' AS "Feb 29"; *** a/src/test/regress/sql/interval.sql --- b/src/test/regress/sql/interval.sql *************** *** 94,99 **** FROM INTERVAL_MULDIV_TBL; --- 94,100 ---- DROP TABLE INTERVAL_MULDIV_TBL; SET DATESTYLE = 'postgres'; + SET INTERVALSTYLE = 'postgres_verbose'; SELECT '' AS ten, * FROM INTERVAL_TBL; *************** *** 118,123 **** SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour"; --- 119,126 ---- -- test fractional second input, and detection of duplicate units SET DATESTYLE = 'ISO'; + SET INTERVALSTYLE = 'postgres'; + SELECT '1 millisecond'::interval, '1 microsecond'::interval, '500 seconds 99 milliseconds 51 microseconds'::interval; SELECT '3 days 5 milliseconds'::interval; *** a/src/test/regress/sql/reltime.sql --- b/src/test/regress/sql/reltime.sql *************** *** 2,7 **** --- 2,10 ---- -- RELTIME -- + -- DateStyle is 'Postgres, MDY' here... + SET intervalstyle to postgres_verbose; + CREATE TABLE RELTIME_TBL (f1 reltime); INSERT INTO RELTIME_TBL (f1) VALUES ('@ 1 minute'); *************** *** 23,29 **** INSERT INTO RELTIME_TBL (f1) VALUES ('badly formatted reltime'); INSERT INTO RELTIME_TBL (f1) VALUES ('@ 30 eons ago'); -- test reltime operators - SELECT '' AS six, * FROM RELTIME_TBL; SELECT '' AS five, * FROM RELTIME_TBL --- 26,31 ---- *** a/src/test/regress/sql/timestamp.sql --- b/src/test/regress/sql/timestamp.sql *************** *** 163,168 **** SELECT '' AS "16", d1 FROM TIMESTAMP_TBL --- 163,171 ---- SELECT '' AS "49", d1 FROM TIMESTAMP_TBL WHERE d1 >= timestamp without time zone '1997-01-02'; + -- DateStyle was 'Postgres, MDY' at this point. + SET intervalstyle to postgres_verbose; + SELECT '' AS "54", d1 - timestamp without time zone '1997-01-02' AS diff FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; *** a/src/test/regress/sql/timestamptz.sql --- b/src/test/regress/sql/timestamptz.sql *************** *** 182,187 **** SELECT '' AS "16", d1 FROM TIMESTAMPTZ_TBL --- 182,190 ---- SELECT '' AS "49", d1 FROM TIMESTAMPTZ_TBL WHERE d1 >= timestamp with time zone '1997-01-02'; + -- Datestyle was Postgres, MDY here + SET intervalstyle TO postgres_verbose; + SELECT '' AS "54", d1 - timestamp with time zone '1997-01-02' AS diff FROM TIMESTAMPTZ_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
Ron Mayer wrote: > Tom Lane wrote: >> In fact, given that we are now >> somewhat SQL-compliant on interval input, a GUC that selected >> PG traditional, SQL-standard, or ISO 8601 interval output format seems >> like it could be a good idea. This patch (that works on top of the IntervalStyle patch I posted earlier today) adds support for ISO8601 standard[0] "Time Interval" "Durations" of the "format with designators" (section 4.4.4.2.1). The other ISO 8601 types of intervals deal with start and end points, so this one seemed most relevant. It builds on a patch I had earlier submitted back in 2003[1], where people noted that we wanted sql-standard intervals first; but I see that ISO 8601 intervals did make it to the todo list. I updated the docs, but I still need to add regression tests, so it's still a WIP, but I think the code's ready (I've been using an older version of this patch internally since '03) so I'd appreciate feedback. [0] http://isotc.iso.org/livelink/livelink/4021199/ISO_8601_2004_E.zip?func=doc.Fetch&nodeid=4021199 [1] http://archives.postgresql.org/pgsql-patches/2003-09/msg00121.php [2] http://wiki.postgresql.org/wiki/Todo *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 1975,1980 **** January 8 04:05:06 1999 PST --- 1975,1996 ---- </para> <para> + Alternatively, <type>interval</type> values can be written as + ISO 8601 time intervals, using the "Format with time-unit designators", + or PnYnMnDTnHnMnS. This format always starts with the character + <literal>'P'</>, followed by a string of values followed by single + character time-unit designators. A <literal>'T'</> separates the + date and time parts of the interval. + In this format, <literal>'n'</> gets replaced by a number, and + <literal>Y</> represents years, + <literal>M</> (in the date part) months, + <literal>D</> months, + <literal>H</> hours, + <literal>M</> (in the time part) minutes, + and <literal>S</> seconds. + </para> + + <para> Internally <type>interval</> values are stored as months, days, and seconds. This is done because the number of days in a month varies, and a day can have 23 or 25 hours if a daylight savings *************** *** 2224,2231 **** January 8 04:05:06 1999 PST <para> The output format of the interval types can be set to one of the four ! styles <literal>sql_standard</>, ! <literal>postgres</>, or <literal>postgres_verbose</>.The default is the <literal>postgres</> format. <xref linkend="interval-style-output-table"> shows examples of each --- 2240,2247 ---- <para> The output format of the interval types can be set to one of the four ! styles <literal>sql_standard</>, <literal>iso_8601</>, ! <literal>postgres</>, or <literal>postgres_verbose</>. The default is the <literal>postgres</> format. <xref linkend="interval-style-output-table"> shows examples of each *************** *** 2244,2249 **** January 8 04:05:06 1999 PST --- 2260,2281 ---- </para> <para> + The <literal>iso_8601</> style will output ISO 8601 + time intervals using the "format with time-unit designators" + This format always starts with the character + <literal>'P'</>, followed by a string of values followed by single + character time-unit designators. A <literal>'T'</> separates the + date and time parts of the interval. + In this format, <literal>'n'</> gets replaced by a number, and + <literal>Y</> represents years, + <literal>M</> (in the date part) months, + <literal>D</> months, + <literal>H</> hours, + <literal>M</> (in the time part) minutes, + and <literal>S</> seconds. + </para> + + <para> The <literal>postgres</> style will output intervals that match the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> parameter was set to <literal>ISO</>. *************** *** 2274,2283 **** January 8 04:05:06 1999 PST <entry>-1-2 +3 -4:05:06</entry> </row> <row> <entry>postgres</entry> <entry>1 year 2 mons</entry> <entry>3 days 04:05:06</entry> ! <entry> -1 years -2 mons +3 days -04:05:06</entry> </row> <row> <entry>postgres_verbose</entry> --- 2306,2321 ---- <entry>-1-2 +3 -4:05:06</entry> </row> <row> + <entry>iso_8601</entry> + <entry>P1Y2M</entry> + <entry>P3DT4H5M6</entry> + <entry>P-1Y-2M3DT-4H-5M-6</entry> + </row> + <row> <entry>postgres</entry> <entry>1 year 2 mons</entry> <entry>3 days 04:05:06</entry> ! <entry>-1 year -2 mons 3 days -04:05:06</entry> </row> <row> <entry>postgres_verbose</entry> *************** *** 2293,2299 **** January 8 04:05:06 1999 PST Note that <literal>sql_standard</> style will only produce strictly standards-conforming string sliterals when given a strictly SQL-standard interval value - meaning that it needs to be a pure year-month or datetime ! interval and not mix positive and negative components. </para> </sect2> --- 2331,2339 ---- Note that <literal>sql_standard</> style will only produce strictly standards-conforming string sliterals when given a strictly SQL-standard interval value - meaning that it needs to be a pure year-month or datetime ! interval and not mix positive and negative components, and ! <literal>iso_8601</> style will only product strictly ISO-8601 standard ! strings when given values that can be represented as ISO-8601 intervals. </para> </sect2> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 248,253 **** assign_intervalstyle(const char *value, bool doit, GucSource source) --- 248,257 ---- { newIntervalStyle = INTSTYLE_SQL_STANDARD; } + else if (pg_strcasecmp(value, "iso_8601") == 0) + { + newIntervalStyle = INTSTYLE_ISO_8601; + } else { ereport(GUC_complaint_elevel(source), *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 2723,2728 **** DecodeSpecial(int field, char *lowtoken, int *val) --- 2723,2906 ---- } + /* + * A small helper function to avoid cut&paste code in DecodeIso8601Interval + */ + static void adjust_fval(double fval,struct pg_tm * tm, fsec_t *fsec, int scale) + { + int sec; + if (fval == 0) return; + fval *= scale; + sec = fval; + tm->tm_sec += sec; + #ifdef HAVE_INT64_TIMESTAMP + *fsec += ((fval - sec) * 1000000); + #else + *fsec += (fval - sec); + #endif + } + + + /* DecodeISO8601Interval() + * + * Check if it's a ISO 8601 Section 5.5.4.2 "Representation of + * time-interval by duration only." + * Basic extended format: PnYnMnDTnHnMnS + * PnW + * For more info. + * http://www.astroclark.freeserve.co.uk/iso8601/index.html + * ftp://ftp.qsl.net/pub/g1smd/154N362_.PDF + * + * Examples: P1D for 1 day + * PT1H for 1 hour + * P2Y6M7DT1H30M for 2 years, 6 months, 7 days 1 hour 30 min + * + * The first field is exactly "p" or "pt" it may be of this type. + * + * Returns DTERR_BAD_FORMAT if the field is not of this type. + * + * It pretty strictly checks the spec, with the two exceptions + * that a week field ('W') may coexist with other units, and that + * this function allows decimals in fields other than the least + * significant units. + */ + int + DecodeISO8601Interval(char *str, struct pg_tm * tm, fsec_t *fsec) + { + char unit; + int fmask = 0, + tmask; + int val; + double fval; + int datepart = true; + int negative = false; + + tm->tm_year = 0; + tm->tm_mon = 0; + tm->tm_mday = 0; + tm->tm_hour = 0; + tm->tm_min = 0; + tm->tm_sec = 0; + *fsec = 0; + + /* + * An ISO 8601 "time-interval by duration only" must start + * with a 'P'. If it contains a date-part, 'p' will be the + * only character in the field. If it contains no date part + * it will contain exactly to characters 'PT' indicating a + * time part. + * Anything else does not match an ISO 8601 basic interval + * and will be treated like a traditional postgresql interval. + */ + if (!(str[0] == 'P')) + { + return DTERR_BAD_FORMAT; + } + str++; + + /* + * Process pairs of fields at a time. + */ + while (*str) + { + if (*str == 'T') + { + datepart = false; + str++; + continue; + } + if (! (isdigit(*str) || *str == '-' || *str=='.') ) + return DTERR_BAD_FORMAT; + + negative = (*str == '-'); + fval = strtod(str, &str); + val = fval; + fval = fval - val; + + unit = *str; + str++; + + if (datepart) + { + switch (unit) /* Y M D W */ + { + case 'D': + tm->tm_mday += val; + adjust_fval(fval,tm,fsec, 86400); + tmask = ((fmask & DTK_M(DAY)) ? 0 : DTK_M(DAY)); + break; + + case 'W': + tm->tm_mday += val * 7; + adjust_fval(fval,tm,fsec,7 * 86400); + tmask = ((fmask & DTK_M(DAY)) ? 0 : DTK_M(DAY)); + break; + + case 'M': + tm->tm_mon += val; + adjust_fval(fval,tm,fsec,30 * 86400); + tmask = DTK_M(MONTH); + break; + + case 'Y': + /* + * Why can fractional months produce seconds, + * but fractional years can't? Well the older + * interval code below has the same property + * so this one follows the other one too. + */ + tm->tm_year += val; + if (fval != 0) + tm->tm_mon += (fval * 12); + tmask = ((fmask & DTK_M(YEAR)) ? 0 : DTK_M(YEAR)); + break; + + default: + return DTERR_BAD_FORMAT; /* not a vald ISO8601 date unit prefix */ + } + } + else + { + switch (unit) /* H M S */ + { + case 'S': + tm->tm_sec += val; + adjust_fval(fval,tm,fsec,1); + tmask = DTK_M(SECOND); + break; + case 'M': + tm->tm_min += val; + adjust_fval(fval,tm,fsec,60); + tmask = DTK_M(MINUTE); + break; + case 'H': + tm->tm_hour += val; + adjust_fval(fval,tm,fsec,3600); + tmask = DTK_M(HOUR); + break; + default: + return DTERR_BAD_FORMAT; /* not a vald ISO8601 time unit prefix */ + } + } + fmask |= tmask; + } + + if (*fsec != 0) + { + int sec; + #ifdef HAVE_INT64_TIMESTAMP + sec = (*fsec / INT64CONST(1000000)); + *fsec -= (sec * INT64CONST(1000000)); + #else + TMODULO(*fsec, sec, 1e0); + #endif + tm->tm_sec += sec; + } + return (fmask != 0) ? 0 : -1; + } + + + /* DecodeInterval() * Interpret previously parsed fields for general time interval. * Returns 0 if successful, DTERR code if bogus input detected. *************** *** 2732,2737 **** DecodeSpecial(int field, char *lowtoken, int *val) --- 2910,2919 ---- * * Allow ISO-style time span, with implicit units on number of days * preceding an hh:mm:ss field. - thomas 1998-04-30 + * + * Allow ISO-8601 style "Representation of time-interval by duration only" + * of the format 'PnYnMnDTnHnMnS' and 'PnW' - ron mayer 2003-08-30 + * also deprecate the not-really-iso-like style from 1998-04-30 */ int DecodeInterval(char **field, int *ftype, int nf, int range, *************** *** 3605,3613 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, return TRUE; } ! /* ! * small helper funciton to avoid copy&paste of this ifdef below */ static void AppendFsec(char * cp,fsec_t fsec) { --- 3787,3803 ---- return TRUE; } ! /* ! * Small helper functions to avoid cut&paste in EncodeInterval below */ + + static char * + AddISO8601IntervalPart(char * cp, int value, char units) + { + if (value==0) return cp; + return cp + sprintf(cp,"%d%c",value,units); + } + static void AppendFsec(char * cp,fsec_t fsec) { *************** *** 3647,3652 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3837,3846 ---- bool is_nonzero = FALSE; char *cp = str; + /* + * These are used so much below, copy them to local variables to make + * the code shorter and more readable. + */ int year = tm->tm_year; int mon = tm->tm_mon; int mday = tm->tm_mday; *************** *** 3730,3735 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3924,3957 ---- } break; } + case INTSTYLE_ISO_8601: + if ((year == 0) && (mon == 0) && (mday == 0) && + (hour == 0) && (min == 0) && (sec == 0) && + (fsec == 0)) + { + sprintf(cp,"PT0S"); + break; + } + cp += sprintf(cp,"P"); + cp = AddISO8601IntervalPart(cp,year,'Y'); + cp = AddISO8601IntervalPart(cp,mon ,'M'); + cp = AddISO8601IntervalPart(cp,mday,'D'); + if ((hour != 0) || (min != 0) || + (sec != 0) || (fsec != 0)) + { + cp += sprintf(cp,"T"); + } + cp = AddISO8601IntervalPart(cp,hour,'H'); + cp = AddISO8601IntervalPart(cp,min ,'M'); + if ((sec != 0) || (fsec != 0)) + { + cp += sprintf(cp, "%d", sec); + AppendFsec(cp,fsec); + TrimTrailingZeros(cp); + cp += strlen(cp); + cp += sprintf(cp,"S"); + } + break; /* compatible with postgresql 8.3 when DateStyle = 'iso' */ case INTSTYLE_POSTGRES: *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 627,632 **** interval_in(PG_FUNCTION_ARGS) --- 627,635 ---- ftype, MAXDATEFIELDS, &nf); if (dterr == 0) dterr = DecodeInterval(field, ftype, nf, range, &dtype, tm, &fsec); + if (dterr == DTERR_BAD_FORMAT) + dterr = DecodeISO8601Interval(str, tm, &fsec); + if (dterr != 0) { if (dterr == DTERR_FIELD_OVERFLOW) *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1956,1963 **** psql_completion(char *text, int start, int end) else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) { static const char *const my_list[] = ! {"postgres","postgres_verbose", "sql_standard", NULL}; ! COMPLETE_WITH_LIST(my_list); } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) --- 1956,1962 ---- else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) { static const char *const my_list[] = ! {"postgres","postgres_verbose", "sql_standard", "iso_8601", NULL}; COMPLETE_WITH_LIST(my_list); } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 197,206 **** extern int DateOrder; --- 197,208 ---- * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' * INTSTYLE_SQL_STANDARD SQL standard interval literals + * INTSTYLE_ISO_8601 Specifies ISO-8601-basic formatted intervals */ #define INTSTYLE_POSTGRES 0 #define INTSTYLE_POSTGRES_VERBOSE 1 #define INTSTYLE_SQL_STANDARD 2 + #define INTSTYLE_ISO_8601 3 extern int IntervalStyle; *** a/src/include/utils/datetime.h --- b/src/include/utils/datetime.h *************** *** 292,297 **** extern int DecodeTimeOnly(char **field, int *ftype, --- 292,300 ---- extern int DecodeInterval(char **field, int *ftype, int nf, int range, int *dtype, struct pg_tm * tm, fsec_t *fsec); + extern int DecodeISO8601Interval(char *str, + struct pg_tm * tm, fsec_t *fsec); + extern void DateTimeParseError(int dterr, const char *str, const char *datatype);
Kevin Grittner wrote: >>>> "Kevin Grittner" <Kevin.Grittner@wicourts.gov> wrote: > > Even more surprising is the behavior for interval(1) here: > [.... some context with nonsurprising examples removed ...] > ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(1); > interval > ---------------------------------- > 1 year 2 mons 3 days 04:05:06.60 > (1 row) > > That trailing zero should be considered a bug. Is there a consensus that we don't want that trailing zero? I notice that datetime.c's "TrimTrailingZeros(char *str)" has the comment: /* chop off trailing zeros... but leave at least 2 fractional digits */ that suggests that the trailing zero was intentional, but I can't find any reasons why 2 fractional disgits were left. The same function's also used for timestamps, so if we remove that trailing zero in both places we'll see some regression differences where we get ! | Mon Feb 10 17:32:01.5 1997 PST | 1997 | 7 | 1 instead of ! | Mon Feb 10 17:32:01.50 1997 PST | 1997 | 7 | 1 IMHO we don't want the extra zero for timestamps either. If people agree I'll fold it into the patch dealing with the other interval rounding eccentricities I have. Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> [some other interval rounding example] > > I don't much like the forced rounding to two digits here, but changing > that doesn't seem like material for back-patching. Are you going to > fix that up while working on your other patches?
On Thu, Oct 09, 2008 at 11:50:17AM -0700, Ron Mayer wrote: > Kevin Grittner wrote: >>>>> "Kevin Grittner" <Kevin.Grittner@wicourts.gov> wrote: >> Even more surprising is the behavior for interval(1) here: >> [.... some context with nonsurprising examples removed ...] >> ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(1); >> interval >> ---------------------------------- >> 1 year 2 mons 3 days 04:05:06.60 >> (1 row) >> That trailing zero should be considered a bug. > > Is there a consensus that we don't want that trailing zero? > I notice that datetime.c's "TrimTrailingZeros(char *str)" has > the comment: > /* chop off trailing zeros... but leave at least 2 fractional digits */ > that suggests that the trailing zero was intentional, but I > can't find any reasons why 2 fractional disgits were left. > > The same function's also used for timestamps, so if we remove that > trailing zero in both places we'll see some regression differences > where we get > ! | Mon Feb 10 17:32:01.5 1997 PST | 1997 | 7 | 1 > instead of > ! | Mon Feb 10 17:32:01.50 1997 PST | 1997 | 7 | 1 > > IMHO we don't want the extra zero for timestamps either. > There is a difference between the result 0.6 and 0.60 in rounding. The first is accurate +-0.05 and the second is +-0.005. Certainly, it does not seem unreasonable that machines can calulate intervals to the nearest 100th of a second. What is not clear to me is how the decision to stop at the 2nd decimal digit was reached. If timestamps are accurate to 1/100th, intervals should be returned to that level of accuracy as well. Trailing digits definitely have meaning. My 2 cents, Ken > > If people agree I'll fold it into the patch dealing with > the other interval rounding eccentricities I have. > > Tom Lane wrote: >> Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >>> [some other interval rounding example] >> I don't much like the forced rounding to two digits here, but changing >> that doesn't seem like material for back-patching. Are you going to >> fix that up while working on your other patches? > > > > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers >
Kenneth Marshall <ktm@rice.edu> writes: > There is a difference between the result 0.6 and 0.60 in rounding. > The first is accurate +-0.05 and the second is +-0.005. Certainly, > it does not seem unreasonable that machines can calulate intervals > to the nearest 100th of a second. What is not clear to me is how the > decision to stop at the 2nd decimal digit was reached. Probably by flipping a coin ;-). You have to remember that all this behavior was designed around floating-point intervals, so there's inherent imprecision in there; and the extent depends on the size of the interval which makes it pretty hard to choose a display precision. In the integer-timestamp world we know that the number is exact in microseconds. We clearly ought to be prepared to display up to six fractional digits, but suppressing trailing zeroes in that seems appropriate. We could try to do the same in the float case, but I'm a bit worried about finding ourselves showing "1234567.799999" where it should be "1234567.8". regards, tom lane
>>> Kenneth Marshall <ktm@rice.edu> wrote: >>> Even more surprising is the behavior for interval(1) here: >>> [.... some context with nonsurprising examples removed ...] >>> ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(1); >>> interval >>> ---------------------------------- >>> 1 year 2 mons 3 days 04:05:06.60 >>> (1 row) >>> That trailing zero should be considered a bug. > What is not clear to me is how the > decision to stop at the 2nd decimal digit was reached. See this posting and others on the thread: http://archives.postgresql.org/pgsql-hackers/2008-09/msg00999.php The current rules seem to be: (1) If precision is specified, round to that precision. (2) If result has only zeros in the fraction, show no fraction, else show at least two digits in the fraction, adding a trailing zero if needed to get to two digits, but don't show any trailing zeros in the fraction beyond the second position. I think it would be ideal if we could track how many digits of accuracy we have in a value, and show them all, even if that involves trailing zeros. If that's not feasible, let's consistently not show trailing zeros. Rounding .64 to .6 and then showing .60 is just plain wrong. -Kevin
On Thu, Oct 09, 2008 at 02:47:24PM -0500, Kevin Grittner wrote: > >>> Kenneth Marshall <ktm@rice.edu> wrote: > > >>> Even more surprising is the behavior for interval(1) here: > >>> [.... some context with nonsurprising examples removed ...] > >>> ccdev=# select '1 year 2 mons 3 days 04:05:06.64321'::interval(1); > >>> interval > >>> ---------------------------------- > >>> 1 year 2 mons 3 days 04:05:06.60 > >>> (1 row) > >>> That trailing zero should be considered a bug. > > > What is not clear to me is how the > > decision to stop at the 2nd decimal digit was reached. > > See this posting and others on the thread: > > http://archives.postgresql.org/pgsql-hackers/2008-09/msg00999.php > > The current rules seem to be: > > (1) If precision is specified, round to that precision. > > (2) If result has only zeros in the fraction, show no fraction, else > show at least two digits in the fraction, adding a trailing zero if > needed to get to two digits, but don't show any trailing zeros in the > fraction beyond the second position. > > I think it would be ideal if we could track how many digits of > accuracy we have in a value, and show them all, even if that involves > trailing zeros. If that's not feasible, let's consistently not show > trailing zeros. Rounding .64 to .6 and then showing .60 is just plain > wrong. > > -Kevin > +1 Ken
Tom Lane wrote: > In the integer-timestamp world we know that the number is exact in > microseconds. We clearly ought to be prepared to display up to six > fractional digits, but suppressing trailing zeroes in that seems > appropriate. Great. > We could try to do the same in the float case, but I'm a bit worried > about finding ourselves showing "1234567.799999" where it should be > "1234567.8". If I understand the code right fsec should mostly be values between -1 and 1 anyway, because even in the floating point case seconds are carried in the tm->tm_sec part. It looks to me that a double should be plenty to do microseconds so long as we don't put big numbers into fsec. printf("%.99f\n",59.111111111111111111); 59.11111111111111426907882... Anyway - I'll try showing up-to-6-digits in both cases and seeing if I can find a test case that breaks. I guess this rounding trickiness with rounding explains some of the bizarre code like this too: #if 0/* chop off trailing one to cope with interval rounding */if (strcmp(str + len - 4,"0001") == 0){ len -= 4; *(str + len) = '\0';} #endif
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Tom Lane wrote: >> We could try to do the same in the float case, but I'm a bit worried >> about finding ourselves showing "1234567.799999" where it should be >> "1234567.8". > If I understand the code right fsec should mostly be values > between -1 and 1 anyway, because even in the floating point > case seconds are carried in the tm->tm_sec part. The problem is that that's a decomposed representation. In the stored form, there's a floating-point seconds field that includes hours, minutes, seconds, and fractional seconds, and therefore large values of the H/M/S fields degrade the accuracy of the fraction part. Here's an example (testing in 8.3, since HEAD defaults to integer): regression=# select '1234567890 hours 0.123 sec'::interval; interval -------------------------1234567890:00:00.123047 (1 row) Since there's a (somewhat arbitrary) limitation of the hours to 2^31, this is close to the worst possible case. (Hm, maybe someone actually did the math and decided that 2 fractional digits were the most they could promise given that? No, because this code dates from a time when we included days in the same field too ... back then there might have been no accuracy at all in the fraction part.) regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Tom Lane wrote: >>> We could try to do the same in the float case, but I'm a bit worried >>> about finding ourselves showing "1234567.799999" ... >> If I understand the code right [I didn't...] > > The problem is ... seconds field that includes hours, > minutes, seconds, and fractional seconds...Here's an example... > regression=# select '1234567890 hours 0.123 sec'::interval; > ... 1234567890:00:00.123047 Hmm. That's also an existence proof that we're not too concerned about showing 6 imprecise digits anyway (at least for some 8.3 DateStyles). Doesn't seem like it'd hurt too much if we show them for all the IntervalStyles. > Since there's a (somewhat arbitrary) limitation of the hours to 2^31, > this is close to the worst possible case. (Hm, maybe someone actually > did the math and decided that 2 fractional digits ... Or I guess we could truncate to 2 digits only in the float case; or truncate to 2 digits only if we're using the float case and have large values. But that extra complexity doesn't seem worth it to me - especially since it seems to only affect people who do two non-default things (pick a date/interval style that used to truncate to 2, and --disable-integer-datetimes). I put a patch up at http://0ape.com/postgres_interval_patches that does what I think seems getting reasonable. For better or worse, it depends on the other two interval patches I was working on, but I could make a version that doesn't depend on those as well if people prefer that.
Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Ron Mayer
Date:
Ron Mayer wrote: > Tom Lane wrote: >> In fact, given that we are now >> somewhat SQL-compliant on interval input, a GUC that selected >> PG traditional, SQL-standard, or ISO 8601 interval output format seems >> like it could be a good idea. Attached are updated versions of the Interval patches (SQL-standard interval output, ISO8601 intervals, and interval rounding) I posted earlier upthread. I mostly brought it up-to-date with HEAD, cleaned up comments and regression tests, and fixed a couple bugs. [Sorry if people get this twice. I tried attaching all 4 patches earlier today, but didn't notice it on the list perhaps because of the combined size.] # Patch 1: "stdintervaloutput.patch" SQL Standard Interval Literal Output Description: This patch adds an IntervalStyle GUC to control the style of intervals. Previously the interval style was a side-effect of the DateStyle GUC. IntervalStyle can be set to "sql_standard" to output SQL Standard Interval Literals. Reason for the patch: Now that we support SQL-standard interval inputs, it's nice to be able to output intervals in that style as well. During the commit-fest I'll post versions of these that are regularly synced with CVS HEAD here: http://0ape.com/postgres_interval_patches/ *** a/doc/src/sgml/config.sgml --- b/doc/src/sgml/config.sgml *************** *** 4016,4021 **** SET XML OPTION { DOCUMENT | CONTENT }; --- 4016,4043 ---- </listitem> </varlistentry> + <varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle"> + <term><varname>IntervalStyle</varname> (<type>string</type>)</term> + <indexterm> + <primary><varname>IntervalStyle</> configuration parameter</primary> + </indexterm> + <listitem> + <para> + Sets the display format for interval values. + The value <literal>sql_standard</> will output SQL Standard + strings when given intervals that conform to the SQL + standard (either year-month only or date-time only; and no + mixing of positive and negative components). + The value <literal>postgres</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'ISO'</>. + The value <literal>postgres_verbose</> will output intervals in + a format that matches what old releases had output when + the DateStyle was set to <literal>'SQL'</>. + </para> + </listitem> + </varlistentry> + <varlistentry id="guc-timezone" xreflabel="timezone"> <term><varname>timezone</varname> (<type>string</type>)</term> <indexterm> *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 2213,2218 **** January 8 04:05:06 1999 PST --- 2213,2305 ---- </para> </sect2> + <sect2 id="interval-output"> + <title>Interval Output</title> + + <indexterm> + <primary>interval</primary> + <secondary>output format</secondary> + <seealso>formatting</seealso> + </indexterm> + + <para> + The output format of the interval types can be set to one of the + three styles <literal>sql_standard</>, + <literal>postgres</>, or <literal>postgres_verbose</>. + The default is the <literal>postgres</> format. + <xref + linkend="interval-style-output-table"> shows examples of each + output style. + </para> + + <para> + The <literal>sql_standard</> style will output SQL standard + interval literal strings where the value of the interval + value consists of only a year-month component or a datetime + component (as required by the sql standard). For an interval + containing both a year-month and a datetime component, the + output will be a SQL Standard unquoted year-month literal + string joined to a SQL Standard unquoted datetime literal + string with a space in between. + </para> + + <para> + The <literal>postgres</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>ISO</>. + </para> + + <para> + The <literal>postgres_verbose</> style will output intervals that match + the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> + parameter was set to <literal>SQL</>. + </para> + + <table id="interval-style-output-table"> + <title>Interval Style Example</title> + <tgroup cols="2"> + <thead> + <row> + <entry>Style Specification</entry> + <entry>Year-Month Interval</entry> + <entry>DateTime Interval</entry> + <entry>Nonstandardrd Extended Interval</entry> + </row> + </thead> + <tbody> + <row> + <entry>sql_standard</entry> + <entry>1-2</entry> + <entry>3 4:05:06</entry> + <entry>-1-2 +3 -4:05:06</entry> + </row> + <row> + <entry>postgres</entry> + <entry>1 year 2 mons</entry> + <entry>3 days 04:05:06</entry> + <entry>-1 year -2 mons +3 days -04:05:06</entry> + </row> + <row> + <entry>postgres_verbose</entry> + <entry>@ 1 year 2 mons</entry> + <entry>@ 3 days 4 hours 5 mins 6 secs</entry> + <entry>@ 1 year 2 mons -3 days 4 hours 5 mins 6 secs ago</entry> + </row> + </tbody> + </tgroup> + </table> + + <para> + Note that <literal>sql_standard</> style will only produce strictly + standards-conforming interval literals when given a strictly SQL-standard + interval value - meaning that it needs to be a pure year-month or datetime + interval and not mix positive and negative components. + </para> + + </sect2> + + + <sect2 id="datatype-timezones"> <title>Time Zones</title> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 229,234 **** assign_datestyle(const char *value, bool doit, GucSource source) --- 229,271 ---- /* + * assign_intervalstyle: GUC assign_hook for datestyle + */ + const char * + assign_intervalstyle(const char *value, bool doit, GucSource source) + { + int newIntervalStyle = IntervalStyle; + char * result = (char *) malloc(32); + if (pg_strcasecmp(value, "postgres") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES; + } + else if (pg_strcasecmp(value, "postgres_verbose") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES_VERBOSE; + } + else if (pg_strcasecmp(value, "sql_standard") == 0) + { + newIntervalStyle = INTSTYLE_SQL_STANDARD; + } + else + { + ereport(GUC_complaint_elevel(source), + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized \"intervalstyle\" key word: \"%s\"", + value))); + return NULL; + } + if (doit) + { + IntervalStyle = newIntervalStyle; + strcpy(result, value); + } + return result; + } + + + /* * TIMEZONE */ *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 2766,2771 **** DecodeInterval(char **field, int *ftype, int nf, int range, --- 2766,2787 ---- case DTK_TIME: dterr = DecodeTime(field[i], fmask, range, &tmask, tm, fsec); + if (IntervalStyle == INTSTYLE_SQL_STANDARD && + field[0][0] == '-' && i == 1 && + field[i][0] != '-' && field[i][0] != '+') + { + /* + * The SQL Standard defines the interval literal + * '-1 1:00:00' + * to mean "negative 1 days and negative one hours" + * while Postgres traditionally treated this as + * to mean "negative 1 days and positive one hours" + */ + tm->tm_hour = -tm->tm_hour; + tm->tm_min = -tm->tm_min; + tm->tm_sec = -tm->tm_sec; + *fsec = - *fsec; + } if (dterr) return dterr; type = DTK_DAY; *************** *** 3605,3610 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3621,3647 ---- return TRUE; } + /* + * Small helper funciton to avoid copy&paste in EncodeInterval below + */ + static void + AppendSeconds(char * cp,int sec, fsec_t fsec) + { + if (fsec==0) + { + sprintf(cp, "%02d", abs(sec)); + } + else + { + #ifdef HAVE_INT64_TIMESTAMP + sprintf(cp, "%02d.%06d", sec, Abs(fsec)); + #else + sprintf(cp, "%012.9f", fabs(sec + fsec)); + #endif + TrimTrailingZeros(cp); + } + } + /* EncodeInterval() * Interpret time structure as a delta time and convert to string. *************** *** 3613,3618 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3650,3666 ---- * Actually, afaik ISO does not address time interval formatting, * but this looks similar to the spec for absolute date/time. * - thomas 1998-04-30 + * + * Actually, afaik, ISO 8601 does specify formats for "time + * intervals...[of the]...format with time-unit designators", which + * are pretty ugly. The format looks something like + * P1Y1M1DT1H1M1.12345S + * but useful for exchanging data with computers instead of humans. + * - ron 2003-07-14 + * + * And ISO's SQL 2008 standard specifies standards for + * "year-month literal"s (that look like '2-3') and + * "day-time literal"s (that look like ('4 5:6:7') */ int EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) *************** *** 3621,3626 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3669,3681 ---- bool is_nonzero = FALSE; char *cp = str; + int year = tm->tm_year; + int mon = tm->tm_mon; + int mday = tm->tm_mday; + int hour = tm->tm_hour; + int min = tm->tm_min; + int sec = tm->tm_sec; + /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and *************** *** 3628,3635 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) */ switch (style) { ! /* compatible with ISO date formats */ ! case USE_ISO_DATES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", --- 3683,3760 ---- */ switch (style) { ! /* SQL Standard interval literals */ ! case INTSTYLE_SQL_STANDARD: ! { ! bool has_negative = (year < 0) || (mon < 0) || ! (mday < 0) || (hour < 0) || ! (min < 0) || (sec < 0) || (fsec<0); ! bool has_positive = (year > 0) || (mon > 0) || ! (mday > 0) || (hour > 0) || ! (min > 0) || (sec > 0) || (fsec>0); ! bool has_year_month = (year != 0) || (mon != 0); ! bool has_datetime = (hour != 0) || (min != 0) || ! (sec != 0) || (fsec!= 0) || (mday != 0); ! bool has_day = (mday != 0); ! bool sql_standard_value = (!(has_negative && has_positive)) && ! (!(has_year_month && has_datetime)); ! /* ! * SQL Standard wants only 1 "<sign>" preceeding the whole ! * interval. ! */ ! if (has_negative && sql_standard_value) ! { ! sprintf(cp,"-"); ! cp++; ! year = -year; ! mon = -mon; ! mday = -mday; ! hour = -hour; ! min = -min; ! sec = -sec; ! fsec = -fsec; ! } ! if (!has_negative && !has_positive) ! { ! sprintf(cp,"0"); ! } ! else if (!sql_standard_value) ! { ! /* ! * For non sql-standard interval values, ! * force outputting the signs to avoid ! * ambiguities with intervals with mixed ! * sign components. ! */ ! char year_sign = (year<0 || mon<0) ? '-' : '+'; ! char day_sign = (mday<0) ? '-' : '+'; ! char sec_sign = (hour<0 || min<0 || sec<0 || fsec<0) ! ? '-' : '+'; ! cp += sprintf(cp,"%c%d-%d %c%d %c%d:%02d:", ! year_sign,abs(year),abs(mon), ! day_sign,abs(mday), ! sec_sign,abs(hour),abs(min)); ! AppendSeconds(cp,sec,fsec); ! } ! else if (has_year_month) ! { ! sprintf(cp,"%d-%d",year,mon); ! } ! else if (has_day) ! { ! cp += sprintf(cp,"%d %d:%02d:",mday,hour,min); ! AppendSeconds(cp,sec,fsec); ! } ! else ! { ! cp += sprintf(cp,"%d:%02d:",hour,min); ! AppendSeconds(cp,sec,fsec); ! } ! break; ! } ! ! /* compatible with postgresql 8.3 when DateStyle = 'iso' */ ! case INTSTYLE_POSTGRES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", *************** *** 3692,3700 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) cp += strlen(cp); } } break; ! case USE_POSTGRES_DATES: default: strcpy(cp, "@ "); cp += strlen(cp); --- 3817,3831 ---- cp += strlen(cp); } } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } break; ! /* compatible with postgresql 8.3 when DateStyle = 'sql' */ ! case INTSTYLE_POSTGRES_VERBOSE: default: strcpy(cp, "@ "); cp += strlen(cp); *************** *** 3821,3842 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } break; } - /* identically zero? then put in a unitless zero... */ - if (!is_nonzero) - { - strcat(cp, "0"); - cp += strlen(cp); - } - - if (is_before && (style != USE_ISO_DATES)) - { - strcat(cp, " ago"); - cp += strlen(cp); - } - return 0; } /* EncodeInterval() */ --- 3952,3970 ---- is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } + if (is_before) + { + strcat(cp, " ago"); + cp += strlen(cp); + } break; } return 0; } /* EncodeInterval() */ *** a/src/backend/utils/adt/nabstime.c --- b/src/backend/utils/adt/nabstime.c *************** *** 671,677 **** reltimeout(PG_FUNCTION_ARGS) char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, DateStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); --- 671,677 ---- char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, IntervalStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 677,683 **** interval_out(PG_FUNCTION_ARGS) if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, DateStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); --- 677,683 ---- if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); *** a/src/backend/utils/init/globals.c --- b/src/backend/utils/init/globals.c *************** *** 88,93 **** bool ExitOnAnyError = false; --- 88,94 ---- int DateStyle = USE_ISO_DATES; int DateOrder = DATEORDER_MDY; + int IntervalStyle = INTSTYLE_POSTGRES; bool HasCTZSet = false; int CTimeZone = 0; *** a/src/backend/utils/misc/guc.c --- b/src/backend/utils/misc/guc.c *************** *** 366,371 **** static bool session_auth_is_superuser; --- 366,372 ---- static double phony_random_seed; static char *client_encoding_string; static char *datestyle_string; + static char *intervalstyle_string; static char *locale_collate; static char *locale_ctype; static char *server_encoding_string; *************** *** 2078,2083 **** static struct config_string ConfigureNamesString[] = --- 2079,2094 ---- "ISO, MDY", assign_datestyle, NULL }, + { + {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE, + gettext_noop("Sets the display format for interval values."), + gettext_noop(""), + GUC_REPORT + }, + &intervalstyle_string, + "postgres", assign_intervalstyle, NULL + }, + { {"default_tablespace", PGC_USERSET, CLIENT_CONN_STATEMENT, gettext_noop("Sets the default tablespace to create tables and indexes in."), *** a/src/backend/utils/misc/postgresql.conf.sample --- b/src/backend/utils/misc/postgresql.conf.sample *************** *** 419,424 **** --- 419,425 ---- # - Locale and Formatting - #datestyle = 'iso, mdy' + #intervalstyle = 'postgres' #timezone = unknown # actually, defaults to TZ environment # setting #timezone_abbreviations = 'Default' # Select the set of available time zone *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1953,1958 **** psql_completion(char *text, int start, int end) --- 1953,1965 ---- COMPLETE_WITH_LIST(my_list); } + else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) + { + static const char *const my_list[] = + {"postgres","postgres_verbose", "sql_standard", NULL}; + + COMPLETE_WITH_LIST(my_list); + } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) { static const char *const my_list[] = *** a/src/include/commands/variable.h --- b/src/include/commands/variable.h *************** *** 15,20 **** --- 15,22 ---- extern const char *assign_datestyle(const char *value, bool doit, GucSource source); + extern const char *assign_intervalstyle(const char *value, + bool doit, GucSource source); extern const char *assign_timezone(const char *value, bool doit, GucSource source); extern const char *show_timezone(void); *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 191,196 **** extern PGDLLIMPORT Oid MyDatabaseTableSpace; --- 191,208 ---- extern int DateStyle; extern int DateOrder; + + /* + * IntervalStyles + * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' + * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' + * INTSTYLE_SQL_STANDARD SQL standard interval literals + */ + #define INTSTYLE_POSTGRES 0 + #define INTSTYLE_POSTGRES_VERBOSE 1 + #define INTSTYLE_SQL_STANDARD 2 + + extern int IntervalStyle; /* * HasCTZSet is true if user has set timezone as a numeric offset from UTC. *** a/src/interfaces/libpq/fe-connect.c --- b/src/interfaces/libpq/fe-connect.c *************** *** 209,214 **** static const PQEnvironmentOption EnvironmentOptions[] = --- 209,217 ---- "PGDATESTYLE", "datestyle" }, { + "PGINTERVALSTYLE", "intervalstyle" + }, + { "PGTZ", "timezone" }, { *** a/src/test/regress/expected/interval.out --- b/src/test/regress/expected/interval.out *************** *** 2,7 **** --- 2,8 ---- -- INTERVAL -- SET DATESTYLE = 'ISO'; + SET IntervalStyle to postgres; -- check acceptance of "time zone style" SELECT INTERVAL '01:00' AS "One hour"; One hour *************** *** 273,278 **** FROM INTERVAL_MULDIV_TBL; --- 274,280 ---- DROP TABLE INTERVAL_MULDIV_TBL; SET DATESTYLE = 'postgres'; + SET IntervalStyle to postgres_verbose; SELECT '' AS ten, * FROM INTERVAL_TBL; ten | f1 -----+------------------------------- *************** *** 326,331 **** SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour"; --- 328,334 ---- -- test fractional second input, and detection of duplicate units SET DATESTYLE = 'ISO'; + SET IntervalStyle TO postgres; SELECT '1 millisecond'::interval, '1 microsecond'::interval, '500 seconds 99 milliseconds 51 microseconds'::interval; interval | interval | interval *************** *** 609,611 **** SELECT interval '1 2:03:04.5678' minute to second(2); --- 612,634 ---- 00:03:04.57 (1 row) + -- test outputting SQL standard interval literals + SET IntervalStyle TO sql_standard; + SELECT interval '0' AS "zero", + interval '1-2' year to month AS "year-month", + interval '1 2:03:04' day to second AS "day-time", + - interval '1-2' AS "negative year-month", + - interval '1 2:03:04' AS "negative day-time"; + zero | year-month | day-time | negative year-month | negative day-time + ------+------------+-----------+---------------------+------------------- + 0 | 1-2 | 1 2:03:04 | -1-2 | -1 2:03:04 + (1 row) + + -- test a couple non-standard interval values too + SELECT interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', + - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; + interval | ?column? + ----------------------+---------------------- + +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789 + (1 row) + *** a/src/test/regress/pg_regress.c --- b/src/test/regress/pg_regress.c *************** *** 708,713 **** initialize_environment(void) --- 708,714 ---- */ putenv("PGTZ=PST8PDT"); putenv("PGDATESTYLE=Postgres, MDY"); + putenv("PGINTERVALSTYLE=postgres_verbose"); if (temp_install) { *** a/src/test/regress/sql/interval.sql --- b/src/test/regress/sql/interval.sql *************** *** 3,8 **** --- 3,9 ---- -- SET DATESTYLE = 'ISO'; + SET IntervalStyle to postgres; -- check acceptance of "time zone style" SELECT INTERVAL '01:00' AS "One hour"; *************** *** 94,99 **** FROM INTERVAL_MULDIV_TBL; --- 95,101 ---- DROP TABLE INTERVAL_MULDIV_TBL; SET DATESTYLE = 'postgres'; + SET IntervalStyle to postgres_verbose; SELECT '' AS ten, * FROM INTERVAL_TBL; *************** *** 118,123 **** SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour"; --- 120,127 ---- -- test fractional second input, and detection of duplicate units SET DATESTYLE = 'ISO'; + SET IntervalStyle TO postgres; + SELECT '1 millisecond'::interval, '1 microsecond'::interval, '500 seconds 99 milliseconds 51 microseconds'::interval; SELECT '3 days 5 milliseconds'::interval; *************** *** 174,176 **** SELECT interval '1 2:03:04.5678' hour to second(2); --- 178,192 ---- SELECT interval '1 2.3456' minute to second(2); SELECT interval '1 2:03.5678' minute to second(2); SELECT interval '1 2:03:04.5678' minute to second(2); + + -- test outputting SQL standard interval literals + SET IntervalStyle TO sql_standard; + SELECT interval '0' AS "zero", + interval '1-2' year to month AS "year-month", + interval '1 2:03:04' day to second AS "day-time", + - interval '1-2' AS "negative year-month", + - interval '1 2:03:04' AS "negative day-time"; + + -- test a couple non-standard interval values too + SELECT interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', + - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds';
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Ron Mayer
Date:
Ron Mayer wrote: > Ron Mayer wrote: > > Tom Lane wrote: > >> In fact, given that we are now > >> somewhat SQL-compliant on interval input, a GUC that selected > >> PG traditional, SQL-standard, or ISO 8601 interval output format seems > >> like it could be a good idea. > > Attached are updated versions of the Interval patches ... # Patch 2: ISO 8601 Formatted Interval Input and Output This patch adds another IntervalStyle 'iso_8601' to output ISO 8601 Time Intervals of the "format with designators". These are a bit more flexible than Sql Standard intervals in that (like postgres) they can express both years and days in the same interval value. Reason for the patch:SQL Standard Intervals are limited compared to postgres in what they allow (no mixed year-month and day-time components). ISO8601 intervals allow such intervals and are easier for machines to parse than the traditional postgres formats. This patch depends on the IntervalStyle patch mentioned above. *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 1975,1980 **** January 8 04:05:06 1999 PST --- 1975,1996 ---- </para> <para> + Alternatively, <type>interval</type> values can be written as + ISO 8601 time intervals, using the "Format with time-unit designators", + or PnYnMnDTnHnMnS. This format always starts with the character + <literal>'P'</>, followed by a string of values followed by single + character time-unit designators. A <literal>'T'</> separates the + date and time parts of the interval. + In this format, <literal>'n'</> gets replaced by a number, and + <literal>Y</> represents years, + <literal>M</> (in the date part) months, + <literal>D</> months, + <literal>H</> hours, + <literal>M</> (in the time part) minutes, + and <literal>S</> seconds. + </para> + + <para> Internally <type>interval</> values are stored as months, days, and seconds. This is done because the number of days in a month varies, and a day can have 23 or 25 hours if a daylight savings *************** *** 2224,2230 **** January 8 04:05:06 1999 PST <para> The output format of the interval types can be set to one of the ! three styles <literal>sql_standard</>, <literal>postgres</>, or <literal>postgres_verbose</>. The default is the <literal>postgres</> format. <xref --- 2240,2246 ---- <para> The output format of the interval types can be set to one of the ! four styles <literal>sql_standard</>, <literal>iso_8601</>, <literal>postgres</>, or <literal>postgres_verbose</>. The default is the <literal>postgres</> format. <xref *************** *** 2244,2249 **** January 8 04:05:06 1999 PST --- 2260,2281 ---- </para> <para> + The <literal>iso_8601</> style will output ISO 8601 + time intervals using the "format with time-unit designators" + This format always starts with the character + <literal>'P'</>, followed by a string of values followed by single + character time-unit designators. A <literal>'T'</> separates the + date and time parts of the interval. + In this format, <literal>'n'</> gets replaced by a number, and + <literal>Y</> represents years, + <literal>M</> (in the date part) months, + <literal>D</> months, + <literal>H</> hours, + <literal>M</> (in the time part) minutes, + and <literal>S</> seconds. + </para> + + <para> The <literal>postgres</> style will output intervals that match the style PostgreSQL 8.3 outputed when the <xref linkend="guc-datestyle"> parameter was set to <literal>ISO</>. *************** *** 2274,2279 **** January 8 04:05:06 1999 PST --- 2306,2317 ---- <entry>-1-2 +3 -4:05:06</entry> </row> <row> + <entry>iso_8601</entry> + <entry>P1Y2M</entry> + <entry>P3DT4H5M6</entry> + <entry>P-1Y-2M3DT-4H-5M-6</entry> + </row> + <row> <entry>postgres</entry> <entry>1 year 2 mons</entry> <entry>3 days 04:05:06</entry> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 248,253 **** assign_intervalstyle(const char *value, bool doit, GucSource source) --- 248,257 ---- { newIntervalStyle = INTSTYLE_SQL_STANDARD; } + else if (pg_strcasecmp(value, "iso_8601") == 0) + { + newIntervalStyle = INTSTYLE_ISO_8601; + } else { ereport(GUC_complaint_elevel(source), *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 2723,2728 **** DecodeSpecial(int field, char *lowtoken, int *val) --- 2723,2865 ---- } + /* + * Small helper functions to avoid cut&paste code in DecodeIso8601Interval + */ + static void + adjust_fractional_seconds(double fval,struct pg_tm * tm, fsec_t *fsec, int scale) + { + int sec; + if (fval == 0) return; + fval *= scale; + sec = fval; + tm->tm_sec += sec; + #ifdef HAVE_INT64_TIMESTAMP + *fsec += rint((fval - sec) * 1000000); + #else + *fsec += (fval - sec); + #endif + } + + static void + adjust_fractional_days(double fval,struct pg_tm * tm, fsec_t *fsec, int scale) + { + int extra_days; + if (fval == 0) return; + fval *= scale; + extra_days = fval; + tm->tm_mday += extra_days; + fval -= extra_days; + adjust_fractional_seconds(fval,tm,fsec, SECS_PER_DAY); + } + + + /* DecodeISO8601Interval() + * Decode an ISO 8601 "Representation of time-interval by + * duration only.... basic extended format" from ISO 8601 section 5.5.4.2 + * + * Examples: P1D for 1 day + * PT1H for 1 hour + * P2Y6M7DT1H30M for 2 years, 6 months, 7 days 1 hour 30 min + * + * Returns DTERR_BAD_FORMAT if the field is not of this type. + * + * A couple exceptions from the spec: + * - a week field ('W') may coexist with other units + * - allows decimals in fields other than the least significant unit. + */ + int + DecodeISO8601Interval(char *str, struct pg_tm * tm, fsec_t *fsec) + { + char unit; + int val; + double fval; + int datepart = true; + int negative = false; + + tm->tm_year = 0; + tm->tm_mon = 0; + tm->tm_mday = 0; + tm->tm_hour = 0; + tm->tm_min = 0; + tm->tm_sec = 0; + *fsec = 0; + + if (strlen(str)<3 || !(str[0] == 'P')) + { + return DTERR_BAD_FORMAT; + } + str++; + + while (*str) + { + if (*str == 'T') /* T indicates the beginning of the time part */ + { + datepart = false; + str++; + continue; + } + if (! (isdigit(*str) || *str == '-' || *str=='.') ) + return DTERR_BAD_FORMAT; + + negative = (*str == '-'); + fval = strtod(str, &str); + val = fval; + fval = fval - val; + unit = *str; + str++; + + if (datepart) + { + switch (unit) /* Y M D W */ + { + case 'D': + tm->tm_mday += val; + adjust_fractional_seconds(fval,tm,fsec, SECS_PER_DAY); + break; + case 'W': + tm->tm_mday += val * 7; + adjust_fractional_days(fval,tm,fsec,7); + break; + case 'M': + tm->tm_mon += val; + adjust_fractional_days(fval,tm,fsec,DAYS_PER_MONTH); + break; + case 'Y': + tm->tm_year += val; + if (fval != 0) + tm->tm_mon += (fval * 12); + break; + default: + return DTERR_BAD_FORMAT; /* not a vald ISO8601 date unit prefix */ + } + } + else + { + switch (unit) /* H M S */ + { + case 'S': + tm->tm_sec += val; + adjust_fractional_seconds(fval,tm,fsec,1); + break; + case 'M': + tm->tm_min += val; + adjust_fractional_seconds(fval,tm,fsec,SECS_PER_MINUTE); + break; + case 'H': + tm->tm_hour += val; + adjust_fractional_seconds(fval,tm,fsec,SECS_PER_HOUR); + break; + default: + return DTERR_BAD_FORMAT; /* not a vald ISO8601 time unit prefix */ + } + } + } + return 0; + } + + + /* DecodeInterval() * Interpret previously parsed fields for general time interval. * Returns 0 if successful, DTERR code if bogus input detected. *************** *** 3621,3648 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, return TRUE; } ! /* ! * Small helper funciton to avoid copy&paste in EncodeInterval below */ static void ! AppendSeconds(char * cp,int sec, fsec_t fsec) { if (fsec==0) { ! sprintf(cp, "%02d", abs(sec)); } else { #ifdef HAVE_INT64_TIMESTAMP ! sprintf(cp, "%02d.%06d", sec, Abs(fsec)); #else ! sprintf(cp, "%012.9f", fabs(sec + fsec)); #endif TrimTrailingZeros(cp); } } /* EncodeInterval() * Interpret time structure as a delta time and convert to string. * --- 3758,3795 ---- return TRUE; } ! ! /* ! * Small helper functions to avoid cut&paste in EncodeInterval below */ + + static char * + AddISO8601IntervalPart(char * cp, int value, char units) + { + if (value==0) return cp; + return cp + sprintf(cp,"%d%c",value,units); + } + static void ! AppendSeconds(char * cp,int sec, fsec_t fsec, bool fillzeros) { if (fsec==0) { ! sprintf(cp, fillzeros ? "%02d" : "%d" , abs(sec)); } else { #ifdef HAVE_INT64_TIMESTAMP ! sprintf(cp, fillzeros ? "%02d.%06d" : "%d.%06d", abs(sec), abs(fsec)); #else ! sprintf(cp, fillzeros ? "%09.6f" : "%.6f", fabs(sec + fsec)); #endif TrimTrailingZeros(cp); } } + /* EncodeInterval() * Interpret time structure as a delta time and convert to string. * *************** *** 3734,3740 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) year_sign,abs(year),abs(mon), day_sign,abs(mday), sec_sign,abs(hour),abs(min)); ! AppendSeconds(cp,sec,fsec); } else if (has_year_month) { --- 3881,3887 ---- year_sign,abs(year),abs(mon), day_sign,abs(mday), sec_sign,abs(hour),abs(min)); ! AppendSeconds(cp,sec,fsec,true); } else if (has_year_month) { *************** *** 3743,3758 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) else if (has_day) { cp += sprintf(cp,"%d %d:%02d:",mday,hour,min); ! AppendSeconds(cp,sec,fsec); } else { cp += sprintf(cp,"%d:%02d:",hour,min); ! AppendSeconds(cp,sec,fsec); } break; } /* compatible with postgresql 8.3 when DateStyle = 'iso' */ case INTSTYLE_POSTGRES: if (tm->tm_year != 0) --- 3890,3932 ---- else if (has_day) { cp += sprintf(cp,"%d %d:%02d:",mday,hour,min); ! AppendSeconds(cp,sec,fsec,true); } else { cp += sprintf(cp,"%d:%02d:",hour,min); ! AppendSeconds(cp,sec,fsec,true); } break; } + /* ISO 8601 "time-intervals by duration only */ + case INTSTYLE_ISO_8601: + if ((year == 0) && (mon == 0) && (mday == 0) && + (hour == 0) && (min == 0) && (sec == 0) && (fsec == 0)) + { + sprintf(cp,"PT0S"); + break; + } + cp += sprintf(cp,"P"); + cp = AddISO8601IntervalPart(cp,year,'Y'); + cp = AddISO8601IntervalPart(cp,mon ,'M'); + cp = AddISO8601IntervalPart(cp,mday,'D'); + if ((hour != 0) || (min != 0) || (sec != 0) || (fsec != 0)) + { + cp += sprintf(cp,"T"); + } + cp = AddISO8601IntervalPart(cp,hour,'H'); + cp = AddISO8601IntervalPart(cp,min ,'M'); + if ((sec != 0) || (fsec != 0)) + { + cp += sprintf(cp, "%s", (sec<0 || fsec<0) ? "-" : ""); + AppendSeconds(cp,sec,fsec,false); + cp += strlen(cp); + cp += sprintf(cp,"S"); + } + break; + /* compatible with postgresql 8.3 when DateStyle = 'iso' */ case INTSTYLE_POSTGRES: if (tm->tm_year != 0) *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 627,632 **** interval_in(PG_FUNCTION_ARGS) --- 627,635 ---- ftype, MAXDATEFIELDS, &nf); if (dterr == 0) dterr = DecodeInterval(field, ftype, nf, range, &dtype, tm, &fsec); + if (dterr == DTERR_BAD_FORMAT) + dterr = DecodeISO8601Interval(str, tm, &fsec); + if (dterr != 0) { if (dterr == DTERR_FIELD_OVERFLOW) *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1956,1963 **** psql_completion(char *text, int start, int end) else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) { static const char *const my_list[] = ! {"postgres","postgres_verbose", "sql_standard", NULL}; ! COMPLETE_WITH_LIST(my_list); } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) --- 1956,1962 ---- else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) { static const char *const my_list[] = ! {"postgres","postgres_verbose", "sql_standard", "iso_8601", NULL}; COMPLETE_WITH_LIST(my_list); } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 197,206 **** extern int DateOrder; --- 197,208 ---- * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' * INTSTYLE_SQL_STANDARD SQL standard interval literals + * INTSTYLE_ISO_8601 Specifies ISO-8601-basic formatted intervals */ #define INTSTYLE_POSTGRES 0 #define INTSTYLE_POSTGRES_VERBOSE 1 #define INTSTYLE_SQL_STANDARD 2 + #define INTSTYLE_ISO_8601 3 extern int IntervalStyle; *** a/src/include/utils/datetime.h --- b/src/include/utils/datetime.h *************** *** 292,297 **** extern int DecodeTimeOnly(char **field, int *ftype, --- 292,300 ---- extern int DecodeInterval(char **field, int *ftype, int nf, int range, int *dtype, struct pg_tm * tm, fsec_t *fsec); + extern int DecodeISO8601Interval(char *str, + struct pg_tm * tm, fsec_t *fsec); + extern void DateTimeParseError(int dterr, const char *str, const char *datatype); *** a/src/test/regress/expected/interval.out --- b/src/test/regress/expected/interval.out *************** *** 632,634 **** SELECT interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', --- 632,663 ---- +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789 (1 row) + -- test outputting iso8601 intervals + SET IntervalStyle to iso_8601; + select interval '0' AS "zero", + interval '1-2' AS "a year 2 months", + interval '1 2:03:04' AS "a bit over a day", + interval '2:03:04.45679' AS "a bit over 2 hours", + (interval '1-2' + interval '3 4:05:06.7') AS "all fields", + (interval '1-2' - interval '3 4:05:06.7') AS "mixed sign", + (- interval '1-2' + interval '3 4:05:06.7') AS "negative" + ; + zero | a year 2 months | a bit over a day | a bit over 2 hours | all fields | mixed sign | negative + ------+-----------------+------------------+--------------------+-------------------+-----------------------+--------------------- + PT0S | P1Y2M | P1DT2H3M4S | PT2H3M4.45679S | P1Y2M3DT4H5M6.70S | P1Y2M-3DT-4H-5M-6.70S | P-1Y-2M3DT4H5M6.70S + (1 row) + + -- test inputting iso8601 intervals + SET IntervalStyle to sql_standard; + select interval 'P0Y' AS "zero", + interval 'P1Y2M' AS "a year 2 months", + interval 'P1W' AS "a week", + interval 'P1DT2H3M4S' AS "a bit over a day", + interval 'P1Y2M3DT4H5M6.7S' AS "all fields", + interval 'P-1Y-2M-3DT-4H-5M-6.7S' AS "negative", + interval 'PT-0.1S' AS "fractional second"; + zero | a year 2 months | a week | a bit over a day | all fields | negative | fractional second + ------+-----------------+-----------+------------------+---------------------+---------------------+------------------- + 0 | 1-2 | 7 0:00:00 | 1 2:03:04 | +1-2 +3 +4:05:06.70 | -1-2 -3 -4:05:06.70 | -0:00:00.10 + (1 row) + *** a/src/test/regress/sql/interval.sql --- b/src/test/regress/sql/interval.sql *************** *** 190,192 **** SELECT interval '0' AS "zero", --- 190,213 ---- -- test a couple non-standard interval values too SELECT interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; + + -- test outputting iso8601 intervals + SET IntervalStyle to iso_8601; + select interval '0' AS "zero", + interval '1-2' AS "a year 2 months", + interval '1 2:03:04' AS "a bit over a day", + interval '2:03:04.45679' AS "a bit over 2 hours", + (interval '1-2' + interval '3 4:05:06.7') AS "all fields", + (interval '1-2' - interval '3 4:05:06.7') AS "mixed sign", + (- interval '1-2' + interval '3 4:05:06.7') AS "negative" + ; + + -- test inputting iso8601 intervals + SET IntervalStyle to sql_standard; + select interval 'P0Y' AS "zero", + interval 'P1Y2M' AS "a year 2 months", + interval 'P1W' AS "a week", + interval 'P1DT2H3M4S' AS "a bit over a day", + interval 'P1Y2M3DT4H5M6.7S' AS "all fields", + interval 'P-1Y-2M-3DT-4H-5M-6.7S' AS "negative", + interval 'PT-0.1S' AS "fractional second";
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Ron Mayer
Date:
Ron Mayer wrote: > Ron Mayer wrote: >> Ron Mayer wrote: >> > Tom Lane wrote: >> >> In fact, given that we are now >> >> somewhat SQL-compliant on interval input, a GUC that selected >> >> PG traditional, SQL-standard, or ISO 8601 interval output format >> seems >> >> like it could be a good idea. >> >> Attached are updated versions of the Interval patches ... # Patch 3: "cleanup.patch" Fix rounding inconsistencies and refactor interval input/output code This patch removes a lot of copy & paste with gratuitous rounding inconsistencies in the old interval code. This patch refactors it to save about 300 lines in datetime.c, and by reusing code (instead of the near-copy-paste that was there before) helps insure that rounding inconsistancies are avoided. It removes almost as much code as the other two patches added. This patch applies on top of patch 1 and 2 posted up-thread.. My apologies if you got these twice, my mailer seems to be rejecting even slightly large attachments so I tried a couple times. During the commit-fest I'll post versions of these that are regularly synced with CVS HEAD here: http://0ape.com/postgres_interval_patches/ along with a combined patch that includes all 3 of these in a single patch.
Attachment
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
"Brendan Jurd"
Date:
On Thu, Sep 18, 2008 at 6:03 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > The attached patch > (1) adds a new GUC called "IntervalStyle" that decouples interval > output from the "DateStyle" GUC, and > (2) adds a new interval style that will match the SQL standards > for interval literals when given interval data that meets the > sql standard (year-month or date-time only; and no mixed sign). > Hi Ron, I've been assigned to do an initial review of your interval patches. I'm going to be reviewing them one at a time, starting with this one (the introduction of the new IntervalStyle GUC). I grabbed the latest version of the patch from the URL posted up on the CF wiki page: http://0ape.com/postgres_interval_patches/stdintervaloutput.patch Nice site you've got set up for the patches, BTW. It certainly makes it all a lot more approachable. On with the review then ... The patch applied cleanly to the latest version of HEAD in the git repository. I was able to build both postgres and the documentation without complaint on x86_64 gentoo. When I ran the regression tests, I got one failure in the new interval tests. Looks like the "nonstandard extended" format gets a bit confused when the seconds are negative: *** /home/direvus/src/postgres/src/test/regress/expected/interval.outTue Nov 4 14:46:34 2008 --- /home/direvus/src/postgres/src/test/regress/results/interval.outTue Nov 4 15:19:53 2008 *************** *** 629,634 **** - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; interval | ?column? ----------------------+---------------------- ! +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789 (1 row) --- 629,634 ---- - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; interval | ?column? ----------------------+---------------------- ! +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:-6.789 (1 row) Otherwise, the feature seemed to behave as advertised. I tried throwing a few bizarre intervals at it, but didn't manage to break anything. The C code has some small stylistic inconsistencies; in some cases the spaces around binary operators are missing (e.g., "(fsec<0)"). See src/backend/utils/adt/datetime.c lines 3691, 3694, 3697, 3729-3731. There are also a lot of function calls missing the space after the argument separator (e.g., "sprintf(cp,"%d %d:%02d:",mday,hour,min)"). Apart from not merging well with the style of the surrounding code, I respectfully suggest that omitting the spaces really does make the code harder to read. The new documentation is good in terms of content, but there are some minor stylistic and spelling cleanups I would suggest. The standard is referred to variously as "SQL standard", "SQL-standard" and "SQL Standard" in the patch. The surrounding documentation seems to use "SQL standard", so that's probably the way to go. These sentences in datatype.sgml are a bit awkward: "The postgres style will output intervals that match the style PostgreSQL 8.3 outputed when the DateStyle parameter was set to ISO. The postgres_verbose style will output intervals that match the style PostgreSQL 8.3 outputed when the DateStyle parameter was set to SQL." As far as I know, "outputed" isn't a word, and singling out 8.3 in particular is a bit misleading, since the statement applies to earlier versions as well. I would go with something more along the lines of: "The postgres style will output intervals matching those output by PostgreSQL prior to version 8.4, with the DateStyle parameter set to ISO." Likewise in config.sgml, the patch has: "The value postgres will output intervals in a format that matches what old releases had output when the DateStyle was set to 'ISO'. The value postgres_verbose will output intervals in a format that matches what old releases had output when the DateStyle was set to 'SQL'." I don't think "old releases" is specific enough. Most folks reading the documentation aren't going to know what is meant by "old". Better to be precise. Again I would suggest phrasing like "... releases prior to 8.4, with the DateStyle set to ...". That's all the feedback I have for the moment. I hope you found my comments helpful. I'll be setting the status of this patch to "Returned with Feedback" and wait for your reponses before I move forward with reviewing the other patches. Cheers, BJ
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
"Robert Haas"
Date:
I think we need to distinguish between patches that are clearly not going in, and patches that are not going in in their present form but might be able to be reworked. My suggestion would be that only the first category be moved to the Returned with feedback section, and the others just have their status changed to "Waiting for new version" or similar. Alternatively, we could create a separate section for patches in this category. ...Robert On Tue, Nov 4, 2008 at 12:22 AM, Brendan Jurd <direvus@gmail.com> wrote: > On Thu, Sep 18, 2008 at 6:03 AM, Ron Mayer > <rm_pg@cheapcomplexdevices.com> wrote: >> The attached patch >> (1) adds a new GUC called "IntervalStyle" that decouples interval >> output from the "DateStyle" GUC, and >> (2) adds a new interval style that will match the SQL standards >> for interval literals when given interval data that meets the >> sql standard (year-month or date-time only; and no mixed sign). >> > > Hi Ron, > > I've been assigned to do an initial review of your interval patches. > I'm going to be reviewing them one at a time, starting with this one > (the introduction of the new IntervalStyle GUC). > > I grabbed the latest version of the patch from the URL posted up on > the CF wiki page: > http://0ape.com/postgres_interval_patches/stdintervaloutput.patch > > Nice site you've got set up for the patches, BTW. It certainly makes > it all a lot more approachable. > > On with the review then ... > > The patch applied cleanly to the latest version of HEAD in the git > repository. I was able to build both postgres and the documentation > without complaint on x86_64 gentoo. > > When I ran the regression tests, I got one failure in the new interval > tests. Looks like the "nonstandard extended" format gets a bit > confused when the seconds are negative: > > *** /home/direvus/src/postgres/src/test/regress/expected/interval.out > Tue Nov 4 14:46:34 2008 > --- /home/direvus/src/postgres/src/test/regress/results/interval.out > Tue Nov 4 15:19:53 2008 > *************** > *** 629,634 **** > - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; > interval | ?column? > ----------------------+---------------------- > ! +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789 > (1 row) > > --- 629,634 ---- > - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; > interval | ?column? > ----------------------+---------------------- > ! +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:-6.789 > (1 row) > > Otherwise, the feature seemed to behave as advertised. I tried > throwing a few bizarre intervals at it, but didn't manage to break > anything. > > The C code has some small stylistic inconsistencies; in some cases the > spaces around binary operators are missing (e.g., "(fsec<0)"). See > src/backend/utils/adt/datetime.c lines 3691, 3694, 3697, 3729-3731. > There are also a lot of function calls missing the space after the > argument separator (e.g., "sprintf(cp,"%d %d:%02d:",mday,hour,min)"). > Apart from not merging well with the style of the surrounding code, I > respectfully suggest that omitting the spaces really does make the > code harder to read. > > The new documentation is good in terms of content, but there are some > minor stylistic and spelling cleanups I would suggest. > > The standard is referred to variously as "SQL standard", > "SQL-standard" and "SQL Standard" in the patch. The surrounding > documentation seems to use "SQL standard", so that's probably the way > to go. > > These sentences in datatype.sgml are a bit awkward: > > "The postgres style will output intervals that match the style > PostgreSQL 8.3 outputed when the DateStyle parameter was set to ISO. > > The postgres_verbose style will output intervals that match the style > PostgreSQL 8.3 outputed when the DateStyle parameter was set to SQL." > > As far as I know, "outputed" isn't a word, and singling out 8.3 in > particular is a bit misleading, since the statement applies to earlier > versions as well. I would go with something more along the lines of: > > "The postgres style will output intervals matching those output by > PostgreSQL prior to version 8.4, with the DateStyle parameter set to > ISO." > > Likewise in config.sgml, the patch has: > > "The value postgres will output intervals in a format that matches > what old releases had output when the DateStyle was set to 'ISO'. The > value postgres_verbose will output intervals in a format that matches > what old releases had output when the DateStyle was set to 'SQL'." > > I don't think "old releases" is specific enough. Most folks reading > the documentation aren't going to know what is meant by "old". Better > to be precise. Again I would suggest phrasing like "... releases > prior to 8.4, with the DateStyle set to ...". > > That's all the feedback I have for the moment. I hope you found my > comments helpful. I'll be setting the status of this patch to > "Returned with Feedback" and wait for your reponses before I move > forward with reviewing the other patches. > > Cheers, > BJ > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers >
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Brendan Jurd wrote: > ...Sep 18, 2008... Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: >> The attached patch >> (1) adds a new GUC called "IntervalStyle" that decouples interval >> output from the "DateStyle" GUC, and >> (2) adds a new interval style that will match the SQL standards >> for interval literals when given interval data that meets the >> sql standard (year-month or date-time only; and no mixed sign). > > I've been assigned to do an initial review of your interval patches. > I'm going to be reviewing them one at a time, starting with this one > (the introduction of the new IntervalStyle GUC). Great! Thanks much! > I grabbed the latest version of the patch from the URL posted up on > the CF wiki page: > http://0ape.com/postgres_interval_patches/stdintervaloutput.patch > > Nice site you've got set up for the patches, BTW. It certainly makes > it all a lot more approachable. Ah. If you're using GIT, you might find it more convenient to pull/merge from http://git.0ape.com/postgresql/ or browse through gitweb: http://git.0ape.com/?p=postgresql;a=shortlog;h=refs/heads/cleanup http://git.0ape.com/git-browser/by-commit.html?r=postgresql though this is the first time I've set up gitweb so it might have rough edges. > The patch applied cleanly to the latest version of HEAD in the git > repository. I was able to build both postgres and the documentation > without complaint on x86_64 gentoo. > > When I ran the regression tests, I got one failure in the new interval > tests. Looks like the "nonstandard extended" format gets a bit > confused when the seconds are negative: Ah yes. Let me guess, HAVE_INT64_TIMESTAMP was defined. I believe the later refactoring patch also avoids that bug; but yes, I obviously should have had it working in this patch. This fix was simple (can be seen on gitweb here: http://tinyurl.com/5fxeyw) and I think I've pushed the updated patches to my website. Once I fix the stylistic points you mentioned below I'll post the resulting patch to the mailing list. > Otherwise, the feature seemed to behave as advertised. I tried > throwing a few bizarre intervals at it, but didn't manage to break > anything. > > The C code has some small stylistic inconsistencies.... > ...documentation...some > minor stylistic and spelling cleanups I would suggest. > Totally agree with all your style suggestions. Will send an update a bit later today.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Ah. And one final question regarding functionality. It seems to me that the last remaining place where we input a SQL-2008 standard literal and do something different from what the standard suggests is with the string: '-1 2:03:04' The standard seems to say that the "-" affects both the days and hour/min/sec part; while PostgreSQL historically, and the patch as I first submitted it only apply the negative sign to the days part. IMHO when the IntervalStyle GUC is set to "sql_standard", it'd be better if the parsing of this literal matched the standard. We already have the precedent where DateStyle is used to interpret otherwise ambiguous output. If the IntervalStyle is set to anything other than sql_standard we'll keep parsing them the old way; so I think backwards compatibility issues would be minimized. And those using the sql_standard mode are likely to be standards fanatics anyway, and would probably appreciate following the standard rather than the backward compatible mode. Thoughts? I have a version of each alternative working here, and I'd be happy to submit the final patch either way.
Re: Patch for SQL-Standard Interval output and decouplingDateStyle from IntervalStyle
From
"Kevin Grittner"
Date:
>>> Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > It seems to me that the last remaining place where we input > a SQL-2008 standard literal and do something different from > what the standard suggests is with the string: > '-1 2:03:04' > The standard seems to say that the "-" affects both the > days and hour/min/sec part; Agreed. > while PostgreSQL historically, > and the patch as I first submitted it only apply the negative > sign to the days part. > > IMHO when the IntervalStyle GUC is set to "sql_standard", > it'd be better if the parsing of this literal matched the > standard. We already have the precedent where DateStyle > is used to interpret otherwise ambiguous output. > > If the IntervalStyle is set to anything other than sql_standard > we'll keep parsing them the old way; so I think backwards > compatibility issues would be minimized. And those > using the sql_standard mode are likely to be standards > fanatics anyway, and would probably appreciate following the > standard rather than the backward compatible mode. > > Thoughts? I think it would be good to be able to configure PostgreSQL such that it didn't take standards-compliant literals and silently treat them in a non-standard way. What you propose here seems sane to me, but if someone objects, it would be good for some other value or other GUC to provide compliant behavior. -Kevin
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Ah. And one final question regarding functionality. > It seems to me that the last remaining place where we input > a SQL-2008 standard literal and do something different from > what the standard suggests is with the string: > '-1 2:03:04' > The standard seems to say that the "-" affects both the > days and hour/min/sec part; while PostgreSQL historically, > and the patch as I first submitted it only apply the negative > sign to the days part. > IMHO when the IntervalStyle GUC is set to "sql_standard", > it'd be better if the parsing of this literal matched the > standard. Then how would you input a value that had different signs for the day and the h/m/s? I don't think "you can't" is an acceptable answer there, because it would mean that interval_out has to fail on such values when IntervalStyle is "sql_standard". Which is very clearly not gonna do. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Ah. And one final question regarding functionality. >> It seems to me that the last remaining place where we input >> a SQL-2008 standard literal and do something different from >> what the standard suggests is with the string: >> '-1 2:03:04' >> The standard seems to say that the "-" affects both the >> days and hour/min/sec part; while PostgreSQL historically, >> and the patch as I first submitted it only apply the negative >> sign to the days part. > >> IMHO when the IntervalStyle GUC is set to "sql_standard", >> it'd be better if the parsing of this literal matched the >> standard. > > Then how would you input a value that had different signs for the > day and the h/m/s? I don't think "you can't" is an acceptable > answer there, because it would mean that interval_out has to fail > on such values when IntervalStyle is "sql_standard". Which is > very clearly not gonna do. In the patch I submitted: "-1 +2:03:04" always means negative day, positive hours/min/sec "+1 -2:03:04" always means positive day, negative hours/min/sec When given a non-standard interval value, EncodeInterval is always outputting all the signs ("+" and "-") to force it to be unambiguous. -- test a couple non-standard interval values too SELECT interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', - interval '1 years 2 months -3 days4 hours 5 minutes 6.789 seconds'; interval | ?column? ----------------------+---------------------- +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789 (1 row)
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Brendan Jurd wrote: > ...Sep 18, 2008...Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: >> (1) ...GUC called "IntervalStyle"... >> (2) ...interval style that will match the SQL standards... > > ...an initial review... > > When I ran the regression tests, I got one failure in the new interval Fixed, and I did a bit more testing both with and without HAVE_INT64_TIMESTAMP. > The C code has some small stylistic inconsistencies; ... > ... spaces around binary operators are missing (e.g., "(fsec<0)"). Thanks. Fixed these. > ...function calls missing the space after the argument separator... I think I fixed all these now too. > The new documentation is good in terms of content, but there are some > minor stylistic and spelling cleanups I would suggest. > ...variously..."SQL standard", "SQL-standard" and "SQL Standard"... Got it. There are a few inconsistencies elsewhere in the file talking about other data types. I wonder if I should fix those as well. > These sentences in datatype.sgml are a bit awkward ... > I would go with something more along the lines of... Yes. Thanks for the better wording. > I don't think "old releases" is specific enough. Yup - fixed that too. > That's all the feedback I have for the moment. I hope you found my > comments helpful. I'll be setting the status of this patch to > "Returned with Feedback" and wait for your responses before I move > forward with reviewing the other patches. Great. I've tried to update the style on my remaining patches as well. In addition, I've added to the docs describing how I use explicit '+' and '-' signs to disambiguate the mixed-sign non-standard intervals when in the sql_standard mode. As before the 3 patches are at: http://0ape.com/postgres_interval_patches/ and http://git.forensiclogic.com/postgresql/ and http://git.forensiclogic.com/?p=postgresql;a=shortlog;h=refs/heads/cleanup I'm attaching the patch dealing with sql standard intervals here for the archives. *** a/doc/src/sgml/config.sgml --- b/doc/src/sgml/config.sgml *************** *** 4013,4018 **** SET XML OPTION { DOCUMENT | CONTENT }; --- 4013,4056 ---- </listitem> </varlistentry> + <varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle"> + <term><varname>IntervalStyle</varname> (<type>string</type>)</term> + <indexterm> + <primary><varname>IntervalStyle</> configuration parameter</primary> + </indexterm> + <listitem> + <para> + Sets the display format for interval values. + The value <literal>sql_standard</> will produce + output matching <acronym>SQL</acronym> standard + interval literals for values that conform to the + <acronym>SQL</acronym> standard (either year-month + only or date-time only; and no mixing of positive + and negative components). + + The value <literal>postgres</> will produce output + matching PostgreSQL releases prior to 8.4 + when the <xref linkend="guc-datestyle"> + parameter was set to <literal>ISO</>. + + The value <literal>postgres_verbose</> will produce output + matching PostgreSQL releases prior to 8.4 + when the <xref linkend="guc-datestyle"> + parameter was set to <literal>SQL</>. + </para> + <para> + The IntervalStyle GUC also affects the interpretation + of one ambiguous interval literal input. In SQL 2008 + the negative sign in the interval literal '-1 2:03:04' + applies to both the days and hour/minute/second parts. + PostgreSQL traditionally only applied the negative + sign to the days part. If IntervalStyle is set to + <literal>sql_standard</literal> it will follow the standard + otherwise it uses the traditional postgres interpretation. + </para> + </listitem> + </varlistentry> + <varlistentry id="guc-timezone" xreflabel="timezone"> <term><varname>timezone</varname> (<type>string</type>)</term> <indexterm> *** a/doc/src/sgml/datatype.sgml --- b/doc/src/sgml/datatype.sgml *************** *** 1962,1968 **** January 8 04:05:06 1999 PST a combination of years and months can be specified with a dash; for example <literal>'200-10'</> is read the same as <literal>'200 years 10 months'</>. (These shorter forms are in fact the only ones allowed ! by the SQL standard.) </para> <para> --- 1962,1968 ---- a combination of years and months can be specified with a dash; for example <literal>'200-10'</> is read the same as <literal>'200 years 10 months'</>. (These shorter forms are in fact the only ones allowed ! by the <acronym>SQL</acronym> standard.) </para> <para> *************** *** 2213,2218 **** January 8 04:05:06 1999 PST --- 2213,2310 ---- </para> </sect2> + <sect2 id="interval-output"> + <title>Interval Output</title> + + <indexterm> + <primary>interval</primary> + <secondary>output format</secondary> + <seealso>formatting</seealso> + </indexterm> + + <para> + The output format of the interval types can be set to one of the + three styles <literal>sql_standard</>, + <literal>postgres</>, or <literal>postgres_verbose</>. + The default is the <literal>postgres</> format. + <xref + linkend="interval-style-output-table"> shows examples of each + output style. + </para> + + <para> + The <literal>sql_standard</> style will output SQL standard + interval literal strings where the value of the interval + value consists of only a year-month component or a datetime + component (as required by the <acronym>SQL</acronym> standard). + For an interval containing both a year-month and a datetime + component, the output will be a <acronym>SQL</acronym> standard + unquoted year-month literal string concatenated with a + <acronym>SQL</acronym> standard unquoted datetime literal + string with a space in between; and '+' and '-' signs added + to disambiguate mixed-sign intervals. + </para> + + <para> + The <literal>postgres</> style will output intervals + matching those output by PostgreSQL releases prior to 8.4 + when the <xref linkend="guc-datestyle"> + parameter was set to <literal>ISO</>. + </para> + + <para> + The <literal>postgres_verbose</> style will output intervals + matching those output by PostgreSQL releases prior to 8.4 + when the <xref linkend="guc-datestyle"> + parameter was set to <literal>SQL</>. + </para> + + <table id="interval-style-output-table"> + <title>Interval Style Example</title> + <tgroup cols="2"> + <thead> + <row> + <entry>Style Specification</entry> + <entry>Year-Month Interval</entry> + <entry>DateTime Interval</entry> + <entry>Nonstandardrd Extended Interval</entry> + </row> + </thead> + <tbody> + <row> + <entry>sql_standard</entry> + <entry>1-2</entry> + <entry>3 4:05:06</entry> + <entry>-1-2 +3 -4:05:06</entry> + </row> + <row> + <entry>postgres</entry> + <entry>1 year 2 mons</entry> + <entry>3 days 04:05:06</entry> + <entry>-1 year -2 mons +3 days -04:05:06</entry> + </row> + <row> + <entry>postgres_verbose</entry> + <entry>@ 1 year 2 mons</entry> + <entry>@ 3 days 4 hours 5 mins 6 secs</entry> + <entry>@ 1 year 2 mons -3 days 4 hours 5 mins 6 secs ago</entry> + </row> + </tbody> + </tgroup> + </table> + + <para> + Note that <literal>sql_standard</> style will only produce strictly + standards-conforming interval literals when given a strictly + <acronym>SQL</acronym> standard interval value - meaning that + it needs to be a pure year-month or datetime interval and not + mix positive and negative components. + </para> + + </sect2> + + + <sect2 id="datatype-timezones"> <title>Time Zones</title> *** a/src/backend/commands/variable.c --- b/src/backend/commands/variable.c *************** *** 229,234 **** assign_datestyle(const char *value, bool doit, GucSource source) --- 229,271 ---- /* + * assign_intervalstyle: GUC assign_hook for datestyle + */ + const char * + assign_intervalstyle(const char *value, bool doit, GucSource source) + { + int newIntervalStyle = IntervalStyle; + char * result = (char *) malloc(32); + if (pg_strcasecmp(value, "postgres") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES; + } + else if (pg_strcasecmp(value, "postgres_verbose") == 0) + { + newIntervalStyle = INTSTYLE_POSTGRES_VERBOSE; + } + else if (pg_strcasecmp(value, "sql_standard") == 0) + { + newIntervalStyle = INTSTYLE_SQL_STANDARD; + } + else + { + ereport(GUC_complaint_elevel(source), + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unrecognized \"intervalstyle\" key word: \"%s\"", + value))); + return NULL; + } + if (doit) + { + IntervalStyle = newIntervalStyle; + strcpy(result, value); + } + return result; + } + + + /* * TIMEZONE */ *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 2766,2771 **** DecodeInterval(char **field, int *ftype, int nf, int range, --- 2766,2787 ---- case DTK_TIME: dterr = DecodeTime(field[i], fmask, range, &tmask, tm, fsec); + if (IntervalStyle == INTSTYLE_SQL_STANDARD && + field[0][0] == '-' && i == 1 && + field[i][0] != '-' && field[i][0] != '+') + { + /* + * The SQL Standard defines the interval literal + * '-1 1:00:00' + * to mean "negative 1 days and negative one hours" + * while Postgres traditionally treated this as + * to mean "negative 1 days and positive one hours" + */ + tm->tm_hour = -tm->tm_hour; + tm->tm_min = -tm->tm_min; + tm->tm_sec = -tm->tm_sec; + *fsec = - *fsec; + } if (dterr) return dterr; type = DTK_DAY; *************** *** 3605,3610 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3621,3647 ---- return TRUE; } + /* + * Small helper funciton to avoid copy&paste in EncodeInterval below + */ + static void + AppendSeconds(char * cp, int sec, fsec_t fsec) + { + if (fsec == 0) + { + sprintf(cp, "%02d", abs(sec)); + } + else + { + #ifdef HAVE_INT64_TIMESTAMP + sprintf(cp, "%02d.%06d", abs(sec), Abs(fsec)); + #else + sprintf(cp, "%012.9f", fabs(sec + fsec)); + #endif + TrimTrailingZeros(cp); + } + } + /* EncodeInterval() * Interpret time structure as a delta time and convert to string. *************** *** 3613,3618 **** EncodeDateTime(struct pg_tm * tm, fsec_t fsec, int *tzp, char **tzn, int style, --- 3650,3666 ---- * Actually, afaik ISO does not address time interval formatting, * but this looks similar to the spec for absolute date/time. * - thomas 1998-04-30 + * + * Actually, afaik, ISO 8601 does specify formats for "time + * intervals...[of the]...format with time-unit designators", which + * are pretty ugly. The format looks something like + * P1Y1M1DT1H1M1.12345S + * but useful for exchanging data with computers instead of humans. + * - ron 2003-07-14 + * + * And ISO's SQL 2008 standard specifies standards for + * "year-month literal"s (that look like '2-3') and + * "day-time literal"s (that look like ('4 5:6:7') */ int EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) *************** *** 3621,3626 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) --- 3669,3681 ---- bool is_nonzero = FALSE; char *cp = str; + int year = tm->tm_year; + int mon = tm->tm_mon; + int mday = tm->tm_mday; + int hour = tm->tm_hour; + int min = tm->tm_min; + int sec = tm->tm_sec; + /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and *************** *** 3628,3635 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) */ switch (style) { ! /* compatible with ISO date formats */ ! case USE_ISO_DATES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", --- 3683,3760 ---- */ switch (style) { ! /* SQL Standard interval literals */ ! case INTSTYLE_SQL_STANDARD: ! { ! bool has_negative = (year < 0) || (mon < 0) || ! (mday < 0) || (hour < 0) || ! (min < 0) || (sec < 0) || (fsec < 0); ! bool has_positive = (year > 0) || (mon > 0) || ! (mday > 0) || (hour > 0) || ! (min > 0) || (sec > 0) || (fsec > 0); ! bool has_year_month = (year != 0) || (mon != 0); ! bool has_datetime = (hour != 0) || (min != 0) || ! (sec != 0) || (fsec != 0) || (mday != 0); ! bool has_day = (mday != 0); ! bool sql_standard_value = (!(has_negative && has_positive)) && ! (!(has_year_month && has_datetime)); ! /* ! * SQL Standard wants only 1 "<sign>" preceeding the whole ! * interval. ! */ ! if (has_negative && sql_standard_value) ! { ! sprintf(cp, "-"); ! cp++; ! year = -year; ! mon = -mon; ! mday = -mday; ! hour = -hour; ! min = -min; ! sec = -sec; ! fsec = -fsec; ! } ! if (!has_negative && !has_positive) ! { ! sprintf(cp, "0"); ! } ! else if (!sql_standard_value) ! { ! /* ! * For non sql-standard interval values, ! * force outputting the signs to avoid ! * ambiguities with intervals with mixed ! * sign components. ! */ ! char year_sign = (year < 0 || mon < 0) ? '-' : '+'; ! char day_sign = (mday < 0) ? '-' : '+'; ! char sec_sign = (hour < 0 || min < 0 || sec < 0 || fsec < 0) ! ? '-' : '+'; ! cp += sprintf(cp, "%c%d-%d %c%d %c%d:%02d:", ! year_sign, abs(year), abs(mon), ! day_sign, abs(mday), ! sec_sign, abs(hour), abs(min)); ! AppendSeconds(cp, sec, fsec); ! } ! else if (has_year_month) ! { ! sprintf(cp, "%d-%d", year, mon); ! } ! else if (has_day) ! { ! cp += sprintf(cp, "%d %d:%02d:", mday, hour, min); ! AppendSeconds(cp, sec, fsec); ! } ! else ! { ! cp += sprintf(cp, "%d:%02d:", hour, min); ! AppendSeconds(cp, sec, fsec); ! } ! break; ! } ! ! /* compatible with postgresql 8.3 when DateStyle = 'iso' */ ! case INTSTYLE_POSTGRES: if (tm->tm_year != 0) { sprintf(cp, "%d year%s", *************** *** 3692,3700 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) cp += strlen(cp); } } break; ! case USE_POSTGRES_DATES: default: strcpy(cp, "@ "); cp += strlen(cp); --- 3817,3831 ---- cp += strlen(cp); } } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } break; ! /* compatible with postgresql 8.3 when DateStyle = 'sql' */ ! case INTSTYLE_POSTGRES_VERBOSE: default: strcpy(cp, "@ "); cp += strlen(cp); *************** *** 3821,3842 **** EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str) is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } break; } - /* identically zero? then put in a unitless zero... */ - if (!is_nonzero) - { - strcat(cp, "0"); - cp += strlen(cp); - } - - if (is_before && (style != USE_ISO_DATES)) - { - strcat(cp, " ago"); - cp += strlen(cp); - } - return 0; } /* EncodeInterval() */ --- 3952,3970 ---- is_before = (tm->tm_sec < 0); is_nonzero = TRUE; } + if (!is_nonzero) + { + strcat(cp, "0"); + cp += strlen(cp); + } + if (is_before) + { + strcat(cp, " ago"); + cp += strlen(cp); + } break; } return 0; } /* EncodeInterval() */ *** a/src/backend/utils/adt/nabstime.c --- b/src/backend/utils/adt/nabstime.c *************** *** 671,677 **** reltimeout(PG_FUNCTION_ARGS) char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, DateStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); --- 671,677 ---- char buf[MAXDATELEN + 1]; reltime2tm(time, tm); ! EncodeInterval(tm, 0, IntervalStyle, buf); result = pstrdup(buf); PG_RETURN_CSTRING(result); *** a/src/backend/utils/adt/timestamp.c --- b/src/backend/utils/adt/timestamp.c *************** *** 677,683 **** interval_out(PG_FUNCTION_ARGS) if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, DateStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); --- 677,683 ---- if (interval2tm(*span, tm, &fsec) != 0) elog(ERROR, "could not convert interval to tm"); ! if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0) elog(ERROR, "could not format interval"); result = pstrdup(buf); *** a/src/backend/utils/init/globals.c --- b/src/backend/utils/init/globals.c *************** *** 88,93 **** bool ExitOnAnyError = false; --- 88,94 ---- int DateStyle = USE_ISO_DATES; int DateOrder = DATEORDER_MDY; + int IntervalStyle = INTSTYLE_POSTGRES; bool HasCTZSet = false; int CTimeZone = 0; *** a/src/backend/utils/misc/guc.c --- b/src/backend/utils/misc/guc.c *************** *** 366,371 **** static bool session_auth_is_superuser; --- 366,372 ---- static double phony_random_seed; static char *client_encoding_string; static char *datestyle_string; + static char *intervalstyle_string; static char *locale_collate; static char *locale_ctype; static char *server_encoding_string; *************** *** 2078,2083 **** static struct config_string ConfigureNamesString[] = --- 2079,2094 ---- "ISO, MDY", assign_datestyle, NULL }, + { + {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE, + gettext_noop("Sets the display format for interval values."), + gettext_noop(""), + GUC_REPORT + }, + &intervalstyle_string, + "postgres", assign_intervalstyle, NULL + }, + { {"default_tablespace", PGC_USERSET, CLIENT_CONN_STATEMENT, gettext_noop("Sets the default tablespace to create tables and indexes in."), *** a/src/backend/utils/misc/postgresql.conf.sample --- b/src/backend/utils/misc/postgresql.conf.sample *************** *** 419,424 **** --- 419,425 ---- # - Locale and Formatting - #datestyle = 'iso, mdy' + #intervalstyle = 'postgres' #timezone = unknown # actually, defaults to TZ environment # setting #timezone_abbreviations = 'Default' # Select the set of available time zone *** a/src/bin/psql/tab-complete.c --- b/src/bin/psql/tab-complete.c *************** *** 1953,1958 **** psql_completion(char *text, int start, int end) --- 1953,1965 ---- COMPLETE_WITH_LIST(my_list); } + else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0) + { + static const char *const my_list[] = + {"postgres","postgres_verbose", "sql_standard", NULL}; + + COMPLETE_WITH_LIST(my_list); + } else if (pg_strcasecmp(prev2_wd, "GEQO") == 0) { static const char *const my_list[] = *** a/src/include/commands/variable.h --- b/src/include/commands/variable.h *************** *** 15,20 **** --- 15,22 ---- extern const char *assign_datestyle(const char *value, bool doit, GucSource source); + extern const char *assign_intervalstyle(const char *value, + bool doit, GucSource source); extern const char *assign_timezone(const char *value, bool doit, GucSource source); extern const char *show_timezone(void); *** a/src/include/miscadmin.h --- b/src/include/miscadmin.h *************** *** 191,196 **** extern PGDLLIMPORT Oid MyDatabaseTableSpace; --- 191,208 ---- extern int DateStyle; extern int DateOrder; + + /* + * IntervalStyles + * INTSTYLE_POSTGRES Like Postgres8.3 when DateStyle = 'iso' + * INTSTYLE_POSTGRES_VERBOSE Like Postgres8.3 when DateStyle = 'sql' + * INTSTYLE_SQL_STANDARD SQL standard interval literals + */ + #define INTSTYLE_POSTGRES 0 + #define INTSTYLE_POSTGRES_VERBOSE 1 + #define INTSTYLE_SQL_STANDARD 2 + + extern int IntervalStyle; /* * HasCTZSet is true if user has set timezone as a numeric offset from UTC. *** a/src/interfaces/libpq/fe-connect.c --- b/src/interfaces/libpq/fe-connect.c *************** *** 209,214 **** static const PQEnvironmentOption EnvironmentOptions[] = --- 209,217 ---- "PGDATESTYLE", "datestyle" }, { + "PGINTERVALSTYLE", "intervalstyle" + }, + { "PGTZ", "timezone" }, { *** a/src/test/regress/expected/interval.out --- b/src/test/regress/expected/interval.out *************** *** 2,7 **** --- 2,8 ---- -- INTERVAL -- SET DATESTYLE = 'ISO'; + SET IntervalStyle to postgres; -- check acceptance of "time zone style" SELECT INTERVAL '01:00' AS "One hour"; One hour *************** *** 273,278 **** FROM INTERVAL_MULDIV_TBL; --- 274,280 ---- DROP TABLE INTERVAL_MULDIV_TBL; SET DATESTYLE = 'postgres'; + SET IntervalStyle to postgres_verbose; SELECT '' AS ten, * FROM INTERVAL_TBL; ten | f1 -----+------------------------------- *************** *** 326,331 **** SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour"; --- 328,334 ---- -- test fractional second input, and detection of duplicate units SET DATESTYLE = 'ISO'; + SET IntervalStyle TO postgres; SELECT '1 millisecond'::interval, '1 microsecond'::interval, '500 seconds 99 milliseconds 51 microseconds'::interval; interval | interval | interval *************** *** 609,611 **** SELECT interval '1 2:03:04.5678' minute to second(2); --- 612,648 ---- 00:03:04.57 (1 row) + -- test inputting and outputting SQL standard interval literals + SET IntervalStyle TO sql_standard; + SELECT interval '0' AS "zero", + interval '1-2' year to month AS "year-month", + interval '1 2:03:04' day to second AS "day-time", + - interval '1-2' AS "negative year-month", + - interval '1 2:03:04' AS "negative day-time"; + zero | year-month | day-time | negative year-month | negative day-time + ------+------------+-----------+---------------------+------------------- + 0 | 1-2 | 1 2:03:04 | -1-2 | -1 2:03:04 + (1 row) + + -- test input of some not-quite-standard interval values in the sql style + SET IntervalStyle TO postgres; + SELECT interval '+1 -1:00:00', + interval '-1 +1:00:00', + interval '+1-2 -3 +4:05:06.789', + interval '-1-2 +3 -4:05:06.789'; + interval | interval | interval | interval + -----------------+-------------------+-------------------------------------+---------------------------------------- + 1 day -01:00:00 | -1 days +01:00:00 | 1 year 2 mons -3 days +04:05:06.789 | -1 years -2 mons +3 days -04:05:06.789 + (1 row) + + -- test output of couple non-standard interval values in the sql style + SET IntervalStyle TO sql_standard; + SELECT interval '1 day -1 hours', + interval '-1 days +1 hours', + interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', + - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds'; + interval | interval | interval | ?column? + ------------------+------------------+----------------------+---------------------- + +0-0 +1 -1:00:00 | +0-0 -1 +1:00:00 | +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789 + (1 row) + *** a/src/test/regress/pg_regress.c --- b/src/test/regress/pg_regress.c *************** *** 708,713 **** initialize_environment(void) --- 708,714 ---- */ putenv("PGTZ=PST8PDT"); putenv("PGDATESTYLE=Postgres, MDY"); + putenv("PGINTERVALSTYLE=postgres_verbose"); if (temp_install) { *** a/src/test/regress/sql/interval.sql --- b/src/test/regress/sql/interval.sql *************** *** 3,8 **** --- 3,9 ---- -- SET DATESTYLE = 'ISO'; + SET IntervalStyle to postgres; -- check acceptance of "time zone style" SELECT INTERVAL '01:00' AS "One hour"; *************** *** 94,99 **** FROM INTERVAL_MULDIV_TBL; --- 95,101 ---- DROP TABLE INTERVAL_MULDIV_TBL; SET DATESTYLE = 'postgres'; + SET IntervalStyle to postgres_verbose; SELECT '' AS ten, * FROM INTERVAL_TBL; *************** *** 118,123 **** SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour"; --- 120,127 ---- -- test fractional second input, and detection of duplicate units SET DATESTYLE = 'ISO'; + SET IntervalStyle TO postgres; + SELECT '1 millisecond'::interval, '1 microsecond'::interval, '500 seconds 99 milliseconds 51 microseconds'::interval; SELECT '3 days 5 milliseconds'::interval; *************** *** 174,176 **** SELECT interval '1 2:03:04.5678' hour to second(2); --- 178,202 ---- SELECT interval '1 2.3456' minute to second(2); SELECT interval '1 2:03.5678' minute to second(2); SELECT interval '1 2:03:04.5678' minute to second(2); + + -- test inputting and outputting SQL standard interval literals + SET IntervalStyle TO sql_standard; + SELECT interval '0' AS "zero", + interval '1-2' year to month AS "year-month", + interval '1 2:03:04' day to second AS "day-time", + - interval '1-2' AS "negative year-month", + - interval '1 2:03:04' AS "negative day-time"; + + -- test input of some not-quite-standard interval values in the sql style + SET IntervalStyle TO postgres; + SELECT interval '+1 -1:00:00', + interval '-1 +1:00:00', + interval '+1-2 -3 +4:05:06.789', + interval '-1-2 +3 -4:05:06.789'; + + -- test output of couple non-standard interval values in the sql style + SET IntervalStyle TO sql_standard; + SELECT interval '1 day -1 hours', + interval '-1 days +1 hours', + interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds', + - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds';
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
"Brendan Jurd"
Date:
On Wed, Nov 5, 2008 at 7:34 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > Brendan Jurd wrote: >> When I ran the regression tests, I got one failure in the new interval > > Fixed, and I did a bit more testing both with and without > HAVE_INT64_TIMESTAMP. Confirmed, all regression tests now pass on my system with the updated patch. >> The C code has some small stylistic inconsistencies; ... >> ... spaces around binary operators are missing (e.g., "(fsec<0)"). > > Thanks. Fixed these. > >> ...function calls missing the space after the argument separator... > > I think I fixed all these now too. Awesome. As far as I can tell, you got them all. I don't have any further nits to pick about the code style. The changes to the documentation all look good. I did notice one final typo that I think was introduced in the latest version. doc/src/sgml/datatype.sgml:2270 has "Nonstandardrd" instead of "Nonstandard". But, apart from that I have no further feedback. I will sign off on this one and mark it "Ready for committer" in the commitfest. Review of the other two patches coming soon to a mail client near you. Cheers, BJ
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Brendan Jurd wrote: > The changes to the documentation all look good. I did notice one > final typo that I think was introduced in the latest version. > doc/src/sgml/datatype.sgml:2270 has "Nonstandardrd" instead of > "Nonstandard". Just checked in a fix to that one; and updated my website at http://0ape.com/postgres_interval_patches/ and pushed it to my (hopefully fixed now) git server. If this'll be the final update to this patch should I be posting it to the mailing list too for the archives? > But, apart from that I have no further feedback. > I will sign off on this one and mark it "Ready for committer" in the commitfest. Cool. I'm not sure if anyone still wants to weigh in on the approach I took for mixed-sign intervals, where '-1 2:03:04' gets interpreted differently depending on the date style, and '-1 +2:03:04' and '-1 -2:03:04' are the way I'm using to disambiguate them. > Review of the other two patches coming soon to a mail client near you. Feel free to do them one-at-a-time too; since no doubt any issues with the first one will probably affect the second one too. I think I updated the other patches for the missing whitespace style issues my first patch had; but no doubt there could be other bad habits I have as well. Ron
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Brendan Jurd wrote: > On Wed, Nov 5, 2008 at 7:34 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: >> Brendan Jurd wrote: >>> ...new interval > Review of the other two patches coming soon to a mail client near you. > Oh - and for review of the next patch, ISO 8601's spec would no doubt be useful. I think this is the right place to get it: http://isotc.iso.org/livelink/livelink/4021199/ISO_8601_2004_E.zip?func=doc.Fetch&nodeid=4021199 Is there anywhere in the comments, docs, or wiki where such links and/or excerpts from specs belong?
On Thu, Oct 2, 2008 at 9:31 PM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > Ron Mayer wrote: > This patch (that works on top of the IntervalStyle patch I > posted earlier today) adds support for ISO8601 standard[0] > "Time Interval" "Durations" of the "format with designators" > (section 4.4.4.2.1). The other ISO 8601 types of intervals > deal with start and end points, so this one seemed most relevant. > Hi Ron, Reviewing this patch now; I'm working from the 'iso8601' branch in your git repository. Compile, regression tests and my own ad hoc tests in psql all worked without a hitch. As I was reading through the new documentation introduced by the patch, I thought of various improvements and decided to try them out for myself. In the end, rather than try to explain all of my changes in detail, I thought I'd post a patch of my own (against your branch) and accompany it with a few explanatory notes. The patch includes some minor changes to the code style in src/backend/utils/adt/datetime.c, similar to my recommendations for the IntervalStyle patch. As for the documentation, I ended up making quite a few changes. Explanations and rationales to follow. ISO section numbers -- in a couple of places, the documentation referred to the wrong parts of ISO 8601. I found references to 5.5.4.2.1 and 5.5.4.2.2, whereas in both cases the first two digits should be '4'. Interval Input syntax -- I thought that the paragraph explaining the ISO input syntax was not verbose enough. One paragraph didn't seem sufficient to explain the syntaxes involved. In particular, the original paragraph didn't mention that units could be omitted or reordered in the "designators" format. I expanded a bit more on how the syntaxes worked, using the same pseudogrammar style used to explain the postgres interval format, and included a table showing the available time-unit designators. Interval Output section structure -- the new section for Interval Output was added at level 2, right below Date/Time Output. I felt this was uncomfortably assymetric with the Input section, which has Date/Time Input as a level 2 section, with Interval Input as a level 3 underneath it. I demoted Interval Output to a level 3 and moved it underneath Date/Time Output. The rest of my doc changes were adding extra linkage, and some minor wording and consistency tweaks. Most of these changes are of a highly subjective nature. I think they are improvements, but someone else might prefer the way it was before I got my hands dirty. Please consider the changes in my patch a set of suggestions for making the documentation on this feature a little easier to digest. You're welcome to take or leave them as you see fit. Cheers, BJ
Attachment
Brendan Jurd wrote: > Reviewing this patch now; I'm working from the 'iso8601' branch in > ... I thought I'd post a patch of my own (against your branch) > and accompany it with a few explanatory notes. Wow thanks! That's very helpful (though it might have been more fair to your time if you just kicked it back to me saying "rewrite the docs" so they make sense)! I've applied them with a couple minor changes. * If ISO 8601 5.5.3.1.d's statement "The designator T shall be absent if all of the time components are absent." also applies to 5.5.4.2.2; then I think the 'T' needed to be inside the <optional> tags, so I moved it there. The link to the spec's below[1]. * There was a <sect2> that the patch changed to a <sect3>, and with that change I get an error: openjade:datatype.sgml:2306:31:E: document type does not allow element "SECT3" here so I changed it back to a <sect2>. You can see my changes to your patch on gitweb here: http://tinyurl.com/6crks6 and see how they got applied after your patch here http://tinyurl.com/685hla I think I've updated my website, my git, and the cleanup patch to include these changes now. > Most of these changes are of a highly subjective nature. I think they > are improvements, but someone else might prefer the way it was before > I got my hands dirty. Please consider the changes in my patch a set > of suggestions for making the documentation on this feature a little > easier to digest. You're welcome to take or leave them as you see > fit. They're clearly improvements. I'm a total novice when it comes to writing docs. [1] http://isotc.iso.org/livelink/livelink/4021199/ISO_8601_2004_E.zip?func=doc.Fetch&nodeid=4021199
On Thu, Nov 6, 2008 at 3:36 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > Wow thanks! That's very helpful (though it might have been more > fair to your time if you just kicked it back to me saying "rewrite > the docs" so they make sense)! > Maybe ... but I figured it would take more time to fully explain what I meant by "rewrite the docs" in an email than it would to actually rewrite them. =) > > I've applied them with a couple minor changes. > > * If ISO 8601 5.5.3.1.d's statement "The designator T shall be > absent if all of the time components are absent." also applies > to 5.5.4.2.2; then I think the 'T' needed to be inside the > <optional> tags, so I moved it there. The link to the spec's > below[1]. Hmm, okay. When I was running my tests in psql I came away with the impression that the T was required in the "alternative format". I might be mistaken. I'll run some further tests a little later on. > * There was a <sect2> that the patch changed to a <sect3>, and > with that change I get an error: > openjade:datatype.sgml:2306:31:E: document type does not allow element > "SECT3" here > so I changed it back to a <sect2>. > Ah, the <sect3> needs to go _inside_ the <sect2>, whereas I originally had just changed the tags and left it in the same position (after the <sect2>). I fixed this in my working copy but I must have forgotten to produce a fresh patch after doing so. Cheers, BJ
Brendan Jurd wrote: >> I've applied them with a couple minor changes. >> >> * If ISO 8601 5.5.3.1.d's statement "The designator T shall be >> absent if all of the time components are absent." also applies >> to 5.5.4.2.2; then I think the 'T' needed to be inside the >> <optional> tags, so I moved it there. The link to the spec's >> below[1]. > > Hmm, okay. When I was running my tests in psql I came away with the > impression that the T was required in the "alternative format". I > might be mistaken. I'll run some further tests a little later on. Indeed that's a bug in my code; where I was sometimes requiring the 'T' (in the ISO8601 "alternative format") and sometimes not (in the ISO8601 format from 5.5.4.2.1). Below's a test case. If I read the spec[1] right both of those should mean 1 day. I'll update git and post a new patch now. If people think I read the specs wrong, I'll undo this change and fix the docs. ========================================================== [2]lt:/home/ramayer/proj/pg% ./psql regression psql (8.4devel) Type "help" for help. regression=# select interval 'P1D'; interval ---------- 1 day (1 row) regression=# select interval 'P0000-00-01'; ERROR: invalid input syntax for type interval: "P0000-00-01" LINE 1: select interval 'P0000-00-01'; ^ ========================================================== [1] http://isotc.iso.org/livelink/livelink/4021199/ISO_8601_2004_E.zip?func=doc.Fetch&nodeid=4021199
Ron Mayer wrote: > Brendan Jurd wrote: >>> 'T' ... <optional> > > Indeed that's a bug in my code; where I was sometimes > requiring the 'T' (in the ISO8601 "alternative format") and > sometimes not (in the ISO8601 format from 5.5.4.2.1). > > Below's a test case. If I read the spec[1] right both of those > should mean 1 day. I'll update git and post a new patch now. > If people think I read the specs wrong, I'll undo this change > and fix the docs. I think I updated the web site and git now, and 'P0000-00-01' is now accepted. It might be useful if someone double checked my reading of the spec, tho. > [1] > http://isotc.iso.org/livelink/livelink/4021199/ISO_8601_2004_E.zip?func=doc.Fetch&nodeid=4021199 >
On Fri, Nov 7, 2008 at 3:35 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > I think I updated the web site and git now, and > 'P0000-00-01' is now accepted. It might be useful if > someone double checked my reading of the spec, tho. > Hi Ron, I've tested out your latest revision and read the spec more closely, and pretty much everything works as expected. 'P0000-00-01' yields 1 day, and various other combinations like 'P0000-01-00' and 'P0000-01' work correctly too. I agree with your interpretation of the spec, it clearly says that 'T' can be omitted when there are no time components. This should apply equally to both the designators format and the alternative format. The examples in Annex B confirm this. I did run into one potential bug: postgres=# select interval 'P0001'; interval ---------- 1 day Whereas, I expected to get '1 year', since the format allows you to omit lower-order components from right-to-left: P0001-01-01 => 1 year 1 month 1 day P0001-01 => 1 year 1 month P0001 => should be 1 year? On the documentation front, I have a few final cleanups to suggest (patch attached). * After giving the spec a closer look, I thought that 4.4.3.2 and 4.4.3.3 were the proper spec references to use for the two formats. * I removed the identation from a <programlisting> element. These elements are left at the start of the line to prevent the initial spacing from being interpreted as part of the listing itself. * I made "Interval Output" a level 3 section again, and this time I corrected that structural issue in my earlier patch. It's now contained within the level 2 section. * There was a sentence in the docs about the 'T' separator being mandatory in the "alternative format". I deleted it. * Changed "format with time-unit designators" to just "format with designators", as that is how the spec refers to it. * Some tabs had crept into the indentation, and there were a few indentation errors in the new tables. I corrected those (the tabs may have been my fault; I sometimes forget to change my vi settings when switching between C code and SGML). Cheers, BJ
Attachment
Brendan Jurd wrote: > On Fri, Nov 7, 2008 at 3:35 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: >> I think I updated the web site and git now, and >> 'P0000-00-01' is now accepted. It might be useful if >> someone double checked my reading of the spec, tho. > > I've tested out your latest revision and read the spec more closely, > and pretty much everything works as expected. ... > I agree with your interpretation of the spec, it clearly says that 'T' > can be omitted when there are no time components. ... > The examples in Annex B confirm this. Cool. Thanks. > I did run into one potential bug: > postgres=# select interval 'P0001'; > ... > Whereas, I expected to get '1 year', since the format allows you to > omit lower-order components from right-to-left: > P0001-01-01 => 1 year 1 month 1 day > P0001-01 => 1 year 1 month > P0001 => should be 1 year? Indeed, that's right. Thanks for catching another one. I just checked in (to my git) a patch that I believe fixes it. regression=# select interval 'P0001',interval 'P00010000',interval 'PT01'; interval | interval | interval ----------+----------+---------- 1 year | 1 year | 01:00:00 (1 row) > On the documentation front, I have a few final cleanups to suggest > (patch attached). > * After giving the spec a closer look, I thought that 4.4.3.2 and > 4.4.3.3 were the proper spec references to use for the two formats. Hmmm... Certainly what I had in datatype.sgml was wrong, but I'm now thinking 5.5.4.2.1 and 5.5.4.2.2 would be the most clear? Totally agree with the rest of your docs changes and applied those.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Brendan Jurd wrote: >> The changes to the documentation all look good. I did notice one >> final typo that I think was introduced in the latest version. >> doc/src/sgml/datatype.sgml:2270 has "Nonstandardrd" instead of >> "Nonstandard". > Just checked in a fix to that one; and updated my website at > http://0ape.com/postgres_interval_patches/ > and pushed it to my (hopefully fixed now) git server. > If this'll be the final update to this patch should I be > posting it to the mailing list too for the archives? Since it's only one line different from your previous, probably no need. I've started reviewing this patch for commit, and I find myself a bit disturbed by its compatibility properties. The SQL_STANDARD output style is simply ambiguous: what is meant by-1 1:00:00 ? What you get from that will depend on the intervalstyle setting at the recipient. Either of the traditional Postgres styles are non-ambiguous and will be interpreted correctly regardless of receiver's intervalstyle --- in particular, Postgres mode always puts an explicit sign on the time part if the days or months part was negative. What this means is that SQL_STANDARD mode is unsafe for dumping data, and *pg_dump had better force Postgres mode*. We can certainly do that with a couple more lines added to the patch, but it's a bit troublesome that we are boxed into using a nonstandard dump-data format until forever. I don't immediately see any way around that, though. Anyone have a bright idea? regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > > I've started reviewing this patch for commit, and I find myself a bit > disturbed by its compatibility properties. The SQL_STANDARD output > style is simply ambiguous: what is meant by > -1 1:00:00 > ? What you get from that will depend on the intervalstyle setting at > the recipient. Nope. The SQL Standard style avoids the ambiguity by following the SQL Standard's rules when the input value complied with the standard's restrictions on intervals. For example - given the sql standard compliant value of negative one days and negative one hours you get "-1 1;00:00". If you give it a non-sql-standard-compliant value like negative one days plus one hours it will force outputting all the signs both positive and negative: regression=# select interval '-1 days +1 hours'; interval ------------------ +0-0 -1 +1:00:00 (1 row) I agree that there's an ambiguity on input - in much the same way that date order can affect ambiguous inputs. > Either of the traditional Postgres styles are > non-ambiguous and will be interpreted correctly regardless of receiver's > intervalstyle --- in particular, Postgres mode always puts an explicit > sign on the time part if the days or months part was negative. What > this means is that SQL_STANDARD mode is unsafe for dumping data, and So long as the SQL Standard style is chosen both on dumping and loading, I think it will preserve any values given to it. > *pg_dump had better force Postgres mode*. We can certainly do that with > a couple more lines added to the patch, but it's a bit troublesome that > we are boxed into using a nonstandard dump-data format until forever. > > I don't immediately see any way around that, though. Anyone have a > bright idea? Are you concerned about someone dumping in SQL_STANDARD mode and then importing in POSTGRES mode? If so, how's the similar case handled with date order?
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Ron Mayer wrote: > Tom Lane wrote: >> *pg_dump had better force Postgres mode*. We can certainly do that with >> a couple more lines added to the patch, but it's a bit troublesome that >> we are boxed into using a nonstandard dump-data format until forever. Ok. I see that is the concern.. Rather than forcing Postgres mode; couldn't it put a "set intervalstyle = [whatever the current interval style is]" in the dump file? That doesn't force us to using a nonstandard dump-data format (except for the nonstandard "set intervalstyle" line).
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Tom Lane wrote: >> I've started reviewing this patch for commit, and I find myself a bit >> disturbed by its compatibility properties. The SQL_STANDARD output >> style is simply ambiguous: what is meant by >> -1 1:00:00 >> ? What you get from that will depend on the intervalstyle setting at >> the recipient. > Nope. The SQL Standard style avoids the ambiguity by following > the SQL Standard's rules when the input value complied with the > standard's restrictions on intervals. You're missing the point: the same string can mean different things to different recipients depending on their intervalstyle setting. This means it's unsafe to use that representation in pg_dump output, unless we take steps to force the interpretation. > Are you concerned about someone dumping in SQL_STANDARD mode and > then importing in POSTGRES mode? Exactly. > If so, how's the similar case handled with date order? ISO date format is read the same regardless of recipient's datestyle, so pg_dump solves this by forcing the dump to be made in ISO style. The corresponding solution for intervals will be to dump in POSTGRES style, not SQL_STANDARD style, which seems a bit unfortunate. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Rather than forcing Postgres mode; couldn't it put a > "set intervalstyle = [whatever the current interval style is]" > in the dump file? This would work for loading into a PG >= 8.4 server, and fail miserably for loading into pre-8.4 servers. Even though we don't guarantee backwards compatibility of dump files, I'm loath to adopt a solution that will successfully load wrong data into an older server. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > > ISO date format is read the same regardless of recipient's datestyle, > so pg_dump solves this by forcing the dump to be made in ISO style. > The corresponding solution for intervals will be to dump in POSTGRES > style, not SQL_STANDARD style, which seems a bit unfortunate. [reading pg_dump.c now] I wonder if it could be similar to standard_conforming_strings where it appears to be reading the current value and setting it to whatever the user chose in the beginning of pg_dump. Then we could dump in whichever intervalstyle the user prefers. Or, for 8.4+ dumps we could even force "set intervalstyle = sql_standard;" in the top of the dump file. For dumps of 8.3 or less we'd need the non-standard style anyway it seems. If this seems sane, I can try experimenting with it tonight.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Rather than forcing Postgres mode; couldn't it put a >> "set intervalstyle = [whatever the current interval style is]" >> in the dump file? > > This would work for loading into a PG >= 8.4 server, and fail miserably > for loading into pre-8.4 servers. Even though we don't guarantee > backwards compatibility of dump files, I'm loath to adopt a solution > that will successfully load wrong data into an older server. 'k. So the options seem to be: (1) Don't output a SQL-standard interval literal for the value "negative one days and negative one hours"; perhaps by sticking an extra '+' sign in there? (2) Force pg_dump to a non-standard mode, at least until 8.3's deprecated in many years? After that, pg_dump can useany intervalstyle so long as it says which one it uses. (3) Put something into the dump file that will make the old server reject the file rather than successfully loading wrong data? (Some "if intervalstyle==std and version<8.3 abort loading the restore" logic?) I don't much like the first one, because it seems we're oh-so-close to meeting the standard. I don't know how to do the third one; but if pg_dump had an "assert(version>=8.4)" feature it might be useful if we ever had other non-backward-compatible changes. pg_dump would only put that assert-like-thing in the dump file if the sql_standard mode (or iso mode, if that gets approved) was chosen. The second one doesn't really seem that scary to me; since the uglyness can go away when we eventually stop restoring into 83.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Rather than forcing Postgres mode; couldn't it put a >> "set intervalstyle = [whatever the current interval style is]" >> in the dump file? > > This would work for loading into a PG >= 8.4 server, and fail miserably > for loading into pre-8.4 servers. Even though we don't guarantee > backwards compatibility of dump files, I'm loath to adopt a solution > that will successfully load wrong data into an older server. How is the case different from standard_conforming_strings; where ISTM depending on postgresql.conf 8.4 will happily dump either SET standard_conforming_strings = off; ... INSERT INTO dumptest VALUES ('\\\\'); or SET standard_conforming_strings = on; ... INSERT INTO dumptest VALUES ('\\'); and AFAICT the latter will happily load wrong data into 8.1 with only the error message ERROR: parameter "standard_conforming_strings" cannot be changed I imagine the use-case for "standard_conforming_strings = 0 " and "intervalstyle = sql_standard" are petty similar as well. I wonder if the best solution is that any dump file with standard_conforming_strings=on include some SQL that will refuse to load in pre-8.2 systems; and that any dump file with intervalstyle=sql_standard refuse to load in pre-8.4 systems. It seems pretty easy to add a sql fragment that checks version() and put that in the beginning of a dump file that uses these GUCs to enforce this.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > So the options seem to be: > (1) Don't output a SQL-standard interval literal for the > value "negative one days and negative one hours"; perhaps > by sticking an extra '+' sign in there? This is pretty much what the postgres style does... > (2) Force pg_dump to a non-standard mode, at least until 8.3's > deprecated in many years? IOW, same as above. > (3) Put something into the dump file that will make the old > server reject the file rather than successfully loading > wrong data? (Some "if intervalstyle==std and version<8.3 > abort loading the restore" logic?) There isn't any way to do that, unless you have a time machine in your hip pocket. The trouble with puttingset intervalstyle = something; into the dump script is that older servers will (by default) report an error on that line and keep right on chugging. The same is true of standard_conforming_strings BTW, which is one of the reasons why that's not a very good solution. But at least you're reasonably likely to get additional errors later in the dump if you try to load it into a server that doesn't handle standard_conforming_strings. What's scaring me about the interval stuff is that it will *silently* adopt the wrong reading of ambiguous interval strings. A DBA who missed seeing that one bleat early in the restore would not know anything was wrong. You're right that we don't have to be frozen into this forever, but I fear that any change is going to be a long way off. We couldn't really change pg_dump's output style until we have obsoleted all pre-8.4 releases. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
BTW, I just noticed that CVS HEAD has a bug in reading negative SQL-spec literals: regression=# select interval '-2008-10'; interval -----------------------2008 years -10 mons (1 row) regression=# select interval '-0000-10';interval ----------10 mons (1 row) Surely the latter must mean -10 months. This is orthogonal to the current patch ... regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > >> (3) Put something into the dump file that will make the old >> server reject the file rather than successfully loading >> wrong data? (Some "if intervalstyle==std and version<8.3 >> abort loading the restore" logic?) > > There isn't any way to do that, unless you have a time machine in > your hip pocket. The trouble with putting > set intervalstyle = something; > into the dump script is that older servers will (by default) report > an error on that line and keep right on chugging. Not necessarily. Couldn't we put select * from (select substring(version() from '[0-9\.]+') as version) as a join (select generate_series(0,100000000000))as b on(version<'8.4'); set intervalstyle = something; Or something similar in the dump file.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Tom Lane wrote: >> There isn't any way to do that, unless you have a time machine in >> your hip pocket. The trouble with putting >> set intervalstyle = something; >> into the dump script is that older servers will (by default) report >> an error on that line and keep right on chugging. > Not necessarily. Couldn't we put > select * from (select substring(version() from '[0-9\.]+') as version) as a > join (select generate_series(0,100000000000)) as b on(version<'8.4'); > set intervalstyle = something; > Or something similar in the dump file. [ shrug... ] It's still just one easily missable bleat. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Tom Lane wrote: >>> The trouble is that older servers will (by default) report >>> an error on that line and keep right on chugging. > >> Not necessarily. Couldn't we put > >> select * from (select substring(version() from '[0-9\.]+') as version) as a >> join (select generate_series(0,100000000000)) as b on(version<'8.4'); >> set intervalstyle = something; > > [ shrug... ] It's still just one easily missable bleat. Not here. On my system it hangs forever on 8.3 or less and proceeds harmlessly with 8.4.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >>> select * from (select substring(version() from '[0-9\.]+') as version) as a >>> join (select generate_series(0,100000000000)) as b on(version<'8.4'); >>> set intervalstyle = something; >> >> [ shrug... ] It's still just one easily missable bleat. > Not here. > On my system it hangs forever on 8.3 or less and proceeds > harmlessly with 8.4. Oh, I see what you're trying to do. The answer is no. We're not going to totally destroy back-portability of dumps, especially not for a problem that won't even affect most people (negative intervals are hardly common). regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Oh, I see what you're trying to do. The answer is no. We're not going > to totally destroy back-portability of dumps, especially not for a > problem that won't even affect most people (negative intervals are > hardly common). Similarly I wonder if pg_dump should add a "fail if version < 8.2" right before it outputs SET standard_conforming_strings = on; which IMHO is far more common than negative intervals and AFAICT has the same risk. For intervals, we would only add the fail code if intervalstyle was set to one of the new interval styles (if the ISO8601 interval's accepted it'll have the problem too). For backward compatible patches, they could still have their GUC settingse specify standard_conforming_strings and interval_style values that are supported by whichever versions they want to support.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > BTW, I just noticed that CVS HEAD has a bug in reading negative SQL-spec > literals: > regression=# select interval '-2008-10'; > regression=# select interval '-0000-10'; > Surely the latter must mean -10 months. This is orthogonal to the > current patch ... Perhaps the below patch fixes that? (though line numbers probably won't match since this was based off of the patched version) *** a/src/backend/utils/adt/datetime.c --- b/src/backend/utils/adt/datetime.c *************** *** 2879,2885 **** DecodeInterval(char **field, int *ftype, int nf, int range, if (*cp != '\0') return DTERR_BAD_FORMAT; type = DTK_MONTH; ! if (val < 0) val2 = -val2; val = val * MONTHS_PER_YEAR+ val2; fval = 0; --- 2879,2885 ---- if (*cp != '\0') return DTERR_BAD_FORMAT; type = DTK_MONTH; ! if (field[0][0] == '-') val2 = -val2; val = val * MONTHS_PER_YEAR+ val2; fval = 0; [5]lt:/home/ramayer/proj/pg/postgresql/src/backend/utils/adt%
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Another thought here ... I'm looking at the sign hack + if (IntervalStyle == INTSTYLE_SQL_STANDARD && + field[0][0] == '-' && i == 1 && + field[i][0] != '-' && field[i][0] != '+') + { + /*---------- + * The SQL Standard defines the interval literal + * '-1 1:00:00' + * to mean "negative 1 days and negative one hours" + * while Postgres traditionally treated this as + * meaning "negative 1 days and positive one hours". + * In SQL_STANDARD style, flip the sign to conform + * to the standard's interpretation. and not liking it very much. Yes, it does the intended thing for strict SQL-spec input, but it seems to produce a bunch of weird corner cases for non-spec input. Consider -1 1:00:00 flips the sign- 1 1:00:00 doesn't flip the sign-1 day 1:00:00 doesn't flip the sign-2008-101:00:00 flips the sign-2008-10 1 doesn't flip the sign-2008 years 1:00:00 doesn't flip the sign If the rule were that it never flipped the sign for non-SQL-spec input then I think that'd be okay, but case 4 here puts the lie to that. I'm also not entirely sure if case 2 is allowed by SQL spec or not, but if it is then we've got a problem with that; and even if it isn't it's awfully hard to explain why it's treated differently from case 1. I'm inclined to think we need a more semantically-based instead of syntactically-based rule. For instance, if first field is negative and no other field has an explicit sign, then force all fields to be <= 0. This would probably have to be applied at the end of DecodeInterval instead of on-the-fly within the loop. Thoughts? regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Another thought here ... I'm looking at the sign hack > + if (IntervalStyle == INTSTYLE_SQL_STANDARD && >.... > and not liking it very much. Yes, it does the intended thing for strict > SQL-spec input, but it seems to produce a bunch of weird corner cases > for non-spec input. Consider [... many examples ...] > > I'm inclined to think we need a more semantically-based instead of > syntactically-based rule. For instance, if first field is negative and > no other field has an explicit sign, then force all fields to be <= 0. > This would probably have to be applied at the end of DecodeInterval > instead of on-the-fly within the loop. > > Thoughts? I'll take a step back and think about that.... Yes, at first glance I think that approach is better; but we'd need to make sure not to apply the rule too enthusiastically on traditional postgres intervals; or worse, ones that mix sql standardish and postgres values For example dish=# select interval '-1 1:1 1 years'; interval -------------------------- 1 year -1days +01:01:00 (1 row) that 8.3 accepts. (or do we not care about those)? In some ways I wonder if we should have 2 totally separate parsing one for the SQL standard ones, and one for the postgres. That would avoid some other confusing inputs like: select interval '-00-01 1 years'; select interval '1-1 hours'; selectinterval '1:1 years'; select interval '1 hours 1-1 1 years' that are currently accepted.
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Tom Lane wrote: >> BTW, I just noticed that CVS HEAD has a bug in reading negative SQL-spec >> literals: > Perhaps the below patch fixes that? Actually I think it should be if (*field[i] == '-') as in the comparable case for fractional seconds just below. Will apply. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Yes, at first glance I think that approach is better; but we'd need > to make sure not to apply the rule too enthusiastically on traditional > postgres intervals; Well, of course we'd only apply it in SQL_STANDARD mode. The idea here is that intervalstyle helps us resolve an ambiguity about what the signs are, more or less independently of syntactic details. If you consider that the issue issql standard: leading sign applies to all fieldspostgres: each field is independently signed this applies perfectly well without any restrictions on syntax. > In some ways I wonder if we should have 2 totally separate parsing > one for the SQL standard ones, and one for the postgres. No, I think we want the style to be a hint for resolving ambiguous cases, not to cause complete failure if the input doesn't conform to the style. That's certainly how DateStyle has always worked. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
I wrote: > ... Consider > -1 1:00:00 flips the sign > - 1 1:00:00 doesn't flip the sign > -1 day 1:00:00 doesn't flip the sign > -2008-10 1:00:00 flips the sign > -2008-10 1 doesn't flip the sign > -2008 years 1:00:00 doesn't flip the sign > If the rule were that it never flipped the sign for non-SQL-spec input > then I think that'd be okay, but case 4 here puts the lie to that. > I'm also not entirely sure if case 2 is allowed by SQL spec or not, > but if it is then we've got a problem with that; and even if it isn't > it's awfully hard to explain why it's treated differently from case 1. Actually case 2 is a red herring --- I now see that ParseDateTime() collapses out the whitespace and makes it just like case 1. So never mind that. Case 4 is still bogus though. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Brendan Jurd wrote: >> The changes to the documentation all look good. I did notice one >> final typo that I think was introduced in the latest version. >> doc/src/sgml/datatype.sgml:2270 has "Nonstandardrd" instead of >> "Nonstandard". > Just checked in a fix to that one; and updated my website at > http://0ape.com/postgres_interval_patches/ > and pushed it to my (hopefully fixed now) git server. Applied with some revisions: I changed the rule for negating input fields in SQL_STANDARD style as we discussed, made IntervalStyle into an "enum" GUC, and did some pretty heavy editorialization on the docs changes. regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Chuck McDevitt
Date:
Doesn't ANSI standard interval syntax have the minus sign before the quotes? Select interval -'2008-10'; ??? > -----Original Message----- > From: pgsql-hackers-owner@postgresql.org [mailto:pgsql-hackers- > owner@postgresql.org] On Behalf Of Tom Lane > Sent: Saturday, November 08, 2008 11:39 AM > To: Ron Mayer > Cc: Brendan Jurd; Kevin Grittner; pgsql-hackers@postgresql.org > Subject: Re: [HACKERS] Patch for SQL-Standard Interval output and > decoupling DateStyle from IntervalStyle > > BTW, I just noticed that CVS HEAD has a bug in reading negative SQL- > spec > literals: > > regression=# select interval '-2008-10'; > interval > ---------------------- > -2008 years -10 mons > (1 row) > > regression=# select interval '-0000-10'; > interval > ---------- > 10 mons > (1 row) > > Surely the latter must mean -10 months. This is orthogonal to the > current patch ... > > regards, tom lane > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Tom Lane
Date:
Chuck McDevitt <cmcdevitt@greenplum.com> writes: > Doesn't ANSI standard interval syntax have the minus sign before the quotes? > Select interval -'2008-10'; They allow it either there or inside the quotes. We can't support outside-the-quotes unless we make INTERVAL a fully reserved word (and even then there are syntactic problems :-(). Putting the minus sign before INTERVAL works fine btw ... regards, tom lane
Re: Patch for SQL-Standard Interval output and decoupling DateStyle from IntervalStyle
From
Ron Mayer
Date:
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Brendan Jurd wrote: >>> ...I did notice one final ... >> Just checked in a fix to that one; and updated my website at >> http://0ape.com/postgres_interval_patches/ >> and pushed it to my (hopefully fixed now) git server. > > Applied with some revisions: I changed the rule for negating input > fields in SQL_STANDARD style as we discussed, made IntervalStyle into > an "enum" GUC, and did some pretty heavy editorialization on the docs > changes. Cool. Thanks! Brendan and anyone else looking at these, I've done an initial merge between the new CVS head and my other interval patches and pushed them to my website link mentioned above; but I probably still need to cleanup some of the docs merges. I'm a bit tied up today; so will probably cleanup the merge and study Tom's changes and post an update when the other patches are ready to continue reviewing, probably late tomorrow.
On Sat, Nov 8, 2008 at 2:19 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > > Hmmm... Certainly what I had in datatype.sgml was wrong, but I'm > now thinking 5.5.4.2.1 and 5.5.4.2.2 would be the most clear? > Sorry, I don't understand what you mean by "5.5.4.2.1". In the spec you linked to, clause 5 "Date and time format representations" doesn't have any numbered subsections at all. It's just a half-page saying, basically, that if applications want to interchange information about datetime formats, they can. Much like the ents, spec authors don't like to say anything unless it's worth taking a very long time to say. So, to the best of my knowledge, there is no 5.5.4.2.1. There is no 5.5. Originally I assumed that when you wrote 5.5.4.2.1, you meant 4.4.4.2.1. However, when I looked closer I noticed that this section is about a textual "representation" of the format, not about the format itself. Therefore I suggested 4.4.3.2, which does specify the format. Cheers, BJ
Brendan Jurd wrote: > On Sat, Nov 8, 2008 at 2:19 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: >> Hmmm... Certainly what I had in datatype.sgml was wrong, but I'm >> now thinking 5.5.4.2.1 and 5.5.4.2.2 would be the most clear? > > Sorry, I don't understand what you mean by "5.5.4.2.1". In the spec Ah! That 5.5.4.2.1 comes from apparently an old Oct 2000 draft version of the spec titled ISO/FDIS 8601. (For now you can see it here: http://0ape.com/postgres_interval_patches/ISO-FDIS-8601.pdf ) I'll fix all the links to point to the 2004 spec.
Ron Mayer wrote: > Ah! That 5.5.4.2.1 comes from apparently an old Oct 2000 > draft version of the spec titled ISO/FDIS 8601. (For now you can > see it here: http://0ape.com/postgres_interval_patches/ISO-FDIS-8601.pdf ) > > I'll fix all the links to point to the 2004 spec. I updated my web site[1] with the latest version of this patch. Main differences since last time * Merged with the IntervalStyle patch as it was checked into CVS. * Fixed references toconsistently refer to the same version of the ISO 8601 spec (ISO 8601:2004(E)) [1] http://0ape.com/postgres_interval_patches/ PS: I realize that this patch makes datetime.c a bit longer that it needs to be; and that some of the functions added in this patch can be used by the other interval styles as well. "patch 3" that can be found on the same HTML page does this refactoring.
On Tue, Nov 11, 2008 at 2:36 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > I updated my web site[1] with the latest version of this patch. I'm just testing this latest version out now. I get the expected result from 'P0001', but oddly enough if I specify only the year and month, it pukes: postgres=# select interval 'P0001-01'; ERROR: invalid input syntax for type interval: "P0001-01" LINE 1: select interval 'P0001-01'; I'm attaching a patch to clean up a few more code style issues and fix broken spec references within C code comments in datetime.c. Cheers, BJ
Attachment
On Tue, Nov 11, 2008 at 5:51 AM, R Mayer <pg_cert@cheapcomplexdevices.com> wrote: > Applied and pushed to the website http://0ape.com/postgres_interval_patches/ > This latest version works as expected and I don't detect any other issues with the code or documentation ... seems I've run out of things to gripe about! I'm ready to sign off on this patch now and move on to the final cleanup patch. I'll update the commitfest to show this one as "ready for committer". Cheers, BJ
"Brendan Jurd" <direvus@gmail.com> writes: > I'm ready to sign off on this patch now and move on to the final > cleanup patch. I'll update the commitfest to show this one as "ready > for committer". OK, I'll pick this one up now. regards, tom lane
Brendan Jurd wrote: > On Tue, Nov 11, 2008 at 2:36 AM, Ron Mayer > I get the expected result from 'P0001', but oddly enough if I specify > only the year and month, it pukes: > postgres=# select interval 'P0001-01'; Indeed. Thanks again. I've fixed this and added regression tests to check the handling of optional fields of the "alternative format" which my patch has been so very bad at handling. > I'm attaching a patch to clean up a few more code style issues and fix > broken spec references within C code comments in datetime.c. Applied and pushed to the website http://0ape.com/postgres_interval_patches/
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
"Brendan Jurd"
Date:
On Sat, Nov 1, 2008 at 3:42 PM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > # Patch 3: "cleanup.patch" > Fix rounding inconsistencies and refactor interval input/output code > Compile, testing and regression tests all checked out. I've picked up on a few code style issues, fixes attached. If I'm reading the patch correctly, it seems you've renamed two of the functions in datetime.c: * AdjustFractionalSeconds => AdjustFractSeconds * AdjustFractionalDays => AdjustFractDays To be frank, this doesn't really seem worthwhile. It only saves five characters in the name. What was your reason for renaming them? I *was* going to question the inconsistent use of a space between the pointer qualifier and the argument name, for example: static char * AddVerboseIntPart(char * cp, int value, char *units, bool * is_zero, bool *is_before) But then I noticed that there's a lot of this going on in datetime.c, some of it appears to predate your patches. So I guess cleaning this up in your function definitions would be a bit of a bolted-horse, barn-door affair. Unless you felt like cleaning it up throughout the file, it's probably not worth worrying about. There are some very large-scale changes to the regression tests. I'm finding it difficult to grok the nature of the changes from reading a diff. If possible, could you post some quick notes on the purpose/rationale of these changes? Cheers, BJ
Attachment
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Tom Lane
Date:
"Brendan Jurd" <direvus@gmail.com> writes: > I *was* going to question the inconsistent use of a space between the > pointer qualifier and the argument name, for example: > ... > But then I noticed that there's a lot of this going on in datetime.c, > some of it appears to predate your patches. Any inconsistency there is pg_indent's fault (caused by not knowing that some words are typedefs). There's no great value in messing with it manually, because pg_indent will set the spacing to suit itself anyway. regards, tom lane
R Mayer <pg_cert@cheapcomplexdevices.com> writes: > Applied and pushed to the website http://0ape.com/postgres_interval_patches/ I ran into an interesting failure case: regression=# select interval 'P-1Y-2M3DT-4H-5M-6'; interval -------------------P-1Y-2M3DT-10H-5M (1 row) This isn't the result I'd expect, and AFAICS the ISO spec does *not* allow any unit markers to be omitted in the format with designators. I think the problem is that the code will accept a value as being alternative format even when it's already read some format-with-designator fields. I propose adding a flag to remember that we've seen a field in the current part (date or time) and rejecting an apparent alternative-format input if the flag is set. regards, tom lane
R Mayer <pg_cert@cheapcomplexdevices.com> writes: > Applied and pushed to the website http://0ape.com/postgres_interval_patches/ Applied with nontrivial revisions --- I fear I probably broke your third patch again :-(. There were still a number of parsing bugs, and I also didn't like the lack of error checking around the strtod() call ... regards, tom lane
Interval code refactoring patch (Was: Re: Patch for ISO-8601-Interval Input and output.)
From
Ron Mayer
Date:
Tom Lane wrote: > ...failure case ... interval 'P-1Y-2M3DT-4H-5M-6'; > This isn't the result I'd expect, and AFAICS the ISO spec does *not* > allow any unit markers to be omitted in the format with designators. Yes, this is true. I see you already made the change. Tom Lane wrote: > Applied with nontrivial revisions --- I fear I probably broke your third > patch again :-(. No problem. It wasn't hard to update. Attached is an updated patch (as well as being updated on my website; but since it applies to HEAD it's as easy to get here). The bulk of the changes are in regression tests where rounding of fractional seconds was changed as discussed up-thread back in Sep. Seems I should also submit one more patch that merge the newest DecodeInterval, EncodeInterval and related functions into /ecpg/pgtypeslib/interval.c? And beyond that, there's still some eccentricities with the interval code (why's "interval '1 year 1 year'" ok but "interval '1 second 1 second'" not) but I don't know if I'd do more harm or good trying to look at those.
Attachment
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Ron Mayer
Date:
Brendan Jurd wrote: > On Sat, Nov 1, 2008 at 3:42 PM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: >> # Patch 3: "cleanup.patch" >> Fix rounding inconsistencies and refactor interval input/output code > > Compile, testing and regression tests all checked out. > I've picked up on a few code style issues, fixes attached. > > If I'm reading the patch correctly, it seems you've renamed two of the > functions in datetime.c: > * AdjustFractionalSeconds => AdjustFractSeconds > * AdjustFractionalDays => AdjustFractDays > To be frank, this doesn't really seem worthwhile. It only saves five > characters in the name. What was your reason for renaming them? Otherwise many lines were over 80 chars long. And it happened often enough I thought the shorter name was less ugly than splitting the arguments in many of the places where it's called. I'm happy either way, tho. > I *was* going to question the inconsistent use of a space between the > pointer qualifier and the argument name, for example: > > static char * > AddVerboseIntPart(char * cp, int value, char *units, > bool * is_zero, bool *is_before) > > But then I noticed that there's a lot of this going on in datetime.c, > some of it appears to predate your patches. So I guess cleaning this > up in your function definitions would be a bit of a bolted-horse, > barn-door affair. Unless you felt like cleaning it up throughout the > file, it's probably not worth worrying about. I don't mindn cleaning it up; but someone could point me to which direction. > There are some very large-scale changes to the regression tests. I'm > finding it difficult to grok the nature of the changes from reading a > diff. If possible, could you post some quick notes on the > purpose/rationale of these changes? Previously, much (but IIRC not quite all) of the interval output stuff rounded to the hundredths place regardless of how many significant digits there were. So, for example, the interval "1.699" seconds would usually appear as "1.70" for most but not all combinations of DateStyle and HAVE_INT64_TIMESTAMP. After a few discussions on the mailing list I think people decided to simply show the digits that were http://archives.postgresql.org/pgsql-hackers/2008-09/msg00998.php
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
"Brendan Jurd"
Date:
On Wed, Nov 12, 2008 at 5:32 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > Brendan Jurd wrote: >> * AdjustFractionalSeconds => AdjustFractSeconds >> * AdjustFractionalDays => AdjustFractDays > > Otherwise many lines were over 80 chars long. > And it happened often enough I thought the shorter name > was less ugly than splitting the arguments in many of the > places where it's called. Fair enough. I don't have a strong opinion about that. >> I *was* going to question the inconsistent use of a space between the >> pointer qualifier and the argument name, for example: >> > I don't mindn cleaning it up; but someone could point me to which direction. > Per Tom's comments, the space is sometimes inserted by pg_indent, because it doesn't know all of the typedefs. So there's no point trying to clean it up at the moment; next time pg_indent is run over the code, it will just insert those spaces again. >> There are some very large-scale changes to the regression tests. ... > > Previously, much (but IIRC not quite all) of the interval output stuff > rounded to the hundredths place regardless of how many significant digits > there were. I understood about the rounding issues. I was a bit confused by the fact that the patch shows differences for an entire table of results from the horology test, but I've just now realised that the whole table is different because changing the output precision in some of the rows has altered the column width. Makes me wonder whether an unaligned psql output format would be a better choice for the regression tests. It would certainly make for clearer diffs. But that's a tangent for another email. I don't have any further gripes regarding this patch, apart from the code style stuff I sent through in my previous post. Did you have any response to those? Cheers, BJ
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Ron Mayer
Date:
Brendan Jurd wrote: > On Wed, Nov 12, 2008 at 5:32 AM, Ron Mayer > <rm_pg@cheapcomplexdevices.com> wrote: >> Brendan Jurd wrote: >>> * AdjustFractionalSeconds => AdjustFractSeconds >>> * AdjustFractionalDays => AdjustFractDays >> Otherwise many lines were over 80 chars long. >> And it happened often enough I thought the shorter name >> was less ugly than splitting the arguments in many of the >> places where it's called. > > Fair enough. I don't have a strong opinion about that. Cool. If anyone does have an opinion on that, let me know and I can change it whichever way people prefer. >>> There are some very large-scale changes to the regression tests. ... >> Previously, much (but IIRC not quite all) of the interval output stuff >> rounded to the hundredths place regardless of how many significant digits >> there were. > > I understood about the rounding issues. I was a bit confused by the > fact that the patch shows differences for an entire table of results > from the horology test, but I've just now realised that the whole > table is different because changing the output precision in some of > the rows has altered the column width. > > Makes me wonder whether an unaligned psql output format would be a > better choice for the regression tests. It would certainly make for > clearer diffs. But that's a tangent for another email. Yeah. And that's what made the patch so big I had to gzip it. > I don't have any further gripes regarding this patch, apart from the > code style stuff I sent through in my previous post. Did you have any > response to those? Yup - you were right again. Applied them and updated the website and attaching the patch. I wonder what's the best way for myself to get out of those habits in the future? Some lint flags or similar?
Attachment
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
"Brendan Jurd"
Date:
On Wed, Nov 12, 2008 at 6:13 AM, Ron Mayer <rm_pg@cheapcomplexdevices.com> wrote: > Brendan Jurd wrote: >> I don't have any further gripes regarding this patch, apart from the >> code style stuff I sent through in my previous post. Did you have any >> response to those? > > Yup - you were right again. > Applied them and updated the website and attaching the patch. > Cool. In that case I'm ready to kick this up to a committer. > I wonder what's the best way for myself to get out of those habits > in the future? Some lint flags or similar? Can't help you there I'm afraid. vi takes care of much of the indentation and such, but my patches have had their fair share of code and error message style problems too. On the bright side I've found that switching between code conventions does get easier with practice.Currently my strategy consists largely of "read thepatch over several times before submitting it". Even so, mistakes sometimes slip through. Cheers, BJ
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Tom Lane
Date:
"Brendan Jurd" <direvus@gmail.com> writes: > On Wed, Nov 12, 2008 at 5:32 AM, Ron Mayer > <rm_pg@cheapcomplexdevices.com> wrote: >> Brendan Jurd wrote: >>> There are some very large-scale changes to the regression tests. ... >> >> Previously, much (but IIRC not quite all) of the interval output stuff >> rounded to the hundredths place regardless of how many significant digits >> there were. > I understood about the rounding issues. I was a bit confused by the > fact that the patch shows differences for an entire table of results > from the horology test, but I've just now realised that the whole > table is different because changing the output precision in some of > the rows has altered the column width. diff --ignore-spaces is the best way to analyze that type of situation. (I believe this is what pg_regress does by default.) regards, tom lane
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Brendan Jurd wrote: >> I don't have any further gripes regarding this patch, apart from the >> code style stuff I sent through in my previous post. Did you have any >> response to those? > Yup - you were right again. > Applied them and updated the website and attaching the patch. Applied with another round of mostly-stylistic revisions, plus a little extra work to factor out some more code duplication (around strtod calls, which were insufficiently error-checked too). There was one part I left out because it worried me: *************** *** 2980,3010 **** switch (type) { case DTK_MICROSEC: ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint(val + fval); ! #else ! *fsec += (val + fval) * 1e-6; ! #endif tmask = DTK_M(MICROSECOND); break; case DTK_MILLISEC: ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint((val + fval) * 1000); ! #else ! *fsec += (val + fval) * 1e-3; ! #endif tmask = DTK_M(MILLISECOND); break; case DTK_SECOND: tm->tm_sec += val; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint(fval * 1000000); ! #else ! *fsec += fval; ! #endif ! /* * If any subseconds were specified, consider this * microsecond and millisecond input as well. --- 2897,2914 ---- switch (type) { case DTK_MICROSEC: ! AdjustFractSeconds((val + fval) * 1e-6, tm, fsec, 1); tmask = DTK_M(MICROSECOND); break; case DTK_MILLISEC: ! AdjustFractSeconds((val + fval) * 1e-3, tm, fsec, 1); tmask = DTK_M(MILLISECOND); break; case DTK_SECOND: tm->tm_sec+= val; ! AdjustFractSeconds(fval, tm, fsec, 1); /* * Ifany subseconds were specified, consider this * microsecond and millisecond input as well. The original INT64 coding here is exact (at least for the common case where fval is zero) but I'm not convinced that your revision can't suffer from roundoff error. regards, tom lane
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Ron Mayer
Date:
Tom Lane wrote: > The original INT64 coding here is exact (at least for the common case > where fval is zero) but I'm not convinced that your revision can't > suffer from roundoff error. Good point. I'll study this tonight; and either try to make a patch that'll be exact where fval's zero or try to come up with convincing reasons that it's harmless. Once this settles I suppose I should post a ECPG patch that's based off of these Decode/Encode interval functions too?
Re: Re: Updated interval patches (SQL std output, ISO8601 intervals, and interval rounding)
From
Tom Lane
Date:
Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: > Once this settles I suppose I should post a ECPG patch that's based > off of these Decode/Encode interval functions too? Yeah, if you want. I think you'll find that the datetime code has drifted far enough since ecpg forked it that you'll be looking at a pretty huge diff :-( regards, tom lane
Tom Lane wrote: > Ron Mayer <rm_pg@cheapcomplexdevices.com> writes: >> Once this settles I suppose I should post a ECPG patch that's based >> off of these Decode/Encode interval functions too? > > Yeah, if you want. I think you'll find that the datetime code has > drifted far enough since ecpg forked it that you'll be looking at a > pretty huge diff :-( Merging of the interval style into ecpg attached. I blindly copy&pasted code from src/backend/utils/adt/datetime.c into src/interfaces/ecpg/pgtypeslib/interval.c and made the minimal changes (pg_tm -> tm; adding constants; etc) to make the regression tests pass; and mentioned that in the comments. I know little enough about ecpg that I can't really tell if these changes are for the better or worse. One thing in the patch that's probably a bug is that the constants in src/include/utils/dt.h and src/include/utils/datetime.h under the section "Fields for time decoding" seem not to match, so when I copied some constants from datetime.h to dt.h to make it compile the values I copied are probably wrong. Unfortunately I know little about ecpg or the history of dt.h to know what the right values should be.
Attachment
On Wed, Nov 12, 2008 at 02:28:56PM -0800, Ron Mayer wrote: > Merging of the interval style into ecpg attached. Thanks for caring about the ecpg changes too. > I know little enough about ecpg that I can't really tell if these changes > are for the better or worse. The closer pgtypeslib is to the backend the better. > One thing in the patch that's probably a bug is that the > constants in src/include/utils/dt.h and src/include/utils/datetime.h > under the section "Fields for time decoding" seem not to match, so Assuming you mean src/interfaces/ecpg/pgtypeslib/dt.h. The numbers should match IMO. Also one files seems to be missing, there are no changes to test/expected/pgtypeslib-dt_test.c in the patch, but when changing dt_test.pgc this file should be changed too. Could you add this to your work too? Michael -- Michael Meskes Michael at Fam-Meskes dot De, Michael at Meskes dot (De|Com|Net|Org) Michael at BorussiaFan dot De, Meskes at (Debian|Postgresql) dot Org ICQ: 179140304, AIM/Yahoo: michaelmeskes, Jabber: meskes@jabber.org Go VfL Borussia! Go SF 49ers! Use Debian GNU/Linux! Use PostgreSQL!
Michael Meskes wrote: > On Wed, Nov 12, 2008 at 02:28:56PM -0800, Ron Mayer wrote: >> Merging of the interval style into ecpg attached. > Thanks for caring about the ecpg changes too. Thanks for the comments. Updated the patch. >> I know little enough about ecpg that I can't really tell if these changes >> are for the better or worse. > The closer pgtypeslib is to the backend the better. > >> One thing in the patch that's probably a bug is that the >> constants in src/include/utils/dt.h and src/include/utils/datetime.h >> under the section "Fields for time decoding" seem not to match, so > Assuming you mean src/interfaces/ecpg/pgtypeslib/dt.h. The numbers should match IMO. Ok. I copy&pasted them from datetime.h to dt.h. This changes a number of values that were like #define DOY 13 #define DOW 14 to #define DOY 15 #define DOW 16 and I'm not quite sure what the consequences of that might be, but the regression tests still pass. > Also one files seems to be missing, there are no changes to > test/expected/pgtypeslib-dt_test.c in the patch, but when changing dt_test.pgc > this file should be changed too. > > Could you add this to your work too? Got it. Patch attached. *** a/src/interfaces/ecpg/pgtypeslib/dt.h --- b/src/interfaces/ecpg/pgtypeslib/dt.h *************** *** 25,30 **** typedef double fsec_t; --- 25,46 ---- #define USE_SQL_DATES 2 #define USE_GERMAN_DATES 3 + #define INTSTYLE_POSTGRES 0 + #define INTSTYLE_POSTGRES_VERBOSE 1 + #define INTSTYLE_SQL_STANDARD 2 + #define INTSTYLE_ISO_8601 3 + + #define INTERVAL_FULL_RANGE (0x7FFF) + #define INTERVAL_MASK(b) (1 << (b)) + #define MAX_INTERVAL_PRECISION 6 + + #define DTERR_BAD_FORMAT (-1) + #define DTERR_FIELD_OVERFLOW (-2) + #define DTERR_MD_FIELD_OVERFLOW (-3) /* triggers hint about DateStyle */ + #define DTERR_INTERVAL_OVERFLOW (-4) + #define DTERR_TZDISP_OVERFLOW (-5) + + #define DAGO "ago" #define EPOCH "epoch" #define INVALID "invalid" *************** *** 77,82 **** typedef double fsec_t; --- 93,101 ---- * Furthermore, the values for YEAR, MONTH, DAY, HOUR, MINUTE, SECOND * must be in the range 0..14 so that the associated bitmasks can fit * into the left half of an INTERVAL's typmod value. + * + * Copy&pasted these values from src/include/utils/datetime.h + * 2008-11-20, changing a number of their values. */ #define RESERV 0 *************** *** 92,111 **** typedef double fsec_t; #define HOUR 10 #define MINUTE 11 #define SECOND 12 ! #define DOY 13 ! #define DOW 14 ! #define UNITS 15 ! #define ADBC 16 /* these are only for relative dates */ ! #define AGO 17 ! #define ABS_BEFORE 18 ! #define ABS_AFTER 19 /* generic fields to help with parsing */ ! #define ISODATE 20 ! #define ISOTIME 21 /* reserved for unrecognized string values */ #define UNKNOWN_FIELD 31 /* * Token field definitions for time parsing and decoding. * These need to fit into the datetkn table type. --- 111,133 ---- #define HOUR 10 #define MINUTE 11 #define SECOND 12 ! #define MILLISECOND 13 ! #define MICROSECOND 14 ! #define DOY 15 ! #define DOW 16 ! #define UNITS 17 ! #define ADBC 18 /* these are only for relative dates */ ! #define AGO 19 ! #define ABS_BEFORE 20 ! #define ABS_AFTER 21 /* generic fields to help with parsing */ ! #define ISODATE 22 ! #define ISOTIME 23 /* reserved for unrecognized string values */ #define UNKNOWN_FIELD 31 + /* * Token field definitions for time parsing and decoding. * These need to fit into the datetkn table type. *************** *** 164,176 **** typedef double fsec_t; /* * Bit mask definitions for time parsing. */ ! #define DTK_M(t) (0x01 << (t)) ! #define DTK_DATE_M (DTK_M(YEAR) | DTK_M(MONTH) | DTK_M(DAY)) #define DTK_TIME_M (DTK_M(HOUR) | DTK_M(MINUTE) | DTK_M(SECOND)) ! #define MAXDATELEN 51 /* maximum possible length of an input date * string (not counting tr. null) */ #define MAXDATEFIELDS 25 /* maximum possible number of fields in a date * string */ --- 186,198 ---- /* * Bit mask definitions for time parsing. */ ! /* Copy&pasted these values from src/include/utils/datetime.h */ #define DTK_M(t) (0x01 << (t)) ! #define DTK_ALL_SECS_M (DTK_M(SECOND) | DTK_M(MILLISECOND) | DTK_M(MICROSECOND)) #define DTK_DATE_M (DTK_M(YEAR) | DTK_M(MONTH) | DTK_M(DAY)) #define DTK_TIME_M (DTK_M(HOUR) | DTK_M(MINUTE) | DTK_M(SECOND)) ! #define MAXDATELEN 63 /* maximum possible length of an input date * string (not counting tr. null) */ #define MAXDATEFIELDS 25 /* maximum possible number of fields in a date * string */ *** a/src/interfaces/ecpg/pgtypeslib/interval.c --- b/src/interfaces/ecpg/pgtypeslib/interval.c *************** *** 13,51 **** #include "pgtypes_error.h" #include "pgtypes_interval.h" ! /* DecodeInterval() ! * Interpret previously parsed fields for general time interval. ! * Return 0 if decoded and -1 if problems. * ! * Allow "date" field DTK_DATE since this could be just ! * an unsigned floating point number. - thomas 1997-11-16 * ! * Allow ISO-style time span, with implicit units on number of days ! * preceding an hh:mm:ss field. - thomas 1998-04-30 */ int ! DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fsec_t *fsec) { ! int is_before = FALSE; ! char *cp; int fmask = 0, tmask, type; int i; int val; double fval; *dtype = DTK_DELTA; - type = IGNORE_DTF; ! tm->tm_year = 0; ! tm->tm_mon = 0; ! tm->tm_mday = 0; ! tm->tm_hour = 0; ! tm->tm_min = 0; ! tm->tm_sec = 0; ! *fsec = 0; /* read through list backwards to pick up units before values */ for (i = nf - 1; i >= 0; i--) --- 13,359 ---- #include "pgtypes_error.h" #include "pgtypes_interval.h" ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static int ! strtoi(const char *nptr, char **endptr, int base) ! { ! long val; ! ! val = strtol(nptr, endptr, base); ! #ifdef HAVE_LONG_INT_64 ! if (val != (long) ((int32) val)) ! errno = ERANGE; ! #endif ! return (int) val; ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c ! * and changesd struct pg_tm to struct tm ! */ ! static void ! AdjustFractSeconds(double frac, struct /*pg_*/tm * tm, fsec_t *fsec, int scale) ! { ! int sec; ! ! if (frac == 0) ! return; ! frac *= scale; ! sec = (int) frac; ! tm->tm_sec += sec; ! frac -= sec; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint(frac * 1000000); ! #else ! *fsec += frac; ! #endif ! } ! ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c ! * and changesd struct pg_tm to struct tm ! */ ! static void ! AdjustFractDays(double frac, struct /*pg_*/tm * tm, fsec_t *fsec, int scale) ! { ! int extra_days; ! ! if (frac == 0) ! return; ! frac *= scale; ! extra_days = (int) frac; ! tm->tm_mday += extra_days; ! frac -= extra_days; ! AdjustFractSeconds(frac, tm, fsec, SECS_PER_DAY); ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static int ! ParseISO8601Number(char *str, char **endptr, int *ipart, double *fpart) ! { ! double val; ! ! if (!(isdigit((unsigned char) *str) || *str == '-' || *str == '.')) ! return DTERR_BAD_FORMAT; ! errno = 0; ! val = strtod(str, endptr); ! /* did we not see anything that looks like a double? */ ! if (*endptr == str || errno != 0) ! return DTERR_BAD_FORMAT; ! /* watch out for overflow */ ! if (val < INT_MIN || val > INT_MAX) ! return DTERR_FIELD_OVERFLOW; ! /* be very sure we truncate towards zero (cf dtrunc()) */ ! if (val >= 0) ! *ipart = (int) floor(val); ! else ! *ipart = (int) -floor(-val); ! *fpart = val - *ipart; ! return 0; ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static int ! ISO8601IntegerWidth(char *fieldstart) ! { ! /* We might have had a leading '-' */ ! if (*fieldstart == '-') ! fieldstart++; ! return strspn(fieldstart, "0123456789"); ! } ! ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c ! * and changesd struct pg_tm to struct tm ! */ ! static inline void ! ClearPgTm(struct /*pg_*/tm *tm, fsec_t *fsec) ! { ! tm->tm_year = 0; ! tm->tm_mon = 0; ! tm->tm_mday = 0; ! tm->tm_hour = 0; ! tm->tm_min = 0; ! tm->tm_sec = 0; ! *fsec = 0; ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c ! * ! * * changesd struct pg_tm to struct tm ! * ! * * Made the function static ! */ ! static int ! DecodeISO8601Interval(char *str, ! int *dtype, struct /*pg_*/tm * tm, fsec_t *fsec) ! { ! bool datepart = true; ! bool havefield = false; ! ! *dtype = DTK_DELTA; ! ClearPgTm(tm, fsec); ! ! if (strlen(str) < 2 || str[0] != 'P') ! return DTERR_BAD_FORMAT; ! ! str++; ! while (*str) ! { ! char *fieldstart; ! int val; ! double fval; ! char unit; ! int dterr; ! ! if (*str == 'T') /* T indicates the beginning of the time part */ ! { ! datepart = false; ! havefield = false; ! str++; ! continue; ! } ! ! fieldstart = str; ! dterr = ParseISO8601Number(str, &str, &val, &fval); ! if (dterr) ! return dterr; ! ! /* ! * Note: we could step off the end of the string here. Code below ! * *must* exit the loop if unit == '\0'. ! */ ! unit = *str++; ! ! if (datepart) ! { ! switch (unit) /* before T: Y M W D */ ! { ! case 'Y': ! tm->tm_year += val; ! tm->tm_mon += (fval * 12); ! break; ! case 'M': ! tm->tm_mon += val; ! AdjustFractDays(fval, tm, fsec, DAYS_PER_MONTH); ! break; ! case 'W': ! tm->tm_mday += val * 7; ! AdjustFractDays(fval, tm, fsec, 7); ! break; ! case 'D': ! tm->tm_mday += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_DAY); ! break; ! case 'T': /* ISO 8601 4.4.3.3 Alternative Format / Basic */ ! case '\0': ! if (ISO8601IntegerWidth(fieldstart) == 8 && !havefield) ! { ! tm->tm_year += val / 10000; ! tm->tm_mon += (val / 100) % 100; ! tm->tm_mday += val % 100; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_DAY); ! if (unit == '\0') ! return 0; ! datepart = false; ! havefield = false; ! continue; ! } ! /* Else fall through to extended alternative format */ ! case '-': /* ISO 8601 4.4.3.3 Alternative Format, Extended */ ! if (havefield) ! return DTERR_BAD_FORMAT; ! ! tm->tm_year += val; ! tm->tm_mon += (fval * 12); ! if (unit == '\0') ! return 0; ! if (unit == 'T') ! { ! datepart = false; ! havefield = false; ! continue; ! } ! ! dterr = ParseISO8601Number(str, &str, &val, &fval); ! if (dterr) ! return dterr; ! tm->tm_mon += val; ! AdjustFractDays(fval, tm, fsec, DAYS_PER_MONTH); ! if (*str == '\0') ! return 0; ! if (*str == 'T') ! { ! datepart = false; ! havefield = false; ! continue; ! } ! if (*str != '-') ! return DTERR_BAD_FORMAT; ! str++; ! ! dterr = ParseISO8601Number(str, &str, &val, &fval); ! if (dterr) ! return dterr; ! tm->tm_mday += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_DAY); ! if (*str == '\0') ! return 0; ! if (*str == 'T') ! { ! datepart = false; ! havefield = false; ! continue; ! } ! return DTERR_BAD_FORMAT; ! default: ! /* not a valid date unit suffix */ ! return DTERR_BAD_FORMAT; ! } ! } ! else ! { ! switch (unit) /* after T: H M S */ ! { ! case 'H': ! tm->tm_hour += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_HOUR); ! break; ! case 'M': ! tm->tm_min += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_MINUTE); ! break; ! case 'S': ! tm->tm_sec += val; ! AdjustFractSeconds(fval, tm, fsec, 1); ! break; ! case '\0': /* ISO 8601 4.4.3.3 Alternative Format */ ! if (ISO8601IntegerWidth(fieldstart) == 6 && !havefield) ! { ! tm->tm_hour += val / 10000; ! tm->tm_min += (val / 100) % 100; ! tm->tm_sec += val % 100; ! AdjustFractSeconds(fval, tm, fsec, 1); ! return 0; ! } ! /* Else fall through to extended alternative format */ ! case ':': /* ISO 8601 4.4.3.3 Alternative Format, Extended */ ! if (havefield) ! return DTERR_BAD_FORMAT; ! ! tm->tm_hour += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_HOUR); ! if (unit == '\0') ! return 0; ! ! dterr = ParseISO8601Number(str, &str, &val, &fval); ! if (dterr) ! return dterr; ! tm->tm_min += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_MINUTE); ! if (*str == '\0') ! return 0; ! if (*str != ':') ! return DTERR_BAD_FORMAT; ! str++; ! ! dterr = ParseISO8601Number(str, &str, &val, &fval); ! if (dterr) ! return dterr; ! tm->tm_sec += val; ! AdjustFractSeconds(fval, tm, fsec, 1); ! if (*str == '\0') ! return 0; ! return DTERR_BAD_FORMAT; ! ! default: ! /* not a valid time unit suffix */ ! return DTERR_BAD_FORMAT; ! } ! } ! ! havefield = true; ! } ! ! return 0; ! } ! ! ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c ! * with 3 exceptions ! * ! * * changesd struct pg_tm to struct tm ! * ! * * ECPG code called this without a 'range' parameter ! * removed 'int range' from the argument list and ! * places where DecodeTime is called; and added ! * int range = INTERVAL_FULL_RANGE; * ! * * ECPG semes not to have a global IntervalStyle ! * so added ! * int IntervalStyle = INTSTYLE_POSTGRES; * ! * * Assert wasn't available so removed it. */ int ! DecodeInterval(char **field, int *ftype, int nf, /*int range,*/ ! int *dtype, struct /*pg_*/tm * tm, fsec_t *fsec) { ! int IntervalStyle = INTSTYLE_POSTGRES_VERBOSE; ! int range = INTERVAL_FULL_RANGE; ! bool is_before = FALSE; char *cp; int fmask = 0, tmask, type; int i; + int dterr; int val; double fval; *dtype = DTK_DELTA; type = IGNORE_DTF; ! ClearPgTm(tm,fsec); /* read through list backwards to pick up units before values */ for (i = nf - 1; i >= 0; i--) *************** *** 53,60 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse switch (ftype[i]) { case DTK_TIME: ! if (DecodeTime(field[i], fmask, &tmask, tm, fsec) != 0) ! return -1; type = DTK_DAY; break; --- 361,370 ---- switch (ftype[i]) { case DTK_TIME: ! dterr = DecodeTime(field[i], fmask, /* range, */ ! &tmask, tm, fsec); ! if (dterr) ! return dterr; type = DTK_DAY; break; *************** *** 62,79 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse /* * Timezone is a token with a leading sign character and ! * otherwise the same as a non-signed time field */ /* ! * A single signed number ends up here, but will be rejected ! * by DecodeTime(). So, work this out to drop through to ! * DTK_NUMBER, which *can* tolerate this. */ ! cp = field[i] + 1; ! while (*cp != '\0' && *cp != ':' && *cp != '.') ! cp++; ! if (*cp == ':' && DecodeTime((field[i] + 1), fmask, &tmask, tm, fsec) == 0) { if (*field[i] == '-') { --- 372,390 ---- /* * Timezone is a token with a leading sign character and ! * at least one digit; there could be ':', '.', '-' ! * embedded in it as well. */ + /* Assert(*field[i] == '-' || *field[i] == '+'); */ /* ! * Try for hh:mm or hh:mm:ss. If not, fall through to ! * DTK_NUMBER case, which can handle signed float numbers ! * and signed year-month values. */ ! if (strchr(field[i] + 1, ':') != NULL && ! DecodeTime(field[i] + 1, fmask, /* INTERVAL_FULL_RANGE, */ ! &tmask, tm, fsec) == 0) { if (*field[i] == '-') { *************** *** 93,139 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse tmask = DTK_M(TZ); break; } ! else if (type == IGNORE_DTF) { ! if (*cp == '.') { ! /* ! * Got a decimal point? Then assume some sort of ! * seconds specification ! */ ! type = DTK_SECOND; ! } ! else if (*cp == '\0') ! { ! /* ! * Only a signed integer? Then must assume a ! * timezone-like usage ! */ ! type = DTK_HOUR; } } - /* DROP THROUGH */ ! case DTK_DATE: ! case DTK_NUMBER: ! val = strtol(field[i], &cp, 10); ! if (type == IGNORE_DTF) ! type = DTK_SECOND; ! if (*cp == '.') { fval = strtod(cp, &cp); ! if (*cp != '\0') ! return -1; ! if (val < 0) fval = -fval; } else if (*cp == '\0') fval = 0; else ! return -1; tmask = 0; /* DTK_M(type); */ --- 404,484 ---- tmask = DTK_M(TZ); break; } ! /* FALL THROUGH */ ! ! case DTK_DATE: ! case DTK_NUMBER: ! if (type == IGNORE_DTF) { ! /* use typmod to decide what rightmost field is */ ! switch (range) { ! case INTERVAL_MASK(YEAR): ! type = DTK_YEAR; ! break; ! case INTERVAL_MASK(MONTH): ! case INTERVAL_MASK(YEAR) | INTERVAL_MASK(MONTH): ! type = DTK_MONTH; ! break; ! case INTERVAL_MASK(DAY): ! type = DTK_DAY; ! break; ! case INTERVAL_MASK(HOUR): ! case INTERVAL_MASK(DAY) | INTERVAL_MASK(HOUR): ! case INTERVAL_MASK(DAY) | INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE): ! case INTERVAL_MASK(DAY) | INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND): ! type = DTK_HOUR; ! break; ! case INTERVAL_MASK(MINUTE): ! case INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE): ! type = DTK_MINUTE; ! break; ! case INTERVAL_MASK(SECOND): ! case INTERVAL_MASK(HOUR) | INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND): ! case INTERVAL_MASK(MINUTE) | INTERVAL_MASK(SECOND): ! type = DTK_SECOND; ! break; ! default: ! type = DTK_SECOND; ! break; } } ! errno = 0; ! val = strtoi(field[i], &cp, 10); ! if (errno == ERANGE) ! return DTERR_FIELD_OVERFLOW; ! if (*cp == '-') ! { ! /* SQL "years-months" syntax */ ! int val2; ! val2 = strtoi(cp + 1, &cp, 10); ! if (errno == ERANGE || val2 < 0 || val2 >= MONTHS_PER_YEAR) ! return DTERR_FIELD_OVERFLOW; ! if (*cp != '\0') ! return DTERR_BAD_FORMAT; ! type = DTK_MONTH; ! if (*field[i] == '-') ! val2 = -val2; ! val = val * MONTHS_PER_YEAR + val2; ! fval = 0; ! } ! else if (*cp == '.') { + errno = 0; fval = strtod(cp, &cp); ! if (*cp != '\0' || errno != 0) ! return DTERR_BAD_FORMAT; ! if (*field[i] == '-') fval = -fval; } else if (*cp == '\0') fval = 0; else ! return DTERR_BAD_FORMAT; tmask = 0; /* DTK_M(type); */ *************** *** 141,275 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse { case DTK_MICROSEC: #ifdef HAVE_INT64_TIMESTAMP ! *fsec += val + fval; #else *fsec += (val + fval) * 1e-6; #endif break; case DTK_MILLISEC: #ifdef HAVE_INT64_TIMESTAMP ! *fsec += (val + fval) * 1000; #else *fsec += (val + fval) * 1e-3; #endif break; case DTK_SECOND: tm->tm_sec += val; #ifdef HAVE_INT64_TIMESTAMP ! *fsec += fval * 1000000; #else *fsec += fval; #endif ! tmask = DTK_M(SECOND); break; case DTK_MINUTE: tm->tm_min += val; ! if (fval != 0) ! { ! int sec; ! ! fval *= SECS_PER_MINUTE; ! sec = fval; ! tm->tm_sec += sec; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += ((fval - sec) * 1000000); ! #else ! *fsec += fval - sec; ! #endif ! } tmask = DTK_M(MINUTE); break; case DTK_HOUR: tm->tm_hour += val; ! if (fval != 0) ! { ! int sec; ! ! fval *= SECS_PER_HOUR; ! sec = fval; ! tm->tm_sec += sec; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += (fval - sec) * 1000000; ! #else ! *fsec += fval - sec; ! #endif ! } tmask = DTK_M(HOUR); break; case DTK_DAY: tm->tm_mday += val; ! if (fval != 0) ! { ! int sec; ! ! fval *= SECS_PER_DAY; ! sec = fval; ! tm->tm_sec += sec; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += (fval - sec) * 1000000; ! #else ! *fsec += fval - sec; ! #endif ! } tmask = (fmask & DTK_M(DAY)) ? 0 : DTK_M(DAY); break; case DTK_WEEK: tm->tm_mday += val * 7; ! if (fval != 0) ! { ! int extra_days; ! ! fval *= 7; ! extra_days = (int32) fval; ! tm->tm_mday += extra_days; ! fval -= extra_days; ! if (fval != 0) ! { ! int sec; ! ! fval *= SECS_PER_DAY; ! sec = fval; ! tm->tm_sec += sec; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += (fval - sec) * 1000000; ! #else ! *fsec += fval - sec; ! #endif ! } ! } tmask = (fmask & DTK_M(DAY)) ? 0 : DTK_M(DAY); break; case DTK_MONTH: tm->tm_mon += val; ! if (fval != 0) ! { ! int day; ! ! fval *= DAYS_PER_MONTH; ! day = fval; ! tm->tm_mday += day; ! fval -= day; ! if (fval != 0) ! { ! int sec; ! ! fval *= SECS_PER_DAY; ! sec = fval; ! tm->tm_sec += sec; ! #ifdef HAVE_INT64_TIMESTAMP ! *fsec += (fval - sec) * 1000000; ! #else ! *fsec += fval - sec; ! #endif ! } ! } tmask = DTK_M(MONTH); break; --- 486,553 ---- { case DTK_MICROSEC: #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint(val + fval); #else *fsec += (val + fval) * 1e-6; #endif + tmask = DTK_M(MICROSECOND); break; case DTK_MILLISEC: #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint((val + fval) * 1000); #else *fsec += (val + fval) * 1e-3; #endif + tmask = DTK_M(MILLISECOND); break; case DTK_SECOND: tm->tm_sec += val; #ifdef HAVE_INT64_TIMESTAMP ! *fsec += rint(fval * 1000000); #else *fsec += fval; #endif ! ! /* ! * If any subseconds were specified, consider this ! * microsecond and millisecond input as well. ! */ ! if (fval == 0) ! tmask = DTK_M(SECOND); ! else ! tmask = DTK_ALL_SECS_M; break; case DTK_MINUTE: tm->tm_min += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_MINUTE); tmask = DTK_M(MINUTE); break; case DTK_HOUR: tm->tm_hour += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_HOUR); tmask = DTK_M(HOUR); + type = DTK_DAY; break; case DTK_DAY: tm->tm_mday += val; ! AdjustFractSeconds(fval, tm, fsec, SECS_PER_DAY); tmask = (fmask & DTK_M(DAY)) ? 0 : DTK_M(DAY); break; case DTK_WEEK: tm->tm_mday += val * 7; ! AdjustFractDays(fval, tm, fsec, 7); tmask = (fmask & DTK_M(DAY)) ? 0 : DTK_M(DAY); break; case DTK_MONTH: tm->tm_mon += val; ! AdjustFractDays(fval, tm, fsec, DAYS_PER_MONTH); tmask = DTK_M(MONTH); break; *************** *** 302,308 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse break; default: ! return -1; } break; --- 580,586 ---- break; default: ! return DTERR_BAD_FORMAT; } break; *************** *** 330,348 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse break; default: ! return -1; } break; default: ! return -1; } if (tmask & fmask) ! return -1; fmask |= tmask; } if (*fsec != 0) { int sec; --- 608,631 ---- break; default: ! return DTERR_BAD_FORMAT; } break; default: ! return DTERR_BAD_FORMAT; } if (tmask & fmask) ! return DTERR_BAD_FORMAT; fmask |= tmask; } + /* ensure that at least one time field has been found */ + if (fmask == 0) + return DTERR_BAD_FORMAT; + + /* ensure fractional seconds are fractional */ if (*fsec != 0) { int sec; *************** *** 356,605 **** DecodeInterval(char **field, int *ftype, int nf, int *dtype, struct tm * tm, fse tm->tm_sec += sec; } if (is_before) { *fsec = -(*fsec); ! tm->tm_sec = -(tm->tm_sec); ! tm->tm_min = -(tm->tm_min); ! tm->tm_hour = -(tm->tm_hour); ! tm->tm_mday = -(tm->tm_mday); ! tm->tm_mon = -(tm->tm_mon); ! tm->tm_year = -(tm->tm_year); } ! /* ensure that at least one time field has been found */ ! return (fmask != 0) ? 0 : -1; ! } /* DecodeInterval() */ ! /* EncodeInterval() ! * Interpret time structure as a delta time and convert to string. ! * ! * Support "traditional Postgres" and ISO-8601 styles. ! * Actually, afaik ISO does not address time interval formatting, ! * but this looks similar to the spec for absolute date/time. ! * - thomas 1998-04-30 */ int ! EncodeInterval(struct tm * tm, fsec_t fsec, int style, char *str) { ! int is_before = FALSE; ! int is_nonzero = FALSE; char *cp = str; /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and ! * is_nonzero when determining the signs of hour/minute/seconds fields. */ switch (style) { ! /* compatible with ISO date formats */ ! case USE_ISO_DATES: ! if (tm->tm_year != 0) ! { ! sprintf(cp, "%d year%s", ! tm->tm_year, (tm->tm_year != 1) ? "s" : ""); ! cp += strlen(cp); ! is_before = (tm->tm_year < 0); ! is_nonzero = TRUE; ! } ! ! if (tm->tm_mon != 0) ! { ! sprintf(cp, "%s%s%d mon%s", is_nonzero ? " " : "", ! (is_before && tm->tm_mon > 0) ? "+" : "", ! tm->tm_mon, (tm->tm_mon != 1) ? "s" : ""); ! cp += strlen(cp); ! is_before = (tm->tm_mon < 0); ! is_nonzero = TRUE; ! } ! ! if (tm->tm_mday != 0) ! { ! sprintf(cp, "%s%s%d day%s", is_nonzero ? " " : "", ! (is_before && tm->tm_mday > 0) ? "+" : "", ! tm->tm_mday, (tm->tm_mday != 1) ? "s" : ""); ! cp += strlen(cp); ! is_before = (tm->tm_mday < 0); ! is_nonzero = TRUE; ! } ! if (!is_nonzero || tm->tm_hour != 0 || tm->tm_min != 0 || ! tm->tm_sec != 0 || fsec != 0) { ! int minus = tm->tm_hour < 0 || tm->tm_min < 0 || ! tm->tm_sec < 0 || fsec < 0; ! sprintf(cp, "%s%s%02d:%02d", (is_nonzero ? " " : ""), ! (minus ? "-" : (is_before ? "+" : "")), ! abs(tm->tm_hour), abs(tm->tm_min)); ! cp += strlen(cp); ! /* Mark as "non-zero" since the fields are now filled in */ ! is_nonzero = TRUE; ! /* fractional seconds? */ ! if (fsec != 0) { ! #ifdef HAVE_INT64_TIMESTAMP ! sprintf(cp, ":%02d", abs(tm->tm_sec)); cp += strlen(cp); ! sprintf(cp, ".%06d", Abs(fsec)); ! #else ! fsec += tm->tm_sec; ! sprintf(cp, ":%012.9f", fabs(fsec)); ! #endif ! TrimTrailingZeros(cp); cp += strlen(cp); ! is_nonzero = TRUE; } ! /* otherwise, integer seconds only? */ ! else if (tm->tm_sec != 0) { ! sprintf(cp, ":%02d", abs(tm->tm_sec)); cp += strlen(cp); ! is_nonzero = TRUE; } } break; ! case USE_POSTGRES_DATES: ! default: ! strcpy(cp, "@ "); ! cp += strlen(cp); ! ! if (tm->tm_year != 0) { ! int year = tm->tm_year; ! ! if (tm->tm_year < 0) ! year = -year; ! ! sprintf(cp, "%d year%s", year, ! (year != 1) ? "s" : ""); ! cp += strlen(cp); ! is_before = (tm->tm_year < 0); ! is_nonzero = TRUE; ! } ! ! if (tm->tm_mon != 0) ! { ! int mon = tm->tm_mon; ! ! if (is_before || (!is_nonzero && tm->tm_mon < 0)) ! mon = -mon; ! ! sprintf(cp, "%s%d mon%s", is_nonzero ? " " : "", mon, ! (mon != 1) ? "s" : ""); ! cp += strlen(cp); ! if (!is_nonzero) ! is_before = (tm->tm_mon < 0); ! is_nonzero = TRUE; ! } ! ! if (tm->tm_mday != 0) ! { ! int day = tm->tm_mday; ! ! if (is_before || (!is_nonzero && tm->tm_mday < 0)) ! day = -day; ! ! sprintf(cp, "%s%d day%s", is_nonzero ? " " : "", day, ! (day != 1) ? "s" : ""); ! cp += strlen(cp); ! if (!is_nonzero) ! is_before = (tm->tm_mday < 0); ! is_nonzero = TRUE; } ! if (tm->tm_hour != 0) { ! int hour = tm->tm_hour; ! ! if (is_before || (!is_nonzero && tm->tm_hour < 0)) ! hour = -hour; ! ! sprintf(cp, "%s%d hour%s", is_nonzero ? " " : "", hour, ! (hour != 1) ? "s" : ""); cp += strlen(cp); ! if (!is_nonzero) ! is_before = (tm->tm_hour < 0); ! is_nonzero = TRUE; } ! if (tm->tm_min != 0) { ! int min = tm->tm_min; ! if (is_before || (!is_nonzero && tm->tm_min < 0)) ! min = -min; ! ! sprintf(cp, "%s%d min%s", is_nonzero ? " " : "", min, ! (min != 1) ? "s" : ""); cp += strlen(cp); ! if (!is_nonzero) ! is_before = (tm->tm_min < 0); ! is_nonzero = TRUE; } ! /* fractional seconds? */ ! if (fsec != 0) ! { ! #ifdef HAVE_INT64_TIMESTAMP ! if (is_before || (!is_nonzero && tm->tm_sec < 0)) ! tm->tm_sec = -tm->tm_sec; ! sprintf(cp, "%s%d.%02d secs", is_nonzero ? " " : "", ! tm->tm_sec, ((int) fsec) / 10000); ! cp += strlen(cp); ! if (!is_nonzero) ! is_before = (fsec < 0); ! #else ! fsec_t sec; ! ! fsec += tm->tm_sec; ! sec = fsec; ! if (is_before || (!is_nonzero && fsec < 0)) ! sec = -sec; ! ! sprintf(cp, "%s%.2f secs", is_nonzero ? " " : "", sec); ! cp += strlen(cp); ! if (!is_nonzero) ! is_before = (fsec < 0); ! #endif ! is_nonzero = TRUE; ! ! /* otherwise, integer seconds only? */ ! } ! else if (tm->tm_sec != 0) { ! int sec = tm->tm_sec; ! ! if (is_before || (!is_nonzero && tm->tm_sec < 0)) ! sec = -sec; ! ! sprintf(cp, "%s%d sec%s", is_nonzero ? " " : "", sec, ! (sec != 1) ? "s" : ""); cp += strlen(cp); ! if (!is_nonzero) ! is_before = (tm->tm_sec < 0); ! is_nonzero = TRUE; } break; } - /* identically zero? then put in a unitless zero... */ - if (!is_nonzero) - { - strcat(cp, "0"); - cp += strlen(cp); - } - - if (is_before && (style != USE_ISO_DATES)) - { - strcat(cp, " ago"); - cp += strlen(cp); - } - return 0; } /* EncodeInterval() */ /* interval2tm() * Convert a interval data type to a tm structure. */ --- 639,982 ---- tm->tm_sec += sec; } + /*---------- + * The SQL standard defines the interval literal + * '-1 1:00:00' + * to mean "negative 1 days and negative 1 hours", while Postgres + * traditionally treats this as meaning "negative 1 days and positive + * 1 hours". In SQL_STANDARD intervalstyle, we apply the leading sign + * to all fields if there are no other explicit signs. + * + * We leave the signs alone if there are additional explicit signs. + * This protects us against misinterpreting postgres-style dump output, + * since the postgres-style output code has always put an explicit sign on + * all fields following a negative field. But note that SQL-spec output + * is ambiguous and can be misinterpreted on load! (So it's best practice + * to dump in postgres style, not SQL style.) + *---------- + */ + if (IntervalStyle == INTSTYLE_SQL_STANDARD && *field[0] == '-') + { + /* Check for additional explicit signs */ + bool more_signs = false; + + for (i = 1; i < nf; i++) + { + if (*field[i] == '-' || *field[i] == '+') + { + more_signs = true; + break; + } + } + + if (!more_signs) + { + /* + * Rather than re-determining which field was field[0], just + * force 'em all negative. + */ + if (*fsec > 0) + *fsec = -(*fsec); + if (tm->tm_sec > 0) + tm->tm_sec = -tm->tm_sec; + if (tm->tm_min > 0) + tm->tm_min = -tm->tm_min; + if (tm->tm_hour > 0) + tm->tm_hour = -tm->tm_hour; + if (tm->tm_mday > 0) + tm->tm_mday = -tm->tm_mday; + if (tm->tm_mon > 0) + tm->tm_mon = -tm->tm_mon; + if (tm->tm_year > 0) + tm->tm_year = -tm->tm_year; + } + } + + /* finally, AGO negates everything */ if (is_before) { *fsec = -(*fsec); ! tm->tm_sec = -tm->tm_sec; ! tm->tm_min = -tm->tm_min; ! tm->tm_hour = -tm->tm_hour; ! tm->tm_mday = -tm->tm_mday; ! tm->tm_mon = -tm->tm_mon; ! tm->tm_year = -tm->tm_year; } ! return 0; ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static char * ! AddVerboseIntPart(char *cp, int value, const char *units, ! bool *is_zero, bool *is_before) ! { ! if (value == 0) ! return cp; ! /* first nonzero value sets is_before */ ! if (*is_zero) ! { ! *is_before = (value < 0); ! value = abs(value); ! } ! else if (*is_before) ! value = -value; ! sprintf(cp, " %d %s%s", value, units, (value == 1) ? "" : "s"); ! *is_zero = FALSE; ! return cp + strlen(cp); ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static char * ! AddPostgresIntPart(char *cp, int value, const char *units, ! bool *is_zero, bool *is_before) ! { ! if (value == 0) ! return cp; ! sprintf(cp, "%s%s%d %s%s", ! (!*is_zero) ? " " : "", ! (*is_before && value > 0) ? "+" : "", ! value, ! units, ! (value != 1) ? "s" : ""); ! /* ! * Each nonzero field sets is_before for (only) the next one. This is ! * a tad bizarre but it's how it worked before... ! */ ! *is_before = (value < 0); ! *is_zero = FALSE; ! return cp + strlen(cp); ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static char * ! AddISO8601IntPart(char *cp, int value, char units) ! { ! if (value == 0) ! return cp; ! sprintf(cp, "%d%c", value, units); ! return cp + strlen(cp); ! } ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c */ ! static void ! AppendSeconds(char *cp, int sec, fsec_t fsec, int precision, bool fillzeros) ! { ! if (fsec == 0) ! { ! if (fillzeros) ! sprintf(cp, "%02d", abs(sec)); ! else ! sprintf(cp, "%d", abs(sec)); ! } ! else ! { ! #ifdef HAVE_INT64_TIMESTAMP ! if (fillzeros) ! sprintf(cp, "%02d.%0*d", abs(sec), precision, (int) Abs(fsec)); ! else ! sprintf(cp, "%d.%0*d", abs(sec), precision, (int) Abs(fsec)); ! #else ! if (fillzeros) ! sprintf(cp, "%0*.*f", precision + 3, precision, fabs(sec + fsec)); ! else ! sprintf(cp, "%.*f", precision, fabs(sec + fsec)); ! #endif ! TrimTrailingZeros(cp); ! } ! } ! ! ! /* copy&pasted from .../src/backend/utils/adt/datetime.c ! * ! * Change pg_tm to tm */ + int ! EncodeInterval(struct /*pg_*/tm * tm, fsec_t fsec, int style, char *str) { ! char *cp = str; + int year = tm->tm_year; + int mon = tm->tm_mon; + int mday = tm->tm_mday; + int hour = tm->tm_hour; + int min = tm->tm_min; + int sec = tm->tm_sec; + bool is_before = FALSE; + bool is_zero = TRUE; /* * The sign of year and month are guaranteed to match, since they are * stored internally as "month". But we'll need to check for is_before and ! * is_zero when determining the signs of day and hour/minute/seconds ! * fields. */ switch (style) { ! /* SQL Standard interval format */ ! case INTSTYLE_SQL_STANDARD: { ! bool has_negative = year < 0 || mon < 0 || ! mday < 0 || hour < 0 || ! min < 0 || sec < 0 || fsec < 0; ! bool has_positive = year > 0 || mon > 0 || ! mday > 0 || hour > 0 || ! min > 0 || sec > 0 || fsec > 0; ! bool has_year_month = year != 0 || mon != 0; ! bool has_day_time = mday != 0 || hour != 0 || ! min != 0 || sec != 0 || fsec != 0; ! bool has_day = mday != 0; ! bool sql_standard_value = !(has_negative && has_positive) && ! !(has_year_month && has_day_time); ! /* ! * SQL Standard wants only 1 "<sign>" preceding the whole ! * interval ... but can't do that if mixed signs. ! */ ! if (has_negative && sql_standard_value) ! { ! *cp++ = '-'; ! year = -year; ! mon = -mon; ! mday = -mday; ! hour = -hour; ! min = -min; ! sec = -sec; ! fsec = -fsec; ! } ! if (!has_negative && !has_positive) { ! sprintf(cp, "0"); ! } ! else if (!sql_standard_value) ! { ! /* ! * For non sql-standard interval values, ! * force outputting the signs to avoid ! * ambiguities with intervals with mixed ! * sign components. ! */ ! char year_sign = (year < 0 || mon < 0) ? '-' : '+'; ! char day_sign = (mday < 0) ? '-' : '+'; ! char sec_sign = (hour < 0 || min < 0 || ! sec < 0 || fsec < 0) ? '-' : '+'; ! ! sprintf(cp, "%c%d-%d %c%d %c%d:%02d:", ! year_sign, abs(year), abs(mon), ! day_sign, abs(mday), ! sec_sign, abs(hour), abs(min)); cp += strlen(cp); ! AppendSeconds(cp, sec, fsec, MAX_INTERVAL_PRECISION, true); ! } ! else if (has_year_month) ! { ! sprintf(cp, "%d-%d", year, mon); ! } ! else if (has_day) ! { ! sprintf(cp, "%d %d:%02d:", mday, hour, min); cp += strlen(cp); ! AppendSeconds(cp, sec, fsec, MAX_INTERVAL_PRECISION, true); } ! else { ! sprintf(cp, "%d:%02d:", hour, min); cp += strlen(cp); ! AppendSeconds(cp, sec, fsec, MAX_INTERVAL_PRECISION, true); } } break; ! /* ISO 8601 "time-intervals by duration only" */ ! case INTSTYLE_ISO_8601: ! /* special-case zero to avoid printing nothing */ ! if (year == 0 && mon == 0 && mday == 0 && ! hour == 0 && min == 0 && sec == 0 && fsec == 0) { ! sprintf(cp, "PT0S"); ! break; } ! *cp++ = 'P'; ! cp = AddISO8601IntPart(cp, year, 'Y'); ! cp = AddISO8601IntPart(cp, mon , 'M'); ! cp = AddISO8601IntPart(cp, mday, 'D'); ! if (hour != 0 || min != 0 || sec != 0 || fsec != 0) ! *cp++ = 'T'; ! cp = AddISO8601IntPart(cp, hour, 'H'); ! cp = AddISO8601IntPart(cp, min , 'M'); ! if (sec != 0 || fsec != 0) { ! if (sec < 0 || fsec < 0) ! *cp++ = '-'; ! AppendSeconds(cp, sec, fsec, MAX_INTERVAL_PRECISION, false); cp += strlen(cp); ! *cp++ = 'S'; ! *cp++ = '\0'; } + break; ! /* Compatible with postgresql < 8.4 when DateStyle = 'iso' */ ! case INTSTYLE_POSTGRES: ! cp = AddPostgresIntPart(cp, year, "year", &is_zero, &is_before); ! cp = AddPostgresIntPart(cp, mon, "mon", &is_zero, &is_before); ! cp = AddPostgresIntPart(cp, mday, "day", &is_zero, &is_before); ! if (is_zero || hour != 0 || min != 0 || sec != 0 || fsec != 0) { ! bool minus = (hour < 0 || min < 0 || sec < 0 || fsec < 0); ! sprintf(cp, "%s%s%02d:%02d:", ! is_zero ? "" : " ", ! (minus ? "-" : (is_before ? "+" : "")), ! abs(hour), abs(min)); cp += strlen(cp); ! AppendSeconds(cp, sec, fsec, MAX_INTERVAL_PRECISION, true); } + break; ! /* Compatible with postgresql < 8.4 when DateStyle != 'iso' */ ! case INTSTYLE_POSTGRES_VERBOSE: ! default: ! strcpy(cp, "@"); ! cp++; ! cp = AddVerboseIntPart(cp, year, "year", &is_zero, &is_before); ! cp = AddVerboseIntPart(cp, mon, "mon", &is_zero, &is_before); ! cp = AddVerboseIntPart(cp, mday, "day", &is_zero, &is_before); ! cp = AddVerboseIntPart(cp, hour, "hour", &is_zero, &is_before); ! cp = AddVerboseIntPart(cp, min, "min", &is_zero, &is_before); ! if (sec != 0 || fsec != 0) { ! *cp++ = ' '; ! if (sec < 0 || (sec == 0 && fsec < 0)) ! { ! if (is_zero) ! is_before = TRUE; ! else if (!is_before) ! *cp++ = '-'; ! } ! else if (is_before) ! *cp++ = '-'; ! AppendSeconds(cp, sec, fsec, MAX_INTERVAL_PRECISION, false); cp += strlen(cp); ! sprintf(cp, " sec%s", ! (abs(sec) != 1 || fsec != 0) ? "s" : ""); ! is_zero = FALSE; } + /* identically zero? then put in a unitless zero... */ + if (is_zero) + strcat(cp, " 0"); + if (is_before) + strcat(cp, " ago"); break; } return 0; } /* EncodeInterval() */ + /* interval2tm() * Convert a interval data type to a tm structure. */ *************** *** 719,725 **** PGTYPESinterval_from_asc(char *str, char **endptr) } if (ParseDateTime(str, lowstr, field, ftype, MAXDATEFIELDS, &nf, ptr) != 0 || ! DecodeInterval(field, ftype, nf, &dtype, tm, &fsec) != 0) { errno = PGTYPES_INTVL_BAD_INTERVAL; return NULL; --- 1096,1103 ---- } if (ParseDateTime(str, lowstr, field, ftype, MAXDATEFIELDS, &nf, ptr) != 0 || ! (DecodeInterval(field, ftype, nf, &dtype, tm, &fsec) != 0 && ! DecodeISO8601Interval(str, &dtype, tm, &fsec) != 0)) { errno = PGTYPES_INTVL_BAD_INTERVAL; return NULL; *************** *** 754,760 **** PGTYPESinterval_to_asc(interval * span) *tm = &tt; fsec_t fsec; char buf[MAXDATELEN + 1]; ! int DateStyle = 0; if (interval2tm(*span, tm, &fsec) != 0) { --- 1132,1138 ---- *tm = &tt; fsec_t fsec; char buf[MAXDATELEN + 1]; ! int IntervalStyle = INTSTYLE_POSTGRES_VERBOSE; if (interval2tm(*span, tm, &fsec) != 0) { *************** *** 762,768 **** PGTYPESinterval_to_asc(interval * span) return NULL; } ! if (EncodeInterval(tm, fsec, DateStyle, buf) != 0) { errno = PGTYPES_INTVL_BAD_INTERVAL; return NULL; --- 1140,1146 ---- return NULL; } ! if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0) { errno = PGTYPES_INTVL_BAD_INTERVAL; return NULL; *** a/src/interfaces/ecpg/test/expected/pgtypeslib-dt_test.c --- b/src/interfaces/ecpg/test/expected/pgtypeslib-dt_test.c *************** *** 77,82 **** if (sqlca.sqlcode < 0) sqlprint ( );} --- 77,88 ---- if (sqlca.sqlcode < 0) sqlprint ( );} #line 30 "dt_test.pgc" + { ECPGdo(__LINE__, 0, 1, NULL, 0, ECPGst_normal, "set intervalstyle to postgres_verbose", ECPGt_EOIT, ECPGt_EORT); + #line 31 "dt_test.pgc" + + if (sqlca.sqlcode < 0) sqlprint ( );} + #line 31 "dt_test.pgc" + date1 = PGTYPESdate_from_asc(d1, NULL); ts1 = PGTYPEStimestamp_from_asc(t1, NULL); *************** *** 86,95 **** if (sqlca.sqlcode < 0) sqlprint ( );} ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_timestamp,&(ts1),(long)1,(long)1,sizeof(timestamp), ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EOIT, ECPGt_EORT); ! #line 35 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 35 "dt_test.pgc" { ECPGdo(__LINE__, 0, 1, NULL, 0, ECPGst_normal, "select * from date_test where d = $1 ", --- 92,101 ---- ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_timestamp,&(ts1),(long)1,(long)1,sizeof(timestamp), ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EOIT, ECPGt_EORT); ! #line 36 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 36 "dt_test.pgc" { ECPGdo(__LINE__, 0, 1, NULL, 0, ECPGst_normal, "select * from date_test where d = $1 ", *************** *** 99,108 **** if (sqlca.sqlcode < 0) sqlprint ( );} ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_timestamp,&(ts1),(long)1,(long)1,sizeof(timestamp), ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EORT); ! #line 37 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 37 "dt_test.pgc" text = PGTYPESdate_to_asc(date1); --- 105,114 ---- ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_timestamp,&(ts1),(long)1,(long)1,sizeof(timestamp), ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EORT); ! #line 38 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 38 "dt_test.pgc" text = PGTYPESdate_to_asc(date1); *************** *** 417,432 **** if (sqlca.sqlcode < 0) sqlprint ( );} free(text); { ECPGtrans(__LINE__, NULL, "rollback "); ! #line 350 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 350 "dt_test.pgc" { ECPGdisconnect(__LINE__, "CURRENT"); ! #line 351 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 351 "dt_test.pgc" return (0); --- 423,438 ---- free(text); { ECPGtrans(__LINE__, NULL, "rollback "); ! #line 351 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 351 "dt_test.pgc" { ECPGdisconnect(__LINE__, "CURRENT"); ! #line 352 "dt_test.pgc" if (sqlca.sqlcode < 0) sqlprint ( );} ! #line 352 "dt_test.pgc" return (0); *** a/src/interfaces/ecpg/test/expected/pgtypeslib-dt_test.stderr --- b/src/interfaces/ecpg/test/expected/pgtypeslib-dt_test.stderr *************** *** 14,42 **** [NO_PID]: sqlca: code: 0, state: 00000 [NO_PID]: ecpg_execute on line 30: OK: SET [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 35: query: insert into date_test ( d , ts ) values ( $1 , $2 ) ; with 2 parameter(s)on connection regress1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 35: using PQexecParams [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: free_params on line 35: parameter 1 = 1966-01-17 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: free_params on line 35: parameter 2 = 2000-07-12 17:34:29 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 35: OK: INSERT 0 1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 37: query: select * from date_test where d = $1 ; with 1 parameter(s) on connectionregress1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 37: using PQexecParams [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: free_params on line 37: parameter 1 = 1966-01-17 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 37: correctly got 1 tuples with 2 fields [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_get_data on line 37: RESULT: 1966-01-17 offset: -1; array: yes [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_get_data on line 37: RESULT: 2000-07-12 17:34:29 offset: -1; array: yes [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ECPGtrans on line 350: action "rollback "; connection "regress1" [NO_PID]: sqlca: code: 0, state: 00000 [NO_PID]: ecpg_finish: connection regress1 closed [NO_PID]: sqlca: code: 0, state: 00000 --- 14,48 ---- [NO_PID]: sqlca: code: 0, state: 00000 [NO_PID]: ecpg_execute on line 30: OK: SET [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 31: query: set intervalstyle to postgres_verbose; with 0 parameter(s) on connection regress1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 31: using PQexec [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 31: OK: SET [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 36: query: insert into date_test ( d , ts ) values ( $1 , $2 ) ; with 2 parameter(s)on connection regress1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 36: using PQexecParams [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: free_params on line 36: parameter 1 = 1966-01-17 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: free_params on line 36: parameter 2 = 2000-07-12 17:34:29 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 36: OK: INSERT 0 1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 38: query: select * from date_test where d = $1 ; with 1 parameter(s) on connectionregress1 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 38: using PQexecParams [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: free_params on line 38: parameter 1 = 1966-01-17 [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_execute on line 38: correctly got 1 tuples with 2 fields ! [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_get_data on line 38: RESULT: 1966-01-17 offset: -1; array: yes ! [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ecpg_get_data on line 38: RESULT: 2000-07-12 17:34:29 offset: -1; array: yes ! [NO_PID]: sqlca: code: 0, state: 00000 ! [NO_PID]: ECPGtrans on line 351: action "rollback "; connection "regress1" [NO_PID]: sqlca: code: 0, state: 00000 [NO_PID]: ecpg_finish: connection regress1 closed [NO_PID]: sqlca: code: 0, state: 00000 *** a/src/interfaces/ecpg/test/pgtypeslib/dt_test.pgc --- b/src/interfaces/ecpg/test/pgtypeslib/dt_test.pgc *************** *** 28,33 **** main(void) --- 28,34 ---- exec sql connect to REGRESSDB1; exec sql create table date_test (d date, ts timestamp); exec sql set datestyle to iso; + exec sql set intervalstyle to postgres_verbose; date1 = PGTYPESdate_from_asc(d1, NULL); ts1 = PGTYPEStimestamp_from_asc(t1, NULL);
On Thu, Nov 20, 2008 at 05:07:40PM -0800, Ron Mayer wrote: > Got it. > Patch attached. Looks reasonable to me. Michael -- Michael Meskes Michael at Fam-Meskes dot De, Michael at Meskes dot (De|Com|Net|Org) Michael at BorussiaFan dot De, Meskes at (Debian|Postgresql) dot Org ICQ: 179140304, AIM/Yahoo: michaelmeskes, Jabber: meskes@jabber.org Go VfL Borussia! Go SF 49ers! Use Debian GNU/Linux! Use PostgreSQL!
Michael Meskes <meskes@postgresql.org> writes: > On Thu, Nov 20, 2008 at 05:07:40PM -0800, Ron Mayer wrote: >> Patch attached. > Looks reasonable to me. Michael, since that's ecpg code, please take charge of committing it if you want it. regards, tom lane
On Wed, Nov 26, 2008 at 09:31:48AM -0500, Tom Lane wrote: > Michael, since that's ecpg code, please take charge of committing it > if you want it. Okay, done. I wasn't sure whether this was related to a backend patch that was still under review. Michael -- Michael Meskes Michael at Fam-Meskes dot De, Michael at Meskes dot (De|Com|Net|Org) Michael at BorussiaFan dot De, Meskes at (Debian|Postgresql) dot Org ICQ: 179140304, AIM/Yahoo: michaelmeskes, Jabber: meskes@jabber.org Go VfL Borussia! Go SF 49ers! Use Debian GNU/Linux! Use PostgreSQL!
Michael Meskes <meskes@postgresql.org> writes: > On Wed, Nov 26, 2008 at 09:31:48AM -0500, Tom Lane wrote: >> Michael, since that's ecpg code, please take charge of committing it >> if you want it. > Okay, done. I wasn't sure whether this was related to a backend patch that was > still under review. No, the backend part went in some time ago. regards, tom lane