From 5d80c2a75b6902fe1832b500e42cf448f8bc8dbf Mon Sep 17 00:00:00 2001 From: Parikshit Sarode Date: Wed, 3 Jan 2024 16:52:21 +0530 Subject: [PATCH] Reimplement datepart function to improve the performance (#2195) 1/ sys. datepart_internal function takes longer time in Babelfish than expected 2/ The function is reimplemented in C for faster execution. 3/ Different wrapper functions are created according to the data type of the second argument in sys.datepart_internal. Additional tests are added covering all cases since previously incorrect query outputs were written in tests and logical errors were present in code Task: BABEL-4302, BABEL-979, BABEL-4366 Signed-off-by: Parikshit Sarode pasarode@amazon.com --- .../src/babelfishpg_common.c | 1 + .../src/babelfishpg_common.h | 1 + .../babelfishpg_common/src/datetimeoffset.h | 1 + contrib/babelfishpg_tsql/runtime/functions.c | 539 ++ .../babelfishpg_tsql/sql/sys_functions.sql | 163 +- .../babelfishpg_tsql--2.7.0--2.8.0.sql | 106 + test/JDBC/expected/BABEL_4302.out | 6304 +++++++++++++++++ test/JDBC/expected/datepart-vu-verify.out | 4 +- test/JDBC/input/BABEL_4302.sql | 2499 +++++++ .../expected_dependency.out | 19 +- 10 files changed, 9561 insertions(+), 76 deletions(-) create mode 100644 test/JDBC/expected/BABEL_4302.out create mode 100644 test/JDBC/input/BABEL_4302.sql diff --git a/contrib/babelfishpg_common/src/babelfishpg_common.c b/contrib/babelfishpg_common/src/babelfishpg_common.c index 0c13f90857..4b754ae336 100644 --- a/contrib/babelfishpg_common/src/babelfishpg_common.c +++ b/contrib/babelfishpg_common/src/babelfishpg_common.c @@ -183,6 +183,7 @@ get_common_utility_plugin(void) common_utility_plugin_var.datetime_in_str = &datetime_in_str; common_utility_plugin_var.datetime2sqlvariant = &datetime2sqlvariant; common_utility_plugin_var.timestamp_datetimeoffset = ×tamp_datetimeoffset; + common_utility_plugin_var.datetimeoffset_timestamp = &datetimeoffset_timestamp; common_utility_plugin_var.tinyint2sqlvariant = &tinyint2sqlvariant; common_utility_plugin_var.translate_pg_type_to_tsql = &translate_pg_type_to_tsql; common_utility_plugin_var.TdsGetPGbaseType = &TdsGetPGbaseType; diff --git a/contrib/babelfishpg_common/src/babelfishpg_common.h b/contrib/babelfishpg_common/src/babelfishpg_common.h index 7beb327118..72c6eb80e9 100644 --- a/contrib/babelfishpg_common/src/babelfishpg_common.h +++ b/contrib/babelfishpg_common/src/babelfishpg_common.h @@ -54,6 +54,7 @@ typedef struct common_utility_plugin Datum (*datetime_in_str) (char *str); Datum (*datetime2sqlvariant) (PG_FUNCTION_ARGS); Datum (*timestamp_datetimeoffset) (PG_FUNCTION_ARGS); + Datum (*datetimeoffset_timestamp) (PG_FUNCTION_ARGS); Datum (*tinyint2sqlvariant) (PG_FUNCTION_ARGS); Datum (*translate_pg_type_to_tsql) (PG_FUNCTION_ARGS); void (*TdsGetPGbaseType) (uint8 variantBaseType, int *pgBaseType, int tempLen, diff --git a/contrib/babelfishpg_common/src/datetimeoffset.h b/contrib/babelfishpg_common/src/datetimeoffset.h index 4fead652c5..d6bcf7676c 100644 --- a/contrib/babelfishpg_common/src/datetimeoffset.h +++ b/contrib/babelfishpg_common/src/datetimeoffset.h @@ -24,6 +24,7 @@ extern void CheckSmalldatetimeRange(const Timestamp time); extern void CheckDatetimeRange(const Timestamp time); extern void CheckDatetime2Range(const Timestamp time); extern Datum timestamp_datetimeoffset(PG_FUNCTION_ARGS); +extern Datum datetimeoffset_timestamp(PG_FUNCTION_ARGS); typedef struct tsql_datetimeoffset { int64 tsql_ts; diff --git a/contrib/babelfishpg_tsql/runtime/functions.c b/contrib/babelfishpg_tsql/runtime/functions.c index 71d6a3cb1f..22dd09dc38 100644 --- a/contrib/babelfishpg_tsql/runtime/functions.c +++ b/contrib/babelfishpg_tsql/runtime/functions.c @@ -3,6 +3,17 @@ #include "funcapi.h" #include "pgstat.h" +#include "postgres.h" +#include "access/hash.h" +#include "utils/builtins.h" +#include "utils/date.h" +#include "utils/datetime.h" +#include "libpq/pqformat.h" +#include "utils/timestamp.h" + +#include "fmgr.h" +#include "miscadmin.h" + #include "access/detoast.h" #include "access/htup_details.h" #include "access/table.h" @@ -52,6 +63,11 @@ #define TSQL_STAT_GET_ACTIVITY_COLS 25 #define SP_DATATYPE_INFO_HELPER_COLS 23 +#define DAYS_BETWEEN_YEARS_1900_TO_2000 36524 /* number of days present in between 1/1/1900 and 1/1/2000 */ +#define DATEPART_MAX_VALUE 2958463 /* maximum value for datepart general_integer_datatype */ +#define DATEPART_MIN_VALUE -53690 /* minimun value for datepart general_integer_datatype */ +#define DATEPART_SMALLMONEY_MAX_VALUE 214748.3647 /* maximum value for datepart smallmoney */ +#define DATEPART_SMALLMONEY_MIN_VALUE -53690 /* minimum value for datepart smallmoney */ typedef enum { @@ -136,11 +152,25 @@ PG_FUNCTION_INFO_V1(getutcdate); PG_FUNCTION_INFO_V1(getdate_internal); PG_FUNCTION_INFO_V1(sysdatetime); PG_FUNCTION_INFO_V1(sysdatetimeoffset); +PG_FUNCTION_INFO_V1(datepart_internal_int); +PG_FUNCTION_INFO_V1(datepart_internal_date); +PG_FUNCTION_INFO_V1(datepart_internal_datetime); +PG_FUNCTION_INFO_V1(datepart_internal_datetimeoffset); +PG_FUNCTION_INFO_V1(datepart_internal_time); +PG_FUNCTION_INFO_V1(datepart_internal_interval); +PG_FUNCTION_INFO_V1(datepart_internal_decimal); +PG_FUNCTION_INFO_V1(datepart_internal_float); +PG_FUNCTION_INFO_V1(datepart_internal_real); +PG_FUNCTION_INFO_V1(datepart_internal_money); +PG_FUNCTION_INFO_V1(datepart_internal_smallmoney); void *string_to_tsql_varchar(const char *input_str); void *get_servername_internal(void); void *get_servicename_internal(void); void *get_language(void); + +Datum datepart_internal(char *field , Timestamp timestamp , float8 df_tz, bool general_integer_datatype); + extern bool canCommitTransaction(void); extern bool is_ms_shipped(char *object_name, int type, Oid schema_id); @@ -168,6 +198,515 @@ const char *bbf_servicename = "MSSQLSERVER"; char *bbf_language = "us_english"; #define MD5_HASH_LEN 32 +/* + * datepart_internal take the timestamp and extracts + * year, month, week, dow, doy, etc. Fields for which date is needed + * back from the timestamp. df_tz is the offset of datetime when there is a + * valid timestamp and it is the general integer datatype when the timestamp + * is not valid for the general numeric datatypes + */ + +Datum +datepart_internal(char* field, Timestamp timestamp, float8 df_tz, bool general_integer_datatype) +{ + fsec_t fsec1; + Timestamp tsql_first_day, first_day; + struct pg_tm tt1, *tm = &tt1; + uint first_week_end, year, month, day, res = 0, day_of_year; /* for Zeller's Congruence */ + int tz1; + + /* + * This block is used when the second argument in datepart is not a + * date or time relate but instead general integer datatypes. datepart_internal converts the general integer datatypes (df_tz) + * into proper timestamp with days offset from 01/01/1970. The general integer datatypes are passed in the df_tz + * i.e. when df_tz = 1.5, it changes to timestamp corresponding to 02/01/1970 12:00:00 + * Converting the df_tz into the appopriate timestamp that is offset from 01/01/1970 by df_tz days (and hours) + */ + if (timestamp == 0 && general_integer_datatype) + { + /* Checking for the limits for general_integer_datatype */ + if(df_tz > DATEPART_MAX_VALUE || df_tz < DATEPART_MIN_VALUE) + { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("Arithmetic overflow error converting expression to data type datetime."))); + } + + timestamp = (Timestamp)(((df_tz) - DAYS_BETWEEN_YEARS_1900_TO_2000) * USECS_PER_DAY); + } + + /* Gets the date time related fields back from timestamp into struct tm pointer */ + if (timestamp2tm(timestamp, &tz1, tm, &fsec1, NULL, NULL) != 0) + { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("Arithmetic overflow error converting expression to data type datetime."))); + } + + year = tm->tm_year; + month = tm->tm_mon; + day = tm->tm_mday; + + if (strcmp(field, "year") == 0) + { + PG_RETURN_INT32(tm->tm_year); + } + else if (strcmp(field, "quarter") == 0) + { + /* There are 3 months in each quarter ( 12 / 3 = 4 ) */ + PG_RETURN_INT32((int)ceil((float)tm->tm_mon / 3.0)); + } + else if (strcmp(field, "month") == 0) + { + PG_RETURN_INT32(tm->tm_mon); + } + else if (strcmp(field, "day") == 0) + { + PG_RETURN_INT32(tm->tm_mday); + } + else if (strcmp(field, "hour") == 0) + { + PG_RETURN_INT32(tm->tm_hour); + } + else if (strcmp(field, "minute") == 0) + { + PG_RETURN_INT32(tm->tm_min); + } + else if (strcmp(field, "second") == 0) + { + PG_RETURN_INT32(tm->tm_sec); + } + else if (strcmp(field, "doy") == 0) /* day-of-year of the date */ + { + PG_RETURN_INT32( (date2j(tm->tm_year, tm->tm_mon, tm->tm_mday) + - date2j(tm->tm_year, 1, 1) + 1)); + } + else if (strcmp(field, "dow") == 0) /* day-of-week of the date */ + { + /* dow calculated using Zeller's Congruence */ + if (tm->tm_mon < 3) + { + month += MONTHS_PER_YEAR; + year -= 1; + } + + /* + * Zeller’s congruence is an algorithm devised by Christian Zeller to calculate + * the day of the week for any calendar date. + * Here is a formula for finding the day of the week for ANY date. + * N = d + 2m + [3(m+1)/5] + y + [y/4] - [y/100] + [y/400] + 2 + * where d is the number of the day of the month, m is the number of the month, and y is the year. + * The brackets around the divisions mean to drop the remainder and just use the integer part that you get. + * Also, a VERY IMPORTANT RULE is the number to use for the months for January and February. + * The numbers of these months are 13 and 14 of the PREVIOUS YEAR. This means that to find the day of the week of New Year's Day this year, 1/1/98, + * you must use the date 13/1/97. + */ + res = (day + 2 * month + ((3 * (month + 1)) / (5)) + year + + year / 4 - year / 100 + year / 400 + 2) % 7; + + /* Adjusting the dow accourding to the datefirst guc */ + PG_RETURN_INT32(((res) + 7 - pltsql_datefirst)%7 == 0 ? + 7 : ((res) + 7 - pltsql_datefirst)%7); + + } + else if (strcasecmp(field , "tsql_week") == 0) /* week number of the year */ + { + /* returns number of days since 1/1/1970 to 1/1/tm_year */ + first_day = date2j(tm->tm_year, 1, 1) - UNIX_EPOCH_JDATE; + + /* convert this first day of tm_year to timestamp into tsql_first_day */ + tsql_first_day = (Timestamp) (first_day - (POSTGRES_EPOCH_JDATE - UNIX_EPOCH_JDATE)) * USECS_PER_DAY; + + first_week_end = 8 - datepart_internal("dow", tsql_first_day, 0, false); + + day_of_year = datepart_internal("doy",timestamp,0, false); + + if(day_of_year <= first_week_end) + { + /* day of year is less than first_week_end means its a first week */ + PG_RETURN_INT32(1); + } + else + { + PG_RETURN_INT32(2+(day_of_year - first_week_end - 1) / 7); + } + } + else if(strcasecmp(field , "week") == 0) + { + PG_RETURN_INT32(date2isoweek(tm->tm_year, tm->tm_mon, tm->tm_mday)); + } + else if(strcasecmp(field , "millisecond") == 0) + { + PG_RETURN_INT32((fsec1) / 1000); + } + else if(strcasecmp(field , "microsecond") == 0) + { + PG_RETURN_INT32(fsec1); + } + else if(strcasecmp(field , "nanosecond") == 0) + { + PG_RETURN_INT32((fsec1) * 1000); + } + else if(strcasecmp(field , "tzoffset") == 0) + { + if(general_integer_datatype) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart tzoffset is not supported by date function datepart for data type datetime."))); + + PG_RETURN_INT32(-1); + } + else + { + PG_RETURN_INT32((int)df_tz); + } + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\'%s\' is not a recognized datepart option",field))); + + PG_RETURN_INT32(-1); + } + + PG_RETURN_INT32(1); +} + + +/* + * datepart_internal_datetimeoffset takes datetimeoffset and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_datetimeoffset(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + Timestamp timestamp; + int df_tz = PG_GETARG_INT32(2); + + timestamp = (Timestamp)(DirectFunctionCall1(common_utility_plugin_ptr->datetimeoffset_timestamp, + PG_GETARG_DATUM(1))); + + timestamp = timestamp + (Timestamp) df_tz * SECS_PER_MINUTE * USECS_PER_SEC; + + return datepart_internal(field, timestamp, (float8)df_tz, false); +} + +/* + * datepart_internal_date takes date and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_date(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + Timestamp timestamp; + int df_tz = PG_GETARG_INT32(2); + + timestamp = DirectFunctionCall1(date_timestamp, PG_GETARG_DATUM(1)); + + return datepart_internal(field, timestamp, (float8)df_tz, false); +} + +/* + * datepart_internal_datetime takes datetime and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_datetime(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + Timestamp timestamp; + int df_tz = PG_GETARG_INT32(2); + + timestamp = PG_GETARG_TIMESTAMP(1); + + return datepart_internal(field, timestamp, (float8)df_tz, false); +} + +/* + * datepart_internal_int takes int and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_int(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + int64 num = PG_GETARG_INT64(1); + + /* + * Setting the timestamp in datepart_internal as 0 and passing num in third argument + * as there is no need of df_tz + */ + return datepart_internal(field, 0, num, true); + +} + +/* + * datepart_internal_money takes money and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_money(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + int64 num = PG_GETARG_INT64(1); + + /* + * Setting the timestamp in datepart_internal as 0 and passing num in third argument + * as there is no need of df_tz. Also dividing num by 10000 as money datatype + * gets a multiple of 10000 internally + */ + return datepart_internal(field, 0, (float8)num/10000, true); +} + +/* + * datepart_internal_smallmoney takes int and converts it to + * timestamp and calls datepart_internal and checks limits + */ + +Datum +datepart_internal_smallmoney(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + int64 arg = PG_GETARG_INT64(1); + float8 num; + + /* Dividing arg by 10000 as money datatype gets a multiple of 10000 internally*/ + num = (float8)arg/10000; + + if(num > DATEPART_SMALLMONEY_MAX_VALUE || num < DATEPART_SMALLMONEY_MIN_VALUE) + { + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("Arithmetic overflow error converting expression to data type datetime."))); + } + + /* + * Setting the timestamp in datepart_internal as 0 and passing num in third argument + * as there is no need of df_tz. + */ + return datepart_internal(field, 0, num, true); +} + +/* + * datepart_internal_decimal takes decimal and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_decimal(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + Numeric argument = PG_GETARG_NUMERIC(1); + float8 num = DatumGetFloat8(DirectFunctionCall1(numeric_float8, NumericGetDatum(argument))); + + /* + * Setting the timestamp in datepart_internal as 0 and passing num in third argument + * as there is no need of df_tz + */ + return datepart_internal(field, 0, num, true); +} + +/* + * datepart_internal_float takes float and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_float(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + float8 arg = PG_GETARG_FLOAT8(1); + + /* + * Setting the timestamp in datepart_internal as 0 and passing arg in third argument + * as there is no need of df_tz + */ + return datepart_internal(field, 0, arg, true); +} + +/* + * datepart_internal_real takes real value and converts it to + * timestamp and calls datepart_internal + */ + +Datum +datepart_internal_real(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + float4 arg = PG_GETARG_FLOAT4(1); + + /* + * Setting the timestamp in datepart_internal as 0 and passing arg in third argument + * as there is no need of df_tz + */ + return datepart_internal(field, 0, arg, true); +} + +/* + * datepart_internal_time takes timestamp and calls datepart_internal + * and thorows valid errors wherever necessary + */ + +Datum +datepart_internal_time(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + Timestamp timestamp; + int df_tz = PG_GETARG_INT32(2); + + timestamp = PG_GETARG_TIMESTAMP(1); + + if(timestamp <= USECS_PER_DAY ) /* when only time is given and no date, we adjust the timestamp date to 1/1/1900 instead of 1/1/2000 */ + { + timestamp = timestamp - (Timestamp)(DAYS_BETWEEN_YEARS_1900_TO_2000 * USECS_PER_DAY * 1L); + + if(strcasecmp(field , "quarter") == 0 || strcasecmp(field , "month") == 0 || + strcasecmp(field , "day") == 0 || strcasecmp(field , "year") == 0 ) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart %s is not supported by date function datepart for data type time.", field))); + } + else if(strcasecmp(field , "dow") == 0) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart weekday is not supported by date function datepart for data type time."))); + } + else if(strcasecmp(field , "doy") == 0) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart dayofyear is not supported by date function datepart for data type time."))); + } + else if(strcasecmp(field , "week") == 0) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart iso_week is not supported by date function datepart for data type time."))); + } + else if(strcasecmp(field , "tsql_week") == 0) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("The datepart week is not supported by date function datepart for data type time."))); + } + } + + return datepart_internal(field, timestamp, (float8)df_tz, false); +} + +/* + * datepart_internal_interval takes interval and extracts the required field + * Since it is interval, there is no need to call datepart_internal + */ + +Datum +datepart_internal_interval(PG_FUNCTION_ARGS) +{ + char *field = text_to_cstring(PG_GETARG_TEXT_PP(0)); + int df_tz = PG_GETARG_INT32(2); + int64 result; + + Interval *interval = PG_GETARG_INTERVAL_P(1); + Timestamp interval_time = interval->time + (Timestamp) df_tz * SECS_PER_MINUTE * USECS_PER_SEC; + int32 interval_days,interval_month; + float8 year,month,days,hours,minutes,sec; + int32 millisec,microsec,nanosec; + + interval_days = interval->day; + interval_month = interval->month; + + /* Extracting year, months, days, etc from the interval period. */ + year = interval_month / MONTHS_PER_YEAR; + month = (interval_month % MONTHS_PER_YEAR); + days = interval_days; + + hours = (interval_time / USECS_PER_HOUR); + minutes = (interval_time / USECS_PER_MINUTE); + + if(interval_time < USECS_PER_SEC) + { + sec = ((float8)interval_time / USECS_PER_SEC); + } + else + { + sec = (interval_time % USECS_PER_SEC) % SECS_PER_MINUTE; + } + + millisec = (int32)(sec * 1000); + microsec = (int32)(millisec * 1000); + nanosec = (int32)(microsec) * 1000; + + if(strcasecmp(field , "year") == 0) + { + result = (int)year; + } + else if(strcasecmp(field , "quarter") == 0) + { + result = (int)ceil((float)month / 3.0); + } + else if(strcasecmp(field , "month") == 0) + { + result = (int)month; + } + else if(strcasecmp(field , "day") == 0) + { + result = (int)days; + } + else if(strcasecmp(field , "y") == 0) + { + result = (int)year; + } + else if(strcasecmp(field , "hour") == 0) + { + result = (int)hours; + } + else if(strcasecmp(field , "minute") == 0) + { + result = (int)minutes; + } + else if(strcasecmp(field , "second") == 0) + { + result = (int)sec; + } + else if(strcasecmp(field , "nanosecond") == 0) + { + result = nanosec; + } + else if(strcasecmp(field , "millisecond") == 0) + { + result = millisec; + } + else if(strcasecmp(field , "microsecond") == 0) + { + result = microsec; + } + else if(strcasecmp(field , "tzoffset") == 0) + { + result = 0; + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\'%s\' is not a recognized datepart option", field))); + + } + + PG_RETURN_INT32(result); +} + + Datum trancount(PG_FUNCTION_ARGS) { diff --git a/contrib/babelfishpg_tsql/sql/sys_functions.sql b/contrib/babelfishpg_tsql/sql/sys_functions.sql index 9062563d5b..be580efceb 100644 --- a/contrib/babelfishpg_tsql/sql/sys_functions.sql +++ b/contrib/babelfishpg_tsql/sql/sys_functions.sql @@ -154,6 +154,96 @@ RETURNS sys.NVARCHAR(128) AS 'babelfishpg_tsql', 'suser_name' LANGUAGE C IMMUTABLE PARALLEL RESTRICTED; +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.BIT ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_int' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date INT ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_int' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date BIGINT ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_int' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.TINYINT ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_int' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date SMALLINT ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_int' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.MONEY ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_money' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.SMALLMONEY ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_smallmoney' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date date ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_date' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.datetime ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_datetime' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.datetime2 ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_datetime' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.smalldatetime ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_datetime' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.DATETIMEOFFSET ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_datetimeoffset' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date time ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_time' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date INTERVAL ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_interval' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.DECIMAL ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_decimal' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date NUMERIC ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_decimal' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date REAL ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_real' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date FLOAT ,df_tz INTEGER DEFAULT 0) +RETURNS INTEGER +AS 'babelfishpg_tsql', 'datepart_internal_float' +LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + CREATE OR REPLACE FUNCTION sys.suser_name(IN server_user_id OID) RETURNS sys.NVARCHAR(128) AS $$ SELECT CASE @@ -1188,79 +1278,6 @@ END; $body$ LANGUAGE plpgsql IMMUTABLE; -CREATE OR REPLACE FUNCTION sys.datepart_internal(IN datepart PG_CATALOG.TEXT, IN arg anyelement,IN df_tz INTEGER DEFAULT 0) RETURNS INTEGER AS $$ -DECLARE - result INTEGER; - first_day DATE; - first_week_end INTEGER; - day INTEGER; -BEGIN - CASE datepart - WHEN 'dow' THEN - result = (date_part(datepart, arg)::INTEGER - current_setting('babelfishpg_tsql.datefirst')::INTEGER + 7) % 7 + 1; - WHEN 'tsql_week' THEN - first_day = make_date(date_part('year', arg)::INTEGER, 1, 1); - first_week_end = 8 - sys.datepart_internal('dow', first_day)::INTEGER; - day = date_part('doy', arg)::INTEGER; - IF day <= first_week_end THEN - result = 1; - ELSE - result = 2 + (day - first_week_end - 1) / 7; - END IF; - WHEN 'second' THEN - result = TRUNC(date_part(datepart, arg))::INTEGER; - WHEN 'millisecond' THEN - result = right(date_part(datepart, arg)::TEXT, 3)::INTEGER; - WHEN 'microsecond' THEN - result = right(date_part(datepart, arg)::TEXT, 6)::INTEGER; - WHEN 'nanosecond' THEN - -- Best we can do - Postgres does not support nanosecond precision - result = right(date_part('microsecond', arg)::TEXT, 6)::INTEGER * 1000; - WHEN 'tzoffset' THEN - -- timezone for datetimeoffset - result = df_tz; - ELSE - result = date_part(datepart, arg)::INTEGER; - END CASE; - RETURN result; -EXCEPTION WHEN invalid_parameter_value THEN - -- date_part() throws an exception when trying to get day/month/year etc. from - -- TIME, so we just need to catch the exception in this case - -- date_part() returns 0 when trying to get hour/minute/second etc. from - -- DATE, which is the desirable behavior for datepart() as well. - -- If the date argument data type does not have the specified datepart, - -- date_part() will return the default value for that datepart. - CASE datepart - -- Case for datepart is year, yy and yyyy, all mappings are defined in gram.y. - WHEN 'year' THEN RETURN 1900; - -- Case for datepart is quater, qq and q - WHEN 'quarter' THEN RETURN 1; - -- Case for datepart is month, mm and m - WHEN 'month' THEN RETURN 1; - -- Case for datepart is day, dd and d - WHEN 'day' THEN RETURN 1; - -- Case for datepart is dayofyear, dy - WHEN 'doy' THEN RETURN 1; - -- Case for datepart is y(also refers to dayofyear) - WHEN 'y' THEN RETURN 1; - -- Case for datepart is week, wk and ww - WHEN 'tsql_week' THEN RETURN 1; - -- Case for datepart is iso_week, isowk and isoww - WHEN 'week' THEN RETURN 1; - -- Case for datepart is tzoffset and tz - WHEN 'tzoffset' THEN RETURN 0; - -- Case for datepart is weekday and dw, return dow according to datefirst - WHEN 'dow' THEN - RETURN (1 - current_setting('babelfishpg_tsql.datefirst')::INTEGER + 7) % 7 + 1 ; - ELSE - RAISE EXCEPTION '''%'' is not a recognized datepart option', datepart; - RETURN -1; - END CASE; -END; -$$ -STRICT -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); diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql index 58e82db736..2c8bee1a9a 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql @@ -49,6 +49,112 @@ LANGUAGE plpgsql; * final behaviour. */ +DO $$ +DECLARE + exception_message text; +BEGIN + + ALTER FUNCTION sys.datepart_internal(PG_CATALOG.TEXT, anyelement, INTEGER) RENAME TO datepart_internal_deprecated_3_5; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.BIT ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_int' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.TINYINT ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_int' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date SMALLINT ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_int' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date INT ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_int' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date BIGINT ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_int' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.MONEY ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_money' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.SMALLMONEY ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_money' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date date ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_date' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.datetime ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_datetime' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.datetime2 ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_datetime' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.smalldatetime ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_datetime' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.DATETIMEOFFSET ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_datetimeoffset' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date time ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_time' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date INTERVAL ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_interval' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date sys.DECIMAL ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_decimal' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date NUMERIC ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_decimal' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date REAL ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_real' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CREATE OR REPLACE FUNCTION sys.datepart_internal(field text, datapart_date FLOAT ,df_tz INTEGER DEFAULT 0) + RETURNS INTEGER + AS 'babelfishpg_tsql', 'datepart_internal_float' + LANGUAGE C STRICT IMMUTABLE PARALLEL SAFE; + + CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'datepart_internal_deprecated_3_5'); + +EXCEPTION WHEN OTHERS THEN + GET STACKED DIAGNOSTICS + exception_message = MESSAGE_TEXT; + RAISE WARNING '%', exception_message; +END; +$$; + CREATE OR REPLACE VIEW sys.sp_pkeys_view AS SELECT CAST(t4."TABLE_CATALOG" AS sys.sysname) AS TABLE_QUALIFIER, diff --git a/test/JDBC/expected/BABEL_4302.out b/test/JDBC/expected/BABEL_4302.out new file mode 100644 index 0000000000..8e05c68a4c --- /dev/null +++ b/test/JDBC/expected/BABEL_4302.out @@ -0,0 +1,6304 @@ + +-- DATEPART with 'day' and different data types +GO +SELECT DATEPART(day, CAST(100987 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(day, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(day, CAST(6542 AS int)); +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(day, CAST(1111 AS smallint)); +GO +~~START~~ +int +17 +~~END~~ + + +SELECT DATEPART(day, CAST(999999 AS bigint)); +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(day, CAST(42 AS tinyint)); +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(day, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +21 +~~END~~ + + +SELECT DATEPART(day, CAST(987654.321 AS real)); +GO +~~START~~ +int +9 +~~END~~ + + +SELECT DATEPART(day, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +21 +~~END~~ + + +SELECT DATEPART(day, CAST(3.14159 AS float)); +GO +~~START~~ +int +4 +~~END~~ + + + +-- DATEPART with 'month' and different data types +GO +SELECT DATEPART(month, CAST(100987 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(month, CAST(6542 AS int)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(month, CAST(1111 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, CAST(999999 AS bigint)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(month, CAST(42 AS tinyint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(month, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(month, CAST(987654.321 AS real)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(month, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(month, CAST(3.14159 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + +-- DATEPART with 'week' and different data types +SELECT DATEPART(week, CAST(100987 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(week, CAST(14 AS smallmoney)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(week, CAST(6542 AS int)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(week, CAST(1111 AS smallint)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(week, CAST(999999 AS bigint)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(week, CAST(42 AS tinyint)); +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(week, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +21 +~~END~~ + + +SELECT DATEPART(week, CAST(987654.321 AS real)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(week, CAST(14 AS numeric)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(week, CAST(3.14159 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'year' and different data types +GO +SELECT DATEPART(year, CAST(100987 AS bit)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(year, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(year, CAST(6542 AS int)); +GO +~~START~~ +int +1917 +~~END~~ + + +SELECT DATEPART(year, CAST(1111 AS smallint)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(year, CAST(999999 AS bigint)); +GO +~~START~~ +int +4637 +~~END~~ + + +SELECT DATEPART(year, CAST(42 AS tinyint)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(year, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(year, CAST(987654.321 AS real)); +GO +~~START~~ +int +4604 +~~END~~ + + +SELECT DATEPART(year, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +2760 +~~END~~ + + +SELECT DATEPART(year, CAST(3.14159 AS float)); +GO +~~START~~ +int +1900 +~~END~~ + + + +-- DATEPART with 'weekday' and different data types +GO +SELECT DATEPART(weekday, CAST(100987 AS bit)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(weekday, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(weekday, CAST(6542 AS int)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(weekday, CAST(1111 AS smallint)); +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, CAST(999999 AS bigint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(weekday, CAST(42 AS tinyint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(weekday, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(weekday, CAST(987654.321 AS real)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(weekday, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(weekday, CAST(3.14159 AS float)); +GO +~~START~~ +int +5 +~~END~~ + + + +-- DATEPART with 'yy' (year without century) and different data types +GO +SELECT DATEPART(yy, CAST(100987 AS bit)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yy, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(yy, CAST(6542 AS int)); +GO +~~START~~ +int +1917 +~~END~~ + + +SELECT DATEPART(yy, CAST(1111 AS smallint)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(yy, CAST(999999 AS bigint)); +GO +~~START~~ +int +4637 +~~END~~ + + +SELECT DATEPART(yy, CAST(42 AS tinyint)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yy, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(yy, CAST(987654.321 AS real)); +GO +~~START~~ +int +4604 +~~END~~ + + +SELECT DATEPART(yy, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +2760 +~~END~~ + + +SELECT DATEPART(yy, CAST(3.14159 AS float)); +GO +~~START~~ +int +1900 +~~END~~ + + + +-- DATEPART with 'yyyy' (year with century) and different data types +GO +SELECT DATEPART(yyyy, CAST(100987 AS bit)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(6542 AS int)); +GO +~~START~~ +int +1917 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(1111 AS smallint)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(999999 AS bigint)); +GO +~~START~~ +int +4637 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(42 AS tinyint)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +1903 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(987654.321 AS real)); +GO +~~START~~ +int +4604 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +2760 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(3.14159 AS float)); +GO +~~START~~ +int +1900 +~~END~~ + + + +-- DATEPART with 'qq' (quarter) and different data types +GO +SELECT DATEPART(qq, CAST(100987 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, CAST(6542 AS int)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(qq, CAST(1111 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(999999 AS bigint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(qq, CAST(42 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, CAST(987654.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(3.14159 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'q' (quarter) and different data types +GO +SELECT DATEPART(q, CAST(100987 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(q, CAST(6542 AS int)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(q, CAST(1111 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(999999 AS bigint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(q, CAST(42 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(q, CAST(987654.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(3.14159 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'mm' (month) and different data types +GO +SELECT DATEPART(mm, CAST(100987 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(mm, CAST(6542 AS int)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(mm, CAST(1111 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, CAST(999999 AS bigint)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(mm, CAST(42 AS tinyint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(mm, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(mm, CAST(987654.321 AS real)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(mm, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(mm, CAST(3.14159 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'm' (month) and different data types +GO +SELECT DATEPART(m, CAST(100987 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(m, CAST(6542 AS int)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(m, CAST(1111 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, CAST(999999 AS bigint)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(m, CAST(42 AS tinyint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(m, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(m, CAST(987654.321 AS real)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(m, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(m, CAST(3.14159 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'dy' (day of the year) and different data types +GO +SELECT DATEPART(dy, CAST(100987 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dy, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +140 +~~END~~ + + +SELECT DATEPART(dy, CAST(6542 AS int)); +GO +~~START~~ +int +334 +~~END~~ + + +SELECT DATEPART(dy, CAST(1111 AS smallint)); +GO +~~START~~ +int +17 +~~END~~ + + +SELECT DATEPART(dy, CAST(999999 AS bigint)); +GO +~~START~~ +int +331 +~~END~~ + + +SELECT DATEPART(dy, CAST(42 AS tinyint)); +GO +~~START~~ +int +43 +~~END~~ + + +SELECT DATEPART(dy, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +141 +~~END~~ + + +SELECT DATEPART(dy, CAST(987654.321 AS real)); +GO +~~START~~ +int +40 +~~END~~ + + +SELECT DATEPART(dy, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +52 +~~END~~ + + +SELECT DATEPART(dy, CAST(3.14159 AS float)); +GO +~~START~~ +int +4 +~~END~~ + + + +-- DATEPART with 'y' (day of the year) and different data types +GO +SELECT DATEPART(y, CAST(100987 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(y, CAST(1234 AS smallmoney)); +GO +~~START~~ +int +140 +~~END~~ + + +SELECT DATEPART(y, CAST(6542 AS int)); +GO +~~START~~ +int +334 +~~END~~ + + +SELECT DATEPART(y, CAST(1111 AS smallint)); +GO +~~START~~ +int +17 +~~END~~ + + +SELECT DATEPART(y, CAST(999999 AS bigint)); +GO +~~START~~ +int +331 +~~END~~ + + +SELECT DATEPART(y, CAST(42 AS tinyint)); +GO +~~START~~ +int +43 +~~END~~ + + +SELECT DATEPART(y, CAST(1234.789 AS decimal)); +GO +~~START~~ +int +141 +~~END~~ + + +SELECT DATEPART(y, CAST(987654.321 AS real)); +GO +~~START~~ +int +40 +~~END~~ + + +SELECT DATEPART(y, CAST(314159.432 AS numeric)); +GO +~~START~~ +int +52 +~~END~~ + + +SELECT DATEPART(y, CAST(3.14159 AS float)); +GO +~~START~~ +int +4 +~~END~~ + + + +-- DATEPART with 'dd' (day of the month) and different data types +GO +SELECT DATEPART(dd, CAST(1234 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dd, CAST(7890 AS smallmoney)); +GO +~~START~~ +int +9 +~~END~~ + + +SELECT DATEPART(dd, CAST(6542 AS int)); +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(dd, CAST(4567 AS smallint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(dd, CAST(333333 AS bigint)); +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(dd, CAST(24 AS tinyint)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(dd, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +22 +~~END~~ + + +SELECT DATEPART(dd, CAST(321987.654 AS real)); +GO +~~START~~ +int +28 +~~END~~ + + +SELECT DATEPART(dd, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +9 +~~END~~ + + +SELECT DATEPART(dd, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'd' (day of the month) and different data types +GO +SELECT DATEPART(d, CAST(1234 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(d, CAST(7890 AS smallmoney)); +GO +~~START~~ +int +9 +~~END~~ + + +SELECT DATEPART(d, CAST(6542 AS int)); +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(d, CAST(4567 AS smallint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(d, CAST(333333 AS bigint)); +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(d, CAST(24 AS tinyint)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(d, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +22 +~~END~~ + + +SELECT DATEPART(d, CAST(321987.654 AS real)); +GO +~~START~~ +int +28 +~~END~~ + + +SELECT DATEPART(d, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +9 +~~END~~ + + +SELECT DATEPART(d, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'wk' (week) and different data types +GO +SELECT DATEPART(wk, CAST(1234 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(wk, CAST(7810 AS smallmoney)); +GO +~~START~~ +int +21 +~~END~~ + + +SELECT DATEPART(wk, CAST(6542 AS int)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(wk, CAST(4567 AS smallint)); +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(wk, CAST(333333 AS bigint)); +GO +~~START~~ +int +34 +~~END~~ + + +SELECT DATEPART(wk, CAST(24 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(wk, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(wk, CAST(3287.654 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(wk, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(wk, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'ww' (week) and different data types +GO +SELECT DATEPART(ww, CAST(1234 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(ww, CAST(780 AS smallmoney)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(ww, CAST(6542 AS int)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(ww, CAST(4567 AS smallint)); +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(ww, CAST(333333 AS bigint)); +GO +~~START~~ +int +34 +~~END~~ + + +SELECT DATEPART(ww, CAST(24 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(ww, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(ww, CAST(3987.654 AS real)); +GO +~~START~~ +int +49 +~~END~~ + + +SELECT DATEPART(ww, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(ww, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'dw' (weekday) and different data types +GO +SELECT DATEPART(dw, CAST(1234 AS bit)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(dw, CAST(7890 AS smallmoney)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(dw, CAST(6542 AS int)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(dw, CAST(4567 AS smallint)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(dw, CAST(333333 AS bigint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dw, CAST(24 AS tinyint)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(dw, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(dw, CAST(321987.654 AS real)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(dw, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(dw, CAST(0.12345 AS float)); +GO +~~START~~ +int +2 +~~END~~ + + + +-- DATEPART with 'iso_week' (ISO week) and different data types +GO +SELECT DATEPART(iso_week, CAST(1234 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(7890 AS smallmoney)); +GO +~~START~~ +int +32 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(6542 AS int)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(4567 AS smallint)); +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(333333 AS bigint)); +GO +~~START~~ +int +34 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(24 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(197.64 AS real)); +GO +~~START~~ +int +29 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'isowk' (ISO week) and different data types +GO +SELECT DATEPART(isowk, CAST(1234 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(isowk, CAST(7890 AS smallmoney)); +GO +~~START~~ +int +32 +~~END~~ + + +SELECT DATEPART(isowk, CAST(6542 AS int)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(isowk, CAST(4567 AS smallint)); +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(isowk, CAST(333333 AS bigint)); +GO +~~START~~ +int +34 +~~END~~ + + +SELECT DATEPART(isowk, CAST(24 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(isowk, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(isowk, CAST(327.654 AS real)); +GO +~~START~~ +int +47 +~~END~~ + + +SELECT DATEPART(isowk, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(isowk, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'isoww' (ISO week) and different data types +GO +SELECT DATEPART(isoww, CAST(1234 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(isoww, CAST(7890 AS smallmoney)); +GO +~~START~~ +int +32 +~~END~~ + + +SELECT DATEPART(isoww, CAST(6542 AS int)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(isoww, CAST(4567 AS smallint)); +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(isoww, CAST(333333 AS bigint)); +GO +~~START~~ +int +34 +~~END~~ + + +SELECT DATEPART(isoww, CAST(24 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(isoww, CAST(654321.987 AS decimal)); +GO +~~START~~ +int +25 +~~END~~ + + +SELECT DATEPART(isoww, CAST(97.65 AS real)); +GO +~~START~~ +int +14 +~~END~~ + + +SELECT DATEPART(isoww, CAST(987654.321 AS numeric)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(isoww, CAST(0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'day' and different data types with negative values +GO +SELECT DATEPART(day, CAST(-5432 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(day, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(day, CAST(-6542 AS int)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(day, CAST(-1111 AS smallint)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(day, CAST(-7655 AS bigint)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(day, CAST(22 AS tinyint)); +GO +~~START~~ +int +23 +~~END~~ + + +SELECT DATEPART(day, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +14 +~~END~~ + + +SELECT DATEPART(day, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(day, CAST(-3.14159 AS float)); +GO +~~START~~ +int +28 +~~END~~ + + + +-- DATEPART with 'month' and different data types with negative values +GO +SELECT DATEPART(month, CAST(-5432 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(month, CAST(-6542 AS int)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(month, CAST(-1111 AS smallint)); +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(month, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, CAST(22 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(month, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(month, CAST(-3.14159 AS float)); +GO +~~START~~ +int +12 +~~END~~ + + + +-- DATEPART with 'week' and different data types with negative values +GO +SELECT DATEPART(week, CAST(-5432 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(week, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +33 +~~END~~ + + +SELECT DATEPART(week, CAST(-6542 AS int)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(week, CAST(-1111 AS smallint)); +GO +~~START~~ +int +51 +~~END~~ + + +SELECT DATEPART(week, CAST(-7655 AS bigint)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(week, CAST(22 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(week, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +33 +~~END~~ + + +SELECT DATEPART(week, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(week, CAST(-123.432 AS numeric)); +GO +~~START~~ +int +35 +~~END~~ + + +SELECT DATEPART(week, CAST(-43.14 AS float)); +GO +~~START~~ +int +46 +~~END~~ + + + +-- DATEPART with 'year' and different data types with negative values +GO +SELECT DATEPART(year, CAST(-5432 AS bit)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(year, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(year, CAST(-6542 AS int)); +GO +~~START~~ +int +1882 +~~END~~ + + +SELECT DATEPART(year, CAST(-1111 AS smallint)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(year, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1879 +~~END~~ + + +SELECT DATEPART(year, CAST(22 AS tinyint)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(year, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(year, CAST(-729.321 AS real)); +GO +~~START~~ +int +1898 +~~END~~ + + +SELECT DATEPART(year, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(year, CAST(-3.14159 AS float)); +GO +~~START~~ +int +1899 +~~END~~ + + + +-- DATEPART with 'weekday' and different data types with negative values +GO +SELECT DATEPART(weekday, CAST(-5432 AS bit)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-6542 AS int)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-1111 AS smallint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-7655 AS bigint)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(weekday, CAST(22 AS tinyint)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-729.321 AS real)); +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(weekday, CAST(-3.14159 AS float)); +GO +~~START~~ +int +5 +~~END~~ + + + +-- DATEPART with 'yy' (year without century) and different data types with negative values +GO +SELECT DATEPART(yy, CAST(-5432 AS bit)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yy, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yy, CAST(-6542 AS int)); +GO +~~START~~ +int +1882 +~~END~~ + + +SELECT DATEPART(yy, CAST(-1111 AS smallint)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yy, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1879 +~~END~~ + + +SELECT DATEPART(yy, CAST(22 AS tinyint)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yy, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yy, CAST(-729.321 AS real)); +GO +~~START~~ +int +1898 +~~END~~ + + +SELECT DATEPART(yy, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yy, CAST(-3.14159 AS float)); +GO +~~START~~ +int +1899 +~~END~~ + + + +-- DATEPART with 'yyyy' (year with century) and different data types with negative values +GO +SELECT DATEPART(yyyy, CAST(-5432 AS bit)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-6542 AS int)); +GO +~~START~~ +int +1882 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-1111 AS smallint)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1879 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(22 AS tinyint)); +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-729.321 AS real)); +GO +~~START~~ +int +1898 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +1896 +~~END~~ + + +SELECT DATEPART(yyyy, CAST(-3.14159 AS float)); +GO +~~START~~ +int +1899 +~~END~~ + + + +-- DATEPART with 'qq' (quarter) and different data types with negative values +GO +SELECT DATEPART(qq, CAST(-5432 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(qq, CAST(-6542 AS int)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(-91 AS smallint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(qq, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(22 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(qq, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(qq, CAST(-5433.14 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'q' (quarter) and different data types with negative values +GO +SELECT DATEPART(q, CAST(-5432 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(q, CAST(-6542 AS int)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(-311 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(22 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(q, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(q, CAST(-33.149 AS float)); +GO +~~START~~ +int +4 +~~END~~ + + + +-- DATEPART with 'mm' (month) and different data types with negative values +GO +SELECT DATEPART(mm, CAST(-5432 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(mm, CAST(-6542 AS int)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(mm, CAST(-1111 AS smallint)); +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(mm, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, CAST(22 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(mm, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(mm, CAST(-3.14159 AS float)); +GO +~~START~~ +int +12 +~~END~~ + + + +-- DATEPART with 'm' (month) and different data types with negative values +GO +SELECT DATEPART(m, CAST(-5432 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(m, CAST(-6542 AS int)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(m, CAST(-1111 AS smallint)); +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(m, CAST(-7655 AS bigint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, CAST(22 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(m, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(m, CAST(-3.14159 AS float)); +GO +~~START~~ +int +12 +~~END~~ + + + +-- DATEPART with 'dy' (day of the year) and different data types with negative values +GO +SELECT DATEPART(dy, CAST(-5432 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dy, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +228 +~~END~~ + + +SELECT DATEPART(dy, CAST(-6542 AS int)); +GO +~~START~~ +int +33 +~~END~~ + + +SELECT DATEPART(dy, CAST(-1111 AS smallint)); +GO +~~START~~ +int +351 +~~END~~ + + +SELECT DATEPART(dy, CAST(-7655 AS bigint)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(dy, CAST(22 AS tinyint)); +GO +~~START~~ +int +23 +~~END~~ + + +SELECT DATEPART(dy, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +227 +~~END~~ + + +SELECT DATEPART(dy, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dy, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +224 +~~END~~ + + +SELECT DATEPART(dy, CAST(-3.14159 AS float)); +GO +~~START~~ +int +362 +~~END~~ + + + +-- DATEPART with 'y' (day of the year) and different data types with negative values +GO +SELECT DATEPART(y, CAST(-5432 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(y, CAST(-1234 AS smallmoney)); +GO +~~START~~ +int +228 +~~END~~ + + +SELECT DATEPART(y, CAST(-6542 AS int)); +GO +~~START~~ +int +33 +~~END~~ + + +SELECT DATEPART(y, CAST(-1111 AS smallint)); +GO +~~START~~ +int +351 +~~END~~ + + +SELECT DATEPART(y, CAST(-7655 AS bigint)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(y, CAST(22 AS tinyint)); +GO +~~START~~ +int +23 +~~END~~ + + +SELECT DATEPART(y, CAST(-1234.789 AS decimal)); +GO +~~START~~ +int +227 +~~END~~ + + +SELECT DATEPART(y, CAST(-729.321 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(y, CAST(-1238.432 AS numeric)); +GO +~~START~~ +int +224 +~~END~~ + + +SELECT DATEPART(y, CAST(-3.14159 AS float)); +GO +~~START~~ +int +362 +~~END~~ + + + +-- DATEPART with 'dd' (day of the month) and different data types with negative values +GO +SELECT DATEPART(dd, CAST(-1234 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dd, CAST(-7890 AS smallmoney)); +GO +~~START~~ +int +26 +~~END~~ + + +SELECT DATEPART(dd, CAST(-6542 AS int)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dd, CAST(-4567 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dd, CAST(-333 AS bigint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dd, CAST(2 AS tinyint)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(dd, CAST(-6521.987 AS decimal)); +GO +~~START~~ +int +22 +~~END~~ + + +SELECT DATEPART(dd, CAST(-3217.654 AS real)); +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(dd, CAST(-94.321 AS numeric)); +GO +~~START~~ +int +29 +~~END~~ + + +SELECT DATEPART(dd, CAST(-0.12345 AS float)); +GO +~~START~~ +int +31 +~~END~~ + + + +-- DATEPART with 'd' (day of the month) and different data types with negative values +GO +SELECT DATEPART(d, CAST(-1256 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(d, CAST(-780 AS smallmoney)); +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(d, CAST(-985 AS int)); +GO +~~START~~ +int +21 +~~END~~ + + +SELECT DATEPART(d, CAST(-4567 AS smallint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(d, CAST(-33 AS bigint)); +GO +~~START~~ +int +29 +~~END~~ + + +SELECT DATEPART(d, CAST(2 AS tinyint)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(d, CAST(-651.987 AS decimal)); +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(d, CAST(-37.654 AS real)); +GO +~~START~~ +int +24 +~~END~~ + + +SELECT DATEPART(d, CAST(-954.321 AS numeric)); +GO +~~START~~ +int +22 +~~END~~ + + +SELECT DATEPART(d, CAST(-0.12345 AS float)); +GO +~~START~~ +int +31 +~~END~~ + + + +-- DATEPART with 'wk' (week) and different data types with negative values +GO +SELECT DATEPART(wk, CAST(-126 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(wk, CAST(-780 AS smallmoney)); +GO +~~START~~ +int +46 +~~END~~ + + +SELECT DATEPART(wk, CAST(-95 AS int)); +GO +~~START~~ +int +39 +~~END~~ + + +SELECT DATEPART(wk, CAST(-45 AS smallint)); +GO +~~START~~ +int +46 +~~END~~ + + +SELECT DATEPART(wk, CAST(-333 AS bigint)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(wk, CAST(2 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(wk, CAST(-65.987 AS decimal)); +GO +~~START~~ +int +43 +~~END~~ + + +SELECT DATEPART(wk, CAST(-327.654 AS real)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(wk, CAST(-54.321 AS numeric)); +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(wk, CAST(-40.12 AS float)); +GO +~~START~~ +int +47 +~~END~~ + + + +-- DATEPART with 'ww' (week) and different data types with negative values +GO +SELECT DATEPART(ww, CAST(-156 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(ww, CAST(-780 AS smallmoney)); +GO +~~START~~ +int +46 +~~END~~ + + +SELECT DATEPART(ww, CAST(-65 AS int)); +GO +~~START~~ +int +43 +~~END~~ + + +SELECT DATEPART(ww, CAST(-17 AS smallint)); +GO +~~START~~ +int +50 +~~END~~ + + +SELECT DATEPART(ww, CAST(-33 AS bigint)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(ww, CAST(2 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(ww, CAST(-61.9 AS decimal)); +GO +~~START~~ +int +44 +~~END~~ + + +SELECT DATEPART(ww, CAST(-37.64 AS real)); +GO +~~START~~ +int +47 +~~END~~ + + +SELECT DATEPART(ww, CAST(-84.321 AS numeric)); +GO +~~START~~ +int +41 +~~END~~ + + +SELECT DATEPART(ww, CAST(-220.12345 AS float)); +GO +~~START~~ +int +21 +~~END~~ + + + +-- DATEPART with 'dw' (weekday) and different data types with negative values +GO +SELECT DATEPART(dw, CAST(-156 AS bit)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(dw, CAST(-780 AS smallmoney)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(dw, CAST(-965 AS int)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(dw, CAST(-4567 AS smallint)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(dw, CAST(-33 AS bigint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(dw, CAST(2 AS tinyint)); +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(dw, CAST(-651.987 AS decimal)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dw, CAST(-321.654 AS real)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dw, CAST(-984.321 AS numeric)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(dw, CAST(-0.12345 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + + +-- DATEPART with 'iso_week' (ISO week) and different data types with negative values +GO +SELECT DATEPART(iso_week, CAST(-156 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-7890 AS smallmoney)); +GO +~~START~~ +int +21 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-985 AS int)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-4567 AS smallint)); +GO +~~START~~ +int +26 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-333 AS bigint)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(2 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-621.987 AS decimal)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-327.654 AS real)); +GO +~~START~~ +int +6 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-984.321 AS numeric)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(iso_week, CAST(-10.12 AS float)); +GO +~~START~~ +int +51 +~~END~~ + + + +-- DATEPART with 'isowk' (ISO week) and different data types with negative values +GO +SELECT DATEPART(isowk, CAST(-1256 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-70 AS smallmoney)); +GO +~~START~~ +int +43 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-965 AS int)); +GO +~~START~~ +int +19 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-467 AS smallint)); +GO +~~START~~ +int +38 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-33 AS bigint)); +GO +~~START~~ +int +48 +~~END~~ + + +SELECT DATEPART(isowk, CAST(2 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-51.97 AS decimal)); +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-37.65 AS real)); +GO +~~START~~ +int +47 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-96.31 AS numeric)); +GO +~~START~~ +int +39 +~~END~~ + + +SELECT DATEPART(isowk, CAST(-110.123 AS float)); +GO +~~START~~ +int +37 +~~END~~ + + + +-- DATEPART with 'isoww' (ISO week) and different data types with negative values +GO +SELECT DATEPART(isoww, CAST(-456 AS bit)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-70 AS smallmoney)); +GO +~~START~~ +int +43 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-965 AS int)); +GO +~~START~~ +int +19 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-47 AS smallint)); +GO +~~START~~ +int +46 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-333 AS bigint)); +GO +~~START~~ +int +5 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-621.987 AS decimal)); +GO +~~START~~ +int +16 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-39.65 AS real)); +GO +~~START~~ +int +47 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-97.321 AS numeric)); +GO +~~START~~ +int +39 +~~END~~ + + +SELECT DATEPART(isoww, CAST(-11.12345 AS float)); +GO +~~START~~ +int +51 +~~END~~ + + + + +-- Datepart with valid second argument +SELECT DATEPART(yyyy, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(yyyy, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +2022 +~~END~~ + + +SELECT DATEPART(yyyy, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +2021 +~~END~~ + + +SELECT DATEPART(yyyy, '2023-04-15') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(yyyy, '12:30:45') +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(yyyy, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(yyyy, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(year, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(year, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +2022 +~~END~~ + + +SELECT DATEPART(year, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +2021 +~~END~~ + + +SELECT DATEPART(year, '2023-04-15') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(year, '12:30:45') +GO +~~START~~ +int +1900 +~~END~~ + + +SELECT DATEPART(year, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(year, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +2023 +~~END~~ + + +SELECT DATEPART(q, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(q, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(q, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(q, '2023-04-15') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(q, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(q, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(q, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(qq, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(qq, '2023-04-15') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(qq, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(quarter, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(quarter, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(quarter, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(quarter, '2023-04-15') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(quarter, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(quarter, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(quarter, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(mm, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(mm, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(mm, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(mm, '2023-04-15') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(mm, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(mm, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(mm, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(m, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(m, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(m, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(m, '2023-04-15') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(m, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(m, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(m, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(month, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(month, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(month, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +11 +~~END~~ + + +SELECT DATEPART(month, '2023-04-15') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(month, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(month, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +4 +~~END~~ + + +SELECT DATEPART(dy, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dy, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +239 +~~END~~ + + +SELECT DATEPART(dy, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +305 +~~END~~ + + +SELECT DATEPART(dy, '2023-04-15') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dy, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dy, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dy, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dayofyear, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dayofyear, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +239 +~~END~~ + + +SELECT DATEPART(dayofyear, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +305 +~~END~~ + + +SELECT DATEPART(dayofyear, '2023-04-15') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dayofyear, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dayofyear, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(dayofyear, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +105 +~~END~~ + + +SELECT DATEPART(d, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(d, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(d, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(d, '2023-04-15') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(d, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(d, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(d, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(dd, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(dd, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(dd, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dd, '2023-04-15') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(dd, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(dd, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(dd, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(day, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(day, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +27 +~~END~~ + + +SELECT DATEPART(day, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, '2023-04-15') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(day, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(day, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(wk, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(wk, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +35 +~~END~~ + + +SELECT DATEPART(wk, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(wk, '2023-04-15') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(wk, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(wk, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(wk, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(ww, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(ww, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +35 +~~END~~ + + +SELECT DATEPART(ww, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(ww, '2023-04-15') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(ww, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(ww, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(ww, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(iso_week, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(iso_week, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +34 +~~END~~ + + +SELECT DATEPART(iso_week, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +44 +~~END~~ + + +SELECT DATEPART(iso_week, '2023-04-15') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(iso_week, '12:30:45') +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(iso_week, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(iso_week, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(dw, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(dw, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(dw, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dw, '2023-04-15') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(dw, '12:30:45') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(dw, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(dw, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(weekday, '2023-04-15') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, '12:30:45') +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(weekday, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(weekday, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +7 +~~END~~ + + +SELECT DATEPART(hh, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hh, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +8 +~~END~~ + +SELECT DATEPART(hh, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +18 +~~END~~ + + +SELECT DATEPART(hh, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(hh, '12:30:45') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hh, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hh, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hour, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hour, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +8 +~~END~~ + + +SELECT DATEPART(hour, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +18 +~~END~~ + + +SELECT DATEPART(hour, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(hour, '12:30:45') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hour, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hour, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(mi, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(mi, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(mi, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(mi, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(mi, '12:30:45') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(mi, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(mi, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(n, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(n, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(n, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(n, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(n, '12:30:45') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(n, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(n, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(minute, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(minute, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(minute, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +20 +~~END~~ + + +SELECT DATEPART(minute, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(minute, '12:30:45') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(minute, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(minute, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(ss, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(ss, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(ss, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(ss, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(ss, '12:30:45') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(ss, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(ss, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(s, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(s, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(s, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(s, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(s, '12:30:45') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(s, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(s, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(second, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(second, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +30 +~~END~~ + + +SELECT DATEPART(second, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(second, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(second, '12:30:45') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(second, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(second, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +45 +~~END~~ + + +SELECT DATEPART(ms, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +678 +~~END~~ + + +SELECT DATEPART(ms, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +123 +~~END~~ + + +SELECT DATEPART(ms, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +987 +~~END~~ + + +SELECT DATEPART(ms, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(ms, '12:30:45') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(ms, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +678 +~~END~~ + + +SELECT DATEPART(ms, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +678 +~~END~~ + + +SELECT DATEPART(millisecond, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +678 +~~END~~ + + +SELECT DATEPART(millisecond, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +123 +~~END~~ + + +SELECT DATEPART(millisecond, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +987 +~~END~~ + + +SELECT DATEPART(millisecond, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(millisecond, '12:30:45') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(millisecond, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +678 +~~END~~ + + +SELECT DATEPART(millisecond, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +678 +~~END~~ + + +SELECT DATEPART(microsecond, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +678900 +~~END~~ + + +SELECT DATEPART(microsecond, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +123400 +~~END~~ + + +SELECT DATEPART(microsecond, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +987600 +~~END~~ + + +SELECT DATEPART(microsecond, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(microsecond, '12:30:45') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(microsecond, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +678900 +~~END~~ + + +SELECT DATEPART(microsecond, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +678900 +~~END~~ + + +SELECT DATEPART(ns, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +678900000 +~~END~~ + + +SELECT DATEPART(ns, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +123400000 +~~END~~ + + +SELECT DATEPART(ns, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +987600000 +~~END~~ + + +SELECT DATEPART(ns, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(ns, '12:30:45') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(ns, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +678900000 +~~END~~ + + +SELECT DATEPART(ns, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +678900000 +~~END~~ + + +SELECT DATEPART(nanosecond, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +678900000 +~~END~~ + + +SELECT DATEPART(nanosecond, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +123400000 +~~END~~ + + +SELECT DATEPART(nanosecond, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +987600000 +~~END~~ + + +SELECT DATEPART(nanosecond, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(nanosecond, '12:30:45') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(nanosecond, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +678900000 +~~END~~ + + +SELECT DATEPART(nanosecond, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +678900000 +~~END~~ + + +SELECT DATEPART(tzoffset, '2023-04-15T12:30:45.6789+05:30') +GO +~~START~~ +int +330 +~~END~~ + + +SELECT DATEPART(tzoffset, '2022-08-27T08:45:30.1234-03:00') +GO +~~START~~ +int +-180 +~~END~~ + + +SELECT DATEPART(tzoffset, '2021-11-01T18:20:15.9876+00:00') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(tzoffset, '2023-04-15') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(tzoffset, '12:30:45') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(tzoffset, '2023-04-15 12:30:45.6789') +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(tzoffset, '2023-04-15T12:30:45.6789Z') +GO +~~START~~ +int +0 +~~END~~ + + + +-- tests when datefirst is changed for iso_week +SET datefirst 7; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 1; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 2; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 3; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 4; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 5; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 6; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + + +-- tests when datefirst is changed for week +SET datefirst 7; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +6 +~~END~~ + + +SET datefirst 1; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +6 +~~END~~ + + +SET datefirst 2; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +6 +~~END~~ + + +SET datefirst 3; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +6 +~~END~~ + + +SET datefirst 4; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 5; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +5 +~~END~~ + + +SET datefirst 6; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +6 +~~END~~ + + + +-- tests when datefirst is changed for doy +SET datefirst 7; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + +SET datefirst 1; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + +SET datefirst 2; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + +SET datefirst 3; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + +SET datefirst 4; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + +SET datefirst 5; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + +SET datefirst 6; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO +~~START~~ +int +34 +~~END~~ + + + +-- Queries that should throw error +SELECT DATEPART(YEAR, cast('12:10:30.123' as time)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart year is not supported by date function datepart for data type time.)~~ + + +SELECT DATEPART(QUARTER, cast('12:10:30.123' as time)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart quarter is not supported by date function datepart for data type time.)~~ + + +SELECT DATEPART(MONTH, cast('12:10:30.123' as time)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart month is not supported by date function datepart for data type time.)~~ + + +SELECT DATEPART(DAY, cast('12:10:30.123' as time)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart day is not supported by date function datepart for data type time.)~~ + + +SELECT DATEPART(dow, cast('12:10:30.123' as time)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart weekday is not supported by date function datepart for data type time.)~~ + + +SELECT DATEPART(doy, cast('12:10:30.123' as time)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart dayofyear is not supported by date function datepart for data type time.)~~ + + + +-- Max Limits checked +SELECT DATEPART(day, CAST(9999999999 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(day, CAST(214748 AS smallmoney)); +GO +~~START~~ +int +17 +~~END~~ + + +SELECT DATEPART(day, CAST(214748.3647 AS smallmoney)); +GO +~~START~~ +int +17 +~~END~~ + + +SELECT DATEPART(day, CAST(2958463 AS int)); +GO +~~START~~ +int +31 +~~END~~ + + +SELECT DATEPART(day, CAST(2958464 AS int)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(32767 AS smallint)); +GO +~~START~~ +int +18 +~~END~~ + + +SELECT DATEPART(day, CAST(32768 AS smallint)); +GO +~~ERROR (Code: 220)~~ + +~~ERROR (Message: smallint out of range)~~ + + +SELECT DATEPART(day, CAST(2958463 AS bigint)); +GO +~~START~~ +int +31 +~~END~~ + + +SELECT DATEPART(day, CAST(2958464 AS bigint)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(255 AS tinyint)); +GO +~~START~~ +int +13 +~~END~~ + + +SELECT DATEPART(day, CAST(256 AS tinyint)); +GO +~~START~~ +int +~~ERROR (Code: 220)~~ + +~~ERROR (Message: value for domain tinyint violates check constraint "tinyint_check")~~ + + +SELECT DATEPART(day, CAST(2958463 AS decimal)); +GO +~~START~~ +int +31 +~~END~~ + + +SELECT DATEPART(day, CAST(2958464 AS decimal)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(2958463 AS real)); +GO +~~START~~ +int +31 +~~END~~ + + +SELECT DATEPART(day, CAST(2958464 AS real)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(2958463 AS numeric)); +GO +~~START~~ +int +31 +~~END~~ + + +SELECT DATEPART(day, CAST(2958464 AS numeric)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(2958463.6 AS float)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(2958464.6 AS float)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + + +-- Min Limits checked +SELECT DATEPART(day, CAST(-999999999 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(day, CAST(-53690 AS smallmoney)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS smallmoney)); +GO +~~START~~ +int +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(-53690 AS int)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS int)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(-32768 AS smallint)); +GO +~~START~~ +int +15 +~~END~~ + + +SELECT DATEPART(day, CAST(-32769 AS smallint)); +GO +~~ERROR (Code: 220)~~ + +~~ERROR (Message: smallint out of range)~~ + + +SELECT DATEPART(day, CAST(-53690 AS bigint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS bigint)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(0 AS tinyint)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-1 AS tinyint)); +GO +~~START~~ +int +~~ERROR (Code: 220)~~ + +~~ERROR (Message: value for domain tinyint violates check constraint "tinyint_check")~~ + + +SELECT DATEPART(day, CAST(-53690 AS decimal)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS decimal)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(-53690 AS real)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS real)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(-53690 AS numeric)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS numeric)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, CAST(-53690 AS float)); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(day, CAST(-53691 AS float)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + + + +-- Max Limits checked for datatypes +SELECT DATEPART(day, CAST(9999999999 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(week, CAST(922337203685477.5807 AS money)); +GO +~~START~~ +int +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(weekday, CAST(214748.3649 AS smallmoney)); +GO +~~START~~ +int +~~ERROR (Code: 220)~~ + +~~ERROR (Message: value for domain smallmoney violates check constraint "smallmoney_check")~~ + + +SELECT DATEPART(year, CAST(2147483647 AS int)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(q, CAST(32767 AS smallint)); +GO +~~START~~ +int +3 +~~END~~ + + +SELECT DATEPART(qq, CAST(9223372036854775807 AS bigint)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(second, CAST(256 AS tinyint)); +GO +~~START~~ +int +~~ERROR (Code: 220)~~ + +~~ERROR (Message: value for domain tinyint violates check constraint "tinyint_check")~~ + + +SELECT DATEPART(ms, CAST(2147483648 AS decimal)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(month, CAST(3.40E+38 AS real)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(microsecond, CAST(2147483648 AS numeric)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(iso_week, CAST(1.79E+308 AS float)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + + +-- Min Limits checked for datatypes +SELECT DATEPART(day, CAST(-9999999999 AS bit)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(week, CAST(-922337203685477.5809 AS money)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: value "-922337203685477.5809" is out of range for type fixeddecimal)~~ + + +SELECT DATEPART(weekday, CAST(-214748.3649 AS smallmoney)); +GO +~~START~~ +int +~~ERROR (Code: 220)~~ + +~~ERROR (Message: value for domain smallmoney violates check constraint "smallmoney_check")~~ + + +SELECT DATEPART(year, CAST(-2147483648 AS int)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(q, CAST(-32768 AS smallint)); +GO +~~START~~ +int +2 +~~END~~ + + +SELECT DATEPART(qq, CAST(-9223372036854775808 AS bigint)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(second, CAST(0 AS tinyint)); +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(ms, CAST(-247483647 AS decimal)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(month, CAST(-3.40E+38 AS real)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(microsecond, CAST(-247483647 AS numeric)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(iso_week, CAST(-1.79E+308 AS float)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + + +-- Max Limits checked for dates +SELECT DATEPART(day, '9999-12-31'); +GO +~~START~~ +int +31 +~~END~~ + + +SELECT DATEPART(week, '9999-12-31 23:59:59.997'); +GO +~~START~~ +int +53 +~~END~~ + + +SELECT DATEPART(second, '12:45:37.123456'); +GO +~~START~~ +int +37 +~~END~~ + + +SELECT DATEPART(year, '9999-12-31 23:59:29.998 +0'); +GO +~~START~~ +int +9999 +~~END~~ + + +SELECT DATEPART(minute, '23:59:59.99'); +GO +~~START~~ +int +59 +~~END~~ + + + +-- Min Limits checked for dates +SELECT DATEPART(day, '0001-01-01 -1'); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(week, '0001-01-01 00:00:00.0000000 +00:00'); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(second, '0001-01-01'); +GO +~~START~~ +int +0 +~~END~~ + + +SELECT DATEPART(year, '00:00:00.0000000'); +GO +~~START~~ +int +1900 +~~END~~ + + + +-- NULL +SELECT DATEPART(day, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(week, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(weekday, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(year, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(q, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(qq, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(second, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(ms, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(month, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(microsecond, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(iso_week, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(nanosecond, NULL); +GO +~~START~~ +int + +~~END~~ + + +SELECT DATEPART(tzoffset, NULL); +GO +~~START~~ +int + +~~END~~ + + + +-- datepart without cast +SELECT DATEPART(day, 2147483647); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(qq, -2147483648); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(month, 9223372036854775807); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(year, -9223372036854775808); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(yy, 214748.3647); +GO +~~START~~ +int +2487 +~~END~~ + + +SELECT DATEPART(day, -214748.3648); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(yy, 922337203685477.5807); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(yyyy, -922337203685477.5808); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, 1.79E+308); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(hour, -1.79E+308); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(second, 3.40E+38); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(minute, -3.40E+38); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(day, 0); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT DATEPART(month, 2958463); +GO +~~START~~ +int +12 +~~END~~ + + +SELECT DATEPART(hour, 2958464); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + + +SELECT DATEPART(year, -53690); +GO +~~START~~ +int +1753 +~~END~~ + + +SELECT DATEPART(microsecond, -53691); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Arithmetic overflow error converting expression to data type datetime.)~~ + diff --git a/test/JDBC/expected/datepart-vu-verify.out b/test/JDBC/expected/datepart-vu-verify.out index bb75d9df13..379d046b4a 100644 --- a/test/JDBC/expected/datepart-vu-verify.out +++ b/test/JDBC/expected/datepart-vu-verify.out @@ -186,7 +186,7 @@ SELECT DATEPART(hh, '01:01:01.1234567 +01:01') GO ~~START~~ int -0 +1 ~~END~~ @@ -479,7 +479,7 @@ SELECT DATEPART(hh, 'Jul 18, 22 01:01:00.1234567 -7:8') GO ~~START~~ int -8 +1 ~~END~~ diff --git a/test/JDBC/input/BABEL_4302.sql b/test/JDBC/input/BABEL_4302.sql new file mode 100644 index 0000000000..bafd4145cc --- /dev/null +++ b/test/JDBC/input/BABEL_4302.sql @@ -0,0 +1,2499 @@ +-- DATEPART with 'day' and different data types + +GO +SELECT DATEPART(day, CAST(100987 AS bit)); +GO + +SELECT DATEPART(day, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(day, CAST(6542 AS int)); +GO + +SELECT DATEPART(day, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(day, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(day, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(day, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(day, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(day, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(day, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'month' and different data types + +GO +SELECT DATEPART(month, CAST(100987 AS bit)); +GO + +SELECT DATEPART(month, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(month, CAST(6542 AS int)); +GO + +SELECT DATEPART(month, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(month, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(month, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(month, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(month, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(month, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(month, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'week' and different data types +SELECT DATEPART(week, CAST(100987 AS bit)); +GO + +SELECT DATEPART(week, CAST(14 AS smallmoney)); +GO + +SELECT DATEPART(week, CAST(6542 AS int)); +GO + +SELECT DATEPART(week, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(week, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(week, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(week, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(week, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(week, CAST(14 AS numeric)); +GO + +SELECT DATEPART(week, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'year' and different data types + +GO +SELECT DATEPART(year, CAST(100987 AS bit)); +GO + +SELECT DATEPART(year, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(year, CAST(6542 AS int)); +GO + +SELECT DATEPART(year, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(year, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(year, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(year, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(year, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(year, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(year, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'weekday' and different data types + +GO +SELECT DATEPART(weekday, CAST(100987 AS bit)); +GO + +SELECT DATEPART(weekday, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(weekday, CAST(6542 AS int)); +GO + +SELECT DATEPART(weekday, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(weekday, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(weekday, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(weekday, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(weekday, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(weekday, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(weekday, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'yy' (year without century) and different data types + +GO +SELECT DATEPART(yy, CAST(100987 AS bit)); +GO + +SELECT DATEPART(yy, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(yy, CAST(6542 AS int)); +GO + +SELECT DATEPART(yy, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(yy, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(yy, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(yy, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(yy, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(yy, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(yy, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'yyyy' (year with century) and different data types + +GO +SELECT DATEPART(yyyy, CAST(100987 AS bit)); +GO + +SELECT DATEPART(yyyy, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(yyyy, CAST(6542 AS int)); +GO + +SELECT DATEPART(yyyy, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(yyyy, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(yyyy, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(yyyy, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(yyyy, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(yyyy, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(yyyy, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'qq' (quarter) and different data types + +GO +SELECT DATEPART(qq, CAST(100987 AS bit)); +GO + +SELECT DATEPART(qq, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(qq, CAST(6542 AS int)); +GO + +SELECT DATEPART(qq, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(qq, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(qq, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(qq, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(qq, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(qq, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(qq, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'q' (quarter) and different data types + +GO +SELECT DATEPART(q, CAST(100987 AS bit)); +GO + +SELECT DATEPART(q, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(q, CAST(6542 AS int)); +GO + +SELECT DATEPART(q, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(q, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(q, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(q, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(q, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(q, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(q, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'mm' (month) and different data types + +GO +SELECT DATEPART(mm, CAST(100987 AS bit)); +GO + +SELECT DATEPART(mm, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(mm, CAST(6542 AS int)); +GO + +SELECT DATEPART(mm, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(mm, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(mm, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(mm, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(mm, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(mm, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(mm, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'm' (month) and different data types + +GO +SELECT DATEPART(m, CAST(100987 AS bit)); +GO + +SELECT DATEPART(m, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(m, CAST(6542 AS int)); +GO + +SELECT DATEPART(m, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(m, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(m, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(m, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(m, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(m, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(m, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'dy' (day of the year) and different data types + +GO +SELECT DATEPART(dy, CAST(100987 AS bit)); +GO + +SELECT DATEPART(dy, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(dy, CAST(6542 AS int)); +GO + +SELECT DATEPART(dy, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(dy, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(dy, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(dy, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(dy, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(dy, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(dy, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'y' (day of the year) and different data types + +GO +SELECT DATEPART(y, CAST(100987 AS bit)); +GO + +SELECT DATEPART(y, CAST(1234 AS smallmoney)); +GO + +SELECT DATEPART(y, CAST(6542 AS int)); +GO + +SELECT DATEPART(y, CAST(1111 AS smallint)); +GO + +SELECT DATEPART(y, CAST(999999 AS bigint)); +GO + +SELECT DATEPART(y, CAST(42 AS tinyint)); +GO + +SELECT DATEPART(y, CAST(1234.789 AS decimal)); +GO + +SELECT DATEPART(y, CAST(987654.321 AS real)); +GO + +SELECT DATEPART(y, CAST(314159.432 AS numeric)); +GO + +SELECT DATEPART(y, CAST(3.14159 AS float)); +GO + +-- DATEPART with 'dd' (day of the month) and different data types + +GO +SELECT DATEPART(dd, CAST(1234 AS bit)); +GO + +SELECT DATEPART(dd, CAST(7890 AS smallmoney)); +GO + +SELECT DATEPART(dd, CAST(6542 AS int)); +GO + +SELECT DATEPART(dd, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(dd, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(dd, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(dd, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(dd, CAST(321987.654 AS real)); +GO + +SELECT DATEPART(dd, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(dd, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'd' (day of the month) and different data types + +GO +SELECT DATEPART(d, CAST(1234 AS bit)); +GO + +SELECT DATEPART(d, CAST(7890 AS smallmoney)); +GO + +SELECT DATEPART(d, CAST(6542 AS int)); +GO + +SELECT DATEPART(d, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(d, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(d, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(d, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(d, CAST(321987.654 AS real)); +GO + +SELECT DATEPART(d, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(d, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'wk' (week) and different data types + +GO +SELECT DATEPART(wk, CAST(1234 AS bit)); +GO + +SELECT DATEPART(wk, CAST(7810 AS smallmoney)); +GO + +SELECT DATEPART(wk, CAST(6542 AS int)); +GO + +SELECT DATEPART(wk, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(wk, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(wk, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(wk, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(wk, CAST(3287.654 AS real)); +GO + +SELECT DATEPART(wk, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(wk, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'ww' (week) and different data types + +GO +SELECT DATEPART(ww, CAST(1234 AS bit)); +GO + +SELECT DATEPART(ww, CAST(780 AS smallmoney)); +GO + +SELECT DATEPART(ww, CAST(6542 AS int)); +GO + +SELECT DATEPART(ww, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(ww, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(ww, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(ww, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(ww, CAST(3987.654 AS real)); +GO + +SELECT DATEPART(ww, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(ww, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'dw' (weekday) and different data types + +GO +SELECT DATEPART(dw, CAST(1234 AS bit)); +GO + +SELECT DATEPART(dw, CAST(7890 AS smallmoney)); +GO + +SELECT DATEPART(dw, CAST(6542 AS int)); +GO + +SELECT DATEPART(dw, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(dw, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(dw, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(dw, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(dw, CAST(321987.654 AS real)); +GO + +SELECT DATEPART(dw, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(dw, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'iso_week' (ISO week) and different data types + +GO +SELECT DATEPART(iso_week, CAST(1234 AS bit)); +GO + +SELECT DATEPART(iso_week, CAST(7890 AS smallmoney)); +GO + +SELECT DATEPART(iso_week, CAST(6542 AS int)); +GO + +SELECT DATEPART(iso_week, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(iso_week, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(iso_week, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(iso_week, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(iso_week, CAST(197.64 AS real)); +GO + +SELECT DATEPART(iso_week, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(iso_week, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'isowk' (ISO week) and different data types + +GO +SELECT DATEPART(isowk, CAST(1234 AS bit)); +GO + +SELECT DATEPART(isowk, CAST(7890 AS smallmoney)); +GO + +SELECT DATEPART(isowk, CAST(6542 AS int)); +GO + +SELECT DATEPART(isowk, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(isowk, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(isowk, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(isowk, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(isowk, CAST(327.654 AS real)); +GO + +SELECT DATEPART(isowk, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(isowk, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'isoww' (ISO week) and different data types + +GO +SELECT DATEPART(isoww, CAST(1234 AS bit)); +GO + +SELECT DATEPART(isoww, CAST(7890 AS smallmoney)); +GO + +SELECT DATEPART(isoww, CAST(6542 AS int)); +GO + +SELECT DATEPART(isoww, CAST(4567 AS smallint)); +GO + +SELECT DATEPART(isoww, CAST(333333 AS bigint)); +GO + +SELECT DATEPART(isoww, CAST(24 AS tinyint)); +GO + +SELECT DATEPART(isoww, CAST(654321.987 AS decimal)); +GO + +SELECT DATEPART(isoww, CAST(97.65 AS real)); +GO + +SELECT DATEPART(isoww, CAST(987654.321 AS numeric)); +GO + +SELECT DATEPART(isoww, CAST(0.12345 AS float)); +GO + +-- DATEPART with 'day' and different data types with negative values + +GO +SELECT DATEPART(day, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(day, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(day, CAST(-6542 AS int)); +GO + +SELECT DATEPART(day, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(day, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(day, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(day, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(day, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(day, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(day, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'month' and different data types with negative values + +GO +SELECT DATEPART(month, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(month, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(month, CAST(-6542 AS int)); +GO + +SELECT DATEPART(month, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(month, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(month, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(month, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(month, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(month, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(month, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'week' and different data types with negative values + +GO +SELECT DATEPART(week, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(week, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(week, CAST(-6542 AS int)); +GO + +SELECT DATEPART(week, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(week, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(week, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(week, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(week, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(week, CAST(-123.432 AS numeric)); +GO + +SELECT DATEPART(week, CAST(-43.14 AS float)); +GO + +-- DATEPART with 'year' and different data types with negative values + +GO +SELECT DATEPART(year, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(year, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(year, CAST(-6542 AS int)); +GO + +SELECT DATEPART(year, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(year, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(year, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(year, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(year, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(year, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(year, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'weekday' and different data types with negative values + +GO +SELECT DATEPART(weekday, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(weekday, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(weekday, CAST(-6542 AS int)); +GO + +SELECT DATEPART(weekday, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(weekday, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(weekday, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(weekday, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(weekday, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(weekday, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(weekday, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'yy' (year without century) and different data types with negative values + +GO +SELECT DATEPART(yy, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(yy, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(yy, CAST(-6542 AS int)); +GO + +SELECT DATEPART(yy, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(yy, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(yy, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(yy, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(yy, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(yy, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(yy, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'yyyy' (year with century) and different data types with negative values + +GO +SELECT DATEPART(yyyy, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(yyyy, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(yyyy, CAST(-6542 AS int)); +GO + +SELECT DATEPART(yyyy, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(yyyy, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(yyyy, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(yyyy, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(yyyy, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(yyyy, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(yyyy, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'qq' (quarter) and different data types with negative values + +GO +SELECT DATEPART(qq, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(qq, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(qq, CAST(-6542 AS int)); +GO + +SELECT DATEPART(qq, CAST(-91 AS smallint)); +GO + +SELECT DATEPART(qq, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(qq, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(qq, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(qq, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(qq, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(qq, CAST(-5433.14 AS float)); +GO + +-- DATEPART with 'q' (quarter) and different data types with negative values + +GO +SELECT DATEPART(q, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(q, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(q, CAST(-6542 AS int)); +GO + +SELECT DATEPART(q, CAST(-311 AS smallint)); +GO + +SELECT DATEPART(q, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(q, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(q, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(q, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(q, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(q, CAST(-33.149 AS float)); +GO + +-- DATEPART with 'mm' (month) and different data types with negative values + +GO +SELECT DATEPART(mm, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(mm, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(mm, CAST(-6542 AS int)); +GO + +SELECT DATEPART(mm, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(mm, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(mm, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(mm, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(mm, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(mm, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(mm, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'm' (month) and different data types with negative values + +GO +SELECT DATEPART(m, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(m, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(m, CAST(-6542 AS int)); +GO + +SELECT DATEPART(m, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(m, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(m, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(m, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(m, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(m, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(m, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'dy' (day of the year) and different data types with negative values + +GO +SELECT DATEPART(dy, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(dy, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(dy, CAST(-6542 AS int)); +GO + +SELECT DATEPART(dy, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(dy, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(dy, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(dy, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(dy, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(dy, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(dy, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'y' (day of the year) and different data types with negative values + +GO +SELECT DATEPART(y, CAST(-5432 AS bit)); +GO + +SELECT DATEPART(y, CAST(-1234 AS smallmoney)); +GO + +SELECT DATEPART(y, CAST(-6542 AS int)); +GO + +SELECT DATEPART(y, CAST(-1111 AS smallint)); +GO + +SELECT DATEPART(y, CAST(-7655 AS bigint)); +GO + +SELECT DATEPART(y, CAST(22 AS tinyint)); +GO + +SELECT DATEPART(y, CAST(-1234.789 AS decimal)); +GO + +SELECT DATEPART(y, CAST(-729.321 AS real)); +GO + +SELECT DATEPART(y, CAST(-1238.432 AS numeric)); +GO + +SELECT DATEPART(y, CAST(-3.14159 AS float)); +GO + +-- DATEPART with 'dd' (day of the month) and different data types with negative values + +GO +SELECT DATEPART(dd, CAST(-1234 AS bit)); +GO + +SELECT DATEPART(dd, CAST(-7890 AS smallmoney)); +GO + +SELECT DATEPART(dd, CAST(-6542 AS int)); +GO + +SELECT DATEPART(dd, CAST(-4567 AS smallint)); +GO + +SELECT DATEPART(dd, CAST(-333 AS bigint)); +GO + +SELECT DATEPART(dd, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(dd, CAST(-6521.987 AS decimal)); +GO + +SELECT DATEPART(dd, CAST(-3217.654 AS real)); +GO + +SELECT DATEPART(dd, CAST(-94.321 AS numeric)); +GO + +SELECT DATEPART(dd, CAST(-0.12345 AS float)); +GO + +-- DATEPART with 'd' (day of the month) and different data types with negative values + +GO +SELECT DATEPART(d, CAST(-1256 AS bit)); +GO + +SELECT DATEPART(d, CAST(-780 AS smallmoney)); +GO + +SELECT DATEPART(d, CAST(-985 AS int)); +GO + +SELECT DATEPART(d, CAST(-4567 AS smallint)); +GO + +SELECT DATEPART(d, CAST(-33 AS bigint)); +GO + +SELECT DATEPART(d, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(d, CAST(-651.987 AS decimal)); +GO + +SELECT DATEPART(d, CAST(-37.654 AS real)); +GO + +SELECT DATEPART(d, CAST(-954.321 AS numeric)); +GO + +SELECT DATEPART(d, CAST(-0.12345 AS float)); +GO + +-- DATEPART with 'wk' (week) and different data types with negative values + +GO +SELECT DATEPART(wk, CAST(-126 AS bit)); +GO + +SELECT DATEPART(wk, CAST(-780 AS smallmoney)); +GO + +SELECT DATEPART(wk, CAST(-95 AS int)); +GO + +SELECT DATEPART(wk, CAST(-45 AS smallint)); +GO + +SELECT DATEPART(wk, CAST(-333 AS bigint)); +GO + +SELECT DATEPART(wk, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(wk, CAST(-65.987 AS decimal)); +GO + +SELECT DATEPART(wk, CAST(-327.654 AS real)); +GO + +SELECT DATEPART(wk, CAST(-54.321 AS numeric)); +GO + +SELECT DATEPART(wk, CAST(-40.12 AS float)); +GO + +-- DATEPART with 'ww' (week) and different data types with negative values + +GO +SELECT DATEPART(ww, CAST(-156 AS bit)); +GO + +SELECT DATEPART(ww, CAST(-780 AS smallmoney)); +GO + +SELECT DATEPART(ww, CAST(-65 AS int)); +GO + +SELECT DATEPART(ww, CAST(-17 AS smallint)); +GO + +SELECT DATEPART(ww, CAST(-33 AS bigint)); +GO + +SELECT DATEPART(ww, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(ww, CAST(-61.9 AS decimal)); +GO + +SELECT DATEPART(ww, CAST(-37.64 AS real)); +GO + +SELECT DATEPART(ww, CAST(-84.321 AS numeric)); +GO + +SELECT DATEPART(ww, CAST(-220.12345 AS float)); +GO + +-- DATEPART with 'dw' (weekday) and different data types with negative values + +GO +SELECT DATEPART(dw, CAST(-156 AS bit)); +GO + +SELECT DATEPART(dw, CAST(-780 AS smallmoney)); +GO + +SELECT DATEPART(dw, CAST(-965 AS int)); +GO + +SELECT DATEPART(dw, CAST(-4567 AS smallint)); +GO + +SELECT DATEPART(dw, CAST(-33 AS bigint)); +GO + +SELECT DATEPART(dw, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(dw, CAST(-651.987 AS decimal)); +GO + +SELECT DATEPART(dw, CAST(-321.654 AS real)); +GO + +SELECT DATEPART(dw, CAST(-984.321 AS numeric)); +GO + +SELECT DATEPART(dw, CAST(-0.12345 AS float)); +GO + +-- DATEPART with 'iso_week' (ISO week) and different data types with negative values + +GO +SELECT DATEPART(iso_week, CAST(-156 AS bit)); +GO + +SELECT DATEPART(iso_week, CAST(-7890 AS smallmoney)); +GO + +SELECT DATEPART(iso_week, CAST(-985 AS int)); +GO + +SELECT DATEPART(iso_week, CAST(-4567 AS smallint)); +GO + +SELECT DATEPART(iso_week, CAST(-333 AS bigint)); +GO + +SELECT DATEPART(iso_week, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(iso_week, CAST(-621.987 AS decimal)); +GO + +SELECT DATEPART(iso_week, CAST(-327.654 AS real)); +GO + +SELECT DATEPART(iso_week, CAST(-984.321 AS numeric)); +GO + +SELECT DATEPART(iso_week, CAST(-10.12 AS float)); +GO + +-- DATEPART with 'isowk' (ISO week) and different data types with negative values + +GO +SELECT DATEPART(isowk, CAST(-1256 AS bit)); +GO + +SELECT DATEPART(isowk, CAST(-70 AS smallmoney)); +GO + +SELECT DATEPART(isowk, CAST(-965 AS int)); +GO + +SELECT DATEPART(isowk, CAST(-467 AS smallint)); +GO + +SELECT DATEPART(isowk, CAST(-33 AS bigint)); +GO + +SELECT DATEPART(isowk, CAST(2 AS tinyint)); +GO + +SELECT DATEPART(isowk, CAST(-51.97 AS decimal)); +GO + +SELECT DATEPART(isowk, CAST(-37.65 AS real)); +GO + +SELECT DATEPART(isowk, CAST(-96.31 AS numeric)); +GO + +SELECT DATEPART(isowk, CAST(-110.123 AS float)); +GO + +-- DATEPART with 'isoww' (ISO week) and different data types with negative values + +GO +SELECT DATEPART(isoww, CAST(-456 AS bit)); +GO + +SELECT DATEPART(isoww, CAST(-70 AS smallmoney)); +GO + +SELECT DATEPART(isoww, CAST(-965 AS int)); +GO + +SELECT DATEPART(isoww, CAST(-47 AS smallint)); +GO + +SELECT DATEPART(isoww, CAST(-333 AS bigint)); +GO + +SELECT DATEPART(isoww, CAST(-621.987 AS decimal)); +GO + +SELECT DATEPART(isoww, CAST(-39.65 AS real)); +GO + +SELECT DATEPART(isoww, CAST(-97.321 AS numeric)); +GO + +SELECT DATEPART(isoww, CAST(-11.12345 AS float)); +GO + +-- Datepart with valid second argument + + +SELECT DATEPART(yyyy, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(yyyy, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(yyyy, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(yyyy, '2023-04-15') +GO + +SELECT DATEPART(yyyy, '12:30:45') +GO + +SELECT DATEPART(yyyy, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(yyyy, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(year, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(year, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(year, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(year, '2023-04-15') +GO + +SELECT DATEPART(year, '12:30:45') +GO + +SELECT DATEPART(year, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(year, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(q, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(q, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(q, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(q, '2023-04-15') +GO + +SELECT DATEPART(q, '12:30:45') +GO + +SELECT DATEPART(q, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(q, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(qq, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(qq, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(qq, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(qq, '2023-04-15') +GO + +SELECT DATEPART(qq, '12:30:45') +GO + +SELECT DATEPART(qq, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(qq, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(quarter, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(quarter, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(quarter, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(quarter, '2023-04-15') +GO + +SELECT DATEPART(quarter, '12:30:45') +GO + +SELECT DATEPART(quarter, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(quarter, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(mm, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(mm, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(mm, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(mm, '2023-04-15') +GO + +SELECT DATEPART(mm, '12:30:45') +GO + +SELECT DATEPART(mm, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(mm, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(m, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(m, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(m, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(m, '2023-04-15') +GO + +SELECT DATEPART(m, '12:30:45') +GO + +SELECT DATEPART(m, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(m, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(month, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(month, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(month, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(month, '2023-04-15') +GO + +SELECT DATEPART(month, '12:30:45') +GO + +SELECT DATEPART(month, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(month, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(dy, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(dy, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(dy, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(dy, '2023-04-15') +GO + +SELECT DATEPART(dy, '12:30:45') +GO + +SELECT DATEPART(dy, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(dy, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(dayofyear, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(dayofyear, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(dayofyear, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(dayofyear, '2023-04-15') +GO + +SELECT DATEPART(dayofyear, '12:30:45') +GO + +SELECT DATEPART(dayofyear, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(dayofyear, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(d, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(d, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(d, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(d, '2023-04-15') +GO + +SELECT DATEPART(d, '12:30:45') +GO + +SELECT DATEPART(d, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(d, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(dd, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(dd, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(dd, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(dd, '2023-04-15') +GO + +SELECT DATEPART(dd, '12:30:45') +GO + +SELECT DATEPART(dd, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(dd, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(day, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(day, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(day, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(day, '2023-04-15') +GO + +SELECT DATEPART(day, '12:30:45') +GO + +SELECT DATEPART(day, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(day, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(wk, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(wk, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(wk, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(wk, '2023-04-15') +GO + +SELECT DATEPART(wk, '12:30:45') +GO + +SELECT DATEPART(wk, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(wk, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(ww, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(ww, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(ww, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(ww, '2023-04-15') +GO + +SELECT DATEPART(ww, '12:30:45') +GO + +SELECT DATEPART(ww, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(ww, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(iso_week, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(iso_week, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(iso_week, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(iso_week, '2023-04-15') +GO + +SELECT DATEPART(iso_week, '12:30:45') +GO + +SELECT DATEPART(iso_week, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(iso_week, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(dw, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(dw, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(dw, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(dw, '2023-04-15') +GO + +SELECT DATEPART(dw, '12:30:45') +GO + +SELECT DATEPART(dw, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(dw, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(weekday, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(weekday, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(weekday, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(weekday, '2023-04-15') +GO + +SELECT DATEPART(weekday, '12:30:45') +GO + +SELECT DATEPART(weekday, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(weekday, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(hh, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(hh, '2022-08-27T08:45:30.1234-03:00') +GO +SELECT DATEPART(hh, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(hh, '2023-04-15') +GO + +SELECT DATEPART(hh, '12:30:45') +GO + +SELECT DATEPART(hh, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(hh, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(hour, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(hour, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(hour, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(hour, '2023-04-15') +GO + +SELECT DATEPART(hour, '12:30:45') +GO + +SELECT DATEPART(hour, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(hour, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(mi, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(mi, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(mi, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(mi, '2023-04-15') +GO + +SELECT DATEPART(mi, '12:30:45') +GO + +SELECT DATEPART(mi, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(mi, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(n, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(n, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(n, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(n, '2023-04-15') +GO + +SELECT DATEPART(n, '12:30:45') +GO + +SELECT DATEPART(n, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(n, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(minute, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(minute, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(minute, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(minute, '2023-04-15') +GO + +SELECT DATEPART(minute, '12:30:45') +GO + +SELECT DATEPART(minute, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(minute, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(ss, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(ss, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(ss, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(ss, '2023-04-15') +GO + +SELECT DATEPART(ss, '12:30:45') +GO + +SELECT DATEPART(ss, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(ss, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(s, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(s, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(s, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(s, '2023-04-15') +GO + +SELECT DATEPART(s, '12:30:45') +GO + +SELECT DATEPART(s, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(s, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(second, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(second, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(second, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(second, '2023-04-15') +GO + +SELECT DATEPART(second, '12:30:45') +GO + +SELECT DATEPART(second, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(second, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(ms, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(ms, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(ms, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(ms, '2023-04-15') +GO + +SELECT DATEPART(ms, '12:30:45') +GO + +SELECT DATEPART(ms, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(ms, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(millisecond, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(millisecond, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(millisecond, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(millisecond, '2023-04-15') +GO + +SELECT DATEPART(millisecond, '12:30:45') +GO + +SELECT DATEPART(millisecond, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(millisecond, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(microsecond, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(microsecond, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(microsecond, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(microsecond, '2023-04-15') +GO + +SELECT DATEPART(microsecond, '12:30:45') +GO + +SELECT DATEPART(microsecond, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(microsecond, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(ns, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(ns, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(ns, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(ns, '2023-04-15') +GO + +SELECT DATEPART(ns, '12:30:45') +GO + +SELECT DATEPART(ns, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(ns, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(nanosecond, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(nanosecond, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(nanosecond, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(nanosecond, '2023-04-15') +GO + +SELECT DATEPART(nanosecond, '12:30:45') +GO + +SELECT DATEPART(nanosecond, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(nanosecond, '2023-04-15T12:30:45.6789Z') +GO + +SELECT DATEPART(tzoffset, '2023-04-15T12:30:45.6789+05:30') +GO + +SELECT DATEPART(tzoffset, '2022-08-27T08:45:30.1234-03:00') +GO + +SELECT DATEPART(tzoffset, '2021-11-01T18:20:15.9876+00:00') +GO + +SELECT DATEPART(tzoffset, '2023-04-15') +GO + +SELECT DATEPART(tzoffset, '12:30:45') +GO + +SELECT DATEPART(tzoffset, '2023-04-15 12:30:45.6789') +GO + +SELECT DATEPART(tzoffset, '2023-04-15T12:30:45.6789Z') +GO + +-- tests when datefirst is changed for iso_week + +SET datefirst 7; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 1; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 2; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 3; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 4; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 5; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 6; +GO +SELECT datepart(iso_week,'2016-02-03 13:30:05.523456'); +GO + +-- tests when datefirst is changed for week + +SET datefirst 7; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 1; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 2; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 3; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 4; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 5; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 6; +GO +SELECT datepart(week,'2016-02-03 13:30:05.523456'); +GO + +-- tests when datefirst is changed for doy + +SET datefirst 7; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 1; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 2; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 3; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 4; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 5; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +SET datefirst 6; +GO +SELECT datepart(dy,'2016-02-03 13:30:05.523456'); +GO + +-- Queries that should throw error + +SELECT DATEPART(YEAR, cast('12:10:30.123' as time)) +GO + +SELECT DATEPART(QUARTER, cast('12:10:30.123' as time)) +GO + +SELECT DATEPART(MONTH, cast('12:10:30.123' as time)) +GO + +SELECT DATEPART(DAY, cast('12:10:30.123' as time)) +GO + +SELECT DATEPART(dow, cast('12:10:30.123' as time)) +GO + +SELECT DATEPART(doy, cast('12:10:30.123' as time)) +GO + +-- Max Limits checked + +SELECT DATEPART(day, CAST(9999999999 AS bit)); +GO + +SELECT DATEPART(day, CAST(214748 AS smallmoney)); +GO + +SELECT DATEPART(day, CAST(214748.3647 AS smallmoney)); +GO + +SELECT DATEPART(day, CAST(2958463 AS int)); +GO + +SELECT DATEPART(day, CAST(2958464 AS int)); +GO + +SELECT DATEPART(day, CAST(32767 AS smallint)); +GO + +SELECT DATEPART(day, CAST(32768 AS smallint)); +GO + +SELECT DATEPART(day, CAST(2958463 AS bigint)); +GO + +SELECT DATEPART(day, CAST(2958464 AS bigint)); +GO + +SELECT DATEPART(day, CAST(255 AS tinyint)); +GO + +SELECT DATEPART(day, CAST(256 AS tinyint)); +GO + +SELECT DATEPART(day, CAST(2958463 AS decimal)); +GO + +SELECT DATEPART(day, CAST(2958464 AS decimal)); +GO + +SELECT DATEPART(day, CAST(2958463 AS real)); +GO + +SELECT DATEPART(day, CAST(2958464 AS real)); +GO + +SELECT DATEPART(day, CAST(2958463 AS numeric)); +GO + +SELECT DATEPART(day, CAST(2958464 AS numeric)); +GO + +SELECT DATEPART(day, CAST(2958463.6 AS float)); +GO + +SELECT DATEPART(day, CAST(2958464.6 AS float)); +GO + +-- Min Limits checked + +SELECT DATEPART(day, CAST(-999999999 AS bit)); +GO + +SELECT DATEPART(day, CAST(-53690 AS smallmoney)); +GO + +SELECT DATEPART(day, CAST(-53691 AS smallmoney)); +GO + +SELECT DATEPART(day, CAST(-53690 AS int)); +GO + +SELECT DATEPART(day, CAST(-53691 AS int)); +GO + +SELECT DATEPART(day, CAST(-32768 AS smallint)); +GO + +SELECT DATEPART(day, CAST(-32769 AS smallint)); +GO + +SELECT DATEPART(day, CAST(-53690 AS bigint)); +GO + +SELECT DATEPART(day, CAST(-53691 AS bigint)); +GO + +SELECT DATEPART(day, CAST(0 AS tinyint)); +GO + +SELECT DATEPART(day, CAST(-1 AS tinyint)); +GO + +SELECT DATEPART(day, CAST(-53690 AS decimal)); +GO + +SELECT DATEPART(day, CAST(-53691 AS decimal)); +GO + +SELECT DATEPART(day, CAST(-53690 AS real)); +GO + +SELECT DATEPART(day, CAST(-53691 AS real)); +GO + +SELECT DATEPART(day, CAST(-53690 AS numeric)); +GO + +SELECT DATEPART(day, CAST(-53691 AS numeric)); +GO + +SELECT DATEPART(day, CAST(-53690 AS float)); +GO + +SELECT DATEPART(day, CAST(-53691 AS float)); +GO + + +-- Max Limits checked for datatypes + +SELECT DATEPART(day, CAST(9999999999 AS bit)); +GO + +SELECT DATEPART(week, CAST(922337203685477.5807 AS money)); +GO + +SELECT DATEPART(weekday, CAST(214748.3649 AS smallmoney)); +GO + +SELECT DATEPART(year, CAST(2147483647 AS int)); +GO + +SELECT DATEPART(q, CAST(32767 AS smallint)); +GO + +SELECT DATEPART(qq, CAST(9223372036854775807 AS bigint)); +GO + +SELECT DATEPART(second, CAST(256 AS tinyint)); +GO + +SELECT DATEPART(ms, CAST(2147483648 AS decimal)); +GO + +SELECT DATEPART(month, CAST(3.40E+38 AS real)); +GO + +SELECT DATEPART(microsecond, CAST(2147483648 AS numeric)); +GO + +SELECT DATEPART(iso_week, CAST(1.79E+308 AS float)); +GO + +-- Min Limits checked for datatypes + +SELECT DATEPART(day, CAST(-9999999999 AS bit)); +GO + +SELECT DATEPART(week, CAST(-922337203685477.5809 AS money)); +GO + +SELECT DATEPART(weekday, CAST(-214748.3649 AS smallmoney)); +GO + +SELECT DATEPART(year, CAST(-2147483648 AS int)); +GO + +SELECT DATEPART(q, CAST(-32768 AS smallint)); +GO + +SELECT DATEPART(qq, CAST(-9223372036854775808 AS bigint)); +GO + +SELECT DATEPART(second, CAST(0 AS tinyint)); +GO + +SELECT DATEPART(ms, CAST(-247483647 AS decimal)); +GO + +SELECT DATEPART(month, CAST(-3.40E+38 AS real)); +GO + +SELECT DATEPART(microsecond, CAST(-247483647 AS numeric)); +GO + +SELECT DATEPART(iso_week, CAST(-1.79E+308 AS float)); +GO + +-- Max Limits checked for dates + +SELECT DATEPART(day, '9999-12-31'); +GO + +SELECT DATEPART(week, '9999-12-31 23:59:59.997'); +GO + +SELECT DATEPART(second, '12:45:37.123456'); +GO + +SELECT DATEPART(year, '9999-12-31 23:59:29.998 +0'); +GO + +SELECT DATEPART(minute, '23:59:59.99'); +GO + +-- Min Limits checked for dates + +SELECT DATEPART(day, '0001-01-01 -1'); +GO + +SELECT DATEPART(week, '0001-01-01 00:00:00.0000000 +00:00'); +GO + +SELECT DATEPART(second, '0001-01-01'); +GO + +SELECT DATEPART(year, '00:00:00.0000000'); +GO + +-- NULL + +SELECT DATEPART(day, NULL); +GO + +SELECT DATEPART(week, NULL); +GO + +SELECT DATEPART(weekday, NULL); +GO + +SELECT DATEPART(year, NULL); +GO + +SELECT DATEPART(q, NULL); +GO + +SELECT DATEPART(qq, NULL); +GO + +SELECT DATEPART(second, NULL); +GO + +SELECT DATEPART(ms, NULL); +GO + +SELECT DATEPART(month, NULL); +GO + +SELECT DATEPART(microsecond, NULL); +GO + +SELECT DATEPART(iso_week, NULL); +GO + +SELECT DATEPART(nanosecond, NULL); +GO + +SELECT DATEPART(tzoffset, NULL); +GO + +-- datepart without cast + +SELECT DATEPART(day, 2147483647); +GO + +SELECT DATEPART(qq, -2147483648); +GO + +SELECT DATEPART(month, 9223372036854775807); +GO + +SELECT DATEPART(year, -9223372036854775808); +GO + +SELECT DATEPART(yy, 214748.3647); +GO + +SELECT DATEPART(day, -214748.3648); +GO + +SELECT DATEPART(yy, 922337203685477.5807); +GO + +SELECT DATEPART(yyyy, -922337203685477.5808); +GO + +SELECT DATEPART(day, 1.79E+308); +GO + +SELECT DATEPART(hour, -1.79E+308); +GO + +SELECT DATEPART(second, 3.40E+38); +GO + +SELECT DATEPART(minute, -3.40E+38); +GO + +SELECT DATEPART(day, 0); +GO + +SELECT DATEPART(month, 2958463); +GO + +SELECT DATEPART(hour, 2958464); +GO + +SELECT DATEPART(year, -53690); +GO + +SELECT DATEPART(microsecond, -53691); +GO diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 0a210dd4de..9409ae3929 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -307,7 +307,24 @@ Function sys.datediff_internal(text,anyelement,anyelement) Function sys.datediff_internal_df(text,anyelement,anyelement) Function sys.datefirst() Function sys.datename(text,text) -Function sys.datepart_internal(text,anyelement,integer) +Function sys.datepart_internal(text,bigint,integer) +Function sys.datepart_internal(text,date,integer) +Function sys.datepart_internal(text,double precision,integer) +Function sys.datepart_internal(text,integer,integer) +Function sys.datepart_internal(text,interval,integer) +Function sys.datepart_internal(text,numeric,integer) +Function sys.datepart_internal(text,real,integer) +Function sys.datepart_internal(text,smallint,integer) +Function sys.datepart_internal(text,sys."bit",integer) +Function sys.datepart_internal(text,sys."decimal",integer) +Function sys.datepart_internal(text,sys.datetime,integer) +Function sys.datepart_internal(text,sys.datetime2,integer) +Function sys.datepart_internal(text,sys.datetimeoffset,integer) +Function sys.datepart_internal(text,sys.money,integer) +Function sys.datepart_internal(text,sys.smalldatetime,integer) +Function sys.datepart_internal(text,sys.smallmoney,integer) +Function sys.datepart_internal(text,sys.tinyint,integer) +Function sys.datepart_internal(text,time without time zone,integer) Function sys.datetime22bpchar(sys.datetime2) Function sys.datetime22char(sys.datetime2) Function sys.datetime22date(sys.datetime2)