Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix behaviour of DATEDIFF() and DATEDIFF_BIG() functions for week and quarter dateparts #3357

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
86 changes: 68 additions & 18 deletions contrib/babelfishpg_common/src/datetime.c
Original file line number Diff line number Diff line change
Expand Up @@ -1318,6 +1318,8 @@ timestamp_diff(PG_FUNCTION_ARGS)
int32 seconddiff;
int32 millisecdiff;
int32 microsecdiff;
int32 days_in_timestamp1;
int32 days_in_timestamp2;
struct pg_tm tt1,
*tm1 = &tt1;
fsec_t fsec1;
Expand All @@ -1340,16 +1342,16 @@ timestamp_diff(PG_FUNCTION_ARGS)
type = DecodeUnits(0, lowunits, &val);

// Decode units does not handle doy properly
if(strncmp(lowunits, "doy", 3) == 0) {
if(strlen(lowunits) == 3 && strncmp(lowunits, "doy", 3) == 0) {
type = UNITS;
val = DTK_DOY;
}

if(strncmp(lowunits, "nanosecond", 11) == 0) {
if(strlen(lowunits) == 10 && strncmp(lowunits, "nanosecond", 10) == 0) {
type = UNITS;
val = DTK_NANO;
}
if(strncmp(lowunits, "weekday", 7) == 0) {
if(strlen(lowunits) == 7 && strncmp(lowunits, "weekday", 7) == 0) {
type = UNITS;
val = DTK_DAY;
}
Expand All @@ -1364,17 +1366,40 @@ timestamp_diff(PG_FUNCTION_ARGS)
yeardiff = tm2->tm_year - tm1->tm_year;
monthdiff = tm2->tm_mon - tm1->tm_mon;
diff = (yeardiff * 12 + monthdiff) / 3;
/* Calculate if quarter boundary is crossed for the remaining months */
if (monthdiff % 3 > 0)
{
if (yeardiff >= 0 && ((tm1->tm_mon - 1) % 3 > (tm2->tm_mon - 1) % 3))
diff++;
else if (yeardiff < 0 && ((tm1->tm_mon - 1) % 3 < (tm2->tm_mon - 1) % 3))
diff--;
}
else if (monthdiff % 3 < 0)
{
if (yeardiff > 0 && ((tm1->tm_mon - 1) % 3 > (tm2->tm_mon - 1) % 3))
diff++;
else if (yeardiff <= 0 && ((tm1->tm_mon - 1) % 3 < (tm2->tm_mon - 1) % 3))
diff--;
}
break;
case DTK_MONTH:
yeardiff = tm2->tm_year - tm1->tm_year;
monthdiff = tm2->tm_mon - tm1->tm_mon;
diff = yeardiff * 12 + monthdiff;
break;
case DTK_WEEK:
daydiff = days_in_date(tm2->tm_mday, tm2->tm_mon, tm2->tm_year) - days_in_date(tm1->tm_mday, tm1->tm_mon, tm1->tm_year);
days_in_timestamp1 = days_in_date(tm1->tm_mday, tm1->tm_mon, tm1->tm_year);
days_in_timestamp2 = days_in_date(tm2->tm_mday, tm2->tm_mon, tm2->tm_year);
daydiff = days_in_timestamp2 - days_in_timestamp1;
diff = daydiff / 7;
if(daydiff % 7 >= 4)
diff++;
/* Calculate if saturday-sunday boundary is crossed for the remaining days */
if (abs(daydiff) % 7 > ((Max(days_in_timestamp1, days_in_timestamp2) - 1) % 7))
{
if (daydiff < 0)
diff--;
else
diff++;
}
break;
case DTK_DAY:
case DTK_DOY:
Expand Down Expand Up @@ -1462,7 +1487,7 @@ timestamp_diff(PG_FUNCTION_ARGS)
if(overflow) {
ereport(ERROR,
(errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE),
errmsg("The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart")));
errmsg("The %s function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use %s with a less precise datepart.", "datediff", "datediff")));
}

PG_RETURN_INT32(diff);
Expand All @@ -1489,6 +1514,8 @@ timestamp_diff_big(PG_FUNCTION_ARGS)
int64 seconddiff;
int64 millisecdiff;
int64 microsecdiff;
int64 days_in_timestamp1;
int64 days_in_timestamp2;
struct pg_tm tt1,
*tm1 = &tt1;
fsec_t fsec1;
Expand All @@ -1511,15 +1538,15 @@ timestamp_diff_big(PG_FUNCTION_ARGS)
type = DecodeUnits(0, lowunits, &val);

