Skip to content

Commit

Permalink
Fix Implicit cast from datetimeoffset to other date/time datatypes. (#…
Browse files Browse the repository at this point in the history
…1927)

Due to implicit cast from datetimeoffset to datetime we are getting wrong output

--- AT TIME ZONE returns datetimeoffset

DECLARE @lvDateEastern DATETIME, @lvDateUTC DATETIME
SET @lvDateUTC = '2021-01-01'
SET @lvDateEastern = @lvDateUTC AT TIME ZONE  'UTC' AT TIME ZONE 'US Eastern Standard Time'
SELECT @lvDateUTC, @lvDateEastern

@lvDateUTC              @lvDateEastern
----------------------- -----------------------
2021-01-01 00:00:00.000 2021-01-01 00:00:00.000

Expected
----------------------- -----------------------
2021-01-01 00:00:00.000 2020-12-31 19:00:00.000
The above same issue is occuring when we are doing implicit cast from datetimeoffset to time,date,smalldatetime,datetime2.

Fixed this issue by excluding the timezone offset addition/subtraction to the original timestamp .

Issues Resolved : BABEL-986
Signed-off-by: Ashish Prasad <[email protected]>
  • Loading branch information
hash-16 authored and Rohit Bhagat committed May 22, 2024
1 parent 9727955 commit 3393219
Show file tree
Hide file tree
Showing 17 changed files with 182 additions and 77 deletions.
10 changes: 5 additions & 5 deletions contrib/babelfishpg_common/src/datetimeoffset.c
Original file line number Diff line number Diff line change
Expand Up @@ -511,7 +511,7 @@ datetimeoffset_smalldatetime(PG_FUNCTION_ARGS)
tsql_datetimeoffset *df = PG_GETARG_DATETIMEOFFSET(0);
Timestamp result;

datetimeoffset_timestamp_internal(df, &result);
result = df->tsql_ts;
CheckSmalldatetimeRange(result);
AdjustTimestampForSmallDatetime(&result);

Expand Down Expand Up @@ -544,7 +544,7 @@ datetimeoffset_datetime(PG_FUNCTION_ARGS)
tsql_datetimeoffset *df = PG_GETARG_DATETIMEOFFSET(0);
Timestamp result;

datetimeoffset_timestamp_internal(df, &result);
result = df->tsql_ts;
CheckDatetimeRange(result);

PG_RETURN_TIMESTAMP(result);
Expand Down Expand Up @@ -576,7 +576,7 @@ datetimeoffset_datetime2(PG_FUNCTION_ARGS)
tsql_datetimeoffset *df = PG_GETARG_DATETIMEOFFSET(0);
Timestamp result;

datetimeoffset_timestamp_internal(df, &result);
result = df->tsql_ts;
CheckDatetime2Range(result);

PG_RETURN_TIMESTAMP(result);
Expand Down Expand Up @@ -644,7 +644,7 @@ datetimeoffset_date(PG_FUNCTION_ARGS)
int tz;
DateADT result;

