Skip to content

Commit

Permalink
Support AT TIME ZONE (#1822)
Browse files Browse the repository at this point in the history
It converts an inputdate (datetime,smalldatetime,datetime2,datetimeoffset) to the corresponding datetimeoffset value in the target time zone.

```
Select convert(datetime,'2022-03-27T01:01:00') AT TIME ZONE 'Atlantic Standard Time'

2022-03-27 01:01:00.000 -03:00 

Here it considers that the given time is currently in the target time zone so no change in the time is observed
it just adds the offset.
```
Engine PR :- [Link](babelfish-for-postgresql/postgresql_modified_for_babelfish#215)

Issues Resolved: BABEL-986

Signed-off-by: Ashish Prasad <[email protected]>
  • Loading branch information
hash-16 authored Sep 27, 2023
1 parent 1d24bd6 commit ffdb644
Show file tree
Hide file tree
Showing 18 changed files with 2,904 additions and 3 deletions.
20 changes: 20 additions & 0 deletions contrib/babelfishpg_tsql/runtime/functions.c
Original file line number Diff line number Diff line change
Expand Up @@ -43,6 +43,7 @@
#include "../src/multidb.h"
#include "../src/session.h"
#include "../src/catalog.h"
#include "../src/timezone.h"
#include "../src/collation.h"
#include "../src/rolecmds.h"
#include "utils/fmgroids.h"
Expand Down Expand Up @@ -102,6 +103,7 @@ PG_FUNCTION_INFO_V1(servicename);
PG_FUNCTION_INFO_V1(xact_state);
PG_FUNCTION_INFO_V1(get_enr_list);
PG_FUNCTION_INFO_V1(tsql_random);
PG_FUNCTION_INFO_V1(timezone_mapping);
PG_FUNCTION_INFO_V1(is_member);
PG_FUNCTION_INFO_V1(schema_id);
PG_FUNCTION_INFO_V1(schema_name);
Expand Down Expand Up @@ -179,6 +181,7 @@ const char *bbf_servicename = "MSSQLSERVER";
char *bbf_language = "us_english";
#define MD5_HASH_LEN 32


Datum
trancount(PG_FUNCTION_ARGS)
{
Expand Down Expand Up @@ -493,6 +496,23 @@ tsql_random(PG_FUNCTION_ARGS)
return result;
}

Datum
timezone_mapping(PG_FUNCTION_ARGS)
{
char *sqltmz = text_to_cstring(PG_GETARG_TEXT_P(0));
VarChar *result = cstring_to_text("NULL");
int len = (sizeof(win32_tzmap) / sizeof(*(win32_tzmap)));
for(int i=0;i<len;i++)
{
if(pg_strcasecmp(win32_tzmap[i].stdname,sqltmz) == 0)
{
result = cstring_to_text(win32_tzmap[i].pgtzname);
break;
}
}
PG_RETURN_VARCHAR_P(result);
}

Datum
is_member(PG_FUNCTION_ARGS)
{
Expand Down
4 changes: 2 additions & 2 deletions contrib/babelfishpg_tsql/sql/sys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ GRANT EXECUTE ON FUNCTION sys.sysdatetimeoffset() TO PUBLIC;


CREATE OR REPLACE FUNCTION sys.sysutcdatetime() RETURNS sys.datetime2
AS $$select (statement_timestamp() AT TIME ZONE 'UTC'::pg_catalog.text)::sys.datetime2;$$
AS $$select (statement_timestamp()::text::datetime2 AT TIME ZONE 'UTC'::pg_catalog.text)::sys.datetime2;$$
LANGUAGE SQL STABLE;
GRANT EXECUTE ON FUNCTION sys.sysutcdatetime() TO PUBLIC;

Expand All @@ -23,7 +23,7 @@ CREATE OR REPLACE FUNCTION sys.getdate() RETURNS sys.datetime
GRANT EXECUTE ON FUNCTION sys.getdate() TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.getutcdate() RETURNS sys.datetime
AS $$select date_trunc('millisecond', statement_timestamp() AT TIME ZONE 'UTC'::pg_catalog.text)::sys.datetime;$$
AS $$select date_trunc('millisecond', ((statement_timestamp()::text::datetime2 AT TIME ZONE 'UTC'::pg_catalog.text)::pg_catalog.text::pg_catalog.TIMESTAMP))::sys.datetime;$$
LANGUAGE SQL STABLE;
GRANT EXECUTE ON FUNCTION sys.getutcdate() TO PUBLIC;

Expand Down
85 changes: 85 additions & 0 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -982,6 +982,91 @@ $BODY$
LANGUAGE plpgsql
IMMUTABLE;

create or replace function sys.babelfish_timezone_mapping(IN tmz text) returns text
AS 'babelfishpg_tsql', 'timezone_mapping'
LANGUAGE C IMMUTABLE ;

CREATE OR REPLACE FUNCTION sys.timezone(IN tzzone PG_CATALOG.TEXT , IN input_expr PG_CATALOG.TEXT)
RETURNS sys.datetimeoffset
AS
$BODY$
BEGIN
IF input_expr = 'NULL' THEN
RAISE USING MESSAGE := 'Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.';
END IF;

IF input_expr IS NULL OR tzzone IS NULL THEN
RETURN NULL;
END IF;

RAISE USING MESSAGE := 'Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.';
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.timezone(IN tzzone PG_CATALOG.TEXT , IN input_expr anyelement)
RETURNS sys.datetimeoffset
AS
$BODY$
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;
BEGIN
IF input_expr IS NULL OR tzzone IS NULL THEN
RETURN NULL;
END IF;

lower_tzn := lower(tzzone);
IF lower_tzn <> 'utc' THEN
tz_name := sys.babelfish_timezone_mapping(lower_tzn);
ELSE
tz_name := 'utc';
END IF;

IF tz_name = 'NULL' THEN
RAISE USING MESSAGE := format('Argument data type or the parameter %s provided to AT TIME ZONE clause is invalid.', tzzone);
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;

result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::TEXT;
tz_diff := (SELECT result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
if LEFT(tz_diff,1) <> '-' THEN
tz_diff := concat('+',tz_diff);
END IF;
tz_offset := left(tz_diff,6);
input_expr_tx := concat(input_expr_tx,tz_offset);
return cast(input_expr_tx as sys.datetimeoffset);
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 result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
if LEFT(tz_diff,1) <> '-' THEN
tz_diff := concat('+',tz_diff);
END IF;
tz_offset := left(tz_diff,6);
result := 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;

END;
$BODY$
LANGUAGE 'plpgsql' STABLE;



CREATE OR REPLACE FUNCTION sys.SWITCHOFFSET(IN input_expr PG_CATALOG.TEXT,
IN tz_offset PG_CATALOG.TEXT)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -702,6 +702,102 @@ $BODY$
LANGUAGE plpgsql
IMMUTABLE;



create or replace function sys.babelfish_timezone_mapping(IN tmz text) returns text
AS 'babelfishpg_tsql', 'timezone_mapping'
LANGUAGE C IMMUTABLE ;

CREATE OR REPLACE FUNCTION sys.timezone(IN tzzone PG_CATALOG.TEXT , IN input_expr PG_CATALOG.TEXT)
RETURNS sys.datetimeoffset
AS
$BODY$
BEGIN
IF input_expr = 'NULL' THEN
RAISE USING MESSAGE := 'Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.';
END IF;

IF input_expr IS NULL OR tzzone IS NULL THEN
RETURN NULL;
END IF;

RAISE USING MESSAGE := 'Argument data type varchar is invalid for argument 1 of AT TIME ZONE function.';
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.timezone(IN tzzone PG_CATALOG.TEXT , IN input_expr anyelement)
RETURNS sys.datetimeoffset
AS
$BODY$
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;
BEGIN
IF input_expr IS NULL OR tzzone IS NULL THEN
RETURN NULL;
END IF;

lower_tzn := lower(tzzone);
IF lower_tzn <> 'utc' THEN
tz_name := sys.babelfish_timezone_mapping(lower_tzn);
ELSE
tz_name := 'utc';
END IF;

IF tz_name = 'NULL' THEN
RAISE USING MESSAGE := format('Argument data type or the parameter %s provided to AT TIME ZONE clause is invalid.', tzzone);
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;

result := (SELECT input_expr_tmz AT TIME ZONE tz_name)::TEXT;
tz_diff := (SELECT result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
if LEFT(tz_diff,1) <> '-' THEN
tz_diff := concat('+',tz_diff);
END IF;
tz_offset := left(tz_diff,6);
input_expr_tx := concat(input_expr_tx,tz_offset);
return cast(input_expr_tx as sys.datetimeoffset);
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 result::TIMESTAMPTZ - input_expr_tmz)::TEXT;
if LEFT(tz_diff,1) <> '-' THEN
tz_diff := concat('+',tz_diff);
END IF;
tz_offset := left(tz_diff,6);
result := 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;

END;
$BODY$
LANGUAGE 'plpgsql' STABLE;

CREATE OR REPLACE FUNCTION sys.sysutcdatetime() RETURNS sys.datetime2
AS $$select (statement_timestamp()::text::datetime2 AT TIME ZONE 'UTC'::pg_catalog.text)::sys.datetime2;$$
LANGUAGE SQL STABLE;
GRANT EXECUTE ON FUNCTION sys.sysutcdatetime() TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.getutcdate() RETURNS sys.datetime
AS $$select date_trunc('millisecond', ((statement_timestamp()::text::datetime2 AT TIME ZONE 'UTC'::pg_catalog.text)::pg_catalog.text::pg_catalog.TIMESTAMP))::sys.datetime;$$
LANGUAGE SQL STABLE;
GRANT EXECUTE ON FUNCTION sys.getutcdate() TO PUBLIC;

-- internal helper function for date_bucket().
CREATE OR REPLACE FUNCTION sys.date_bucket_internal_helper(IN datepart PG_CATALOG.TEXT, IN number INTEGER, IN check_date boolean, IN origin boolean, IN date ANYELEMENT default NULL) RETURNS boolean
AS
Expand Down Expand Up @@ -996,6 +1092,7 @@ END;
$body$
LANGUAGE plpgsql IMMUTABLE;


-- This is a temporary procedure which is called during upgrade to update guest schema
-- for the guest users in the already existing databases
CREATE OR REPLACE PROCEDURE sys.babelfish_update_user_catalog_for_guest_schema()
Expand All @@ -1007,9 +1104,11 @@ CALL sys.babelfish_update_user_catalog_for_guest_schema();
-- Drop this procedure after it gets executed once.
DROP PROCEDURE sys.babelfish_update_user_catalog_for_guest_schema();


-- Drops the temporary procedure used by the upgrade script.
-- Please have this be one of the last statements executed in this upgrade script.
DROP PROCEDURE sys.babelfish_drop_deprecated_object(varchar, varchar, varchar);


-- Reset search_path to not affect any subsequent scripts
SELECT set_config('search_path', trim(leading 'sys, ' from current_setting('search_path')), false);
Loading

0 comments on commit ffdb644

Please sign in to comment.