// Decode units does not handle doy or nano properly
if(strncmp(lowunits, "doy", 3) == 0) {
if(strlen(lowunits) == 3 && strncmp(lowunits, "doy", 3) == 0) {
type = UNITS;
val = DTK_DOY;
}
if(strncmp(lowunits, "nanosecond", 11) == 0) {
if(strlen(lowunits) == 10 && strncmp(lowunits, "nanosecond", 10) == 0) {
type = UNITS;
val = DTK_NANO;
}
if(strncmp(lowunits, "weekday", 7) == 0) {
if(strlen(lowunits) == 7 && strncmp(lowunits, "weekday", 7) == 0) {
type = UNITS;
val = DTK_DAY;
}
Expand All @@ -1535,17 +1562,40 @@ timestamp_diff_big(PG_FUNCTION_ARGS)
yeardiff = tm2->tm_year - tm1->tm_year;
monthdiff = tm2->tm_mon - tm1->tm_mon;
diff = (yeardiff * 12 + monthdiff) / 3;
/* Calculate if quarter boundary is crossed for the remaining months */
if (monthdiff % 3 > 0)
{
if (yeardiff >= 0 && ((tm1->tm_mon - 1) % 3 > (tm2->tm_mon - 1) % 3))
diff++;
else if (yeardiff < 0 && ((tm1->tm_mon - 1) % 3 < (tm2->tm_mon - 1) % 3))
diff--;
}
else if (monthdiff % 3 < 0)
{
if (yeardiff > 0 && ((tm1->tm_mon - 1) % 3 > (tm2->tm_mon - 1) % 3))
diff++;
else if (yeardiff <= 0 && ((tm1->tm_mon - 1) % 3 < (tm2->tm_mon - 1) % 3))
diff--;
}
break;
case DTK_MONTH:
yeardiff = tm2->tm_year - tm1->tm_year;
monthdiff = tm2->tm_mon - tm1->tm_mon;
diff = yeardiff * 12 + monthdiff;
break;
case DTK_WEEK:
daydiff = days_in_date(tm2->tm_mday, tm2->tm_mon, tm2->tm_year) - days_in_date(tm1->tm_mday, tm1->tm_mon, tm1->tm_year);
days_in_timestamp1 = days_in_date(tm1->tm_mday, tm1->tm_mon, tm1->tm_year);
days_in_timestamp2 = days_in_date(tm2->tm_mday, tm2->tm_mon, tm2->tm_year);
daydiff = days_in_timestamp2 - days_in_timestamp1;
diff = daydiff / 7;
if(daydiff % 7 >= 4)
diff++;
/* Calculate if saturday-sunday boundary is crossed for the remaining days */
if (abs(daydiff) % 7 > ((Max(days_in_timestamp1, days_in_timestamp2) - 1) % 7))
{
if (daydiff < 0)
diff--;
else
diff++;
}
break;
case DTK_DAY:
case DTK_DOY:
Expand Down Expand Up @@ -1627,12 +1677,12 @@ timestamp_diff_big(PG_FUNCTION_ARGS)
if(!validDateDiff) {
ereport(ERROR,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("\'%s\' is not a recognized %s option", lowunits, "datediff")));
errmsg("\'%s\' is not a recognized %s option", lowunits, "datediff_big")));
}
if(overflow) {
ereport(ERROR,
(errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE),
errmsg("The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart")));
errmsg("The %s function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use %s with a less precise datepart.", "datediff_big", "datediff_big")));
}