datetimeoffset_timestamp_internal(df, &time);
time = df->tsql_ts;
if (timestamp2tm(time, &tz, tm, &fsec, NULL, NULL) != 0)
ereport(ERROR,
(errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE),
Expand All @@ -665,7 +665,7 @@ datetimeoffset_time(PG_FUNCTION_ARGS)
Timestamp time;
TimeADT result;

datetimeoffset_timestamp_internal(df, &time);
time = df->tsql_ts;
if (time < 0)
result = time - (time / USECS_PER_DAY * USECS_PER_DAY) + USECS_PER_DAY;
else
Expand Down
2 changes: 1 addition & 1 deletion test/JDBC/expected/BABEL-3474-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -396,7 +396,7 @@ SELECT BABEL_3474_vu_prepare_f13()
GO
~~START~~
date
2016-12-26
2016-12-27
~~END~~

DROP FUNCTION BABEL_3474_vu_prepare_f13
Expand Down
16 changes: 8 additions & 8 deletions test/JDBC/expected/TestDatetimeoffset-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -293,14 +293,14 @@ select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-06 15:59:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS datetime);
go
~~START~~
datetime
2079-06-07 09:29:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('1920-05-25 00:59:29.99' AS datetime2) AS datetimeoffset);
Expand All @@ -314,7 +314,7 @@ select CAST(CAST('1900-05-06 13:59:29.998 -8:00' AS datetimeoffset) AS datetime2
go
~~START~~
datetime2
1900-05-06 21:59:29.9980000
1900-05-06 13:59:29.9980000
~~END~~


Expand Down Expand Up @@ -381,7 +381,7 @@ select CAST(CAST('1900-05-06 23:59:29.998+8:00' AS datetimeoffset) AS time);
go
~~START~~
time
15:59:29.9980000
23:59:29.9980000
~~END~~

select CAST(CAST('1920-05-25 00:59:29.99 +0' AS datetimeoffset) AS time);
Expand Down Expand Up @@ -416,7 +416,7 @@ select CAST(CAST('2050-05-06 23:59:29.998+8:00' AS datetimeoffset) AS time);
go
~~START~~
time
15:59:29.9980000
23:59:29.9980000
~~END~~


Expand All @@ -425,21 +425,21 @@ select CAST(CAST('2000-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS smalldate
go
~~START~~
smalldatetime
2000-06-07 09:29:00.0
2000-06-06 23:59:00.0
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS smalldatetime);
go
~~START~~
smalldatetime
2079-06-06 15:59:00.0
2079-06-06 23:59:00.0
~~END~~

select CAST(CAST('1900-05-06 13:59:29.998 -8:00' AS datetimeoffset) AS smalldatetime);
go
~~START~~
smalldatetime
1900-05-06 21:59:00.0
1900-05-06 13:59:00.0
~~END~~

select CAST(CAST('2020-03-15 23:59:29.99' AS smalldatetime) AS datetimeoffset);
Expand Down
2 changes: 1 addition & 1 deletion test/JDBC/expected/babel_datatype_sqlvariant-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -249,7 +249,7 @@ select cast(cast(cast('2020-10-05 09:00:00-9:00' as datetimeoffset) as sql_varia
go
~~START~~
datetime2
2020-10-05 18:00:00.0000000
2020-10-05 09:00:00.0000000
~~END~~

-- datetime2 2 datetimeoffset
Expand Down
2 changes: 1 addition & 1 deletion test/JDBC/expected/babel_datatype_sqlvariant.out
Original file line number Diff line number Diff line change
Expand Up @@ -456,7 +456,7 @@ select cast(cast(cast('2020-10-05 09:00:00-9:00' as datetimeoffset) as sql_varia
go
~~START~~
datetime2
2020-10-05 18:00:00.0000000
2020-10-05 09:00:00.0000000
~~END~~

-- datetime2 2 datetimeoffset
Expand Down
6 changes: 3 additions & 3 deletions test/JDBC/expected/babel_datetime-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -194,21 +194,21 @@ select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-06 15:59:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-07 09:29:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('2079-06-06 23:59:12.345678 -9:30' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-07 09:29:12.347
2079-06-06 23:59:12.347
~~END~~

-- out of range
Expand Down
6 changes: 3 additions & 3 deletions test/JDBC/expected/babel_datetime.out
Original file line number Diff line number Diff line change
Expand Up @@ -238,21 +238,21 @@ select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-06 15:59:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-07 09:29:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('2079-06-06 23:59:12.345678 -9:30' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-07 09:29:12.347
2079-06-06 23:59:12.347
~~END~~

-- out of range
Expand Down
10 changes: 5 additions & 5 deletions test/JDBC/expected/babel_datetime2.out
Original file line number Diff line number Diff line change
Expand Up @@ -423,35 +423,35 @@ select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS datetime2
go
~~START~~
datetime2
2079-06-06 15:59:29.9980000
2079-06-06 23:59:29.9980000
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS datetime2);
go
~~START~~
datetime2
2079-06-07 09:29:29.9980000
2079-06-06 23:59:29.9980000
~~END~~

select CAST(CAST('2079-06-06 23:59:12.345678 -9:30' AS datetimeoffset) AS datetime2);
go
~~START~~
datetime2
2079-06-07 09:29:12.3456780
2079-06-06 23:59:12.3456780
~~END~~

select CAST(CAST('0001-06-06 23:59:12.345678 -9:30' AS datetimeoffset) AS datetime2);
go
~~START~~
datetime2
0001-06-07 09:29:12.3456780
0001-06-06 23:59:12.3456780
~~END~~

select CAST(CAST('0001-06-06 23:59:12.345678 -9:30' AS datetimeoffset) AS datetime2(5));
go
~~START~~
datetime2
0001-06-07 09:29:12.34568
0001-06-06 23:59:12.34568
~~END~~


Expand Down
87 changes: 79 additions & 8 deletions test/JDBC/expected/babel_datetimeoffset.out
Original file line number Diff line number Diff line change
Expand Up @@ -343,14 +343,14 @@ select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS datetime)
go
~~START~~
datetime
2079-06-06 15:59:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS datetime);
go
~~START~~
datetime
2079-06-07 09:29:29.997
2079-06-06 23:59:29.997
~~END~~

select CAST(CAST('1920-05-25 00:59:29.99' AS datetime2) AS datetimeoffset);
Expand All @@ -364,7 +364,7 @@ select CAST(CAST('1900-05-06 13:59:29.998 -8:00' AS datetimeoffset) AS datetime2
go
~~START~~
datetime2
1900-05-06 21:59:29.9980000
1900-05-06 13:59:29.9980000
~~END~~


Expand Down Expand Up @@ -431,7 +431,7 @@ select CAST(CAST('1900-05-06 23:59:29.998+8:00' AS datetimeoffset) AS time);
go
~~START~~
time
15:59:29.9980000
23:59:29.9980000
~~END~~

select CAST(CAST('1920-05-25 00:59:29.99 +0' AS datetimeoffset) AS time);
Expand Down Expand Up @@ -466,7 +466,7 @@ select CAST(CAST('2050-05-06 23:59:29.998+8:00' AS datetimeoffset) AS time);
go
~~START~~
time
15:59:29.9980000
23:59:29.9980000
~~END~~


Expand All @@ -475,21 +475,21 @@ select CAST(CAST('2000-06-06 23:59:29.998 -9:30' AS datetimeoffset) AS smalldate
go
~~START~~
smalldatetime
2000-06-07 09:29:00.0
2000-06-06 23:59:00.0
~~END~~

select CAST(CAST('2079-06-06 23:59:29.998 +8:00' AS datetimeoffset) AS smalldatetime);
go
~~START~~
smalldatetime
2079-06-06 15:59:00.0
2079-06-06 23:59:00.0
~~END~~

select CAST(CAST('1900-05-06 13:59:29.998 -8:00' AS datetimeoffset) AS smalldatetime);
go
~~START~~
smalldatetime
1900-05-06 21:59:00.0
1900-05-06 13:59:00.0
~~END~~

select CAST(CAST('2020-03-15 23:59:29.99' AS smalldatetime) AS datetimeoffset);
Expand Down Expand Up @@ -932,11 +932,82 @@ DECLARE @dto datetimeoffset = CAST('1930-05-06 13:39:29.123456 +0:00' AS datetim
exec cmp_datetimeoffset @dto;
go

DECLARE @lvDateEastern DATETIME, @lvDateUTC DATETIME
SET @lvDateUTC = '2021-01-01'
SET @lvDateEastern = @lvDateUTC AT TIME ZONE 'UTC' AT TIME ZONE 'US Eastern Standard Time'
SELECT @lvDateUTC, @lvDateEastern
go
~~START~~
datetime#!#datetime
2021-01-01 00:00:00.0#!#2020-12-31 19:00:00.0
~~END~~


DECLARE @lvDateEastern DATETIME2, @lvDateUTC DATETIME
SET @lvDateUTC = '2021-01-01'
SET @lvDateEastern = @lvDateUTC AT TIME ZONE 'UTC' AT TIME ZONE 'US Eastern Standard Time'
SELECT @lvDateUTC, @lvDateEastern
go
~~START~~
datetime#!#datetime2
2021-01-01 00:00:00.0#!#2020-12-31 19:00:00.0000000
~~END~~


DECLARE @lvDateEastern SMALLDATETIME, @lvDateUTC DATETIME
SET @lvDateUTC = '2021-01-01'
SET @lvDateEastern = @lvDateUTC AT TIME ZONE 'UTC' AT TIME ZONE 'US Eastern Standard Time'
SELECT @lvDateUTC, @lvDateEastern
go
~~START~~
datetime#!#smalldatetime
2021-01-01 00:00:00.0#!#2020-12-31 19:00:00.0
~~END~~


DECLARE @lvDateEastern DATE, @lvDateUTC DATETIME
SET @lvDateUTC = '2021-01-01'
SET @lvDateEastern = @lvDateUTC AT TIME ZONE 'UTC' AT TIME ZONE 'US Eastern Standard Time'
SELECT @lvDateUTC, @lvDateEastern
go
~~START~~
datetime#!#date
2021-01-01 00:00:00.0#!#2020-12-31
~~END~~


DECLARE @lvDateEastern TIME, @lvDateUTC DATETIME
SET @lvDateUTC = '2021-01-01'
SET @lvDateEastern = @lvDateUTC AT TIME ZONE 'UTC' AT TIME ZONE 'US Eastern Standard Time'
SELECT @lvDateUTC, @lvDateEastern
go
~~START~~
datetime#!#time
2021-01-01 00:00:00.0#!#19:00:00.0000000
~~END~~


Create table implicit_cast ( a datetime)
go
insert into implicit_cast values (cast('1900-05-06 13:59:29.998 -8:00' as datetimeoffset))
go
~~ROW COUNT: 1~~

Select * from implicit_cast
go
~~START~~
datetime
1900-05-06 13:59:29.997
~~END~~


-- Clean up
drop table datetimeoffset_testing;
go
drop table t1;
go
drop table implicit_cast;
go
drop procedure cast_datetimeoffset;
go
drop procedure cmp_datetimeoffset;
Expand Down
Loading

0 comments on commit 3393219

Please sign in to comment.