Skip to content

Commit

Permalink
Merge branch 'babelfish-for-postgresql:BABEL_3_X_DEV' into jira-babel…
Browse files Browse the repository at this point in the history
…-4393
  • Loading branch information
Deepesh125 authored Oct 18, 2023
2 parents eabf316 + a5250b7 commit e8745f7
Show file tree
Hide file tree
Showing 126 changed files with 9,718 additions and 386 deletions.
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/antlr/TSqlLexer.g4
Original file line number Diff line number Diff line change
Expand Up @@ -243,6 +243,7 @@ DATEFORMAT: D A T E F O R M A T;
DATE_FORMAT: D A T E UNDERLINE F O R M A T;
DATENAME: D A T E N A M E;
DATEPART: D A T E P A R T;
DATETRUNC: D A T E T R U N C;
DATE_CORRELATION_OPTIMIZATION: D A T E UNDERLINE C O R R E L A T I O N UNDERLINE O P T I M I Z A T I O N;
DAY: D A Y;
DAYS: D A Y S;
Expand Down
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/antlr/TSqlParser.g4
Original file line number Diff line number Diff line change
Expand Up @@ -4338,6 +4338,7 @@ keyword
| DATE_FORMAT
| DATENAME
| DATEPART
| DATETRUNC
| DATE_CORRELATION_OPTIMIZATION
| DATE_FORMAT
| DAY
Expand Down
16 changes: 16 additions & 0 deletions contrib/babelfishpg_tsql/runtime/functions.c
Original file line number Diff line number Diff line change
Expand Up @@ -147,6 +147,8 @@ PG_FUNCTION_INFO_V1(object_schema_name);
PG_FUNCTION_INFO_V1(parsename);
PG_FUNCTION_INFO_V1(pg_extension_config_remove);
PG_FUNCTION_INFO_V1(objectproperty_internal);
PG_FUNCTION_INFO_V1(sysutcdatetime);
PG_FUNCTION_INFO_V1(getutcdate);

void *string_to_tsql_varchar(const char *input_str);
void *get_servername_internal(void);
Expand Down Expand Up @@ -240,6 +242,20 @@ version(PG_FUNCTION_ARGS)
PG_RETURN_VARCHAR_P(info);
}

Datum sysutcdatetime(PG_FUNCTION_ARGS)
{
PG_RETURN_TIMESTAMP(DirectFunctionCall2(timestamptz_zone,CStringGetTextDatum("UTC"),
PointerGetDatum(GetCurrentStatementStartTimestamp())));

}

Datum getutcdate(PG_FUNCTION_ARGS)
{
PG_RETURN_TIMESTAMP(DirectFunctionCall2(timestamp_trunc,CStringGetTextDatum("millisecond"),DirectFunctionCall2(timestamptz_zone,CStringGetTextDatum("UTC"),
PointerGetDatum(GetCurrentStatementStartTimestamp()))));

}

