diff --git a/contrib/babelfishpg_common/src/datetime.c b/contrib/babelfishpg_common/src/datetime.c index 97d74acf14b..7bcacd2ef57 100644 --- a/contrib/babelfishpg_common/src/datetime.c +++ b/contrib/babelfishpg_common/src/datetime.c @@ -15,7 +15,8 @@ #include "utils/numeric.h" #include "utils/timestamp.h" #include "libpq/pqformat.h" - +#include "parser/scansup.h" +#include "common/int.h" #include "miscadmin.h" #include "datetime.h" @@ -52,9 +53,15 @@ PG_FUNCTION_INFO_V1(datetime_to_float4); PG_FUNCTION_INFO_V1(datetime_to_float8); PG_FUNCTION_INFO_V1(datetime_to_numeric); +PG_FUNCTION_INFO_V1(dateadd_datetime); +PG_FUNCTION_INFO_V1(timestamp_diff); +PG_FUNCTION_INFO_V1(timestamp_diff_big); + void CheckDatetimeRange(const Timestamp time); void CheckDatetimePrecision(fsec_t fsec); +#define DTK_NANO 32 + Datum datetime_in_str(char *str) { @@ -797,4 +804,582 @@ datetime_to_numeric(PG_FUNCTION_ARGS) Timestamp timestamp_left = PG_GETARG_TIMESTAMP(0); float8 result = calculateDaysFromDefaultDatetime(timestamp_left); PG_RETURN_NUMERIC(DirectFunctionCall1(float8_numeric, Float8GetDatum(result))); -} \ No newline at end of file +} + +/* + * Returns the difference of two timestamps based on a provided unit + * INT64 representation for bigints + */ +Datum +timestamp_diff(PG_FUNCTION_ARGS) +{ + + text *field = PG_GETARG_TEXT_PP(0); + Timestamp timestamp1 = PG_GETARG_TIMESTAMP(1); + Timestamp timestamp2 = PG_GETARG_TIMESTAMP(2); + int32 diff = -1; + int tm1Valid; + int tm2Valid; + int32 yeardiff; + int32 monthdiff; + int32 daydiff; + int32 hourdiff; + int32 minutediff; + int32 seconddiff; + int32 millisecdiff; + int32 microsecdiff; + struct pg_tm tt1, + *tm1 = &tt1; + fsec_t fsec1; + struct pg_tm tt2, + *tm2 = &tt2; + fsec_t fsec2; + int type, + val; + char *lowunits; + bool overflow = false; + bool validDateDiff = true; + + tm1Valid = timestamp2tm(timestamp1, NULL, tm1, &fsec1, NULL, NULL); + tm2Valid = timestamp2tm(timestamp2, NULL, tm2, &fsec2, NULL, NULL); + + lowunits = downcase_truncate_identifier(VARDATA_ANY(field), + VARSIZE_ANY_EXHDR(field), + false); + + type = DecodeUnits(0, lowunits, &val); + + // Decode units does not handle doy properly + if(strncmp(lowunits, "doy", 3) == 0) { + type = UNITS; + val = DTK_DOY; + } + + if(strncmp(lowunits, "nanosecond", 11) == 0) { + type = UNITS; + val = DTK_NANO; + } + if(strncmp(lowunits, "weekday", 7) == 0) { + type = UNITS; + val = DTK_DAY; + } + + if(type == UNITS) { + if(tm1Valid == 0 && tm2Valid == 0) { + switch(val) { + case DTK_YEAR: + diff = tm2->tm_year - tm1->tm_year; + break; + case DTK_QUARTER: + yeardiff = tm2->tm_year - tm1->tm_year; + monthdiff = tm2->tm_mon - tm1->tm_mon; + diff = (yeardiff * 12 + monthdiff) / 3; + 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); + diff = daydiff / 7; + if(daydiff % 7 >= 4) + diff++; + break; + case DTK_DAY: + case DTK_DOY: + diff = days_in_date(tm2->tm_mday, tm2->tm_mon, tm2->tm_year) - days_in_date(tm1->tm_mday, tm1->tm_mon, tm1->tm_year); + break; + case DTK_HOUR: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + overflow = (overflow || !(int32_multiply_add(daydiff, 24, &hourdiff))); + diff = hourdiff; + break; + case DTK_MINUTE: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + overflow = (overflow || !(int32_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int32_multiply_add(hourdiff, 60, &minutediff))); + diff = minutediff; + break; + case DTK_SECOND: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + overflow = (overflow || !(int32_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int32_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int32_multiply_add(minutediff, 60, &seconddiff))); + diff = seconddiff; + break; + case DTK_MILLISEC: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + millisecdiff = (fsec2 / 1000) - (fsec1 / 1000); + overflow = (overflow || !(int32_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int32_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int32_multiply_add(minutediff, 60, &seconddiff))); + overflow = (overflow || !(int32_multiply_add(seconddiff, 1000, &millisecdiff))); + diff = millisecdiff; + break; + case DTK_MICROSEC: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + microsecdiff = fsec2 - fsec1; + overflow = (overflow || !(int32_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int32_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int32_multiply_add(minutediff, 60, &seconddiff))); + overflow = (overflow || !(int32_multiply_add(seconddiff, 1000000, µsecdiff))); + diff = microsecdiff; + break; + case DTK_NANO: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + microsecdiff = fsec2 - fsec1; + overflow = (overflow || !(int32_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int32_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int32_multiply_add(minutediff, 60, &seconddiff))); + overflow = (overflow || !(int32_multiply_add(seconddiff, 1000000, µsecdiff))); + overflow = (overflow || (pg_mul_s32_overflow(microsecdiff, 1000, &diff))); + break; + default: + validDateDiff = false; + break; + } + } + else { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + } + } else { + validDateDiff = false; + } + + if(!validDateDiff) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\'%s\' is not a recognized %s option", lowunits, "datediff"))); + } + 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"))); + } + + PG_RETURN_INT32(diff); +} + +/* + * Returns the difference of two timestamps based on a provided unit + * INT64 representation for bigints + */ +Datum +timestamp_diff_big(PG_FUNCTION_ARGS) +{ + text *field = PG_GETARG_TEXT_PP(0); + Timestamp timestamp1 = PG_GETARG_TIMESTAMP(1); + Timestamp timestamp2 = PG_GETARG_TIMESTAMP(2); + int64 diff = -1; + int tm1Valid; + int tm2Valid; + int64 yeardiff; + int64 monthdiff; + int64 daydiff; + int64 hourdiff; + int64 minutediff; + int64 seconddiff; + int64 millisecdiff; + int64 microsecdiff; + struct pg_tm tt1, + *tm1 = &tt1; + fsec_t fsec1; + struct pg_tm tt2, + *tm2 = &tt2; + fsec_t fsec2; + int type, + val; + char *lowunits; + bool overflow = false; + bool validDateDiff = true; + + tm1Valid = timestamp2tm(timestamp1, NULL, tm1, &fsec1, NULL, NULL); + tm2Valid = timestamp2tm(timestamp2, NULL, tm2, &fsec2, NULL, NULL); + + lowunits = downcase_truncate_identifier(VARDATA_ANY(field), + VARSIZE_ANY_EXHDR(field), + false); + + type = DecodeUnits(0, lowunits, &val); + + // Decode units does not handle doy or nano properly + if(strncmp(lowunits, "doy", 3) == 0) { + type = UNITS; + val = DTK_DOY; + } + if(strncmp(lowunits, "nanosecond", 11) == 0) { + type = UNITS; + val = DTK_NANO; + } + if(strncmp(lowunits, "weekday", 7) == 0) { + type = UNITS; + val = DTK_DAY; + } + + if(type == UNITS) { + if(tm1Valid == 0 && tm2Valid == 0) { + switch(val) + { + case DTK_YEAR: + diff = tm2->tm_year - tm1->tm_year; + break; + case DTK_QUARTER: + yeardiff = tm2->tm_year - tm1->tm_year; + monthdiff = tm2->tm_mon - tm1->tm_mon; + diff = (yeardiff * 12 + monthdiff) / 3; + 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); + diff = daydiff / 7; + if(daydiff % 7 >= 4) + diff++; + break; + case DTK_DAY: + case DTK_DOY: + diff = days_in_date(tm2->tm_mday, tm2->tm_mon, tm2->tm_year) - days_in_date(tm1->tm_mday, tm1->tm_mon, tm1->tm_year); + break; + case DTK_HOUR: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + overflow = (overflow || !(int64_multiply_add(daydiff, 24, &hourdiff))); + diff = hourdiff; + break; + case DTK_MINUTE: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + overflow = (overflow || !(int64_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int64_multiply_add(hourdiff, 60, &minutediff))); + diff = minutediff; + break; + case DTK_SECOND: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + overflow = (overflow || !(int64_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int64_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int64_multiply_add(minutediff, 60, &seconddiff))); + diff = seconddiff; + break; + case DTK_MILLISEC: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + millisecdiff = (fsec2 / 1000) - (fsec1 / 1000); + overflow = (overflow || !(int64_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int64_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int64_multiply_add(minutediff, 60, &seconddiff))); + overflow = (overflow || !(int64_multiply_add(seconddiff, 1000, &millisecdiff))); + diff = millisecdiff; + break; + case DTK_MICROSEC: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + microsecdiff = fsec2 - fsec1; + overflow = (overflow || !(int64_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int64_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int64_multiply_add(minutediff, 60, &seconddiff))); + overflow = (overflow || !(int64_multiply_add(seconddiff, 1000000, µsecdiff))); + diff = microsecdiff; + break; + case DTK_NANO: + 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); + hourdiff = tm2->tm_hour - tm1->tm_hour; + minutediff = tm2->tm_min - tm1->tm_min; + seconddiff = tm2->tm_sec - tm1->tm_sec; + microsecdiff = fsec2 - fsec1; + overflow = (overflow || !(int64_multiply_add(daydiff, 24, &hourdiff))); + overflow = (overflow || !(int64_multiply_add(hourdiff, 60, &minutediff))); + overflow = (overflow || !(int64_multiply_add(minutediff, 60, &seconddiff))); + overflow = (overflow || !(int64_multiply_add(seconddiff, 1000000, µsecdiff))); + overflow = (overflow || (pg_mul_s64_overflow(microsecdiff, 1000, &diff))); + break; + default: + validDateDiff = false; + } + } + else { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + } + } else { + validDateDiff = false; + } + + if(!validDateDiff) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\'%s\' is not a recognized %s option", lowunits, "datediff"))); + } + 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"))); + } + + PG_RETURN_INT64(diff); +} + +bool +int64_multiply_add(int64 val, int64 multiplier, int64 *sum) +{ + int64 product; + + if (pg_mul_s64_overflow(val, multiplier, &product) || + pg_add_s64_overflow(*sum, product, sum)) + return false; + return true; +} + +bool +int32_multiply_add(int32 val, int32 multiplier, int32 *sum) +{ + int32 product; + + if (pg_mul_s32_overflow(val, multiplier, &product) || + pg_add_s32_overflow(*sum, product, sum)) + return false; + return true; +} + +int days_in_date(int day, int month, int year) { + int n1 = year * 365 + day; + for(int i = 1; i < month; i++) { + if(i == 2) + n1 += 28; + else if(i == 4 || i == 6 || i == 9 || i == 11) + n1 += 30; + else + n1 += 31; + } + if(month <= 2) + year -= 1; + n1 += (year / 4 - year / 100 + year / 400); + return n1; +} + +char *datetypeName(int num) { + char* ret; + switch(num) { + case 0: + ret = "time"; + break; + case 1: + ret = "date"; + break; + case 2: + ret = "smalldatetime"; + break; + case 3: + ret = "datetime"; + break; + case 4: + ret = "datetime2"; + break; + default: + ret = "unknown"; + } + return ret; +} + +Datum +dateadd_datetime(PG_FUNCTION_ARGS) { + text *field = PG_GETARG_TEXT_PP(0); + int num = PG_GETARG_INT32(1); + enum Datetimetype { + TIME, + DATE, + SMALLDATETIME, + DATETIME, + DATETIME2 + }; + Timestamp timestamp; + enum Datetimetype dttype = PG_GETARG_INT32(3); + char *lowunits; + int type, + val; + Timestamp result; + Interval *interval; + bool validDateAdd = true; + bool incompatibleDatePart = false; + + switch(dttype) { + case TIME: + timestamp = DirectFunctionCall1(time_datetime, (TimeADT) PG_GETARG_TIMEADT(2)); + break; + case DATE: + timestamp = DirectFunctionCall1(date_datetime, (DateADT) PG_GETARG_DATEADT(2)); + break; + default: + timestamp = PG_GETARG_TIMESTAMP(2); + } + + lowunits = downcase_truncate_identifier(VARDATA_ANY(field), + VARSIZE_ANY_EXHDR(field), + false); + + type = DecodeUnits(0, lowunits, &val); + + if(strncmp(lowunits, "doy", 3) == 0 || strncmp(lowunits, "dayofyear", 9) == 0) { + type = UNITS; + val = DTK_DOY; + } + if(strncmp(lowunits, "nanosecond", 11) == 0) { + type = UNITS; + val = DTK_NANO; + } + if(strncmp(lowunits, "weekday", 7) == 0) { + type = UNITS; + val = DTK_DAY; + } + + + if(type == UNITS) { + switch(val) { + case DTK_YEAR: + if(dttype == TIME) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, num, 0, 0, 0, 0, 0, 0); + break; + case DTK_QUARTER: + if(dttype == TIME) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, num * 3, 0, 0, 0, 0, 0); + break; + case DTK_MONTH: + if(dttype == TIME) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, num, 0, 0, 0, 0, 0); + break; + case DTK_WEEK: + if(dttype == TIME) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, num, 0, 0, 0, 0); + break; + case DTK_DAY: + case DTK_DOY: + if(dttype == TIME) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, num, 0, 0, 0); + break; + case DTK_HOUR: + if(dttype == DATE) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, num, 0, 0); + break; + case DTK_MINUTE: + if(dttype == DATE) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, num, 0); + break; + case DTK_SECOND: + if(dttype == DATE) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum(num)); + break; + case DTK_MILLISEC: + if(dttype == DATE) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum((float) num * 0.001)); + break; + case DTK_MICROSEC: + if(dttype == SMALLDATETIME || dttype == DATETIME || dttype == DATE) { + incompatibleDatePart = true; + break; + } + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum((float) num * 0.000001)); + break; + case DTK_NANO: + if(dttype == SMALLDATETIME || dttype == DATETIME || dttype == DATE) { + incompatibleDatePart = true; + break; + } + num = num / 1000 * 1000; // Floors the number to avoid incorrect rounding + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum((float) num * 0.000000001)); + break; + default: + validDateAdd = false; + break; + } + } else { + validDateAdd = false; + } + + if(incompatibleDatePart) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart %s is not supported by date function %s for data type %s.", lowunits, "dateadd", datetypeName(dttype)))); + } + + if(!validDateAdd) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\'%s\' is not a recognized %s option", lowunits, "dateadd"))); + } + + PG_TRY(); + { + result = DirectFunctionCall2(timestamp_pl_interval, timestamp, PointerGetDatum(interval)); + + /* + * This check is required because the range of valid timestamps + * is greater than the range of valid datetimes + */ + CheckDatetimeRange(result); + } + PG_CATCH(); + { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("Adding a value to a \'%s\' column caused an overflow.", datetypeName(dttype)))); + } + PG_END_TRY(); + + PG_RETURN_TIMESTAMP(result); +} diff --git a/contrib/babelfishpg_common/src/datetime.h b/contrib/babelfishpg_common/src/datetime.h index 4d50efa6588..592677cb059 100644 --- a/contrib/babelfishpg_common/src/datetime.h +++ b/contrib/babelfishpg_common/src/datetime.h @@ -32,6 +32,12 @@ extern Timestamp initializeToDefaultDatetime(void); extern double calculateDaysFromDefaultDatetime(Timestamp timestamp_left); extern int roundFractionalSeconds(int fractseconds); +extern int days_in_date(int day, int month, int year); +extern char* datetypeName(int num); + +extern bool int64_multiply_add(int64 val, int64 multiplier, int64 *sum); +extern bool int32_multiply_add(int32 val, int32 multiplier, int32 *sum); + /* Range-check a datetime */ #define IS_VALID_DATETIME(t) (MIN_DATETIME <= (t) && (t) < END_DATETIME) diff --git a/contrib/babelfishpg_common/src/datetimeoffset.c b/contrib/babelfishpg_common/src/datetimeoffset.c index 78242fac677..1041e0e2c51 100644 --- a/contrib/babelfishpg_common/src/datetimeoffset.c +++ b/contrib/babelfishpg_common/src/datetimeoffset.c @@ -13,6 +13,7 @@ #include "utils/datetime.h" #include "libpq/pqformat.h" #include "utils/timestamp.h" +#include "parser/scansup.h" #include "fmgr.h" #include "miscadmin.h" @@ -63,6 +64,9 @@ PG_FUNCTION_INFO_V1(datetimeoffset_datetime2); PG_FUNCTION_INFO_V1(datetimeoffset_scale); PG_FUNCTION_INFO_V1(get_datetimeoffset_tzoffset_internal); +PG_FUNCTION_INFO_V1(dateadd_datetimeoffset); + +#define DTK_NANO 32 /* datetimeoffset_in() @@ -832,3 +836,104 @@ EncodeDatetimeoffsetTimezone(char *str, int tz, int style) *tmp = '\0'; } + +Datum +dateadd_datetimeoffset(PG_FUNCTION_ARGS) { + text *field = PG_GETARG_TEXT_PP(0); + int num = PG_GETARG_INT32(1); + tsql_datetimeoffset *init_startdate = PG_GETARG_DATETIMEOFFSET(2); + bool validDateAdd = true; + char *lowunits; + int type, + val; + tsql_datetimeoffset *result; + Interval *interval; + int timezone = DirectFunctionCall1(get_datetimeoffset_tzoffset_internal, DatetimeoffsetGetDatum(init_startdate)) * 2; + tsql_datetimeoffset *startdate = (tsql_datetimeoffset *) DirectFunctionCall2(datetimeoffset_pl_interval, DatetimeoffsetGetDatum(init_startdate), DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, timezone, 0)); + + + lowunits = downcase_truncate_identifier(VARDATA_ANY(field), + VARSIZE_ANY_EXHDR(field), + false); + + type = DecodeUnits(0, lowunits, &val); + + if(strncmp(lowunits, "doy", 3) == 0 || strncmp(lowunits, "dayofyear", 9) == 0) { + type = UNITS; + val = DTK_DOY; + } + + if(strncmp(lowunits, "nanosecond", 11) == 0) { + type = UNITS; + val = DTK_NANO; + } + if(strncmp(lowunits, "weekday", 7) == 0) { + type = UNITS; + val = DTK_DAY; + } + + if(type == UNITS) { + switch(val) { + case DTK_YEAR: + interval = (Interval *) DirectFunctionCall7(make_interval, num, 0, 0, 0, 0, 0, 0); + break; + case DTK_QUARTER: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, num * 3, 0, 0, 0, 0, 0); + break; + case DTK_MONTH: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, num, 0, 0, 0, 0, 0); + break; + case DTK_WEEK: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, num, 0, 0, 0, 0); + break; + case DTK_DAY: + case DTK_DOY: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, num, 0, 0, 0); + break; + case DTK_HOUR: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, num, 0, 0); + break; + case DTK_MINUTE: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, num, 0); + break; + case DTK_SECOND: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum(num)); + break; + case DTK_MILLISEC: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum((float) num * 0.001)); + break; + case DTK_MICROSEC: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum((float) num * 0.000001)); + break; + case DTK_NANO: + interval = (Interval *) DirectFunctionCall7(make_interval, 0, 0, 0, 0, 0, 0, Float8GetDatum((float) num * 0.000000001)); + break; + default: + validDateAdd = false; + break; + } + } else { + validDateAdd = false; + } + + if(!validDateAdd) { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\'%s\' is not a recognized %s option", lowunits, "dateadd"))); + } + + PG_TRY(); + { + result = (tsql_datetimeoffset *) DirectFunctionCall2(datetimeoffset_pl_interval, DatetimeoffsetGetDatum(startdate), PointerGetDatum(interval)); + + } + PG_CATCH(); + { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("Adding a value to a \'%s\' column caused an overflow.", "datetimeoffset"))); + } + PG_END_TRY(); + + PG_RETURN_DATETIMEOFFSET(result); +} \ No newline at end of file diff --git a/contrib/babelfishpg_tds/error_mapping.txt b/contrib/babelfishpg_tds/error_mapping.txt index 631eb52cfba..6f6f6ee4ca6 100644 --- a/contrib/babelfishpg_tds/error_mapping.txt +++ b/contrib/babelfishpg_tds/error_mapping.txt @@ -179,4 +179,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 +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 diff --git a/contrib/babelfishpg_tsql/sql/sys_functions.sql b/contrib/babelfishpg_tsql/sql/sys_functions.sql index aa97647955b..e4a7070b546 100644 --- a/contrib/babelfishpg_tsql/sql/sys_functions.sql +++ b/contrib/babelfishpg_tsql/sql/sys_functions.sql @@ -1556,7 +1556,7 @@ CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdat AS $body$ BEGIN - return CAST(sys.datediff_internal_date(datepart, startdate, enddate) AS INTEGER); + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1565,7 +1565,7 @@ CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdat AS $body$ BEGIN - return CAST(sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP) AS INTEGER); + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1574,7 +1574,7 @@ CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdat AS $body$ BEGIN - return CAST(sys.datediff_internal_df(datepart, startdate, enddate) AS INTEGER); + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1583,7 +1583,7 @@ CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdat AS $body$ BEGIN - return CAST(sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP) AS INTEGER); + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1592,7 +1592,7 @@ CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdat AS $body$ BEGIN - return CAST(sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP) AS INTEGER); + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1601,7 +1601,7 @@ CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdat AS $body$ BEGIN - return CAST(sys.datediff_internal(datepart, startdate, enddate) AS INTEGER); + return sys.datediff_internal(datepart, startdate, enddate); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1611,7 +1611,7 @@ CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN star AS $body$ BEGIN - return sys.datediff_internal_date(datepart, startdate, enddate); + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1620,7 +1620,7 @@ CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN star AS $body$ BEGIN - return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1629,7 +1629,7 @@ CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN star AS $body$ BEGIN - return sys.datediff_internal_df(datepart, startdate, enddate); + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1638,7 +1638,7 @@ CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN star AS $body$ BEGIN - return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1647,7 +1647,7 @@ CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN star AS $body$ BEGIN - return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1656,7 +1656,7 @@ CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN star AS $body$ BEGIN - return sys.datediff_internal(datepart, startdate, enddate); + return sys.datediff_internal_big(datepart, startdate, enddate); END $body$ LANGUAGE plpgsql IMMUTABLE; @@ -1883,384 +1883,51 @@ LANGUAGE plpgsql IMMUTABLE; but the error shows : operator does not exist: sys.datetimeoffset + interval. As the result, we should not use '+' directly but should keep using OPERATOR(sys.+) when input date is in datetimeoffset type. */ -CREATE OR REPLACE FUNCTION sys.dateadd_internal_df(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate datetimeoffset) RETURNS datetimeoffset AS $$ -DECLARE - timezone INTEGER; -BEGIN - timezone = sys.babelfish_get_datetimeoffset_tzoffset(startdate)::INTEGER * 2; - startdate = startdate OPERATOR(sys.+) make_interval(mins => timezone); - CASE datepart - WHEN 'year' THEN - RETURN startdate OPERATOR(sys.+) make_interval(years => num); - WHEN 'quarter' THEN - RETURN startdate OPERATOR(sys.+) make_interval(months => num * 3); - WHEN 'month' THEN - RETURN startdate OPERATOR(sys.+) make_interval(months => num); - WHEN 'dayofyear', 'y' THEN - RETURN startdate OPERATOR(sys.+) make_interval(days => num); - WHEN 'day' THEN - RETURN startdate OPERATOR(sys.+) make_interval(days => num); - WHEN 'week' THEN - RETURN startdate OPERATOR(sys.+) make_interval(weeks => num); - WHEN 'weekday' THEN - RETURN startdate OPERATOR(sys.+) make_interval(days => num); - WHEN 'hour' THEN - RETURN startdate OPERATOR(sys.+) make_interval(hours => num); - WHEN 'minute' THEN - RETURN startdate OPERATOR(sys.+) make_interval(mins => num); - WHEN 'second' THEN - RETURN startdate OPERATOR(sys.+) make_interval(secs => num); - WHEN 'millisecond' THEN - RETURN startdate OPERATOR(sys.+) make_interval(secs => (num::numeric) * 0.001); - WHEN 'microsecond' THEN - RETURN startdate OPERATOR(sys.+) make_interval(secs => (num::numeric) * 0.000001); - WHEN 'nanosecond' THEN - -- Best we can do - Postgres does not support nanosecond precision - RETURN startdate OPERATOR(sys.+) make_interval(secs => TRUNC((num::numeric)* 0.000000001, 6)); - ELSE - RAISE EXCEPTION '"%" is not a recognized dateadd option.', datepart; - END CASE; -END; -$$ +CREATE OR REPLACE FUNCTION sys.dateadd_internal_df(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate datetimeoffset) +RETURNS datetimeoffset AS +'babelfishpg_common', 'dateadd_datetimeoffset' STRICT -LANGUAGE plpgsql IMMUTABLE; +LANGUAGE C IMMUTABLE PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.dateadd_internal(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate ANYELEMENT) RETURNS ANYELEMENT AS $$ BEGIN - IF pg_typeof(startdate) = 'date'::regtype AND - datepart IN ('hour', 'minute', 'second', 'millisecond', 'microsecond', 'nanosecond') THEN - RAISE EXCEPTION 'The datepart % is not supported by date function dateadd for data type date.', datepart; + IF pg_typeof(startdate) = 'time'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 0); END IF; - IF pg_typeof(startdate) = 'time'::regtype AND - datepart IN ('year', 'quarter', 'month', 'doy', 'day', 'week', 'weekday') THEN - RAISE EXCEPTION 'The datepart % is not supported by date function dateadd for data type time.', datepart; + IF pg_typeof(startdate) = 'date'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 1); END IF; - - CASE datepart - WHEN 'year' THEN - RETURN startdate + make_interval(years => num); - WHEN 'quarter' THEN - RETURN startdate + make_interval(months => num * 3); - WHEN 'month' THEN - RETURN startdate + make_interval(months => num); - WHEN 'dayofyear', 'y' THEN - RETURN startdate + make_interval(days => num); - WHEN 'day' THEN - RETURN startdate + make_interval(days => num); - WHEN 'week' THEN - RETURN startdate + make_interval(weeks => num); - WHEN 'weekday' THEN - RETURN startdate + make_interval(days => num); - WHEN 'hour' THEN - RETURN startdate + make_interval(hours => num); - WHEN 'minute' THEN - RETURN startdate + make_interval(mins => num); - WHEN 'second' THEN - RETURN startdate + make_interval(secs => num); - WHEN 'millisecond' THEN - RETURN startdate + make_interval(secs => (num::numeric) * 0.001); - WHEN 'microsecond' THEN - IF pg_typeof(startdate) = 'time'::regtype THEN - RETURN startdate + make_interval(secs => (num::numeric) * 0.000001); - ELSIF pg_typeof(startdate) = 'sys.datetime2'::regtype THEN - RETURN startdate + make_interval(secs => (num::numeric) * 0.000001); - ELSIF pg_typeof(startdate) = 'sys.smalldatetime'::regtype THEN - RAISE EXCEPTION 'The datepart % is not supported by date function dateadd for data type smalldatetime.', datepart; - ELSE - RAISE EXCEPTION 'The datepart % is not supported by date function dateadd for data type datetime.', datepart; - END IF; - WHEN 'nanosecond' THEN - IF pg_typeof(startdate) = 'time'::regtype THEN - RETURN startdate + make_interval(secs => TRUNC((num::numeric)* 0.000000001, 6)); - ELSIF pg_typeof(startdate) = 'sys.datetime2'::regtype THEN - RETURN startdate + make_interval(secs => TRUNC((num::numeric)* 0.000000001, 6)); - ELSIF pg_typeof(startdate) = 'sys.smalldatetime'::regtype THEN - RAISE EXCEPTION 'The datepart % is not supported by date function dateadd for data type smalldatetime.', datepart; - ELSE - RAISE EXCEPTION 'The datepart % is not supported by date function dateadd for data type datetime.', datepart; - END IF; - ELSE - RAISE EXCEPTION '''%'' is not a recognized dateadd option.', datepart; - END CASE; + IF pg_typeof(startdate) = 'sys.smalldatetime'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 2); + END IF; + IF (pg_typeof(startdate) = 'sys.datetime'::regtype or pg_typeof(startdate) = 'timestamp'::regtype) THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 3); + END IF; + IF pg_typeof(startdate) = 'sys.datetime2'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 4); + END IF; END; $$ STRICT LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION sys.datediff_internal_df(IN datepart PG_CATALOG.TEXT, IN startdate anyelement, IN enddate anyelement) RETURNS BIGINT AS $$ -DECLARE - result BIGINT; - year_diff BIGINT; - month_diff BIGINT; - day_diff BIGINT; - hour_diff BIGINT; - minute_diff BIGINT; - second_diff BIGINT; - millisecond_diff BIGINT; - microsecond_diff BIGINT; - y1 BIGINT; - m1 BIGINT; - d1 BIGINT; - y2 BIGINT; - m2 BIGINT; - d2 BIGINT; -BEGIN - CASE datepart - WHEN 'year' THEN - year_diff = sys.datepart('year', enddate) - sys.datepart('year', startdate); - result = year_diff; - WHEN 'quarter' THEN - year_diff = sys.datepart('year', enddate) - sys.datepart('year', startdate); - month_diff = sys.datepart('month', enddate) - sys.datepart('month', startdate); - result = (year_diff * 12 + month_diff) / 3; - WHEN 'month' THEN - year_diff = sys.datepart('year', enddate) - sys.datepart('year', startdate); - month_diff = sys.datepart('month', enddate) - sys.datepart('month', startdate); - result = year_diff * 12 + month_diff; - WHEN 'doy', 'y' THEN - day_diff = sys.datepart('day', enddate OPERATOR(sys.-) startdate); - result = day_diff; - WHEN 'day' THEN - y1 = sys.datepart('year', enddate); - m1 = sys.datepart('month', enddate); - d1 = sys.datepart('day', enddate); - y2 = sys.datepart('year', startdate); - m2 = sys.datepart('month', startdate); - d2 = sys.datepart('day', startdate); - result = sys.num_days_in_date(d1, m1, y1) - sys.num_days_in_date(d2, m2, y2); - WHEN 'week' THEN - day_diff = sys.datepart('day', enddate OPERATOR(sys.-) startdate); - result = day_diff / 7; - WHEN 'hour' THEN - y1 = sys.datepart('year', enddate); - m1 = sys.datepart('month', enddate); - d1 = sys.datepart('day', enddate); - y2 = sys.datepart('year', startdate); - m2 = sys.datepart('month', startdate); - d2 = sys.datepart('day', startdate); - day_diff = sys.num_days_in_date(d1, m1, y1) - sys.num_days_in_date(d2, m2, y2); - hour_diff = sys.datepart('hour', enddate) - sys.datepart('hour', startdate); - result = day_diff * 24 + hour_diff; - WHEN 'minute' THEN - day_diff = sys.datepart('day', enddate OPERATOR(sys.-) startdate); - hour_diff = sys.datepart('hour', enddate OPERATOR(sys.-) startdate); - minute_diff = sys.datepart('minute', enddate OPERATOR(sys.-) startdate); - result = (day_diff * 24 + hour_diff) * 60 + minute_diff; - WHEN 'second' THEN - day_diff = sys.datepart('day', enddate OPERATOR(sys.-) startdate); - hour_diff = sys.datepart('hour', enddate OPERATOR(sys.-) startdate); - minute_diff = sys.datepart('minute', enddate OPERATOR(sys.-) startdate); - second_diff = TRUNC(sys.datepart('second', enddate OPERATOR(sys.-) startdate)); - result = ((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60 + second_diff; - WHEN 'millisecond' THEN - -- millisecond result from date_part by default contains second value, - -- so we do not need to add second_diff again - day_diff = sys.datepart('day', enddate OPERATOR(sys.-) startdate); - hour_diff = sys.datepart('hour', enddate OPERATOR(sys.-) startdate); - minute_diff = sys.datepart('minute', enddate OPERATOR(sys.-) startdate); - second_diff = TRUNC(sys.datepart('second', enddate OPERATOR(sys.-) startdate)); - millisecond_diff = TRUNC(sys.datepart('millisecond', enddate OPERATOR(sys.-) startdate)); - result = (((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60) * 1000 + millisecond_diff; - WHEN 'microsecond' THEN - -- microsecond result from date_part by default contains second and millisecond values, - -- so we do not need to add second_diff and millisecond_diff again - day_diff = sys.datepart('day', enddate OPERATOR(sys.-) startdate); - hour_diff = sys.datepart('hour', enddate OPERATOR(sys.-) startdate); - minute_diff = sys.datepart('minute', enddate OPERATOR(sys.-) startdate); - second_diff = TRUNC(sys.datepart('second', enddate OPERATOR(sys.-) startdate)); - millisecond_diff = TRUNC(sys.datepart('millisecond', enddate OPERATOR(sys.-) startdate)); - microsecond_diff = TRUNC(sys.datepart('microsecond', enddate OPERATOR(sys.-) startdate)); - result = ((((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60) * 1000) * 1000 + microsecond_diff; - WHEN 'nanosecond' THEN - -- Best we can do - Postgres does not support nanosecond precision - day_diff = sys.datepart('day', enddate - startdate); - hour_diff = sys.datepart('hour', enddate OPERATOR(sys.-) startdate); - minute_diff = sys.datepart('minute', enddate OPERATOR(sys.-) startdate); - second_diff = TRUNC(sys.datepart('second', enddate OPERATOR(sys.-) startdate)); - millisecond_diff = TRUNC(sys.datepart('millisecond', enddate OPERATOR(sys.-) startdate)); - microsecond_diff = TRUNC(sys.datepart('microsecond', enddate OPERATOR(sys.-) startdate)); - result = (((((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60) * 1000) * 1000 + microsecond_diff) * 1000; - ELSE - RAISE EXCEPTION '"%" is not a recognized datediff option.', datepart; - END CASE; - - return result; -END; -$$ +CREATE OR REPLACE FUNCTION sys.dateadd_internal_datetime(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate ANYELEMENT, IN datetimetype INT) +RETURNS TIMESTAMP AS +'babelfishpg_common', 'dateadd_datetime' STRICT -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION sys.datediff_internal_date(IN datepart PG_CATALOG.TEXT, IN startdate PG_CATALOG.date, IN enddate PG_CATALOG.date) RETURNS BIGINT AS $$ -DECLARE - result BIGINT; - year_diff BIGINT; - month_diff BIGINT; - day_diff BIGINT; - hour_diff BIGINT; - minute_diff BIGINT; - second_diff BIGINT; - millisecond_diff BIGINT; - microsecond_diff BIGINT; -BEGIN - CASE datepart - WHEN 'year' THEN - year_diff = date_part('year', enddate)::BIGINT - date_part('year', startdate)::BIGINT; - result = year_diff; - WHEN 'quarter' THEN - year_diff = date_part('year', enddate)::BIGINT - date_part('year', startdate)::BIGINT; - month_diff = date_part('month', enddate)::BIGINT - date_part('month', startdate)::BIGINT; - result = (year_diff * 12 + month_diff) / 3; - WHEN 'month' THEN - year_diff = date_part('year', enddate)::BIGINT - date_part('year', startdate)::BIGINT; - month_diff = date_part('month', enddate)::BIGINT - date_part('month', startdate)::BIGINT; - result = year_diff * 12 + month_diff; - -- for all intervals smaller than month, (DATE - DATE) already returns the integer number of days - -- between the dates, so just use that directly as the day_diff. There is no finer resolution - -- than days with the DATE type anyways. - WHEN 'doy', 'y' THEN - day_diff = enddate - startdate; - result = day_diff; - WHEN 'day' THEN - day_diff = enddate - startdate; - result = day_diff; - WHEN 'week' THEN - day_diff = enddate - startdate; - result = day_diff / 7; - WHEN 'hour' THEN - day_diff = enddate - startdate; - result = day_diff * 24; - WHEN 'minute' THEN - day_diff = enddate - startdate; - result = day_diff * 24 * 60; - WHEN 'second' THEN - day_diff = enddate - startdate; - result = day_diff * 24 * 60 * 60; - WHEN 'millisecond' THEN - -- millisecond result from date_part by default contains second value, - -- so we do not need to add second_diff again - day_diff = enddate - startdate; - result = day_diff * 24 * 60 * 60 * 1000; - WHEN 'microsecond' THEN - -- microsecond result from date_part by default contains second and millisecond values, - -- so we do not need to add second_diff and millisecond_diff again - day_diff = enddate - startdate; - result = day_diff * 24 * 60 * 60 * 1000 * 1000; - WHEN 'nanosecond' THEN - -- Best we can do - Postgres does not support nanosecond precision - day_diff = enddate - startdate; - result = day_diff * 24 * 60 * 60 * 1000 * 1000 * 1000; - ELSE - RAISE EXCEPTION '"%" is not a recognized datediff option.', datepart; - END CASE; +LANGUAGE C IMMUTABLE PARALLEL SAFE; - return result; -END; -$$ +CREATE OR REPLACE FUNCTION sys.datediff_internal_big(IN datepart PG_CATALOG.TEXT, IN startdate anyelement, IN enddate anyelement) +RETURNS BIGINT AS +'babelfishpg_common', 'timestamp_diff_big' STRICT -LANGUAGE plpgsql IMMUTABLE; - -CREATE OR REPLACE FUNCTION sys.datediff_internal(IN datepart PG_CATALOG.TEXT, IN startdate anyelement, IN enddate anyelement) RETURNS BIGINT AS $$ -DECLARE - result BIGINT; - year_diff BIGINT; - month_diff BIGINT; - day_diff BIGINT; - hour_diff BIGINT; - minute_diff BIGINT; - second_diff BIGINT; - millisecond_diff BIGINT; - microsecond_diff BIGINT; - y1 BIGINT; - m1 BIGINT; - d1 BIGINT; - y2 BIGINT; - m2 BIGINT; - d2 BIGINT; -BEGIN - CASE datepart - WHEN 'year' THEN - year_diff = date_part('year', enddate)::BIGINT - date_part('year', startdate)::BIGINT; - result = year_diff; - WHEN 'quarter' THEN - year_diff = date_part('year', enddate)::BIGINT - date_part('year', startdate)::BIGINT; - month_diff = date_part('month', enddate)::BIGINT - date_part('month', startdate)::BIGINT; - result = (year_diff * 12 + month_diff) / 3; - WHEN 'month' THEN - year_diff = date_part('year', enddate)::BIGINT - date_part('year', startdate)::BIGINT; - month_diff = date_part('month', enddate)::BIGINT - date_part('month', startdate)::BIGINT; - result = year_diff * 12 + month_diff; - WHEN 'doy', 'y' THEN - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - result = day_diff; - WHEN 'day' THEN - y1 = date_part('year', enddate)::BIGINT; - m1 = date_part('month', enddate)::BIGINT; - d1 = date_part('day', enddate)::BIGINT; - y2 = date_part('year', startdate)::BIGINT; - m2 = date_part('month', startdate)::BIGINT; - d2 = date_part('day', startdate)::BIGINT; - result = sys.num_days_in_date(d1, m1, y1) - sys.num_days_in_date(d2, m2, y2); - WHEN 'week' THEN - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - result = day_diff / 7; - WHEN 'hour' THEN - y1 = date_part('year', enddate)::BIGINT; - m1 = date_part('month', enddate)::BIGINT; - d1 = date_part('day', enddate)::BIGINT; - y2 = date_part('year', startdate)::BIGINT; - m2 = date_part('month', startdate)::BIGINT; - d2 = date_part('day', startdate)::BIGINT; - day_diff = sys.num_days_in_date(d1, m1, y1) - sys.num_days_in_date(d2, m2, y2); - hour_diff = date_part('hour', enddate)::BIGINT - date_part('hour', startdate)::BIGINT; - result = day_diff * 24 + hour_diff; - WHEN 'minute' THEN - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - hour_diff = date_part('hour', enddate OPERATOR(sys.-) startdate)::BIGINT; - minute_diff = date_part('minute', enddate OPERATOR(sys.-) startdate)::BIGINT; - result = (day_diff * 24 + hour_diff) * 60 + minute_diff; - WHEN 'second' THEN - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - hour_diff = date_part('hour', enddate OPERATOR(sys.-) startdate)::BIGINT; - minute_diff = date_part('minute', enddate OPERATOR(sys.-) startdate)::BIGINT; - second_diff = TRUNC(date_part('second', enddate OPERATOR(sys.-) startdate)); - result = ((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60 + second_diff; - WHEN 'millisecond' THEN - -- millisecond result from date_part by default contains second value, - -- so we do not need to add second_diff again - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - hour_diff = date_part('hour', enddate OPERATOR(sys.-) startdate)::BIGINT; - minute_diff = date_part('minute', enddate OPERATOR(sys.-) startdate)::BIGINT; - second_diff = TRUNC(date_part('second', enddate OPERATOR(sys.-) startdate)); - millisecond_diff = TRUNC(date_part('millisecond', enddate OPERATOR(sys.-) startdate)); - result = (((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60) * 1000 + millisecond_diff; - WHEN 'microsecond' THEN - -- microsecond result from date_part by default contains second and millisecond values, - -- so we do not need to add second_diff and millisecond_diff again - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - hour_diff = date_part('hour', enddate OPERATOR(sys.-) startdate)::BIGINT; - minute_diff = date_part('minute', enddate OPERATOR(sys.-) startdate)::BIGINT; - second_diff = TRUNC(date_part('second', enddate OPERATOR(sys.-) startdate)); - millisecond_diff = TRUNC(date_part('millisecond', enddate OPERATOR(sys.-) startdate)); - microsecond_diff = TRUNC(date_part('microsecond', enddate OPERATOR(sys.-) startdate)); - result = ((((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60) * 1000) * 1000 + microsecond_diff; - WHEN 'nanosecond' THEN - -- Best we can do - Postgres does not support nanosecond precision - day_diff = date_part('day', enddate OPERATOR(sys.-) startdate)::BIGINT; - hour_diff = date_part('hour', enddate OPERATOR(sys.-) startdate)::BIGINT; - minute_diff = date_part('minute', enddate OPERATOR(sys.-) startdate)::BIGINT; - second_diff = TRUNC(date_part('second', enddate OPERATOR(sys.-) startdate)); - millisecond_diff = TRUNC(date_part('millisecond', enddate OPERATOR(sys.-) startdate)); - microsecond_diff = TRUNC(date_part('microsecond', enddate OPERATOR(sys.-) startdate)); - result = (((((day_diff * 24 + hour_diff) * 60 + minute_diff) * 60) * 1000) * 1000 + microsecond_diff) * 1000; - ELSE - RAISE EXCEPTION '"%" is not a recognized datediff option.', datepart; - END CASE; +LANGUAGE C IMMUTABLE PARALLEL SAFE; - return result; -END; -$$ +CREATE OR REPLACE FUNCTION sys.datediff_internal(IN datepart PG_CATALOG.TEXT, IN startdate anyelement, IN enddate anyelement) +RETURNS INT AS +'babelfishpg_common', 'timestamp_diff' STRICT -LANGUAGE plpgsql IMMUTABLE; +LANGUAGE C IMMUTABLE PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.datename(IN dp PG_CATALOG.TEXT, IN arg anyelement) RETURNS TEXT AS $BODY$ diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql index 05f0aadbbc1..fe141534577 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql @@ -4329,6 +4329,178 @@ AS 'babelfishpg_tsql', 'sysdatetimeoffset' LANGUAGE C STABLE; GRANT EXECUTE ON FUNCTION sys.sysdatetimeoffset() TO PUBLIC; +ALTER FUNCTION sys.datediff_internal(PG_CATALOG.TEXT, anyelement, anyelement) RENAME TO datediff_internal_deprecated_3_4_0; +CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'datediff_internal_deprecated_3_4_0'); + +ALTER FUNCTION sys.datediff_internal_df(PG_CATALOG.TEXT, anyelement, anyelement) RENAME TO datediff_internal_df_deprecated_in_3_4_0; +CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'datediff_internal_df_deprecated_in_3_4_0'); + +ALTER FUNCTION sys.datediff_internal_date(PG_CATALOG.TEXT, PG_CATALOG.date, PG_CATALOG.date) RENAME TO datediff_internal_date_deprecated_in_3_4_0; +CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'datediff_internal_date_deprecated_in_3_4_0'); + +CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdate PG_CATALOG.date, IN enddate PG_CATALOG.date) RETURNS INTEGER +AS +$body$ +BEGIN + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdate sys.datetime, IN enddate sys.datetime) RETURNS INTEGER +AS +$body$ +BEGIN + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdate sys.datetimeoffset, IN enddate sys.datetimeoffset) RETURNS INTEGER +AS +$body$ +BEGIN + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdate sys.datetime2, IN enddate sys.datetime2) RETURNS INTEGER +AS +$body$ +BEGIN + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdate sys.smalldatetime, IN enddate sys.smalldatetime) RETURNS INTEGER +AS +$body$ +BEGIN + return sys.datediff_internal(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff(IN datepart PG_CATALOG.TEXT, IN startdate PG_CATALOG.time, IN enddate PG_CATALOG.time) RETURNS INTEGER +AS +$body$ +BEGIN + return sys.datediff_internal(datepart, startdate, enddate); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +-- datediff big +CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN startdate PG_CATALOG.date, IN enddate PG_CATALOG.date) RETURNS BIGINT +AS +$body$ +BEGIN + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN startdate sys.datetime, IN enddate sys.datetime) RETURNS BIGINT +AS +$body$ +BEGIN + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN startdate sys.datetimeoffset, IN enddate sys.datetimeoffset) RETURNS BIGINT +AS +$body$ +BEGIN + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN startdate sys.datetime2, IN enddate sys.datetime2) RETURNS BIGINT +AS +$body$ +BEGIN + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN startdate sys.smalldatetime, IN enddate sys.smalldatetime) RETURNS BIGINT +AS +$body$ +BEGIN + return sys.datediff_internal_big(datepart, startdate::TIMESTAMP, enddate::TIMESTAMP); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.datediff_big(IN datepart PG_CATALOG.TEXT, IN startdate PG_CATALOG.time, IN enddate PG_CATALOG.time) RETURNS BIGINT +AS +$body$ +BEGIN + return sys.datediff_internal_big(datepart, startdate, enddate); +END +$body$ +LANGUAGE plpgsql IMMUTABLE; + + +/* + This function is needed when input date is datetimeoffset type. When running the following query in postgres using tsql dialect, it faied. + select dateadd(minute, -70, '2016-12-26 00:30:05.523456+8'::datetimeoffset); + We tried to merge this function with sys.dateadd_internal by using '+' when adding interval to datetimeoffset, + but the error shows : operator does not exist: sys.datetimeoffset + interval. As the result, we should not use '+' directly + but should keep using OPERATOR(sys.+) when input date is in datetimeoffset type. +*/ +CREATE OR REPLACE FUNCTION sys.dateadd_internal_df(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate datetimeoffset) +RETURNS datetimeoffset AS +'babelfishpg_common', 'dateadd_datetimeoffset' +STRICT +LANGUAGE C IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.dateadd_internal(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate ANYELEMENT) RETURNS ANYELEMENT AS $$ +BEGIN + IF pg_typeof(startdate) = 'time'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 0); + END IF; + IF pg_typeof(startdate) = 'date'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 1); + END IF; + IF pg_typeof(startdate) = 'sys.smalldatetime'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 2); + END IF; + IF (pg_typeof(startdate) = 'sys.datetime'::regtype or pg_typeof(startdate) = 'timestamp'::regtype) THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 3); + END IF; + IF pg_typeof(startdate) = 'sys.datetime2'::regtype THEN + return sys.dateadd_internal_datetime(datepart, num, startdate, 4); + END IF; +END; +$$ +STRICT +LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION sys.dateadd_internal_datetime(IN datepart PG_CATALOG.TEXT, IN num INTEGER, IN startdate ANYELEMENT, IN datetimetype INT) +RETURNS TIMESTAMP AS +'babelfishpg_common', 'dateadd_datetime' +STRICT +LANGUAGE C IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datediff_internal_big(IN datepart PG_CATALOG.TEXT, IN startdate anyelement, IN enddate anyelement) +RETURNS BIGINT AS +'babelfishpg_common', 'timestamp_diff_big' +STRICT +LANGUAGE C IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datediff_internal(IN datepart PG_CATALOG.TEXT, IN startdate anyelement, IN enddate anyelement) +RETURNS INT AS +'babelfishpg_common', 'timestamp_diff' +STRICT +LANGUAGE C IMMUTABLE PARALLEL SAFE; + -- Drops the temporary procedure used by the upgrade script. -- Please have this be one of the last statements executed in this upgrade script. DROP PROCEDURE sys.babelfish_drop_deprecated_object(varchar, varchar, varchar); diff --git a/contrib/babelfishpg_tsql/src/err_handler.c b/contrib/babelfishpg_tsql/src/err_handler.c index d4242adc768..631745e6dc3 100644 --- a/contrib/babelfishpg_tsql/src/err_handler.c +++ b/contrib/babelfishpg_tsql/src/err_handler.c @@ -131,7 +131,10 @@ is_ignorable_error(int pg_error_code, uint8_t override_flag) case SQL_ERROR_8145: case SQL_ERROR_8146: case SQL_ERROR_213: - case SQL_ERROR_6615: + case SQL_ERROR_6615: + case SQL_ERROR_155: + case SQL_ERROR_9810: + case SQL_ERROR_535: case SQL_ERROR_15003: { elog(DEBUG1, "TSQL TXN is_ignorable_error %d", latest_error_code); diff --git a/contrib/babelfishpg_tsql/src/err_handler.h b/contrib/babelfishpg_tsql/src/err_handler.h index 687bd393eb0..1e4c6049b79 100644 --- a/contrib/babelfishpg_tsql/src/err_handler.h +++ b/contrib/babelfishpg_tsql/src/err_handler.h @@ -38,6 +38,7 @@ uint8_t override_txn_behaviour(PLtsql_stmt *stmt); #define SQL_ERROR_141 141 #define SQL_ERROR_142 142 #define SQL_ERROR_153 153 +#define SQL_ERROR_155 155 #define SQL_ERROR_180 180 #define SQL_ERROR_201 201 #define SQL_ERROR_206 206 @@ -58,6 +59,7 @@ uint8_t override_txn_behaviour(PLtsql_stmt *stmt); #define SQL_ERROR_512 512 #define SQL_ERROR_515 515 #define SQL_ERROR_517 517 +#define SQL_ERROR_535 535 #define SQL_ERROR_545 545 #define SQL_ERROR_547 547 #define SQL_ERROR_550 550 @@ -135,6 +137,7 @@ uint8_t override_txn_behaviour(PLtsql_stmt *stmt); #define SQL_ERROR_9441 9441 #define SQL_ERROR_9451 9451 #define SQL_ERROR_9809 9809 +#define SQL_ERROR_9810 9810 #define SQL_ERROR_10610 10610 #define SQL_ERROR_10727 10727 #define SQL_ERROR_10733 10733 diff --git a/test/JDBC/expected/BABEL-2812-vu-verify.out b/test/JDBC/expected/BABEL-2812-vu-verify.out index af56128db05..7752d63442c 100644 --- a/test/JDBC/expected/BABEL-2812-vu-verify.out +++ b/test/JDBC/expected/BABEL-2812-vu-verify.out @@ -282,7 +282,7 @@ SELECT * FROM babel_2812_vu_v32 GO ~~START~~ int -51 +52 ~~END~~ SELECT * FROM babel_2812_vu_v33 @@ -323,9 +323,9 @@ int -- should overflow SELECT * FROM babel_2812_vu_v38 GO -~~ERROR (Code: 8115)~~ +~~ERROR (Code: 535)~~ -~~ERROR (Message: integer out of range)~~ +~~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 @@ -338,9 +338,9 @@ int -- should overflow SELECT * FROM babel_2812_vu_v40 GO -~~ERROR (Code: 8115)~~ +~~ERROR (Code: 535)~~ -~~ERROR (Message: integer out of range)~~ +~~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 diff --git a/test/JDBC/expected/BABEL-3474-vu-verify.out b/test/JDBC/expected/BABEL-3474-vu-verify.out index 6e252d51917..17a5ee899fb 100644 --- a/test/JDBC/expected/BABEL-3474-vu-verify.out +++ b/test/JDBC/expected/BABEL-3474-vu-verify.out @@ -30,7 +30,7 @@ GO SELECT * FROM BABEL_3474_vu_prepare_v4 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart microsecond is not supported by date function dateadd for data type datetime.)~~ @@ -39,7 +39,7 @@ GO SELECT * FROM BABEL_3474_vu_prepare_v5 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart microsecond is not supported by date function dateadd for data type smalldatetime.)~~ @@ -78,7 +78,7 @@ GO SELECT * FROM BABEL_3474_vu_prepare_v9 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart nanosecond is not supported by date function dateadd for data type datetime.)~~ @@ -87,7 +87,7 @@ GO SELECT * FROM BABEL_3474_vu_prepare_v10 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart nanosecond is not supported by date function dateadd for data type smalldatetime.)~~ @@ -96,7 +96,7 @@ GO SELECT * FROM BABEL_3474_vu_prepare_v11 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart day is not supported by date function dateadd for data type time.)~~ @@ -105,7 +105,7 @@ GO SELECT * FROM BABEL_3474_vu_prepare_v12 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart second is not supported by date function dateadd for data type date.)~~ @@ -164,7 +164,7 @@ GO EXEC BABEL_3474_vu_prepare_p4 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart microsecond is not supported by date function dateadd for data type datetime.)~~ @@ -173,7 +173,7 @@ GO EXEC BABEL_3474_vu_prepare_p5 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart microsecond is not supported by date function dateadd for data type smalldatetime.)~~ @@ -212,7 +212,7 @@ GO EXEC BABEL_3474_vu_prepare_p9 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart nanosecond is not supported by date function dateadd for data type datetime.)~~ @@ -221,7 +221,7 @@ GO EXEC BABEL_3474_vu_prepare_p10 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart nanosecond is not supported by date function dateadd for data type smalldatetime.)~~ @@ -230,7 +230,7 @@ GO EXEC BABEL_3474_vu_prepare_p11 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart day is not supported by date function dateadd for data type time.)~~ @@ -239,7 +239,7 @@ GO EXEC BABEL_3474_vu_prepare_p12 GO -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart second is not supported by date function dateadd for data type date.)~~ @@ -300,7 +300,7 @@ SELECT BABEL_3474_vu_prepare_f4() GO ~~START~~ datetime -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart microsecond is not supported by date function dateadd for data type datetime.)~~ @@ -311,7 +311,7 @@ SELECT BABEL_3474_vu_prepare_f5() GO ~~START~~ smalldatetime -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart microsecond is not supported by date function dateadd for data type smalldatetime.)~~ @@ -352,7 +352,7 @@ SELECT BABEL_3474_vu_prepare_f9() GO ~~START~~ datetime -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart nanosecond is not supported by date function dateadd for data type datetime.)~~ @@ -363,7 +363,7 @@ SELECT BABEL_3474_vu_prepare_f10() GO ~~START~~ smalldatetime -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart nanosecond is not supported by date function dateadd for data type smalldatetime.)~~ @@ -374,7 +374,7 @@ SELECT BABEL_3474_vu_prepare_f11() GO ~~START~~ time -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart day is not supported by date function dateadd for data type time.)~~ @@ -385,7 +385,7 @@ SELECT BABEL_3474_vu_prepare_f12() GO ~~START~~ date -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 9810)~~ ~~ERROR (Message: The datepart second is not supported by date function dateadd for data type date.)~~ diff --git a/test/JDBC/expected/TestErrorHelperFunctions.out b/test/JDBC/expected/TestErrorHelperFunctions.out index 17c0a6f4928..049b0a2c380 100644 --- a/test/JDBC/expected/TestErrorHelperFunctions.out +++ b/test/JDBC/expected/TestErrorHelperFunctions.out @@ -202,6 +202,10 @@ 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 +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 ~~END~~ diff --git a/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out b/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out index 67cd5e10de6..b33c88085d7 100644 --- a/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out +++ b/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out @@ -33,6 +33,7 @@ int 512 515 517 +535 545 547 550 @@ -111,6 +112,7 @@ int 9441 9451 9809 +9810 10610 10727 10733 @@ -307,6 +309,10 @@ int 213 15003 330 +535 +155 +9810 +517 ~~END~~ @@ -473,6 +479,10 @@ int 213 15003 330 +535 +155 +9810 +517 ~~END~~ @@ -480,6 +490,6 @@ EXEC TestErrorHelperFunctionsUpgrade_VU_PREPARE_PROC GO ~~START~~ int -159 +163 ~~END~~ diff --git a/test/JDBC/expected/babel_datetime-vu-verify.out b/test/JDBC/expected/babel_datetime-vu-verify.out index 5dc05ac2672..d6df7886af6 100644 --- a/test/JDBC/expected/babel_datetime-vu-verify.out +++ b/test/JDBC/expected/babel_datetime-vu-verify.out @@ -376,8 +376,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ - +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) select pg_typeof(c1) FROM (SELECT cast('2016-12-26 23:30:05' as datetime) as C1 UNION SELECT cast('2016-12-26 23:30:05' as smalldatetime) as C1) T diff --git a/test/JDBC/expected/babel_datetime.out b/test/JDBC/expected/babel_datetime.out index fc88466a1b5..804bba9f289 100644 --- a/test/JDBC/expected/babel_datetime.out +++ b/test/JDBC/expected/babel_datetime.out @@ -420,7 +420,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/babel_datetime2.out b/test/JDBC/expected/babel_datetime2.out index df31d17cd43..fdb49852f82 100644 --- a/test/JDBC/expected/babel_datetime2.out +++ b/test/JDBC/expected/babel_datetime2.out @@ -658,9 +658,9 @@ datetime2 -- out of range select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime2)); go -~~ERROR (Code: 33557097)~~ +~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime2)~~ +~~ERROR (Message: Adding a value to a 'datetime2' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/babel_smalldatetime.out b/test/JDBC/expected/babel_smalldatetime.out index 9e3dd9dd9cd..46224c22a2a 100644 --- a/test/JDBC/expected/babel_smalldatetime.out +++ b/test/JDBC/expected/babel_smalldatetime.out @@ -372,9 +372,19 @@ text May ~~END~~ +~~START~~ +smalldatetime +2016-12-26 23:30:00.0 +~~END~~ + +~~START~~ +smalldatetime +2016-12-27 00:25:00.0 +~~END~~ + ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: operator is not unique: smalldatetime + interval)~~ +~~ERROR (Message: data out of range for smalldatetime)~~ -- Clean up diff --git a/test/JDBC/expected/babel_smalldatetime_before_15-5.out b/test/JDBC/expected/babel_smalldatetime_before_15-5.out new file mode 100644 index 00000000000..9e3dd9dd9cd --- /dev/null +++ b/test/JDBC/expected/babel_smalldatetime_before_15-5.out @@ -0,0 +1,383 @@ +-- Testing rounding behaviour when inserting into the table +create table smalldatetime_testing ( sm smalldatetime ); +INSERT INTO smalldatetime_testing VALUES('23:40:29.998'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:29.998'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:29.998'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:29.999'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:30.000'); +INSERT INTO smalldatetime_testing VALUES('2002-05-23 23:41:29.998'); +INSERT INTO smalldatetime_testing VALUES('2002-05-23 23:41:29.999'); +INSERT INTO smalldatetime_testing VALUES('2002-05-23 23:41:30.000'); +INSERT INTO smalldatetime_testing VALUES('2000-01-01 00:00:29.998'); +INSERT INTO smalldatetime_testing VALUES('2000-01-01 00:00:29.999'); +INSERT INTO smalldatetime_testing VALUES('1999-12-31 23:59:30.000'); +INSERT INTO smalldatetime_testing VALUES('1999-12-31 23:59:29.999'); +INSERT INTO smalldatetime_testing VALUES('1999-12-31 23:59:29.998'); +select * from smalldatetime_testing; +go +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~START~~ +smalldatetime +1900-01-01 23:40:00.0 +1992-05-23 23:40:00.0 +1992-05-23 23:40:00.0 +1992-05-23 23:41:00.0 +1992-05-23 23:41:00.0 +2002-05-23 23:41:00.0 +2002-05-23 23:42:00.0 +2002-05-23 23:42:00.0 +2000-01-01 00:00:00.0 +2000-01-01 00:01:00.0 +2000-01-01 00:00:00.0 +2000-01-01 00:00:00.0 +1999-12-31 23:59:00.0 +~~END~~ + + +-- Test comparision with datetime/smalldatetime/date +select * from smalldatetime_testing where sm >= cast('2000-01-01 00:00:59' as smalldatetime); +select * from smalldatetime_testing where sm >= cast('1992-05-23 23:40:00' as datetime) + and sm < cast('1992-05-23 23:41:00' as datetime); +select * from smalldatetime_testing where sm < cast(cast('1992-05-24' as date) as smalldatetime); +go +~~START~~ +smalldatetime +2002-05-23 23:41:00.0 +2002-05-23 23:42:00.0 +2002-05-23 23:42:00.0 +2000-01-01 00:01:00.0 +~~END~~ + +~~START~~ +smalldatetime +1992-05-23 23:40:00.0 +1992-05-23 23:40:00.0 +~~END~~ + +~~START~~ +smalldatetime +1900-01-01 23:40:00.0 +1992-05-23 23:40:00.0 +1992-05-23 23:40:00.0 +1992-05-23 23:41:00.0 +1992-05-23 23:41:00.0 +~~END~~ + + +-- Test rounding for 23:59:59 +SELECT CAST('1992-05-09 23:59:59' AS SMALLDATETIME); +SELECT CAST('2002-05-09 23:59:59' AS SMALLDATETIME); +SELECT CAST('1999-12-31 23:59:59' AS SMALLDATETIME); +go +~~START~~ +smalldatetime +1992-05-10 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2002-05-10 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2000-01-01 00:00:00.0 +~~END~~ + + +-- Test type cast to/from other time formats +-- Cast to smalldatetime +select CAST(CAST('00:00:00.234' AS time) AS smalldatetime); +select CAST(CAST('01:02:03.456' AS time) AS smalldatetime); +select CAST(CAST('2020-03-15' AS date) AS smalldatetime); +select CAST(CAST('2020-03-15' AS datetime) AS smalldatetime); +select CAST(CAST('2010-07-08 23:59:29.998' AS datetime) AS smalldatetime); +select CAST(CAST('1980-07-08 23:59:29.123456 +8:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('2010-07-08 23:59:29.123456 +8:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('1980-07-08 23:59:29.123456 -8:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('2010-07-08 23:59:29.123456 -8:00' AS datetimeoffset) AS smalldatetime); +go +~~START~~ +smalldatetime +1900-01-01 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +1900-01-01 01:02:00.0 +~~END~~ + +~~START~~ +smalldatetime +2020-03-15 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2020-03-15 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2010-07-08 23:59:00.0 +~~END~~ + +~~START~~ +smalldatetime +1980-07-08 23:59:00.0 +~~END~~ + +~~START~~ +smalldatetime +2010-07-08 23:59:00.0 +~~END~~ + +~~START~~ +smalldatetime +1980-07-08 23:59:00.0 +~~END~~ + +~~START~~ +smalldatetime +2010-07-08 23:59:00.0 +~~END~~ + +-- Cast from smalldatetime +select CAST(CAST('2010-07-08' AS smalldatetime) AS time); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS time); +select CAST(CAST('2010-07-08 23:59:31.998' AS smalldatetime) AS time); +select CAST(CAST('1980-07-08 23:59:29.998' AS smalldatetime) AS time); +select CAST(CAST('1980-07-08 23:59:31.998' AS smalldatetime) AS time); +select CAST(CAST('2020-03-15' AS smalldatetime) AS date); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS date); +select CAST(CAST('2010-07-08 23:59:30.000' AS smalldatetime) AS date); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS datetime); +select CAST(CAST('1992-07-08 23:59:29.998' AS smalldatetime) AS datetime); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS datetimeoffset); +select CAST(CAST('1990-07-08 23:59:29.998' AS smalldatetime) AS datetimeoffset); +go +~~START~~ +time +00:00:00.0000000 +~~END~~ + +~~START~~ +time +23:59:00.0000000 +~~END~~ + +~~START~~ +time +00:00:00.0000000 +~~END~~ + +~~START~~ +time +23:59:00.0000000 +~~END~~ + +~~START~~ +time +00:00:00.0000000 +~~END~~ + +~~START~~ +date +2020-03-15 +~~END~~ + +~~START~~ +date +2010-07-08 +~~END~~ + +~~START~~ +date +2010-07-09 +~~END~~ + +~~START~~ +datetime +2010-07-08 23:59:00.0 +~~END~~ + +~~START~~ +datetime +1992-07-08 23:59:00.0 +~~END~~ + +~~START~~ +datetimeoffset +2010-07-08 23:59:00.0000000 +00:00 +~~END~~ + +~~START~~ +datetimeoffset +1990-07-08 23:59:00.0000000 +00:00 +~~END~~ + + +-- Test smalldatetime value ranges +select cast('1900-01-01' as smalldatetime); +select cast('2079-06-06' as smalldatetime); +select cast('1899-12-31 23:59:29.999' as smalldatetime); +select cast('2079-06-06 23:59:29.998' as smalldatetime); +select CAST(CAST('1899-12-31 23:59:30.000' AS datetime) AS smalldatetime); +select CAST(CAST('1899-12-31 23:59:30.000 +0:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('2079-06-06 23:59:30.000 +1:00' AS datetimeoffset) AS smalldatetime); +select cast('1899-12-31' as smalldatetime); -- out of range +select cast('2079-06-07' as smalldatetime); -- out of range +select cast('2079-06-06 23:59:29.999' as smalldatetime); -- out of range +select CAST(CAST('2099-03-15' AS date) AS smalldatetime); -- out of range +select CAST(CAST('1800-03-15 23:59:29.998' AS datetime) AS smalldatetime);-- out of range +select CAST(CAST('2099-03-15 23:59:29.998' AS datetime) AS smalldatetime);-- out of range +select CAST(CAST('1899-12-31 23:59:30.000 +1:00' AS datetimeoffset) AS smalldatetime);-- out of range +select CAST(CAST('2099-03-15 23:59:29.998 +6:00' AS datetimeoffset) AS smalldatetime);-- out of range +go +~~START~~ +smalldatetime +1900-01-01 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2079-06-06 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +1900-01-01 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2079-06-06 23:59:00.0 +~~END~~ + +~~START~~ +smalldatetime +1900-01-01 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +1900-01-01 00:00:00.0 +~~END~~ + +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: data out of range for smalldatetime)~~ + + +-- Test smalldatetime default value +create table t1 (a smalldatetime, b int); +insert into t1 (b) values (1); +select a from t1 where b = 1; +go +~~ROW COUNT: 1~~ + +~~START~~ +smalldatetime + +~~END~~ + + +-- Test smalldatetime as parameter for time related functions +select day(cast('2002-05-23 23:41:29.998' as smalldatetime)); +select month(cast('2002-05-23 23:41:29.998' as smalldatetime)); +select year(cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(quarter, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(hour, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(dayofyear, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(second, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datename(year, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datename(dw, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datename(month, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select dateadd(second, 56, cast('2016-12-26 23:29:29' as smalldatetime)); +select dateadd(minute, 56, cast('2016-12-26 23:29:29' as smalldatetime)); +select dateadd(year, 150, cast('2016-12-26 23:29:29' as smalldatetime)); -- Expect error +go +~~START~~ +int +23 +~~END~~ + +~~START~~ +int +5 +~~END~~ + +~~START~~ +int +2002 +~~END~~ + +~~START~~ +int +2 +~~END~~ + +~~START~~ +int +23 +~~END~~ + +~~START~~ +int +143 +~~END~~ + +~~START~~ +int +0 +~~END~~ + +~~START~~ +text +2002 +~~END~~ + +~~START~~ +text +Thursday +~~END~~ + +~~START~~ +text +May +~~END~~ + +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: operator is not unique: smalldatetime + interval)~~ + + +-- Clean up +drop table smalldatetime_testing; +drop table t1; +go diff --git a/test/JDBC/expected/dateadd-vu-cleanup.out b/test/JDBC/expected/dateadd-vu-cleanup.out new file mode 100644 index 00000000000..5e7690b0cb9 --- /dev/null +++ b/test/JDBC/expected/dateadd-vu-cleanup.out @@ -0,0 +1,29 @@ +DROP PROCEDURE dateadd_p1 +GO + +DROP PROCEDURE dateadd_p2 +GO + +DROP PROCEDURE dateadd_p3 +GO + +DROP PROCEDURE dateadd_p4 +GO + +DROP PROCEDURE dateadd_p5 +GO + +DROP PROCEDURE dateadd_p6 +GO + +DROP PROCEDURE dateadd_p7 +GO + +DROP PROCEDURE dateadd_p8 +GO + +DROP PROCEDURE dateadd_p9 +GO + +DROP PROCEDURE dateadd_p10 +GO diff --git a/test/JDBC/expected/dateadd-vu-prepare.out b/test/JDBC/expected/dateadd-vu-prepare.out new file mode 100644 index 00000000000..eb893e92e02 --- /dev/null +++ b/test/JDBC/expected/dateadd-vu-prepare.out @@ -0,0 +1,29 @@ +CREATE PROCEDURE dateadd_p1 as (select dateadd(day, 2, cast('1900-01-01' as date))); +GO + +CREATE PROCEDURE dateadd_p2 as (select dateadd(hour, 2, cast('01:01:21' as time))); +GO + +CREATE PROCEDURE dateadd_p3 as (select dateadd(hour, 5, cast('01:01:21 +10:00' as datetimeoffset))); +GO + +CREATE PROCEDURE dateadd_p4 as (select dateadd(second, 1, cast('1999-12-31 23:59:59' as datetime))); +GO + +CREATE PROCEDURE dateadd_p5 as (select dateadd(millisecond, 1, cast('1999-12-31 23:59:59' as datetime))); +GO + +CREATE PROCEDURE dateadd_p6 as (select dateadd(millisecond, 1, cast('1999-12-31 23:59:59' as datetime2))); +GO + +CREATE PROCEDURE dateadd_p7 as (select dateadd(day, 2, cast('01:01:21' as time))); +GO + +CREATE PROCEDURE dateadd_p8 as (select dateadd(hour, 2, cast('1900-01-01' as date))); +GO + +CREATE PROCEDURE dateadd_p9 as (select dateadd(minute, -70, cast('2016-12-26 00:30:05.523456+8' as datetimeoffset))); +GO + +CREATE PROCEDURE dateadd_p10 as (select sys.dateadd_internal_datetime('day', 1, cast('2016-12-26 00:30:05' as datetime), 3)); +GO diff --git a/test/JDBC/expected/dateadd-vu-verify.out b/test/JDBC/expected/dateadd-vu-verify.out new file mode 100644 index 00000000000..b74a4cf799a --- /dev/null +++ b/test/JDBC/expected/dateadd-vu-verify.out @@ -0,0 +1,185 @@ +exec dateadd_p1 +GO +~~START~~ +date +1900-01-03 +~~END~~ + + +exec dateadd_p2 +GO +~~START~~ +time +03:01:21.0000000 +~~END~~ + + +exec dateadd_p3 +GO +~~START~~ +datetimeoffset +1900-01-01 06:01:21.0000000 +10:00 +~~END~~ + + +exec dateadd_p4 +GO +~~START~~ +datetime +2000-01-01 00:00:00.0 +~~END~~ + + +exec dateadd_p5 +GO +~~START~~ +datetime +1999-12-31 23:59:59.0 +~~END~~ + + +exec dateadd_p6 +GO +~~START~~ +datetime2 +1999-12-31 23:59:59.0010000 +~~END~~ + + +exec dateadd_p7 +GO +~~ERROR (Code: 9810)~~ + +~~ERROR (Message: The datepart day is not supported by date function dateadd for data type time.)~~ + + +exec dateadd_p8 +GO +~~ERROR (Code: 9810)~~ + +~~ERROR (Message: The datepart hour is not supported by date function dateadd for data type date.)~~ + + +exec dateadd_p9 +GO +~~START~~ +datetimeoffset +2016-12-25 23:20:05.5234560 +08:00 +~~END~~ + + +exec dateadd_p10 +GO +~~START~~ +datetime +2016-12-27 00:30:05.0 +~~END~~ + + +begin transaction +go + +SELECT dateadd(fakeoption, 2, cast('1900-01-01' as date)); +go +~~ERROR (Code: 155)~~ + +~~ERROR (Message: 'fakeoption' is not a recognized dateadd option)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT dateadd(day, 2, cast('01:01:21' as time)); +go +~~ERROR (Code: 9810)~~ + +~~ERROR (Message: The datepart day is not supported by date function dateadd for data type time.)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(YY,-300,getdate()); +go +~~START~~ +datetime +~~ERROR (Code: 517)~~ + +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(YY,-30000000, cast('1900-01-01' as datetime)); +go +~~ERROR (Code: 517)~~ + +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(year,-300000000,cast('1900-01-01' as datetime)); +go +~~ERROR (Code: 517)~~ + +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + diff --git a/test/JDBC/expected/datediff-vu-cleanup.out b/test/JDBC/expected/datediff-vu-cleanup.out new file mode 100644 index 00000000000..64b76e5988d --- /dev/null +++ b/test/JDBC/expected/datediff-vu-cleanup.out @@ -0,0 +1,47 @@ +DROP PROCEDURE datediff_p1 +GO + +DROP PROCEDURE datediff_p2 +GO + +DROP PROCEDURE datediff_p3 +GO + +DROP PROCEDURE datediff_p4 +GO + +DROP PROCEDURE datediff_p5 +GO + +DROP PROCEDURE datediff_p6 +GO + +DROP PROCEDURE datediff_p7 +GO + +DROP PROCEDURE datediff_p8 +GO + +DROP PROCEDURE datediff_p9 +GO + +DROP PROCEDURE datediff_p10 +GO + +DROP PROCEDURE datediff_p11 +GO + +DROP PROCEDURE datediff_p12 +GO + +DROP PROCEDURE datediff_p13 +GO + +DROP PROCEDURE datediff_p14 +GO + +DROP PROCEDURE datediff_p15 +GO + +DROP PROCEDURE datediff_p16 +GO diff --git a/test/JDBC/expected/datediff-vu-prepare.out b/test/JDBC/expected/datediff-vu-prepare.out new file mode 100644 index 00000000000..bad18b9072e --- /dev/null +++ b/test/JDBC/expected/datediff-vu-prepare.out @@ -0,0 +1,60 @@ +-- 123 +CREATE PROCEDURE datediff_p1 as (select datediff(year, cast('1900-01-01' as datetime), cast('2023-01-02' as datetime))); +GO + +-- -30 +CREATE PROCEDURE datediff_p2 as (select datediff(year, cast('2020-01-01' as datetime), cast('1990-01-02' as datetime))); +GO + +-- -120 +CREATE PROCEDURE datediff_p3 as (select datediff(quarter, cast('2020-01-01' as datetime), cast('1990-01-02' as datetime))); +GO + +-- 24 +CREATE PROCEDURE datediff_p4 as (select datediff(month, cast('2020-01-01' as datetime), cast('2022-01-02' as datetime))); +GO + +-- 105 +CREATE PROCEDURE datediff_p5 as (select datediff(week, cast('2020-01-01' as datetime2), cast('2022-01-02' as datetime2))); +GO + +-- -10957 +CREATE PROCEDURE datediff_p6 as (select datediff(day, cast('2020-01-01' as smalldatetime), cast('1990-01-01' as smalldatetime))); +GO + +-- -262963 +CREATE PROCEDURE datediff_p7 as (select datediff(hour, cast('2020-01-01 01:01:20.99' as smalldatetime), cast('1990-01-01 06:01:20.99' as smalldatetime))); +GO +-- -15777780 +CREATE PROCEDURE datediff_p8 as (select datediff(minute, cast('2020-01-01 01:01:20.99' as datetime), cast('1990-01-01 06:01:20.99' as smalldatetime))); +GO + +-- 157885200 +CREATE PROCEDURE datediff_p9 as (select datediff(second, cast('2000-01-01 01:01:20.99' as datetime), cast('2005-01-01 10:01:20.99' as datetime))); +GO + +-- 32400000 +CREATE PROCEDURE datediff_p10 as (select datediff(millisecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 10:01:20.99' as datetime))); +GO + +-- 1200000000 +CREATE PROCEDURE datediff_p11 as (select datediff(microsecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 1:21:20.99' as datetime))); +GO + +-- overflow +CREATE PROCEDURE datediff_p12 as (select datediff(nanosecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 1:21:20.99' as datetime))); +GO + +-- 1200000000000 +CREATE PROCEDURE datediff_p13 as (select datediff_big(nanosecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 1:21:20.99' as datetime))); +GO + +-- 15 +CREATE PROCEDURE datediff_p14 as (select datediff(hour, cast('2020-01-01 01:01:20.99 +10:00' as datetimeoffset), cast('2020-01-01 06:01:20.99' as datetimeoffset))); +GO + +CREATE PROCEDURE datediff_p15 as (select datediff(dayofyear, cast('2020-01-01 01:01:20.99 +10:00' as datetimeoffset), cast('2023-01-01 06:01:20.99' as datetimeoffset))); +GO + +CREATE PROCEDURE datediff_p16 as (select sys.datediff_internal_big('week', cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 01:01:20.99' as datetime))); +GO diff --git a/test/JDBC/expected/datediff-vu-verify.out b/test/JDBC/expected/datediff-vu-verify.out new file mode 100644 index 00000000000..1ea3659990b --- /dev/null +++ b/test/JDBC/expected/datediff-vu-verify.out @@ -0,0 +1,182 @@ +-- 123 +exec datediff_p1 +GO +~~START~~ +int +123 +~~END~~ + + +-- -30 +exec datediff_p2 +GO +~~START~~ +int +-30 +~~END~~ + + +-- -120 +exec datediff_p3 +GO +~~START~~ +int +-120 +~~END~~ + + +-- 24 +exec datediff_p4 +GO +~~START~~ +int +24 +~~END~~ + + +-- 105 +exec datediff_p5 +GO +~~START~~ +int +105 +~~END~~ + + +-- -10957 +exec datediff_p6 +GO +~~START~~ +int +-10957 +~~END~~ + + +-- -262963 +exec datediff_p7 +GO +~~START~~ +int +-262963 +~~END~~ + + +-- -15777780 +exec datediff_p8 +GO +~~START~~ +int +-15777780 +~~END~~ + + +-- 157885200 +exec datediff_p9 +GO +~~START~~ +int +157885200 +~~END~~ + + +-- 32400000 +exec datediff_p10 +GO +~~START~~ +int +32400000 +~~END~~ + + +-- 1200000000 +exec datediff_p11 +GO +~~START~~ +int +1200000000 +~~END~~ + + +-- overflow +exec datediff_p12 +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)~~ + + +-- 1200000000000 +exec datediff_p13 +GO +~~START~~ +bigint +1200000000000 +~~END~~ + + +-- 15 +exec datediff_p14 +GO +~~START~~ +int +15 +~~END~~ + + +exec datediff_p15 +GO +~~START~~ +int +1097 +~~END~~ + + +exec datediff_p16 +GO +~~START~~ +bigint +0 +~~END~~ + + +begin transaction +go + +SELECT DATEDIFF(fakeoption, cast('2023-01-01 01:01:20.98' as datetime), cast('2023-01-01 01:01:20.98' as datetime)) +go +~~ERROR (Code: 155)~~ + +~~ERROR (Message: 'fakeoption' is not a recognized datediff option)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEDIFF(nanosecond, cast('1900-01-01 01:01:20.98' as datetime), cast('2023-01-01 01:01:20.98' as datetime)) +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)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO diff --git a/test/JDBC/expected/datediff_big-vu-verify.out b/test/JDBC/expected/datediff_big-vu-verify.out index cba97675d71..310c4dad300 100644 --- a/test/JDBC/expected/datediff_big-vu-verify.out +++ b/test/JDBC/expected/datediff_big-vu-verify.out @@ -2,22 +2,22 @@ SELECT * FROM datediff_big_vu_prepare_v1 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -1000#!#4000#!#12000#!#365243#!#365243#!#52177#!#8765832#!#525949920#!#31556995200#!#31556995200000#!#31556995200000000#!#6311433600000000000 +1000#!#4000#!#12000#!#365243#!#365243#!#52178#!#8765832#!#525949920#!#31556995200#!#31556995200000#!#31556995200000000#!#6311433600000000000 ~~END~~ SELECT * FROM datediff_big_vu_prepare_v2 GO -~~ERROR (Code: 8115)~~ +~~ERROR (Code: 535)~~ -~~ERROR (Message: bigint out of range)~~ +~~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)~~ SELECT * FROM datediff_big_vu_prepare_v3 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -200#!#803#!#2411#!#73413#!#73413#!#10487#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 +200#!#803#!#2411#!#73413#!#73413#!#10488#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 ~~END~~ @@ -25,7 +25,7 @@ SELECT * FROM datediff_big_vu_prepare_v4 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -200#!#803#!#2411#!#73413#!#73413#!#10487#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 +200#!#803#!#2411#!#73413#!#73413#!#10488#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 ~~END~~ @@ -33,7 +33,7 @@ SELECT * FROM datediff_big_vu_prepare_v5 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -100#!#396#!#1189#!#36160#!#36160#!#5165#!#867840#!#52070401#!#3124224060#!#3124224060000#!#3124224060000000#!#3124224060000000000 +100#!#396#!#1189#!#36160#!#36160#!#5166#!#867840#!#52070401#!#3124224060#!#3124224060000#!#3124224060000000#!#3124224060000000000 ~~END~~ @@ -55,16 +55,18 @@ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#! SELECT * FROM datediff_big_vu_prepare_v8 GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: unit "year" not supported for type time without time zone)~~ +~~START~~ +bigint +0 +~~END~~ SELECT * FROM datediff_big_vu_prepare_v9 GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: operator is not unique: time without time zone sys.- time without time zone)~~ +~~START~~ +bigint +51 +~~END~~ SELECT * FROM datediff_big_vu_prepare_v10 @@ -95,22 +97,22 @@ EXEC datediff_big_vu_prepare_p1 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -1000#!#4000#!#12000#!#365243#!#365243#!#52177#!#8765832#!#525949920#!#31556995200#!#31556995200000#!#31556995200000000#!#6311433600000000000 +1000#!#4000#!#12000#!#365243#!#365243#!#52178#!#8765832#!#525949920#!#31556995200#!#31556995200000#!#31556995200000000#!#6311433600000000000 ~~END~~ EXEC datediff_big_vu_prepare_p2 GO -~~ERROR (Code: 8115)~~ +~~ERROR (Code: 535)~~ -~~ERROR (Message: bigint out of range)~~ +~~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)~~ EXEC datediff_big_vu_prepare_p3 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -200#!#803#!#2411#!#73413#!#73413#!#10487#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 +200#!#803#!#2411#!#73413#!#73413#!#10488#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 ~~END~~ @@ -118,7 +120,7 @@ EXEC datediff_big_vu_prepare_p4 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -200#!#803#!#2411#!#73413#!#73413#!#10487#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 +200#!#803#!#2411#!#73413#!#73413#!#10488#!#1761912#!#105714720#!#6342883200#!#6342883200000#!#6342883200000000#!#6342883200000000000 ~~END~~ @@ -126,7 +128,7 @@ EXEC datediff_big_vu_prepare_p5 GO ~~START~~ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint -100#!#396#!#1189#!#36160#!#36160#!#5165#!#867840#!#52070401#!#3124224060#!#3124224060000#!#3124224060000000#!#3124224060000000000 +100#!#396#!#1189#!#36160#!#36160#!#5166#!#867840#!#52070401#!#3124224060#!#3124224060000#!#3124224060000000#!#3124224060000000000 ~~END~~ @@ -148,16 +150,18 @@ bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#!#bigint#! EXEC datediff_big_vu_prepare_p8 GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: unit "year" not supported for type time without time zone)~~ +~~START~~ +bigint +0 +~~END~~ EXEC datediff_big_vu_prepare_p9 GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: unit "year" not supported for type time without time zone)~~ +~~START~~ +bigint +0 +~~END~~ EXEC datediff_big_vu_prepare_p10 @@ -190,3 +194,66 @@ bigint#!#bigint#!#bigint#!#bigint 0#!#366#!#739013#!#3652424 ~~END~~ + +begin transaction +go + +SELECT DATEDIFF_BIG(fakeoption, cast('2023-01-01 01:01:20.98' as datetime), cast('2023-01-01 01:01:20.98' as datetime)) +go +~~ERROR (Code: 155)~~ + +~~ERROR (Message: 'fakeoption' is not a recognized datediff option)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEDIFF_BIG(nanosecond, cast('1900-01-01 01:01:20.98' as datetime), cast('3000-01-01 01:01:20.98' as datetime)) +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)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(YY,-30000000, cast('1900-01-01' as datetime)); +go +~~ERROR (Code: 517)~~ + +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ + + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO +~~START~~ +text +compile time error +~~END~~ + + +if (@@trancount > 0) rollback tran +GO diff --git a/test/JDBC/expected/datediff_internal_date-vu-cleanup.out b/test/JDBC/expected/datediff_internal_date-before-14_10-or-15_5-vu-cleanup.out similarity index 100% rename from test/JDBC/expected/datediff_internal_date-vu-cleanup.out rename to test/JDBC/expected/datediff_internal_date-before-14_10-or-15_5-vu-cleanup.out diff --git a/test/JDBC/expected/datediff_internal_date-vu-prepare.out b/test/JDBC/expected/datediff_internal_date-before-14_10-or-15_5-vu-prepare.out similarity index 100% rename from test/JDBC/expected/datediff_internal_date-vu-prepare.out rename to test/JDBC/expected/datediff_internal_date-before-14_10-or-15_5-vu-prepare.out diff --git a/test/JDBC/expected/datediff_internal_date-vu-verify.out b/test/JDBC/expected/datediff_internal_date-before-14_10-or-15_5-vu-verify.out similarity index 100% rename from test/JDBC/expected/datediff_internal_date-vu-verify.out rename to test/JDBC/expected/datediff_internal_date-before-14_10-or-15_5-vu-verify.out diff --git a/test/JDBC/expected/latest__verification_cleanup__13_4__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__13_4__babel_datetime-vu-verify.out index beb8038af85..9e181de4a0f 100644 --- a/test/JDBC/expected/latest__verification_cleanup__13_4__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__13_4__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/latest__verification_cleanup__13_5__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__13_5__babel_datetime-vu-verify.out index beb8038af85..9e181de4a0f 100644 --- a/test/JDBC/expected/latest__verification_cleanup__13_5__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__13_5__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/latest__verification_cleanup__13_6__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__13_6__babel_datetime-vu-verify.out index de673fd4ae6..4107ba95104 100644 --- a/test/JDBC/expected/latest__verification_cleanup__13_6__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__13_6__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/latest__verification_cleanup__13_7__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__13_7__babel_datetime-vu-verify.out index beb8038af85..9e181de4a0f 100644 --- a/test/JDBC/expected/latest__verification_cleanup__13_7__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__13_7__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/latest__verification_cleanup__13_8__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__13_8__babel_datetime-vu-verify.out index beb8038af85..9e181de4a0f 100644 --- a/test/JDBC/expected/latest__verification_cleanup__13_8__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__13_8__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/latest__verification_cleanup__13_9__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__13_9__babel_datetime-vu-verify.out index de673fd4ae6..4107ba95104 100644 --- a/test/JDBC/expected/latest__verification_cleanup__13_9__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__13_9__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/expected/latest__verification_cleanup__14_3__babel_datetime-vu-verify.out b/test/JDBC/expected/latest__verification_cleanup__14_3__babel_datetime-vu-verify.out index de673fd4ae6..4107ba95104 100644 --- a/test/JDBC/expected/latest__verification_cleanup__14_3__babel_datetime-vu-verify.out +++ b/test/JDBC/expected/latest__verification_cleanup__14_3__babel_datetime-vu-verify.out @@ -377,7 +377,7 @@ select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go ~~ERROR (Code: 517)~~ -~~ERROR (Message: data out of range for datetime)~~ +~~ERROR (Message: Adding a value to a 'datetime' column caused an overflow.)~~ -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) diff --git a/test/JDBC/input/babel_datetime-vu-verify.sql b/test/JDBC/input/babel_datetime-vu-verify.sql index 55395a3fda1..af11f60a3ab 100644 --- a/test/JDBC/input/babel_datetime-vu-verify.sql +++ b/test/JDBC/input/babel_datetime-vu-verify.sql @@ -128,7 +128,6 @@ go -- out of range select dateadd(year, 150, cast('9900-12-26 23:29:29' as datetime)) go - -- Test data type precedence TODO Fix [BABEL-883] missing TDS support for type regtype (was pg_typeof produces error in sqlcmd) select pg_typeof(c1) FROM (SELECT cast('2016-12-26 23:30:05' as datetime) as C1 UNION SELECT cast('2016-12-26 23:30:05' as smalldatetime) as C1) T go diff --git a/test/JDBC/input/babel_smalldatetime_before_15-5.sql b/test/JDBC/input/babel_smalldatetime_before_15-5.sql new file mode 100644 index 00000000000..390b4587710 --- /dev/null +++ b/test/JDBC/input/babel_smalldatetime_before_15-5.sql @@ -0,0 +1,102 @@ +-- Testing rounding behaviour when inserting into the table +create table smalldatetime_testing ( sm smalldatetime ); +INSERT INTO smalldatetime_testing VALUES('23:40:29.998'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:29.998'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:29.998'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:29.999'); +INSERT INTO smalldatetime_testing VALUES('1992-05-23 23:40:30.000'); +INSERT INTO smalldatetime_testing VALUES('2002-05-23 23:41:29.998'); +INSERT INTO smalldatetime_testing VALUES('2002-05-23 23:41:29.999'); +INSERT INTO smalldatetime_testing VALUES('2002-05-23 23:41:30.000'); +INSERT INTO smalldatetime_testing VALUES('2000-01-01 00:00:29.998'); +INSERT INTO smalldatetime_testing VALUES('2000-01-01 00:00:29.999'); +INSERT INTO smalldatetime_testing VALUES('1999-12-31 23:59:30.000'); +INSERT INTO smalldatetime_testing VALUES('1999-12-31 23:59:29.999'); +INSERT INTO smalldatetime_testing VALUES('1999-12-31 23:59:29.998'); +select * from smalldatetime_testing; +go + +-- Test comparision with datetime/smalldatetime/date +select * from smalldatetime_testing where sm >= cast('2000-01-01 00:00:59' as smalldatetime); +select * from smalldatetime_testing where sm >= cast('1992-05-23 23:40:00' as datetime) + and sm < cast('1992-05-23 23:41:00' as datetime); +select * from smalldatetime_testing where sm < cast(cast('1992-05-24' as date) as smalldatetime); +go + +-- Test rounding for 23:59:59 +SELECT CAST('1992-05-09 23:59:59' AS SMALLDATETIME); +SELECT CAST('2002-05-09 23:59:59' AS SMALLDATETIME); +SELECT CAST('1999-12-31 23:59:59' AS SMALLDATETIME); +go + +-- Test type cast to/from other time formats +-- Cast to smalldatetime +select CAST(CAST('00:00:00.234' AS time) AS smalldatetime); +select CAST(CAST('01:02:03.456' AS time) AS smalldatetime); +select CAST(CAST('2020-03-15' AS date) AS smalldatetime); +select CAST(CAST('2020-03-15' AS datetime) AS smalldatetime); +select CAST(CAST('2010-07-08 23:59:29.998' AS datetime) AS smalldatetime); +select CAST(CAST('1980-07-08 23:59:29.123456 +8:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('2010-07-08 23:59:29.123456 +8:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('1980-07-08 23:59:29.123456 -8:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('2010-07-08 23:59:29.123456 -8:00' AS datetimeoffset) AS smalldatetime); +go +-- Cast from smalldatetime +select CAST(CAST('2010-07-08' AS smalldatetime) AS time); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS time); +select CAST(CAST('2010-07-08 23:59:31.998' AS smalldatetime) AS time); +select CAST(CAST('1980-07-08 23:59:29.998' AS smalldatetime) AS time); +select CAST(CAST('1980-07-08 23:59:31.998' AS smalldatetime) AS time); +select CAST(CAST('2020-03-15' AS smalldatetime) AS date); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS date); +select CAST(CAST('2010-07-08 23:59:30.000' AS smalldatetime) AS date); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS datetime); +select CAST(CAST('1992-07-08 23:59:29.998' AS smalldatetime) AS datetime); +select CAST(CAST('2010-07-08 23:59:29.998' AS smalldatetime) AS datetimeoffset); +select CAST(CAST('1990-07-08 23:59:29.998' AS smalldatetime) AS datetimeoffset); +go + +-- Test smalldatetime value ranges +select cast('1900-01-01' as smalldatetime); +select cast('2079-06-06' as smalldatetime); +select cast('1899-12-31 23:59:29.999' as smalldatetime); +select cast('2079-06-06 23:59:29.998' as smalldatetime); +select CAST(CAST('1899-12-31 23:59:30.000' AS datetime) AS smalldatetime); +select CAST(CAST('1899-12-31 23:59:30.000 +0:00' AS datetimeoffset) AS smalldatetime); +select CAST(CAST('2079-06-06 23:59:30.000 +1:00' AS datetimeoffset) AS smalldatetime); +select cast('1899-12-31' as smalldatetime); -- out of range +select cast('2079-06-07' as smalldatetime); -- out of range +select cast('2079-06-06 23:59:29.999' as smalldatetime); -- out of range +select CAST(CAST('2099-03-15' AS date) AS smalldatetime); -- out of range +select CAST(CAST('1800-03-15 23:59:29.998' AS datetime) AS smalldatetime);-- out of range +select CAST(CAST('2099-03-15 23:59:29.998' AS datetime) AS smalldatetime);-- out of range +select CAST(CAST('1899-12-31 23:59:30.000 +1:00' AS datetimeoffset) AS smalldatetime);-- out of range +select CAST(CAST('2099-03-15 23:59:29.998 +6:00' AS datetimeoffset) AS smalldatetime);-- out of range +go + +-- Test smalldatetime default value +create table t1 (a smalldatetime, b int); +insert into t1 (b) values (1); +select a from t1 where b = 1; +go + +-- Test smalldatetime as parameter for time related functions +select day(cast('2002-05-23 23:41:29.998' as smalldatetime)); +select month(cast('2002-05-23 23:41:29.998' as smalldatetime)); +select year(cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(quarter, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(hour, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(dayofyear, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datepart(second, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datename(year, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datename(dw, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select datename(month, cast('2002-05-23 23:41:29.998' as smalldatetime)); +select dateadd(second, 56, cast('2016-12-26 23:29:29' as smalldatetime)); +select dateadd(minute, 56, cast('2016-12-26 23:29:29' as smalldatetime)); +select dateadd(year, 150, cast('2016-12-26 23:29:29' as smalldatetime)); -- Expect error +go + +-- Clean up +drop table smalldatetime_testing; +drop table t1; +go diff --git a/test/JDBC/input/dateFunctions/dateadd-vu-cleanup.sql b/test/JDBC/input/dateFunctions/dateadd-vu-cleanup.sql new file mode 100644 index 00000000000..64afaa6c7e6 --- /dev/null +++ b/test/JDBC/input/dateFunctions/dateadd-vu-cleanup.sql @@ -0,0 +1,29 @@ +DROP PROCEDURE dateadd_p1 +GO + +DROP PROCEDURE dateadd_p2 +GO + +DROP PROCEDURE dateadd_p3 +GO + +DROP PROCEDURE dateadd_p4 +GO + +DROP PROCEDURE dateadd_p5 +GO + +DROP PROCEDURE dateadd_p6 +GO + +DROP PROCEDURE dateadd_p7 +GO + +DROP PROCEDURE dateadd_p8 +GO + +DROP PROCEDURE dateadd_p9 +GO + +DROP PROCEDURE dateadd_p10 +GO \ No newline at end of file diff --git a/test/JDBC/input/dateFunctions/dateadd-vu-prepare.sql b/test/JDBC/input/dateFunctions/dateadd-vu-prepare.sql new file mode 100644 index 00000000000..eb893e92e02 --- /dev/null +++ b/test/JDBC/input/dateFunctions/dateadd-vu-prepare.sql @@ -0,0 +1,29 @@ +CREATE PROCEDURE dateadd_p1 as (select dateadd(day, 2, cast('1900-01-01' as date))); +GO + +CREATE PROCEDURE dateadd_p2 as (select dateadd(hour, 2, cast('01:01:21' as time))); +GO + +CREATE PROCEDURE dateadd_p3 as (select dateadd(hour, 5, cast('01:01:21 +10:00' as datetimeoffset))); +GO + +CREATE PROCEDURE dateadd_p4 as (select dateadd(second, 1, cast('1999-12-31 23:59:59' as datetime))); +GO + +CREATE PROCEDURE dateadd_p5 as (select dateadd(millisecond, 1, cast('1999-12-31 23:59:59' as datetime))); +GO + +CREATE PROCEDURE dateadd_p6 as (select dateadd(millisecond, 1, cast('1999-12-31 23:59:59' as datetime2))); +GO + +CREATE PROCEDURE dateadd_p7 as (select dateadd(day, 2, cast('01:01:21' as time))); +GO + +CREATE PROCEDURE dateadd_p8 as (select dateadd(hour, 2, cast('1900-01-01' as date))); +GO + +CREATE PROCEDURE dateadd_p9 as (select dateadd(minute, -70, cast('2016-12-26 00:30:05.523456+8' as datetimeoffset))); +GO + +CREATE PROCEDURE dateadd_p10 as (select sys.dateadd_internal_datetime('day', 1, cast('2016-12-26 00:30:05' as datetime), 3)); +GO diff --git a/test/JDBC/input/dateFunctions/dateadd-vu-verify.sql b/test/JDBC/input/dateFunctions/dateadd-vu-verify.sql new file mode 100644 index 00000000000..6a8c2d0a6ae --- /dev/null +++ b/test/JDBC/input/dateFunctions/dateadd-vu-verify.sql @@ -0,0 +1,90 @@ +exec dateadd_p1 +GO + +exec dateadd_p2 +GO + +exec dateadd_p3 +GO + +exec dateadd_p4 +GO + +exec dateadd_p5 +GO + +exec dateadd_p6 +GO + +exec dateadd_p7 +GO + +exec dateadd_p8 +GO + +exec dateadd_p9 +GO + +exec dateadd_p10 +GO + +begin transaction +go + +SELECT dateadd(fakeoption, 2, cast('1900-01-01' as date)); +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT dateadd(day, 2, cast('01:01:21' as time)); +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(YY,-300,getdate()); +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(YY,-30000000, cast('1900-01-01' as datetime)); +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(year,-300000000,cast('1900-01-01' as datetime)); +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + diff --git a/test/JDBC/input/dateFunctions/datediff-vu-cleanup.sql b/test/JDBC/input/dateFunctions/datediff-vu-cleanup.sql new file mode 100644 index 00000000000..675b046c78a --- /dev/null +++ b/test/JDBC/input/dateFunctions/datediff-vu-cleanup.sql @@ -0,0 +1,47 @@ +DROP PROCEDURE datediff_p1 +GO + +DROP PROCEDURE datediff_p2 +GO + +DROP PROCEDURE datediff_p3 +GO + +DROP PROCEDURE datediff_p4 +GO + +DROP PROCEDURE datediff_p5 +GO + +DROP PROCEDURE datediff_p6 +GO + +DROP PROCEDURE datediff_p7 +GO + +DROP PROCEDURE datediff_p8 +GO + +DROP PROCEDURE datediff_p9 +GO + +DROP PROCEDURE datediff_p10 +GO + +DROP PROCEDURE datediff_p11 +GO + +DROP PROCEDURE datediff_p12 +GO + +DROP PROCEDURE datediff_p13 +GO + +DROP PROCEDURE datediff_p14 +GO + +DROP PROCEDURE datediff_p15 +GO + +DROP PROCEDURE datediff_p16 +GO \ No newline at end of file diff --git a/test/JDBC/input/dateFunctions/datediff-vu-prepare.sql b/test/JDBC/input/dateFunctions/datediff-vu-prepare.sql new file mode 100644 index 00000000000..40cc2b58d42 --- /dev/null +++ b/test/JDBC/input/dateFunctions/datediff-vu-prepare.sql @@ -0,0 +1,60 @@ +-- 123 +CREATE PROCEDURE datediff_p1 as (select datediff(year, cast('1900-01-01' as datetime), cast('2023-01-02' as datetime))); +GO + +-- -30 +CREATE PROCEDURE datediff_p2 as (select datediff(year, cast('2020-01-01' as datetime), cast('1990-01-02' as datetime))); +GO + +-- -120 +CREATE PROCEDURE datediff_p3 as (select datediff(quarter, cast('2020-01-01' as datetime), cast('1990-01-02' as datetime))); +GO + +-- 24 +CREATE PROCEDURE datediff_p4 as (select datediff(month, cast('2020-01-01' as datetime), cast('2022-01-02' as datetime))); +GO + +-- 105 +CREATE PROCEDURE datediff_p5 as (select datediff(week, cast('2020-01-01' as datetime2), cast('2022-01-02' as datetime2))); +GO + +-- -10957 +CREATE PROCEDURE datediff_p6 as (select datediff(day, cast('2020-01-01' as smalldatetime), cast('1990-01-01' as smalldatetime))); +GO + +-- -262963 +CREATE PROCEDURE datediff_p7 as (select datediff(hour, cast('2020-01-01 01:01:20.99' as smalldatetime), cast('1990-01-01 06:01:20.99' as smalldatetime))); +GO +-- -15777780 +CREATE PROCEDURE datediff_p8 as (select datediff(minute, cast('2020-01-01 01:01:20.99' as datetime), cast('1990-01-01 06:01:20.99' as smalldatetime))); +GO + +-- 157885200 +CREATE PROCEDURE datediff_p9 as (select datediff(second, cast('2000-01-01 01:01:20.99' as datetime), cast('2005-01-01 10:01:20.99' as datetime))); +GO + +-- 32400000 +CREATE PROCEDURE datediff_p10 as (select datediff(millisecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 10:01:20.99' as datetime))); +GO + +-- 1200000000 +CREATE PROCEDURE datediff_p11 as (select datediff(microsecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 1:21:20.99' as datetime))); +GO + +-- overflow +CREATE PROCEDURE datediff_p12 as (select datediff(nanosecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 1:21:20.99' as datetime))); +GO + +-- 1200000000000 +CREATE PROCEDURE datediff_p13 as (select datediff_big(nanosecond, cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 1:21:20.99' as datetime))); +GO + +-- 15 +CREATE PROCEDURE datediff_p14 as (select datediff(hour, cast('2020-01-01 01:01:20.99 +10:00' as datetimeoffset), cast('2020-01-01 06:01:20.99' as datetimeoffset))); +GO + +CREATE PROCEDURE datediff_p15 as (select datediff(dayofyear, cast('2020-01-01 01:01:20.99 +10:00' as datetimeoffset), cast('2023-01-01 06:01:20.99' as datetimeoffset))); +GO + +CREATE PROCEDURE datediff_p16 as (select sys.datediff_internal_big('week', cast('2005-01-01 01:01:20.99' as datetime), cast('2005-01-01 01:01:20.99' as datetime))); +GO \ No newline at end of file diff --git a/test/JDBC/input/dateFunctions/datediff-vu-verify.sql b/test/JDBC/input/dateFunctions/datediff-vu-verify.sql new file mode 100644 index 00000000000..2792eef63c4 --- /dev/null +++ b/test/JDBC/input/dateFunctions/datediff-vu-verify.sql @@ -0,0 +1,85 @@ +-- 123 +exec datediff_p1 +GO + +-- -30 +exec datediff_p2 +GO + +-- -120 +exec datediff_p3 +GO + +-- 24 +exec datediff_p4 +GO + +-- 105 +exec datediff_p5 +GO + +-- -10957 +exec datediff_p6 +GO + +-- -262963 +exec datediff_p7 +GO + +-- -15777780 +exec datediff_p8 +GO + +-- 157885200 +exec datediff_p9 +GO + +-- 32400000 +exec datediff_p10 +GO + +-- 1200000000 +exec datediff_p11 +GO + +-- overflow +exec datediff_p12 +GO + +-- 1200000000000 +exec datediff_p13 +GO + +-- 15 +exec datediff_p14 +GO + +exec datediff_p15 +GO + +exec datediff_p16 +GO + +begin transaction +go + +SELECT DATEDIFF(fakeoption, cast('2023-01-01 01:01:20.98' as datetime), cast('2023-01-01 01:01:20.98' as datetime)) +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEDIFF(nanosecond, cast('1900-01-01 01:01:20.98' as datetime), cast('2023-01-01 01:01:20.98' as datetime)) +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO diff --git a/test/JDBC/input/functions/datediff_big-vu-verify.sql b/test/JDBC/input/functions/datediff_big-vu-verify.sql index 29bba9a2522..b969588987c 100644 --- a/test/JDBC/input/functions/datediff_big-vu-verify.sql +++ b/test/JDBC/input/functions/datediff_big-vu-verify.sql @@ -72,3 +72,39 @@ GO EXEC datediff_big_vu_prepare_p13 GO + +begin transaction +go + +SELECT DATEDIFF_BIG(fakeoption, cast('2023-01-01 01:01:20.98' as datetime), cast('2023-01-01 01:01:20.98' as datetime)) +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEDIFF_BIG(nanosecond, cast('1900-01-01 01:01:20.98' as datetime), cast('3000-01-01 01:01:20.98' as datetime)) +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO + +begin transaction +go + +SELECT DATEADD(YY,-30000000, cast('1900-01-01' as datetime)); +go + +if (@@trancount > 0) select cast('compile time error' as text) else select cast('runtime error' as text) +GO + +if (@@trancount > 0) rollback tran +GO \ No newline at end of file diff --git a/test/JDBC/input/functions/datediff_internal_date-vu-cleanup.sql b/test/JDBC/input/functions/datediff_internal_date-before-14_10-or-15_5-vu-cleanup.sql similarity index 100% rename from test/JDBC/input/functions/datediff_internal_date-vu-cleanup.sql rename to test/JDBC/input/functions/datediff_internal_date-before-14_10-or-15_5-vu-cleanup.sql diff --git a/test/JDBC/input/functions/datediff_internal_date-vu-prepare.sql b/test/JDBC/input/functions/datediff_internal_date-before-14_10-or-15_5-vu-prepare.sql similarity index 100% rename from test/JDBC/input/functions/datediff_internal_date-vu-prepare.sql rename to test/JDBC/input/functions/datediff_internal_date-before-14_10-or-15_5-vu-prepare.sql diff --git a/test/JDBC/input/functions/datediff_internal_date-vu-verify.sql b/test/JDBC/input/functions/datediff_internal_date-before-14_10-or-15_5-vu-verify.sql similarity index 100% rename from test/JDBC/input/functions/datediff_internal_date-vu-verify.sql rename to test/JDBC/input/functions/datediff_internal_date-before-14_10-or-15_5-vu-verify.sql diff --git a/test/JDBC/jdbc_schedule b/test/JDBC/jdbc_schedule index 797c18906eb..1f0fae49f82 100644 --- a/test/JDBC/jdbc_schedule +++ b/test/JDBC/jdbc_schedule @@ -140,9 +140,13 @@ ignore#!#test_windows_login_before_15_2-vu-cleanup ignore#!#datediff_internal_date-before-14_7-or-15_2-vu-prepare ignore#!#datediff_internal_date-before-14_7-or-15_2-vu-verify ignore#!#datediff_internal_date-before-14_7-or-15_2-vu-cleanup +ignore#!#datediff_internal_date-before-14_10-or-15_5-vu-prepare +ignore#!#datediff_internal_date-before-14_10-or-15_5-vu-verify +ignore#!#datediff_internal_date-before-14_10-or-15_5-vu-cleanup ignore#!#datetime2fromparts-vu-prepare ignore#!#datetime2fromparts-vu-verify ignore#!#datetime2fromparts-vu-cleanup +ignore#!#babel_smalldatetime_before_15-5 # These tests are meant for only upgrade ignore#!#openquery_upgrd-vu-prepare diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index 1064d1bdecf..4dd95acdc39 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -391,7 +391,6 @@ BABEL-3914 BABEL_OBJECT_NAME sys-systypes BABEL_OBJECT_DEFINITION -datediff_internal_date Test-sp_rename Test-sp_rename-dep BABEL-3657 diff --git a/test/JDBC/upgrade/14_7/schedule b/test/JDBC/upgrade/14_7/schedule index d71c2791683..4ceb592efb0 100644 --- a/test/JDBC/upgrade/14_7/schedule +++ b/test/JDBC/upgrade/14_7/schedule @@ -186,7 +186,7 @@ column_domain_usage constraint_column_usage dateadd_internal_df datediff_big -datediff_internal_date +datediff_internal_date-before-14_10-or-15_5 datepart datetime2fromparts forjson diff --git a/test/JDBC/upgrade/14_8/schedule b/test/JDBC/upgrade/14_8/schedule index deb6e59d059..527fc5e57a1 100644 --- a/test/JDBC/upgrade/14_8/schedule +++ b/test/JDBC/upgrade/14_8/schedule @@ -184,7 +184,7 @@ column_domain_usage constraint_column_usage dateadd_internal_df datediff_big -datediff_internal_date +datediff_internal_date-before-14_10-or-15_5 datepart datetime2fromparts forjson diff --git a/test/JDBC/upgrade/14_9/schedule b/test/JDBC/upgrade/14_9/schedule index fa471c060f5..367c135afa6 100644 --- a/test/JDBC/upgrade/14_9/schedule +++ b/test/JDBC/upgrade/14_9/schedule @@ -371,7 +371,7 @@ ISC-Columns ISC-Table_Constraints sys_server_principals_dep sys_database_principals_dep -datediff_big +datediff_big-before-15_5 atn2 app_name str @@ -391,7 +391,7 @@ BABEL-3914 BABEL_OBJECT_NAME sys-systypes BABEL_OBJECT_DEFINITION -datediff_internal_date +datediff_internal_date-before-14_10-or-15_5 Test-sp_rename Test-sp_rename-dep BABEL-3657 diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index 2d053948d7d..6fc69d77500 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -186,7 +186,7 @@ column_domain_usage constraint_column_usage dateadd_internal_df datediff_big -datediff_internal_date +datediff_internal_date-before-14_10-or-15_5 datepart datetime2fromparts forjson diff --git a/test/JDBC/upgrade/15_3/schedule b/test/JDBC/upgrade/15_3/schedule index 73a390d814d..9844bb16911 100644 --- a/test/JDBC/upgrade/15_3/schedule +++ b/test/JDBC/upgrade/15_3/schedule @@ -195,7 +195,7 @@ column_domain_usage constraint_column_usage dateadd_internal_df datediff_big -datediff_internal_date +datediff_internal_date-before-14_10-or-15_5 datepart datetime2fromparts-after-15-2 forjson diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index b18a4b72b0c..bf4ba499230 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -198,7 +198,7 @@ column_domain_usage constraint_column_usage dateadd_internal_df datediff_big -datediff_internal_date +datediff_internal_date-before-14_10-or-15_5 datepart datetime2fromparts-after-15-2 forjson diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index efe73dc34be..9743239b1d6 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -207,7 +207,8 @@ column_domain_usage constraint_column_usage dateadd_internal_df datediff_big -datediff_internal_date +datediff +dateadd datepart datetime2fromparts-after-15-2 forjson diff --git a/test/JDBC/upgrade/master/schedule b/test/JDBC/upgrade/master/schedule index e228922a6b5..e9845c928fb 100644 --- a/test/JDBC/upgrade/master/schedule +++ b/test/JDBC/upgrade/master/schedule @@ -162,7 +162,8 @@ collation_tests_mongolian collation_tests_polish dateadd_internal_df datediff_big -datediff_internal_date +datediff +dateadd datepart datetime2fromparts-after-15-2 forjson diff --git a/test/python/expected/sql_validation_framework/expected_create.out b/test/python/expected/sql_validation_framework/expected_create.out index 0aa3907ff7b..26777ae841c 100644 --- a/test/python/expected/sql_validation_framework/expected_create.out +++ b/test/python/expected/sql_validation_framework/expected_create.out @@ -14,7 +14,6 @@ Could not find tests for function sys.columns_internal Could not find tests for function sys.date_bucket_internal_helper Could not find tests for function sys.dateadd_internal Could not find tests for function sys.datediff_internal -Could not find tests for function sys.datediff_internal_df Could not find tests for function sys.datepart_internal Could not find tests for function sys.default_domain Could not find tests for function sys.get_current_full_xact_id @@ -116,7 +115,6 @@ Could not find upgrade tests for function sys.cursor_status Could not find upgrade tests for function sys.date_bucket_internal_helper Could not find upgrade tests for function sys.dateadd_internal Could not find upgrade tests for function sys.datediff_internal -Could not find upgrade tests for function sys.datediff_internal_df Could not find upgrade tests for function sys.datepart_internal Could not find upgrade tests for function sys.default_domain Could not find upgrade tests for function sys.error_line diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 904cd2cc24a..af4fc3240a8 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -313,11 +313,12 @@ Function sys.date2smalldatetime(date) Function sys.date_bucket_internal_helper(text,integer,boolean,boolean,anyelement) Function sys.date_sqlvariant(date) Function sys.dateadd_internal(text,integer,anyelement) +Function sys.dateadd_internal_datetime(text,integer,anyelement,integer) Function sys.datediff(text,sys.datetime2,sys.datetime2) Function sys.datediff(text,sys.smalldatetime,sys.smalldatetime) Function sys.datediff(text,time without time zone,time without time zone) Function sys.datediff_internal(text,anyelement,anyelement) -Function sys.datediff_internal_df(text,anyelement,anyelement) +Function sys.datediff_internal_big(text,anyelement,anyelement) Function sys.datefirst() Function sys.datefromparts(integer,integer,integer) Function sys.datename(text,text)