Skip to content

Commit

Permalink
Fix timezone offset in case of non-default timezone (#3186)
Browse files Browse the repository at this point in the history
1. Issue

    When the default timezone is not UTC then the result shows incorrect timezone offset value with AT TIME ZONE property. This is due to the fact that the timezone offset which is calculated using input_expr_tmz which is text explicitly converted to TIMESTAMPTZ which takes into account the current session timezone setting which produces this timezone difference in the output.

2. Changes made to fix the issue

    We will now calculate the timezone offset with absolute value of timezone that is by subtracting the datetime value in current timezone with the value in UTC timezone.

# Previous output (incorrect)
1> Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
2> go
timezone                                     
---------------------------------------------
           2001-12-31 21:01:00.0000000 -05:00

(1 rows affected)
1> select set_config('timezone', 'Asia/Kolkata', false)
2> go
set_config                                                                                                                                                                                                                                                      
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Asia/Kolkata                                                                                                                                                                                                                                                    

(1 rows affected)
1> Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
2> go
timezone                                     
---------------------------------------------
           2001-12-31 21:01:00.0000000 -10:30

# Current output (Correct)
1> Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
2> go
timezone                                     
---------------------------------------------
           2001-12-31 21:01:00.0000000 -05:00

(1 rows affected)
1> select set_config('timezone', 'Asia/Kolkata', false)
2> go
set_config                                                                                                                                                                                                                                                      
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Asia/Kolkata                                                                                                                                                                                                                                                    

(1 rows affected)
1> Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
2> go
timezone                                     
---------------------------------------------
           2001-12-31 21:01:00.0000000 -05:00

    Added test cases for the issue.

cherry-picked: #3174

Task: BABEL- 5316

Signed-off-by: Anikait Agrawal [email protected]
  • Loading branch information
Anikait143 authored Nov 30, 2024
1 parent 4ad36c5 commit b9e4d53
Show file tree
Hide file tree
Showing 4 changed files with 115 additions and 7 deletions.
5 changes: 2 additions & 3 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1196,8 +1196,7 @@ BEGIN
input_expr_tx := input_expr::TEXT;
input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;

result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::TEXT;
tz_diff := (SELECT result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
tz_diff := (SELECT input_expr_tmz AT TIME ZONE tz_name - input_expr_tmz AT TIME ZONE 'UTC')::TEXT;
if PG_CATALOG.LEFT(tz_diff,1) <> '-' THEN
tz_diff := PG_CATALOG.concat('+',tz_diff);
END IF;
Expand All @@ -1208,7 +1207,7 @@ BEGIN
input_expr_tx := input_expr::TEXT;
input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;
result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::TEXT;
tz_diff := (SELECT result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
tz_diff := (SELECT input_expr_tmz AT TIME ZONE tz_name - input_expr_tmz AT TIME ZONE 'UTC')::TEXT;
if PG_CATALOG.LEFT(tz_diff,1) <> '-' THEN
tz_diff := PG_CATALOG.concat('+',tz_diff);
END IF;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -2181,8 +2181,7 @@ BEGIN
input_expr_tx := input_expr::TEXT;
input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;

result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::TEXT;
tz_diff := (SELECT result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
tz_diff := (SELECT input_expr_tmz AT TIME ZONE tz_name - input_expr_tmz AT TIME ZONE 'UTC')::TEXT;
if PG_CATALOG.LEFT(tz_diff,1) <> '-' THEN
tz_diff := PG_CATALOG.concat('+',tz_diff);
END IF;
Expand All @@ -2193,7 +2192,7 @@ BEGIN
input_expr_tx := input_expr::TEXT;
input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;
result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::TEXT;
tz_diff := (SELECT result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
tz_diff := (SELECT input_expr_tmz AT TIME ZONE tz_name - input_expr_tmz AT TIME ZONE 'UTC')::TEXT;
if PG_CATALOG.LEFT(tz_diff,1) <> '-' THEN
tz_diff := PG_CATALOG.concat('+',tz_diff);
END IF;
Expand Down
80 changes: 80 additions & 0 deletions test/JDBC/expected/ATTIMEZONE-dep-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -44,3 +44,83 @@ datetimeoffset

~~ERROR (Message: Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.)~~


Select convert(datetime2,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO
~~START~~
datetimeoffset
2002-01-01 02:01:00.0000000 -05:00
~~END~~


Select convert(datetime2,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO
~~START~~
datetimeoffset
9999-12-31 15:59:59.0000000 +01:00
~~END~~


Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO
~~START~~
datetimeoffset
2001-12-31 21:01:00.0000000 -05:00
~~END~~


Select convert(datetimeoffset,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO
~~START~~
datetimeoffset
9999-12-31 16:59:59.0000000 +01:00
~~END~~


select set_config('timezone', 'Asia/Kolkata', false);
GO
~~START~~
text
Asia/Kolkata
~~END~~


Select convert(datetime2,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO
~~START~~
datetimeoffset
2002-01-01 02:01:00.0000000 -05:00
~~END~~


Select convert(datetime2,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO
~~START~~
datetimeoffset
9999-12-31 15:59:59.0000000 +01:00
~~END~~


Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO
~~START~~
datetimeoffset
2001-12-31 21:01:00.0000000 -05:00
~~END~~


Select convert(datetimeoffset,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO
~~START~~
datetimeoffset
9999-12-31 16:59:59.0000000 +01:00
~~END~~


select set_config('timezone', 'UTC', false);
GO
~~START~~
text
UTC
~~END~~

32 changes: 31 additions & 1 deletion test/JDBC/input/ATTIMEZONE-dep-vu-verify.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,4 +14,34 @@ SELECT ATTIMEZONE_dep_vu_prepare_f1()
GO

SELECT ATTIMEZONE_dep_vu_prepare_f2()
GO
GO

Select convert(datetime2,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO

Select convert(datetime2,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO

Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO

Select convert(datetimeoffset,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO

select set_config('timezone', 'Asia/Kolkata', false);
GO

Select convert(datetime2,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO

Select convert(datetime2,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO

Select convert(datetimeoffset,'2002-01-01 02:01:00.000 +00:00') AT TIME ZONE 'eastern standard time';
GO

Select convert(datetimeoffset,'9999-12-31 15:59:59.000 +00:00') AT TIME ZONE 'Central Europe Standard Time';
GO

select set_config('timezone', 'UTC', false);
GO

0 comments on commit b9e4d53

Please sign in to comment.