void *
string_to_tsql_varchar(const char *input_str)
{
Expand Down
11 changes: 11 additions & 0 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,17 @@ CREATE TABLE sys.babelfish_sysdatabases (

GRANT SELECT on sys.babelfish_sysdatabases TO PUBLIC;

-- BABELFISH_SCHEMA_PERMISSIONS
CREATE TABLE sys.babelfish_schema_permissions (
dbid smallint NOT NULL,
schema_name NAME NOT NULL,
object_name NAME NOT NULL,
permission NAME NOT NULL,
grantee NAME NOT NULL,
object_type NAME,
PRIMARY KEY(dbid, schema_name, object_name, permission, grantee)
);

-- BABELFISH_FUNCTION_EXT
CREATE TABLE sys.babelfish_function_ext (
nspname NAME NOT NULL,
Expand Down
15 changes: 6 additions & 9 deletions contrib/babelfishpg_tsql/sql/sys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,21 +11,18 @@ CREATE OR REPLACE FUNCTION sys.sysdatetimeoffset() RETURNS sys.datetimeoffset
GRANT EXECUTE ON FUNCTION sys.sysdatetimeoffset() TO PUBLIC;


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.sysutcdatetime() returns sys.datetime2
AS 'babelfishpg_tsql', 'sysutcdatetime'
LANGUAGE C STABLE;

CREATE OR REPLACE FUNCTION sys.getdate() RETURNS sys.datetime
AS $$select date_trunc('millisecond', statement_timestamp()::pg_catalog.timestamp)::sys.datetime;$$
LANGUAGE SQL STABLE;
GRANT EXECUTE ON FUNCTION sys.getdate() 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;
create or replace function sys.getutcdate() returns sys.datetime
AS 'babelfishpg_tsql', 'getutcdate'
LANGUAGE C STABLE;


CREATE FUNCTION sys.isnull(text,text) RETURNS text AS $$
Expand Down
236 changes: 155 additions & 81 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4014,93 +4014,61 @@ GRANT EXECUTE ON FUNCTION sys.fn_listextendedproperty TO PUBLIC;
-- Matches and returns column length of the corresponding column of the given table
CREATE OR REPLACE FUNCTION sys.COL_LENGTH(IN object_name TEXT, IN column_name TEXT)
RETURNS SMALLINT AS $BODY$
DECLARE
col_name TEXT;
object_id oid;
column_id INT;
column_length INT;
column_data_type TEXT;
column_precision INT;
BEGIN
-- Get the object ID for the provided object_name
object_id = sys.OBJECT_ID(object_name);
IF object_id IS NULL THEN
RETURN NULL;
END IF;
DECLARE
col_name TEXT;
object_id oid;
column_id INT;
column_length SMALLINT;
column_data_type TEXT;
typeid oid;
typelen INT;
typemod INT;
BEGIN
-- Get the object ID for the provided object_name
object_id := sys.OBJECT_ID(object_name, 'U');
IF object_id IS NULL THEN
RETURN NULL;
END IF;

-- Truncate and normalize the column name
col_name = sys.babelfish_truncate_identifier(sys.babelfish_remove_delimiter_pair(lower(column_name)));
-- Truncate and normalize the column name
col_name := sys.babelfish_truncate_identifier(sys.babelfish_remove_delimiter_pair(lower(column_name)));

-- Get the column ID for the provided column_name
SELECT attnum INTO column_id FROM pg_attribute
WHERE attrelid = object_id AND lower(attname) = col_name
COLLATE sys.database_default;
-- Get the column ID, typeid, length, and typmod for the provided column_name
SELECT attnum, a.atttypid, a.attlen, a.atttypmod
INTO column_id, typeid, typelen, typemod
FROM pg_attribute a
WHERE attrelid = object_id AND lower(attname) = col_name COLLATE sys.database_default;

IF column_id IS NULL THEN
RETURN NULL;
END IF;
IF column_id IS NULL THEN
RETURN NULL;
END IF;

-- Get the correct data type
column_data_type := sys.translate_pg_type_to_tsql(typeid);

IF column_data_type = 'sysname' THEN
column_length := 256;
ELSIF column_data_type IS NULL THEN

-- Check if it's a user-defined data type
SELECT sys.translate_pg_type_to_tsql(typbasetype), typlen, typtypmod
INTO column_data_type, typelen, typemod
FROM pg_type
WHERE oid = typeid;

-- Retrieve the data type, precision, scale, and column length in characters
SELECT a.atttypid::regtype,
CASE
WHEN a.atttypmod > 0 THEN ((a.atttypmod - 4) >> 16) & 65535
ELSE NULL
END,
CASE
WHEN a.atttypmod > 0 THEN ((a.atttypmod - 4) & 65535)
ELSE a.atttypmod
END
INTO column_data_type, column_precision, column_length
FROM pg_attribute a
WHERE a.attrelid = object_id AND a.attnum = column_id;

-- Remove delimiters
column_data_type := sys.babelfish_remove_delimiter_pair(column_data_type);

IF column_data_type IS NOT NULL THEN
column_length := CASE
-- Columns declared with max specifier case
WHEN column_length = -1 AND column_data_type IN ('varchar', 'nvarchar', 'varbinary')
THEN -1
WHEN column_data_type = 'xml'
THEN -1
WHEN column_data_type IN ('tinyint', 'bit')
THEN 1
WHEN column_data_type = 'smallint'
THEN 2
WHEN column_data_type = 'date'
THEN 3
WHEN column_data_type IN ('int', 'integer', 'real', 'smalldatetime', 'smallmoney')
THEN 4
WHEN column_data_type IN ('time', 'time without time zone')
THEN 5
WHEN column_data_type IN ('double precision', 'bigint', 'datetime', 'datetime2', 'money')
THEN 8
WHEN column_data_type = 'datetimeoffset'
THEN 10
WHEN column_data_type IN ('uniqueidentifier', 'text', 'image', 'ntext')
THEN 16
WHEN column_data_type = 'sysname'
THEN 256
WHEN column_data_type = 'sql_variant'
THEN 8016
WHEN column_data_type IN ('bpchar', 'char', 'varchar', 'binary', 'varbinary')
THEN column_length
WHEN column_data_type IN ('nchar', 'nvarchar')
THEN column_length * 2
WHEN column_data_type IN ('numeric', 'decimal')
THEN
CASE
WHEN column_precision IS NULL
THEN NULL
ELSE ((column_precision + 8) / 9 * 4 + 1)
END
ELSE NULL
END;
IF column_data_type = 'sysname' THEN
column_length := 256;
ELSE
-- Calculate column length based on base type information
column_length := sys.tsql_type_max_length_helper(column_data_type, typelen, typemod);
END IF;
ELSE
-- Calculate column length based on base type information
column_length := sys.tsql_type_max_length_helper(column_data_type, typelen, typemod);
END IF;

RETURN column_length::SMALLINT;
END;
RETURN column_length;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE
Expand Down Expand Up @@ -4418,3 +4386,109 @@ BEGIN
END;
$body$
LANGUAGE plpgsql IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.DATETRUNC(IN datepart PG_CATALOG.TEXT, IN date ANYELEMENT) RETURNS ANYELEMENT AS
$body$
DECLARE
days_offset INT;
v_day INT;
result_date timestamp;
input_expr_timestamp timestamp;
date_arg_datatype regtype;
offset_string PG_CATALOG.TEXT;
datefirst_value INT;
BEGIN
BEGIN
/* perform input validation */
date_arg_datatype := pg_typeof(date);
IF datepart NOT IN ('year', 'quarter', 'month', 'week', 'tsql_week', 'hour', 'minute', 'second', 'millisecond', 'microsecond',
'doy', 'day', 'nanosecond', 'tzoffset') THEN
RAISE EXCEPTION '''%'' is not a recognized datetrunc option.', datepart;
ELSIF date_arg_datatype NOT IN ('date'::regtype, 'time'::regtype, 'sys.datetime'::regtype, 'sys.datetime2'::regtype,
'sys.datetimeoffset'::regtype, 'sys.smalldatetime'::regtype) THEN
RAISE EXCEPTION 'Argument data type ''%'' is invalid for argument 2 of datetrunc function.', date_arg_datatype;
ELSIF datepart IN ('nanosecond', 'tzoffset') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''%''.',datepart, date_arg_datatype;
ELSIF datepart IN ('dow') THEN
RAISE EXCEPTION 'The datepart ''weekday'' is not supported by date function datetrunc for data type ''%''.', date_arg_datatype;
ELSIF date_arg_datatype = 'date'::regtype AND datepart IN ('hour', 'minute', 'second', 'millisecond', 'microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''date''.', datepart;
ELSIF date_arg_datatype = 'datetime'::regtype AND datepart IN ('microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''datetime''.', datepart;
ELSIF date_arg_datatype = 'smalldatetime'::regtype AND datepart IN ('millisecond', 'microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''smalldatetime''.', datepart;
ELSIF date_arg_datatype = 'time'::regtype THEN
IF datepart IN ('year', 'quarter', 'month', 'doy', 'day', 'week', 'tsql_week') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''time''.', datepart;
END IF;
-- Limitation in determining if the specified fractional scale (if provided any) for time datatype is
-- insufficient to support provided datepart (millisecond, microsecond) value
ELSIF date_arg_datatype IN ('datetime2'::regtype, 'datetimeoffset'::regtype) THEN
-- Limitation in determining if the specified fractional scale (if provided any) for the above datatype is
-- insufficient to support for provided datepart (millisecond, microsecond) value
END IF;

/* input validation is complete, proceed with result calculation. */
IF date_arg_datatype = 'time'::regtype THEN
RETURN date_trunc(datepart, date);
ELSE
input_expr_timestamp = date::timestamp;
-- preserving offset_string value in the case of datetimeoffset datatype before converting it to timestamps
IF date_arg_datatype = 'sys.datetimeoffset'::regtype THEN
offset_string = RIGHT(date::PG_CATALOG.TEXT, 6);
input_expr_timestamp := LEFT(date::PG_CATALOG.TEXT, -6)::timestamp;
END IF;
CASE
WHEN datepart IN ('year', 'quarter', 'month', 'week', 'hour', 'minute', 'second', 'millisecond', 'microsecond') THEN
result_date := date_trunc(datepart, input_expr_timestamp);
WHEN datepart IN ('doy', 'day') THEN
result_date := date_trunc('day', input_expr_timestamp);
WHEN datepart IN ('tsql_week') THEN
-- sql server datepart 'iso_week' is similar to postgres 'week' datepart
-- handle sql server datepart 'week' here based on the value of set variable 'DATEFIRST'
v_day := EXTRACT(dow from input_expr_timestamp)::INT;
datefirst_value := current_setting('babelfishpg_tsql.datefirst')::INT;
IF v_day = 0 THEN
v_day := 7;
END IF;
result_date := date_trunc('day', input_expr_timestamp);
days_offset := (7 + v_day - datefirst_value)%7;
result_date := result_date - make_interval(days => days_offset);
END CASE;
-- concat offset_string to result_date in case of datetimeoffset before converting it to datetimeoffset datatype.
IF date_arg_datatype = 'sys.datetimeoffset'::regtype THEN
RETURN concat(result_date, ' ', offset_string)::sys.datetimeoffset;
ELSE
RETURN result_date;
END IF;
END IF;
END;
END;
$body$
LANGUAGE plpgsql STABLE;

-- another definition of datetrunc as anyelement can not handle unknown type.
CREATE OR REPLACE FUNCTION sys.DATETRUNC(IN datepart PG_CATALOG.TEXT, IN date PG_CATALOG.TEXT) RETURNS SYS.DATETIME2 AS
$body$
DECLARE
input_expr_datetime2 sys.datetime2;
BEGIN
IF datepart NOT IN ('year', 'quarter', 'month', 'week', 'tsql_week', 'hour', 'minute', 'second', 'millisecond', 'microsecond',
'doy', 'day', 'nanosecond', 'tzoffset') THEN
RAISE EXCEPTION '''%'' is not a recognized datetrunc option.', datepart;
END IF;
BEGIN
input_expr_datetime2 := cast(date as sys.datetime2);
exception
WHEN others THEN
RAISE USING MESSAGE := 'Conversion failed when converting date and/or time from character string.';
END;
IF input_expr_datetime2 IS NULL THEN
RETURN NULL;
ELSE
-- input string literal is valid, call the datetrunc function with datetime2 datatype.
RETURN sys.DATETRUNC(datepart, input_expr_datetime2);
END IF;
END;
$body$
LANGUAGE plpgsql STABLE;
36 changes: 36 additions & 0 deletions contrib/babelfishpg_tsql/sql/sys_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3052,6 +3052,42 @@ SELECT
WHERE FALSE;
GRANT SELECT ON sys.sql_expression_dependencies TO PUBLIC;


create or replace view sys.sequences as
select
CAST(p.relname as sys.nvarchar(128)) as name
, CAST(p.oid as int) as object_id
, CAST(null as int) as principal_id
, CAST(s.schema_id as int) as schema_id
, CAST(0 as int) as parent_object_id
, CAST('SO' as sys.bpchar(2)) as type
, CAST('SEQUENCE_OBJECT' as sys.nvarchar(60)) as type_desc
, CAST(null as sys.datetime) as create_date
, CAST(null as sys.datetime) as modify_date
, CAST(0 as sys.bit) as is_ms_shipped
, CAST(0 as sys.bit) as is_published
, CAST(0 as sys.bit) as is_schema_published
, CAST(ps.seqstart as sys.sql_variant ) as start_value
, CAST(ps.seqincrement as sys.sql_variant ) as increment
, CAST(ps.seqmin as sys.sql_variant ) as minimum_value
, CAST(ps.seqmax as sys.sql_variant ) as maximum_value
, CASE ps.seqcycle when 't' then CAST(1 as sys.bit) else CAST(0 as sys.bit) end as is_cycling
, CAST(0 as sys.bit ) as is_cached
, CAST(ps.seqcache as int ) as cache_size
, CAST(ps.seqtypid as int ) as system_type_id
, CAST(ps.seqtypid as int ) as user_type_id
, CAST(0 as sys.tinyint ) as precision
, CAST(0 as sys.tinyint ) as scale
, CAST('ABC' as sys.sql_variant ) as current_value
, CAST(0 as sys.bit ) as is_exhausted
, CAST('ABC' as sys.sql_variant ) as last_used_value
from pg_class p
inner join pg_sequence ps on ps.seqrelid = p.oid
inner join sys.schemas s on s.schema_id = p.relnamespace
and p.relkind = 'S'
and has_schema_privilege(s.schema_id, 'USAGE');
GRANT SELECT ON sys.sequences TO PUBLIC;

CREATE OR REPLACE VIEW sys.database_permissions
AS
SELECT
Expand Down
Loading

0 comments on commit e8745f7

Please sign in to comment.