Skip to content

Commit

Permalink
Fix 'AT TIME ZONE' issue near DST change time with DATETIME2 datatype…
Browse files Browse the repository at this point in the history
… conversion. (#3347)

Convert function when converting to datetime2, datetime, smalldatettime with given timezone using AT TIME ZONE gives wrong output near DST change time.

Fix timestamp value to consider it in the given timezone instead of UTC for datetime2, datetime, smalldatettime datatypes. This fixes the issue and also makes it independent of local timezone setting.

Task: BABEL-5513

Signed-off-by: Anikait Agrawal <[email protected]>
  • Loading branch information
Anikait143 authored Jan 3, 2025
1 parent 7b3e322 commit fbe64c3
Show file tree
Hide file tree
Showing 4 changed files with 1,299 additions and 44 deletions.
36 changes: 14 additions & 22 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1116,9 +1116,7 @@ DECLARE
tz_offset PG_CATALOG.TEXT;
tz_name PG_CATALOG.TEXT;
lower_tzn PG_CATALOG.TEXT;
prev_res PG_CATALOG.TEXT;
result PG_CATALOG.TEXT;
is_dstt bool;
tz_diff PG_CATALOG.TEXT;
input_expr_tx PG_CATALOG.TEXT;
input_expr_tmz TIMESTAMPTZ;
Expand All @@ -1139,31 +1137,25 @@ BEGIN
END IF;

IF pg_typeof(input_expr) IN ('sys.smalldatetime'::regtype, 'sys.datetime'::regtype, 'sys.datetime2'::regtype) THEN
input_expr_tx := input_expr::TEXT;
input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;

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;
tz_offset := PG_CATALOG.left(tz_diff,6);
input_expr_tx := PG_CATALOG.concat(input_expr_tx,tz_offset);
return cast(input_expr_tx as sys.datetimeoffset);
input_expr_tx := input_expr::TEXT || ' ' || tz_name;
ELSIF pg_typeof(input_expr) = 'sys.DATETIMEOFFSET'::regtype THEN
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 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;
tz_offset := PG_CATALOG.left(tz_diff,6);
result := PG_CATALOG.concat(result,tz_offset);
return cast(result as sys.datetimeoffset);
ELSE
RAISE USING MESSAGE := 'Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.';
END IF;


input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;
result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::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;

tz_offset := PG_CATALOG.left(tz_diff,6);
result := PG_CATALOG.concat(result,tz_offset);

return cast(result as sys.datetimeoffset);
END;
$BODY$
LANGUAGE 'plpgsql' STABLE;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -8449,9 +8449,7 @@ DECLARE
tz_offset PG_CATALOG.TEXT;
tz_name PG_CATALOG.TEXT;
lower_tzn PG_CATALOG.TEXT;
prev_res PG_CATALOG.TEXT;
result PG_CATALOG.TEXT;
is_dstt bool;
tz_diff PG_CATALOG.TEXT;
input_expr_tx PG_CATALOG.TEXT;
input_expr_tmz TIMESTAMPTZ;
Expand All @@ -8472,31 +8470,25 @@ BEGIN
END IF;

IF pg_typeof(input_expr) IN ('sys.smalldatetime'::regtype, 'sys.datetime'::regtype, 'sys.datetime2'::regtype) THEN
input_expr_tx := input_expr::TEXT;
input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;

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;
tz_offset := PG_CATALOG.left(tz_diff,6);
input_expr_tx := PG_CATALOG.concat(input_expr_tx,tz_offset);
return cast(input_expr_tx as sys.datetimeoffset);
input_expr_tx := input_expr::TEXT || ' ' || tz_name;
ELSIF pg_typeof(input_expr) = 'sys.DATETIMEOFFSET'::regtype THEN
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 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;
tz_offset := PG_CATALOG.left(tz_diff,6);
result := PG_CATALOG.concat(result,tz_offset);
return cast(result as sys.datetimeoffset);
ELSE
RAISE USING MESSAGE := 'Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.';
END IF;


input_expr_tmz := input_expr_tx :: TIMESTAMPTZ;
result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::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;

tz_offset := PG_CATALOG.left(tz_diff,6);
result := PG_CATALOG.concat(result,tz_offset);

return cast(result as sys.datetimeoffset);
END;
$BODY$
LANGUAGE 'plpgsql' STABLE;
Expand Down
Loading

0 comments on commit fbe64c3

Please sign in to comment.