PG_RETURN_INT64(diff);
Expand Down Expand Up @@ -1738,15 +1788,15 @@ dateadd_datetime(PG_FUNCTION_ARGS) {

type = DecodeUnits(0, lowunits, &val);

if(strncmp(lowunits, "doy", 3) == 0 || strncmp(lowunits, "dayofyear", 9) == 0) {
if((strlen(lowunits) == 3 && strncmp(lowunits, "doy", 3) == 0) || (strlen(lowunits) == 9 && strncmp(lowunits, "dayofyear", 9) == 0)) {
type = UNITS;
val = DTK_DOY;
}
if(strncmp(lowunits, "nanosecond", 11) == 0) {
if(strlen(lowunits) == 10 && strncmp(lowunits, "nanosecond", 10) == 0) {
type = UNITS;
val = DTK_NANO;
}
if(strncmp(lowunits, "weekday", 7) == 0) {
if(strlen(lowunits) == 7 && strncmp(lowunits, "weekday", 7) == 0) {
type = UNITS;
val = DTK_DAY;
}
Expand Down
2 changes: 1 addition & 1 deletion contrib/babelfishpg_tds/error_mapping.txt
Original file line number Diff line number Diff line change
Expand Up @@ -181,7 +181,7 @@ XX000 ERRCODE_INTERNAL_ERROR "The table-valued parameter \"%s\" must be declared
0A000 ERRCODE_FEATURE_NOT_SUPPORTED "Column name or number of supplied values does not match table definition." SQL_ERROR_213 16
42501 ERRCODE_INSUFFICIENT_PRIVILEGE "Only members of the sysadmin role can execute this stored procedure." SQL_ERROR_15003 16
42809 ERRCODE_WRONG_OBJECT_TYPE "The target \"%s\" of the OUTPUT INTO clause cannot be a view or common table expression." SQL_ERROR_330 16
22008 ERRCODE_DATETIME_VALUE_OUT_OF_RANGE "The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart" SQL_ERROR_535 16
22008 ERRCODE_DATETIME_VALUE_OUT_OF_RANGE "The %s function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use %s with a less precise datepart." SQL_ERROR_535 16
22023 ERRCODE_INVALID_PARAMETER_VALUE "\'%s\' is not a recognized %s option" SQL_ERROR_155 15
22023 ERRCODE_INVALID_PARAMETER_VALUE "The datepart %s is not supported by date function %s for data type %s." SQL_ERROR_9810 16
22008 ERRCODE_DATETIME_VALUE_OUT_OF_RANGE "Adding a value to a \'%s\' column caused an overflow." SQL_ERROR_517 16
Expand Down
8 changes: 4 additions & 4 deletions test/JDBC/expected/BABEL-2347.out
Original file line number Diff line number Diff line change
Expand Up @@ -132,7 +132,7 @@ SELECT DATEDIFF(quarter, @date1, @date2) as quarter_diff
go
~~START~~
int
0
1
~~END~~


Expand All @@ -144,7 +144,7 @@ SELECT DATEDIFF(qq, @date1, @date2) as qq_diff
go
~~START~~
int
0
1
~~END~~


Expand Down Expand Up @@ -241,7 +241,7 @@ SELECT DATEDIFF(quarter, @date1, @date2) as quarter_diff
go
~~START~~
int
0
1
~~END~~


Expand All @@ -253,7 +253,7 @@ SELECT DATEDIFF(qq, @date1, @date2) as qq_diff
go
~~START~~
int
0
1
~~END~~


Expand Down
4 changes: 2 additions & 2 deletions test/JDBC/expected/BABEL-2812-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -325,7 +325,7 @@ SELECT * FROM babel_2812_vu_v38
GO
~~ERROR (Code: 535)~~

~~ERROR (Message: The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart)~~
~~ERROR (Message: The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart.)~~

-- smaller interval for millisecond
SELECT * FROM babel_2812_vu_v39
Expand All @@ -340,7 +340,7 @@ SELECT * FROM babel_2812_vu_v40
GO
~~ERROR (Code: 535)~~

~~ERROR (Message: The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart)~~
~~ERROR (Message: The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart.)~~

-- microsecond and nanosecond can only handle diff of 0 for date type
SELECT * FROM babel_2812_vu_v41
Expand Down
2 changes: 1 addition & 1 deletion test/JDBC/expected/TestErrorHelperFunctions.out
Original file line number Diff line number Diff line change
Expand Up @@ -204,7 +204,7 @@ XX000#!#The table-valued parameter "%s" must be declared with the READONLY optio
0A000#!#Column name or number of supplied values does not match table definition.#!##!#213
42501#!#Only members of the sysadmin role can execute this stored procedure.#!##!#15003
42809#!#The target "%s" of the OUTPUT INTO clause cannot be a view or common table expression.#!##!#330
22008#!#The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart#!##!#535
22008#!#The %s function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use %s with a less precise datepart.#!##!#535
22023#!#'%s' is not a recognized %s option#!##!#155
22023#!#The datepart %s is not supported by date function %s for data type %s.#!##!#9810
22008#!#Adding a value to a '%s' column caused an overflow.#!##!#517
Expand Down
4 changes: 2 additions & 2 deletions test/JDBC/expected/babel_function.out
Original file line number Diff line number Diff line change
Expand Up @@ -1369,7 +1369,7 @@ select datediff(week,CAST('2037-03-01 23:30:05.523'AS sys.datetime),CAST('2036-0
GO
~~START~~
int
-52
-53
~~END~~

select datediff(hour, CAST('2037-03-01 23:30:05.523'AS sys.datetime), CAST('2036-02-28 23:30:05.523'AS sys.datetime));
Expand Down Expand Up @@ -1426,7 +1426,7 @@ select datediff(quarter,CAST('2016-12-26 23:30:05.523456'AS datetime2), CAST('20
GO
~~START~~
int
6
7
~~END~~

select datediff(hour, CAST('2016-12-26 23:30:05'AS smalldatetime), CAST('2016-12-28 21:29:05'AS smalldatetime));
Expand Down
Loading