diff --git a/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 b/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 index f20791fb29..d52ea2f0a8 100644 --- a/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 +++ b/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 @@ -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; diff --git a/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 b/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 index f99ee992eb..93267cdeaa 100644 --- a/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 +++ b/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 @@ -4338,6 +4338,7 @@ keyword | DATE_FORMAT | DATENAME | DATEPART + | DATETRUNC | DATE_CORRELATION_OPTIMIZATION | DATE_FORMAT | DAY diff --git a/contrib/babelfishpg_tsql/runtime/functions.c b/contrib/babelfishpg_tsql/runtime/functions.c index 374a7f893b..ee190bf126 100644 --- a/contrib/babelfishpg_tsql/runtime/functions.c +++ b/contrib/babelfishpg_tsql/runtime/functions.c @@ -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); @@ -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) { diff --git a/contrib/babelfishpg_tsql/sql/ownership.sql b/contrib/babelfishpg_tsql/sql/ownership.sql index 5f6a2aa9f7..38e34be5ca 100644 --- a/contrib/babelfishpg_tsql/sql/ownership.sql +++ b/contrib/babelfishpg_tsql/sql/ownership.sql @@ -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, diff --git a/contrib/babelfishpg_tsql/sql/sys.sql b/contrib/babelfishpg_tsql/sql/sys.sql index 4b87ac7845..ba57508375 100644 --- a/contrib/babelfishpg_tsql/sql/sys.sql +++ b/contrib/babelfishpg_tsql/sql/sys.sql @@ -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 $$ diff --git a/contrib/babelfishpg_tsql/sql/sys_functions.sql b/contrib/babelfishpg_tsql/sql/sys_functions.sql index 1cd7ea7333..92b73b1511 100644 --- a/contrib/babelfishpg_tsql/sql/sys_functions.sql +++ b/contrib/babelfishpg_tsql/sql/sys_functions.sql @@ -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 @@ -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; diff --git a/contrib/babelfishpg_tsql/sql/sys_views.sql b/contrib/babelfishpg_tsql/sql/sys_views.sql index 8deb11267b..24699a2973 100644 --- a/contrib/babelfishpg_tsql/sql/sys_views.sql +++ b/contrib/babelfishpg_tsql/sql/sys_views.sql @@ -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 diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql index 48f1f67825..91b1355aa8 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql @@ -437,93 +437,61 @@ LANGUAGE plpgsql; -- 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 - -- 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; + -- 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; + + 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 @@ -790,6 +758,122 @@ 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; + +-- BABELFISH_SCHEMA_PERMISSIONS +CREATE TABLE IF NOT EXISTS 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) +); create or replace function sys.babelfish_timezone_mapping(IN tmz text) returns text AS 'babelfishpg_tsql', 'timezone_mapping' @@ -875,15 +959,13 @@ 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.sysutcdatetime() returns sys.datetime2 +AS 'babelfishpg_tsql', 'sysutcdatetime' +LANGUAGE C STABLE; -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; -- 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 @@ -1179,6 +1261,41 @@ END; $body$ LANGUAGE plpgsql IMMUTABLE; +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 char(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; + -- This is a temporary procedure which is called during upgrade to update guest schema -- for the guest users in the already existing databases diff --git a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y index 2e01b52cad..7b8a33a840 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y +++ b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y @@ -96,7 +96,7 @@ %token TSQL_ATAT TSQL_ALLOW_SNAPSHOT_ISOLATION TSQL_CALLER TSQL_CHOOSE TSQL_CLUSTERED TSQL_COLUMNSTORE TSQL_CONVERT - TSQL_DATENAME TSQL_DATEPART TSQL_DATEDIFF TSQL_DATEDIFF_BIG TSQL_DATE_BUCKET TSQL_DATEADD TSQL_DEFAULT_SCHEMA TSQL_ISNULL + TSQL_DATENAME TSQL_DATEPART TSQL_DATETRUNC TSQL_DATEDIFF TSQL_DATEDIFF_BIG TSQL_DATE_BUCKET TSQL_DATEADD TSQL_DEFAULT_SCHEMA TSQL_ISNULL TSQL_D TSQL_DAYOFYEAR TSQL_DD TSQL_DW TSQL_DY TSQL_HH TSQL_ISO_WEEK TSQL_ISOWK TSQL_ISOWW TSQL_LOGIN TSQL_M TSQL_MCS TSQL_MI TSQL_MICROSECOND TSQL_MILLISECOND TSQL_MM TSQL_MS TSQL_N TSQL_NANOSECOND TSQL_NONCLUSTERED TSQL_NS TSQL_OUTPUT TSQL_OUT TSQL_PARSE TSQL_Q diff --git a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y index 5e57be9d3c..b595c5adc1 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y +++ b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y @@ -1936,6 +1936,13 @@ func_expr_common_subexpr: COERCE_EXPLICIT_CALL, @1); } + | TSQL_DATETRUNC '(' datepart_arg ',' a_expr ')' + { + $$ = (Node *) makeFuncCall(TsqlSystemFuncName2("datetrunc"), + list_make2(makeStringConst($3, @3), $5), + COERCE_EXPLICIT_CALL, + @1); + } | TSQL_DATENAME '(' datepart_arg ',' a_expr ')' { $$ = (Node *) makeFuncCall(TsqlSystemFuncName2("datename"), @@ -4465,6 +4472,7 @@ reserved_keyword: | TSQL_DATE_BUCKET | TSQL_DATENAME | TSQL_DATEPART + | TSQL_DATETRUNC | TSQL_IIF | TSQL_OUT | TSQL_OUTER diff --git a/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h b/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h index 86a2fb3855..3c6e55488f 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h +++ b/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h @@ -116,6 +116,7 @@ PG_KEYWORD("datediff", TSQL_DATEDIFF, RESERVED_KEYWORD) PG_KEYWORD("datediff_big", TSQL_DATEDIFF_BIG, RESERVED_KEYWORD) PG_KEYWORD("datename", TSQL_DATENAME, RESERVED_KEYWORD) PG_KEYWORD("datepart", TSQL_DATEPART, RESERVED_KEYWORD) +PG_KEYWORD("datetrunc", TSQL_DATETRUNC, RESERVED_KEYWORD) PG_KEYWORD("day", DAY_P, UNRESERVED_KEYWORD) PG_KEYWORD("dayofyear", TSQL_DAYOFYEAR, UNRESERVED_KEYWORD) PG_KEYWORD("dd", TSQL_DD, UNRESERVED_KEYWORD) diff --git a/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l b/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l index fb9d9c7c10..38ea5a6aa6 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l +++ b/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l @@ -218,6 +218,7 @@ case TSQL_DATE_BUCKET: case TSQL_DATENAME: case TSQL_DATEPART: + case TSQL_DATETRUNC: case TSQL_D: case TSQL_DAYOFYEAR: case TSQL_DD: diff --git a/contrib/babelfishpg_tsql/src/catalog.c b/contrib/babelfishpg_tsql/src/catalog.c index 9279f87012..26e9a97341 100644 --- a/contrib/babelfishpg_tsql/src/catalog.c +++ b/contrib/babelfishpg_tsql/src/catalog.c @@ -83,6 +83,12 @@ Oid bbf_servers_def_idx_oid; Oid bbf_function_ext_oid; Oid bbf_function_ext_idx_oid; +/***************************************** + * SCHEMA + *****************************************/ +Oid bbf_schema_perms_oid; +Oid bbf_schema_perms_idx_oid; + /***************************************** * DOMAIN MAPPING *****************************************/ @@ -1435,6 +1441,29 @@ clean_up_bbf_function_ext(int16 dbid) table_close(bbf_function_ext_rel, RowExclusiveLock); } + +/***************************************** + * SCHEMA + *****************************************/ + +Oid +get_bbf_schema_perms_oid() +{ + if (!OidIsValid(bbf_schema_perms_oid)) + bbf_schema_perms_oid = get_relname_relid(BBF_SCHEMA_PERMS_TABLE_NAME, + get_namespace_oid("sys", false)); + return bbf_schema_perms_oid; +} + +Oid +get_bbf_schema_perms_idx_oid() +{ + if (!OidIsValid(bbf_schema_perms_idx_oid)) + bbf_schema_perms_idx_oid = get_relname_relid(BBF_SCHEMA_PERMS_IDX_NAME, + get_namespace_oid("sys", false)); + return bbf_schema_perms_idx_oid; +} + /***************************************** * DOMAIN MAPPING *****************************************/ @@ -2799,6 +2828,346 @@ rename_procfunc_update_bbf_catalog(RenameStmt *stmt) table_close(bbf_func_ext_rel, RowExclusiveLock); } +/* Add a catalog entry. */ +void +add_entry_to_bbf_schema(const char *schema_name, + const char *object_name, + const char *permission, + const char *grantee, + const char *object_type) +{ + Relation bbf_schema_rel; + TupleDesc bbf_schema_dsc; + HeapTuple tuple_bbf_schema; + Datum new_record_bbf_schema[BBF_SCHEMA_PERMS_NUM_OF_COLS]; + bool new_record_nulls_bbf_schema[BBF_SCHEMA_PERMS_NUM_OF_COLS]; + int16 dbid = get_cur_db_id(); + + /* Fetch the relation */ + bbf_schema_rel = table_open(get_bbf_schema_perms_oid(), + RowExclusiveLock); + bbf_schema_dsc = RelationGetDescr(bbf_schema_rel); + + /* Build a tuple to insert */ + MemSet(new_record_bbf_schema, 0, sizeof(new_record_bbf_schema)); + MemSet(new_record_nulls_bbf_schema, false, sizeof(new_record_nulls_bbf_schema)); + + new_record_bbf_schema[BBF_SCHEMA_PERMS_DBID] = Int16GetDatum(dbid); + new_record_bbf_schema[BBF_SCHEMA_PERMS_SCHEMA_NAME] = CStringGetDatum(pstrdup(schema_name)); + new_record_bbf_schema[BBF_SCHEMA_PERMS_OBJECT_NAME] = CStringGetDatum(pstrdup(object_name)); + new_record_bbf_schema[BBF_SCHEMA_PERMS_PERMISSION] = CStringGetDatum(pstrdup(permission)); + new_record_bbf_schema[BBF_SCHEMA_PERMS_GRANTEE] = CStringGetDatum(pstrdup(grantee)); + if (object_type != NULL) + new_record_bbf_schema[BBF_SCHEMA_PERMS_OBJECT_TYPE] = CStringGetDatum(pstrdup(object_type)); + else + new_record_nulls_bbf_schema[BBF_SCHEMA_PERMS_OBJECT_TYPE] = true; + + tuple_bbf_schema = heap_form_tuple(bbf_schema_dsc, + new_record_bbf_schema, + new_record_nulls_bbf_schema); + + /* Insert new record in the bbf_authid_user_ext table */ + CatalogTupleInsert(bbf_schema_rel, tuple_bbf_schema); + + /* Close bbf_authid_user_ext, but keep lock till commit */ + table_close(bbf_schema_rel, RowExclusiveLock); + + /* Advance cmd counter to make the insert visible */ + CommandCounterIncrement(); +} + +/* Check if the catalog entry exists. */ +bool +check_bbf_schema_for_entry(const char *schema_name, + const char *object_name, + const char *permission, + const char *grantee) +{ + Relation bbf_schema_rel; + HeapTuple tuple_bbf_schema; + ScanKeyData key[5]; + TableScanDesc scan; + bool catalog_entry_exists = false; + int16 dbid = get_cur_db_id(); + + bbf_schema_rel = table_open(get_bbf_schema_perms_oid(), + AccessShareLock); + ScanKeyInit(&key[0], + Anum_bbf_schema_perms_dbid, + BTEqualStrategyNumber, F_INT2EQ, + Int16GetDatum(dbid)); + ScanKeyInit(&key[1], + Anum_bbf_schema_perms_schema_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(schema_name)); + ScanKeyInit(&key[2], + Anum_bbf_schema_perms_object_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(object_name)); + ScanKeyInit(&key[3], + Anum_bbf_schema_perms_permission, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(permission)); + ScanKeyInit(&key[4], + Anum_bbf_schema_perms_grantee, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(grantee)); + + scan = table_beginscan_catalog(bbf_schema_rel, 5, key); + + tuple_bbf_schema = heap_getnext(scan, ForwardScanDirection); + if (HeapTupleIsValid(tuple_bbf_schema)) + catalog_entry_exists = true; + + table_endscan(scan); + table_close(bbf_schema_rel, AccessShareLock); + return catalog_entry_exists; +} + +bool +check_bbf_schema_for_schema(const char *schema_name, + const char *object_name, + const char *permission) +{ + Relation bbf_schema_rel; + HeapTuple tuple_bbf_schema; + ScanKeyData key[4]; + TableScanDesc scan; + bool catalog_entry_exists = false; + int16 dbid = get_cur_db_id(); + + bbf_schema_rel = table_open(get_bbf_schema_perms_oid(), + AccessShareLock); + ScanKeyInit(&key[0], + Anum_bbf_schema_perms_dbid, + BTEqualStrategyNumber, F_INT2EQ, + Int16GetDatum(dbid)); + ScanKeyInit(&key[1], + Anum_bbf_schema_perms_schema_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(schema_name)); + ScanKeyInit(&key[2], + Anum_bbf_schema_perms_object_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(object_name)); + ScanKeyInit(&key[3], + Anum_bbf_schema_perms_permission, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(permission)); + + scan = table_beginscan_catalog(bbf_schema_rel, 4, key); + + tuple_bbf_schema = heap_getnext(scan, ForwardScanDirection); + if (HeapTupleIsValid(tuple_bbf_schema)) + catalog_entry_exists = true; + + table_endscan(scan); + table_close(bbf_schema_rel, AccessShareLock); + return catalog_entry_exists; +} + +void +del_from_bbf_schema(const char *schema_name, + const char *object_name, + const char *permission, + const char *grantee) +{ + Relation bbf_schema_rel; + HeapTuple tuple_bbf_schema; + ScanKeyData key[5]; + TableScanDesc scan; + int16 dbid = get_cur_db_id(); + + bbf_schema_rel = table_open(get_bbf_schema_perms_oid(), + RowExclusiveLock); + ScanKeyInit(&key[0], + Anum_bbf_schema_perms_dbid, + BTEqualStrategyNumber, F_INT2EQ, + Int16GetDatum(dbid)); + ScanKeyInit(&key[1], + Anum_bbf_schema_perms_schema_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(schema_name)); + ScanKeyInit(&key[2], + Anum_bbf_schema_perms_object_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(object_name)); + ScanKeyInit(&key[3], + Anum_bbf_schema_perms_permission, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(permission)); + ScanKeyInit(&key[4], + Anum_bbf_schema_perms_grantee, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(grantee)); + + scan = table_beginscan_catalog(bbf_schema_rel, 5, key); + + tuple_bbf_schema = heap_getnext(scan, ForwardScanDirection); + + if (HeapTupleIsValid(tuple_bbf_schema)) + CatalogTupleDelete(bbf_schema_rel, &tuple_bbf_schema->t_self); + + table_endscan(scan); + table_close(bbf_schema_rel, RowExclusiveLock); + + CommandCounterIncrement(); +} + +void +clean_up_bbf_schema(const char *schema_name, + const char *object_name, + bool is_schema) +{ + SysScanDesc scan; + Relation bbf_schema_rel; + HeapTuple tuple_bbf_schema; + int16 dbid = get_cur_db_id(); + + /* Fetch the relation */ + bbf_schema_rel = table_open(get_bbf_schema_perms_oid(), + RowExclusiveLock); + + if (is_schema) + { + ScanKeyData scanKey[2]; + ScanKeyInit(&scanKey[0], + Anum_bbf_schema_perms_dbid, + BTEqualStrategyNumber, F_INT2EQ, + Int16GetDatum(dbid)); + ScanKeyInit(&scanKey[1], + Anum_bbf_schema_perms_schema_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(schema_name)); + scan = systable_beginscan(bbf_schema_rel, + get_bbf_schema_perms_idx_oid(), + true, NULL, 2, scanKey); + } + else + { + ScanKeyData scanKey[3]; + ScanKeyInit(&scanKey[0], + Anum_bbf_schema_perms_dbid, + BTEqualStrategyNumber, F_INT2EQ, + Int16GetDatum(dbid)); + ScanKeyInit(&scanKey[1], + Anum_bbf_schema_perms_schema_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(schema_name)); + ScanKeyInit(&scanKey[2], + Anum_bbf_schema_perms_object_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(object_name)); + scan = systable_beginscan(bbf_schema_rel, + get_bbf_schema_perms_idx_oid(), + true, NULL, 3, scanKey); + } + + while ((tuple_bbf_schema = systable_getnext(scan)) != NULL) + { + if (HeapTupleIsValid(tuple_bbf_schema)) + CatalogTupleDelete(bbf_schema_rel, + &tuple_bbf_schema->t_self); + } + + systable_endscan(scan); + table_close(bbf_schema_rel, RowExclusiveLock); +} + +void +grant_perms_to_objects_in_schema(const char *schema_name, + const char *permission, + const char *grantee) +{ + TableScanDesc scan; + Relation bbf_schema_rel; + HeapTuple tuple_bbf_schema; + const char *object_name; + const char *object_type; + ScanKeyData scanKey[4]; + int16 dbid = get_cur_db_id(); + const char *db_name = get_cur_db_name(); + + /* Fetch the relation */ + bbf_schema_rel = table_open(get_bbf_schema_perms_oid(), + AccessShareLock); + ScanKeyInit(&scanKey[0], + Anum_bbf_schema_perms_dbid, + BTEqualStrategyNumber, F_INT2EQ, + Int16GetDatum(dbid)); + ScanKeyInit(&scanKey[1], + Anum_bbf_schema_perms_schema_name, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(schema_name)); + ScanKeyInit(&scanKey[2], + Anum_bbf_schema_perms_permission, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(permission)); + ScanKeyInit(&scanKey[3], + Anum_bbf_schema_perms_grantee, + BTEqualStrategyNumber, F_NAMEEQ, + CStringGetDatum(grantee)); + + scan = table_beginscan_catalog(bbf_schema_rel, 4, scanKey); + tuple_bbf_schema = heap_getnext(scan, ForwardScanDirection); + + while (HeapTupleIsValid(tuple_bbf_schema)) + { + Form_bbf_schema_perms schemaform; + schemaform = (Form_bbf_schema_perms) GETSTRUCT(tuple_bbf_schema); + object_name = pstrdup(NameStr(schemaform->object_name)); + object_type = pstrdup(NameStr(schemaform->object_type)); + + /* For each object, grant the permission explicitly. */ + if (strcmp(object_name, "ALL") != 0) + { + StringInfoData query; + char *schema; + List *res; + Node *res_stmt; + PlannedStmt *wrapper; + + schema = get_physical_schema_name((char *)db_name, schema_name); + initStringInfo(&query); + if (strcmp(permission, "execute") != 0) + appendStringInfo(&query, "GRANT \"%s\" ON \"%s\".\"%s\" TO \"%s\"; ", permission, schema, object_name, grantee); + else + { + if (object_type != NULL && strcmp(object_type, "f") == 0) + appendStringInfo(&query, "GRANT \"%s\" ON FUNCTION \"%s\".\"%s\" TO \"%s\"; ", permission, schema, object_name, grantee); + else + appendStringInfo(&query, "GRANT \"%s\" ON PROCEDURE \"%s\".\"%s\" TO \"%s\"; ", permission, schema, object_name, grantee); + } + res = raw_parser(query.data, RAW_PARSE_DEFAULT); + res_stmt = ((RawStmt *) linitial(res))->stmt; + + /* need to make a wrapper PlannedStmt */ + wrapper = makeNode(PlannedStmt); + wrapper->commandType = CMD_UTILITY; + wrapper->canSetTag = false; + wrapper->utilityStmt = res_stmt; + wrapper->stmt_location = 0; + wrapper->stmt_len = 1; + + /* do this step */ + ProcessUtility(wrapper, + "(GRANT STATEMENT )", + false, + PROCESS_UTILITY_SUBCOMMAND, + NULL, + NULL, + None_Receiver, + NULL); + + /* make sure later steps can see the object created here */ + CommandCounterIncrement(); + } + tuple_bbf_schema = heap_getnext(scan, ForwardScanDirection); + } + table_endscan(scan); + table_close(bbf_schema_rel, AccessShareLock); +} + PG_FUNCTION_INFO_V1(update_user_catalog_for_guest_schema); Datum update_user_catalog_for_guest_schema(PG_FUNCTION_ARGS) @@ -2880,4 +3249,4 @@ alter_guest_schema_for_db (const char *dbname) table_endscan(tblscan); table_close(bbf_authid_user_ext_rel, RowExclusiveLock); -} \ No newline at end of file +} diff --git a/contrib/babelfishpg_tsql/src/catalog.h b/contrib/babelfishpg_tsql/src/catalog.h index 0fd604f6f9..95eae77b8b 100644 --- a/contrib/babelfishpg_tsql/src/catalog.h +++ b/contrib/babelfishpg_tsql/src/catalog.h @@ -278,6 +278,71 @@ typedef struct FormData_bbf_function_ext typedef FormData_bbf_function_ext *Form_bbf_function_ext; +/***************************************** + * SCHEMA_PERMISSIONS + *****************************************/ +#define BBF_SCHEMA_PERMS_TABLE_NAME "babelfish_schema_permissions" +#define BBF_SCHEMA_PERMS_IDX_NAME "babelfish_schema_permissions_pkey" +#define BBF_SCHEMA_PERMS_NUM_OF_COLS 6 +#define BBF_SCHEMA_PERMS_DBID 0 +#define BBF_SCHEMA_PERMS_SCHEMA_NAME 1 +#define BBF_SCHEMA_PERMS_OBJECT_NAME 2 +#define BBF_SCHEMA_PERMS_PERMISSION 3 +#define BBF_SCHEMA_PERMS_GRANTEE 4 +#define BBF_SCHEMA_PERMS_OBJECT_TYPE 5 +#define Anum_bbf_schema_perms_dbid 1 +#define Anum_bbf_schema_perms_schema_name 2 +#define Anum_bbf_schema_perms_object_name 3 +#define Anum_bbf_schema_perms_permission 4 +#define Anum_bbf_schema_perms_grantee 5 +#define Anum_bbf_schema_perms_object_type 6 + +extern Oid bbf_schema_perms_oid; +extern Oid bbf_schema_perms_idx_oid; + +extern Oid get_bbf_schema_perms_oid(void); +extern Oid get_bbf_schema_perms_idx_oid(void); + +typedef struct FormData_bbf_schema_perms +{ + int16 dbid; + NameData schema_name; + NameData object_name; + NameData permission; + NameData grantee; + NameData object_type; +} FormData_bbf_schema_perms; + +typedef FormData_bbf_schema_perms *Form_bbf_schema_perms; + +extern void add_entry_to_bbf_schema(const char *schema_name, + const char *object_name, + const char *permission, + const char *grantee, + const char *object_type); + +extern bool check_bbf_schema_for_entry(const char *schema_name, + const char *object_name, + const char *permission, + const char *grantee); + +extern void del_from_bbf_schema(const char *schema_name, + const char *object_name, + const char *permission, + const char *grantee); + +extern bool check_bbf_schema_for_schema(const char *schema_name, + const char *object_name, + const char *permission); + +extern void clean_up_bbf_schema(const char *schema_name, + const char *object_name, + bool is_schema); + +extern void grant_perms_to_objects_in_schema(const char *schema_name, + const char *permission, + const char *grantee); + /***************************************** * DOMAIN MAPPING *****************************************/ diff --git a/contrib/babelfishpg_tsql/src/codegen.c b/contrib/babelfishpg_tsql/src/codegen.c index 1108a78d9c..c6726ba373 100644 --- a/contrib/babelfishpg_tsql/src/codegen.c +++ b/contrib/babelfishpg_tsql/src/codegen.c @@ -300,6 +300,7 @@ stmt_default_act(Walker_context *ctx, PLtsql_stmt *stmt) case PLTSQL_STMT_THROW: case PLTSQL_STMT_USEDB: case PLTSQL_STMT_GRANTDB: + case PLTSQL_STMT_GRANTSCHEMA: case PLTSQL_STMT_INSERT_BULK: case PLTSQL_STMT_SET_EXPLAIN_MODE: /* TSQL-only executable node */ diff --git a/contrib/babelfishpg_tsql/src/dbcmds.c b/contrib/babelfishpg_tsql/src/dbcmds.c index 74d7e7534a..c602c66920 100644 --- a/contrib/babelfishpg_tsql/src/dbcmds.c +++ b/contrib/babelfishpg_tsql/src/dbcmds.c @@ -42,6 +42,9 @@ #include "pltsql.h" #include "extendedproperty.h" +Oid sys_babelfish_db_seq_oid = InvalidOid; + +static Oid get_sys_babelfish_db_seq_oid(void); static bool have_createdb_privilege(void); static List *gen_createdb_subcmds(const char *schema, const char *dbo, @@ -57,6 +60,20 @@ static Oid do_create_bbf_db(const char *dbname, List *options, const char *owner static void create_bbf_db_internal(const char *dbname, List *options, const char *owner, int16 dbid); static void drop_related_bbf_namespace_entries(int16 dbid); +static Oid +get_sys_babelfish_db_seq_oid() +{ + if(!OidIsValid(sys_babelfish_db_seq_oid)) + { + RangeVar *sequence = makeRangeVarFromNameList(stringToQualifiedNameList("sys.babelfish_db_seq")); + Oid seqid = RangeVarGetRelid(sequence, NoLock, false); + + Assert(OidIsValid(seqid)); + sys_babelfish_db_seq_oid = seqid; + } + return sys_babelfish_db_seq_oid; +} + static bool have_createdb_privilege(void) { @@ -111,7 +128,6 @@ gen_createdb_subcmds(const char *schema, const char *dbo, const char *db_owner, /* create sysdatabases under current DB's DBO schema */ appendStringInfo(&query, "CREATE VIEW dummy.sysdatabases AS SELECT * FROM sys.sysdatabases; "); appendStringInfo(&query, "ALTER VIEW dummy.sysdatabases OWNER TO dummy; "); - appendStringInfo(&query, "GRANT SELECT ON dummy.sysdatabases TO dummy; "); /* create guest schema in the database. This has to be the last statement */ if (guest) @@ -120,9 +136,9 @@ gen_createdb_subcmds(const char *schema, const char *dbo, const char *db_owner, res = raw_parser(query.data, RAW_PARSE_DEFAULT); if (guest) - expected_stmt_num = list_length(logins) > 0 ? 10 : 9; + expected_stmt_num = list_length(logins) > 0 ? 9 : 8; else - expected_stmt_num = 7; + expected_stmt_num = 6; if (list_length(res) != expected_stmt_num) ereport(ERROR, @@ -138,7 +154,7 @@ gen_createdb_subcmds(const char *schema, const char *dbo, const char *db_owner, update_CreateRoleStmt(stmt, dbo, NULL, db_owner); stmt = parsetree_nth_stmt(res, i++); - update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, dbo); + update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, dbo, NULL); if (guest) { @@ -165,10 +181,7 @@ gen_createdb_subcmds(const char *schema, const char *dbo, const char *db_owner, stmt = parsetree_nth_stmt(res, i++); update_AlterTableStmt(stmt, schema, db_owner); - - stmt = parsetree_nth_stmt(res, i++); - update_GrantStmt(stmt, NULL, schema, db_owner); - + if (guest) { stmt = parsetree_nth_stmt(res, i++); @@ -301,9 +314,12 @@ getAvailDbid(void) int16 dbid; int16 start = 0; + if(GetUserId() != get_role_oid("sysadmin", true)) + return InvalidDbid; + do { - dbid = DirectFunctionCall1(nextval, CStringGetTextDatum("sys.babelfish_db_seq")); + dbid = nextval_internal(get_sys_babelfish_db_seq_oid(), false); if (start == 0) start = dbid; else if (start == dbid) @@ -351,12 +367,8 @@ getDbidForLogicalDbRestore(Oid relid) * dbid while inserting into sysdatabases catalog. */ else - { - RangeVar *sequence = makeRangeVarFromNameList(stringToQualifiedNameList("sys.babelfish_db_seq")); - Oid seqid = RangeVarGetRelid(sequence, NoLock, false); + dbid = DirectFunctionCall1(currval_oid, get_sys_babelfish_db_seq_oid()); - dbid = DirectFunctionCall1(currval_oid, seqid); - } bbf_set_current_user(prev_current_user); return dbid; @@ -408,6 +420,9 @@ create_bbf_db_internal(const char *dbname, List *options, const char *owner, int const char *guest; const char *prev_current_user; int stmt_number = 0; + int save_sec_context; + bool is_set_userid; + Oid save_userid; /* TODO: Extract options */ @@ -519,16 +534,24 @@ create_bbf_db_internal(const char *dbname, List *options, const char *owner, int /* Run all subcommands */ foreach(parsetree_item, parsetree_list) { - Node *stmt = ((RawStmt *) lfirst(parsetree_item))->stmt; - PlannedStmt *wrapper; + Node *stmt = ((RawStmt *) lfirst(parsetree_item))->stmt; + PlannedStmt *wrapper; + is_set_userid = false; + if(stmt->type == T_CreateSchemaStmt || stmt->type == T_AlterTableStmt + || stmt->type == T_ViewStmt) + { + GetUserIdAndSecContext(&save_userid, &save_sec_context); + SetUserIdAndSecContext(get_role_oid(dbo_role, true), + save_sec_context | SECURITY_LOCAL_USERID_CHANGE); + is_set_userid = true; + } /* need to make a wrapper PlannedStmt */ wrapper = makeNode(PlannedStmt); wrapper->commandType = CMD_UTILITY; wrapper->canSetTag = false; wrapper->utilityStmt = stmt; wrapper->stmt_location = 0; - stmt_number++; if (guest && list_length(parsetree_list) == stmt_number) wrapper->stmt_len = 19; @@ -545,7 +568,9 @@ create_bbf_db_internal(const char *dbname, List *options, const char *owner, int None_Receiver, NULL); - /* make sure later steps can see the object created here */ + if(is_set_userid) + SetUserIdAndSecContext(save_userid, save_sec_context); + CommandCounterIncrement(); } set_cur_db(old_dbid, old_dbname); @@ -567,6 +592,9 @@ create_bbf_db_internal(const char *dbname, List *options, const char *owner, int } PG_CATCH(); { + if(is_set_userid) + SetUserIdAndSecContext(save_userid, save_sec_context); + /* Clean up. Restore previous state. */ bbf_set_current_user(prev_current_user); set_cur_db(old_dbid, old_dbname); diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 361373149e..a20b2f0462 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -160,6 +160,7 @@ static void declare_parameter_unquoted_string_reset(Node *paramDft); static Node* call_argument_unquoted_string(Node *arg); static void call_argument_unquoted_string_reset(Node *colref_arg); +static char *get_local_schema_for_bbf_functions(Oid proc_nsp_oid); /***************************************** * Replication Hooks @@ -226,6 +227,7 @@ static table_variable_satisfies_update_hook_type prev_table_variable_satisfies_u static table_variable_satisfies_vacuum_hook_type prev_table_variable_satisfies_vacuum = NULL; static table_variable_satisfies_vacuum_horizon_hook_type prev_table_variable_satisfies_vacuum_horizon = NULL; static drop_relation_refcnt_hook_type prev_drop_relation_refcnt_hook = NULL; +static set_local_schema_for_func_hook_type prev_set_local_schema_for_func_hook = NULL; /***************************************** * Install / Uninstall @@ -389,6 +391,9 @@ InstallExtendedHooks(void) prev_drop_relation_refcnt_hook = drop_relation_refcnt_hook; drop_relation_refcnt_hook = pltsql_drop_relation_refcnt_hook; + + prev_set_local_schema_for_func_hook = set_local_schema_for_func_hook; + set_local_schema_for_func_hook = get_local_schema_for_bbf_functions; } void @@ -452,6 +457,7 @@ UninstallExtendedHooks(void) IsToastRelationHook = PrevIsToastRelationHook; IsToastClassHook = PrevIsToastClassHook; drop_relation_refcnt_hook = prev_drop_relation_refcnt_hook; + set_local_schema_for_func_hook = prev_set_local_schema_for_func_hook; } /***************************************** @@ -1195,12 +1201,11 @@ extract_identifier(const char *start) * greater than 1 */ /* - * valid identifier cannot be longer than 258 (2*128+2) bytes. SQL server - * allows up to 128 bascially. And escape character can take additional - * one byte for each character in worst case. And additional 2 byes for - * delimiter + * Reaching here implies of valid identifier. It means we can reach + * identifier's end in both the cases of single and multibyte characters. + * If the identifier is not valid, the scanner should have already reported a syntax error. */ - while (i < 258) + while (true) { char c = start[i]; @@ -1759,7 +1764,7 @@ pre_transform_target_entry(ResTarget *res, ParseState *pstate, memcpy(alias + (alias_len) - 32, identifier_name + (alias_len) - 32, 32); - alias[alias_len+1] = '\0'; + alias[alias_len] = '\0'; } /* Identifier is not truncated. */ else @@ -4251,3 +4256,29 @@ static void call_argument_unquoted_string_reset (Node *colref_arg) return; } +static char * +get_local_schema_for_bbf_functions(Oid proc_nsp_oid) +{ + HeapTuple tuple; + char *func_schema_name = NULL, + *new_search_path = NULL; + const char *func_dbo_schema, + *cur_dbname = get_cur_db_name(); + + tuple = SearchSysCache1(NAMESPACEOID, + ObjectIdGetDatum(proc_nsp_oid)); + if(HeapTupleIsValid(tuple)) + { + func_schema_name = NameStr(((Form_pg_namespace) GETSTRUCT(tuple))->nspname); + func_dbo_schema = get_dbo_schema_name(cur_dbname); + + if(strcmp(func_schema_name, func_dbo_schema) != 0 + && strcmp(func_schema_name, "sys") != 0) + new_search_path = psprintf("%s, %s, \"$user\", sys, pg_catalog", + quote_identifier(func_schema_name), + quote_identifier(func_dbo_schema)); + + ReleaseSysCache(tuple); + } + return new_search_path; +} diff --git a/contrib/babelfishpg_tsql/src/iterative_exec.c b/contrib/babelfishpg_tsql/src/iterative_exec.c index 1f83bf5e6c..553e371e1e 100644 --- a/contrib/babelfishpg_tsql/src/iterative_exec.c +++ b/contrib/babelfishpg_tsql/src/iterative_exec.c @@ -800,6 +800,15 @@ dispatch_stmt(PLtsql_execstate *estate, PLtsql_stmt *stmt) } exec_stmt_grantdb(estate, (PLtsql_stmt_grantdb *) stmt); break; + case PLTSQL_STMT_GRANTSCHEMA: + if (pltsql_explain_only) + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Showing Estimated Execution Plan for GRANT DB statment is not yet supported"))); + } + exec_stmt_grantschema(estate, (PLtsql_stmt_grantschema *) stmt); + break; case PLTSQL_STMT_INSERT_BULK: if (pltsql_explain_only) { diff --git a/contrib/babelfishpg_tsql/src/pl_exec-2.c b/contrib/babelfishpg_tsql/src/pl_exec-2.c index dbd4a06471..ef9c40a9e4 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec-2.c +++ b/contrib/babelfishpg_tsql/src/pl_exec-2.c @@ -50,6 +50,7 @@ static int exec_run_dml_with_output(PLtsql_execstate *estate, PLtsql_stmt_push_r static int exec_stmt_usedb(PLtsql_execstate *estate, PLtsql_stmt_usedb *stmt); static int exec_stmt_usedb_explain(PLtsql_execstate *estate, PLtsql_stmt_usedb *stmt, bool shouldRestoreDb); static int exec_stmt_grantdb(PLtsql_execstate *estate, PLtsql_stmt_grantdb *stmt); +static int exec_stmt_grantschema(PLtsql_execstate *estate, PLtsql_stmt_grantschema *stmt); static int exec_stmt_insert_execute_select(PLtsql_execstate *estate, PLtsql_expr *expr); static int exec_stmt_insert_bulk(PLtsql_execstate *estate, PLtsql_stmt_insert_bulk *expr); extern Datum pltsql_inline_handler(PG_FUNCTION_ARGS); @@ -3287,3 +3288,98 @@ get_insert_bulk_kilobytes_per_batch() { return insert_bulk_kilobytes_per_batch; } + +static int +exec_stmt_grantschema(PLtsql_execstate *estate, PLtsql_stmt_grantschema *stmt) +{ + List *parsetree_list; + ListCell *parsetree_item; + char *dbname = get_cur_db_name(); + char *login = GetUserNameFromId(GetSessionUserId(), false); + bool login_is_db_owner; + Oid datdba; + char *rolname; + char *schema_name; + ListCell *lc; + ListCell *lc1; + Oid schemaOid; + + /* + * If the login is not the db owner or the login is not the member of + * sysadmin or login is not the schema owner, then it doesn't have the permission to GRANT/REVOKE. + */ + login_is_db_owner = 0 == strncmp(login, get_owner_of_db(dbname), NAMEDATALEN); + datdba = get_role_oid("sysadmin", false); + schema_name = get_physical_schema_name(dbname, stmt->schema_name); + schemaOid = LookupExplicitNamespace(schema_name, true); + + if (!OidIsValid(schemaOid)) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_SCHEMA), + errmsg("schema \"%s\" does not exist", + schema_name))); + + if (!is_member_of_role(GetSessionUserId(), datdba) && !login_is_db_owner && !pg_namespace_ownercheck(schemaOid, GetUserId())) + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("Cannot find the schema \"%s\", because it does not exist or you do not have permission.", stmt->schema_name))); + + foreach(lc1, stmt->privileges) + { + char *priv_name = (char *) lfirst(lc1); + foreach(lc, stmt->grantees) + { + char *grantee_name = (char *) lfirst(lc); + Oid role_oid; + bool grantee_is_db_owner; + rolname = get_physical_user_name(dbname, grantee_name); + role_oid = get_role_oid(rolname, true); + grantee_is_db_owner = 0 == strncmp(grantee_name, get_owner_of_db(dbname), NAMEDATALEN); + + if (pg_namespace_ownercheck(schemaOid, role_oid) || is_member_of_role(role_oid, datdba) || grantee_is_db_owner) + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("Cannot grant, deny, or revoke permissions to sa, dbo, entity owner, information_schema, sys, or yourself."))); + + parsetree_list = gen_grantschema_subcmds(schema_name, rolname, stmt->is_grant, stmt->with_grant_option, priv_name); + /* Run all subcommands */ + foreach(parsetree_item, parsetree_list) + { + Node *stmt = ((RawStmt *) lfirst(parsetree_item))->stmt; + PlannedStmt *wrapper; + + /* need to make a wrapper PlannedStmt */ + wrapper = makeNode(PlannedStmt); + wrapper->commandType = CMD_UTILITY; + wrapper->canSetTag = false; + wrapper->utilityStmt = stmt; + wrapper->stmt_location = 0; + wrapper->stmt_len = 0; + + /* do this step */ + ProcessUtility(wrapper, + "(GRANT SCHEMA )", + false, + PROCESS_UTILITY_SUBCOMMAND, + NULL, + NULL, + None_Receiver, + NULL); + + /* make sure later steps can see the object created here */ + CommandCounterIncrement(); + } + /* Add entry for each grant statement. */ + if (stmt->is_grant && !check_bbf_schema_for_entry(stmt->schema_name, "ALL", priv_name, rolname)) + add_entry_to_bbf_schema(stmt->schema_name, "ALL", priv_name, rolname, NULL); + /* Remove entry for each revoke statement. */ + if (!stmt->is_grant && check_bbf_schema_for_entry(stmt->schema_name, "ALL", priv_name, rolname)) + { + /* If any object in the schema has the OBJECT level permission. Then, internally grant that permission back. */ + grant_perms_to_objects_in_schema(stmt->schema_name, priv_name, rolname); + del_from_bbf_schema(stmt->schema_name, "ALL", priv_name, rolname); + } + } + } + return PLTSQL_RC_OK; +} diff --git a/contrib/babelfishpg_tsql/src/pl_exec.c b/contrib/babelfishpg_tsql/src/pl_exec.c index 188d0fbc16..31f21c5f4d 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec.c +++ b/contrib/babelfishpg_tsql/src/pl_exec.c @@ -10322,13 +10322,8 @@ reset_search_path(PLtsql_stmt_execsql *stmt, char **old_search_path, bool *reset top_es_entry = top_es_entry->next; } - /* - * When there is a function call: search the specified schema for the - * object. If not found, then search the dbo schema. Don't update the path - * for "sys" schema. - */ - if ((stmt->func_call || stmt->is_create_view) && stmt->schema_name != NULL && - (strcmp(stmt->schema_name, "sys") != 0 && strcmp(stmt->schema_name, "pg_catalog") != 0)) + if (stmt->is_create_view && stmt->schema_name != NULL && (strcmp(stmt->schema_name, "sys") != 0 + && strcmp(stmt->schema_name, "pg_catalog") != 0)) { cur_dbname = get_cur_db_name(); physical_schema = get_physical_schema_name(cur_dbname, stmt->schema_name); diff --git a/contrib/babelfishpg_tsql/src/pl_funcs-2.c b/contrib/babelfishpg_tsql/src/pl_funcs-2.c index e27f145da8..c095a74a9f 100644 --- a/contrib/babelfishpg_tsql/src/pl_funcs-2.c +++ b/contrib/babelfishpg_tsql/src/pl_funcs-2.c @@ -483,6 +483,7 @@ free_stmt2(PLtsql_stmt *stmt) case PLTSQL_STMT_USEDB: case PLTSQL_STMT_INSERT_BULK: case PLTSQL_STMT_GRANTDB: + case PLTSQL_STMT_GRANTSCHEMA: case PLTSQL_STMT_SET_EXPLAIN_MODE: { /* Nothing to free */ diff --git a/contrib/babelfishpg_tsql/src/pl_handler.c b/contrib/babelfishpg_tsql/src/pl_handler.c index 52c95b19a1..b4ba87196a 100644 --- a/contrib/babelfishpg_tsql/src/pl_handler.c +++ b/contrib/babelfishpg_tsql/src/pl_handler.c @@ -3213,6 +3213,7 @@ bbf_ProcessUtility(PlannedStmt *pstmt, List *res; GrantStmt *stmt; PlannedStmt *wrapper; + RoleSpec *rolspec = create_schema->authrole; if (strcmp(queryString, "(CREATE LOGICAL DATABASE )") == 0 && context == PROCESS_UTILITY_SUBCOMMAND) @@ -3261,7 +3262,45 @@ bbf_ProcessUtility(PlannedStmt *pstmt, NULL); CommandCounterIncrement(); - + /* Grant all privileges to the user.*/ + if (rolspec && strcmp(queryString, "(CREATE LOGICAL DATABASE )") != 0) + { + char *permissions[] = {"select", "insert", "update", "references", "delete", "execute"}; + List *parsetree_list; + ListCell *parsetree_item; + int i; + for (i = 0; i < 6; i++) + { + parsetree_list = gen_grantschema_subcmds(create_schema->schemaname, rolspec->rolename, true, false, permissions[i]); + /* Run all subcommands */ + foreach(parsetree_item, parsetree_list) + { + Node *stmt = ((RawStmt *) lfirst(parsetree_item))->stmt; + PlannedStmt *wrapper; + + /* need to make a wrapper PlannedStmt */ + wrapper = makeNode(PlannedStmt); + wrapper->commandType = CMD_UTILITY; + wrapper->canSetTag = false; + wrapper->utilityStmt = stmt; + wrapper->stmt_location = 0; + wrapper->stmt_len = 0; + + /* do this step */ + ProcessUtility(wrapper, + "(GRANT SCHEMA )", + false, + PROCESS_UTILITY_SUBCOMMAND, + NULL, + NULL, + None_Receiver, + NULL); + + /* make sure later steps can see the object created here */ + CommandCounterIncrement(); + } + } + } return; } else @@ -3275,7 +3314,6 @@ bbf_ProcessUtility(PlannedStmt *pstmt, { if (sql_dialect == SQL_DIALECT_TSQL) bbf_ExecDropStmt(drop_stmt); - break; } @@ -3287,10 +3325,11 @@ bbf_ProcessUtility(PlannedStmt *pstmt, * database command. */ const char *schemaname = strVal(lfirst(list_head(drop_stmt->objects))); + char *cur_db = get_cur_db_name(); + const char *logicalschema = get_logical_schema_name(schemaname, true); if (strcmp(queryString, "(DROP DATABASE )") != 0) { - char *cur_db = get_cur_db_name(); char *guest_schema_name = get_physical_schema_name(cur_db, "guest"); if (strcmp(schemaname, guest_schema_name) == 0) @@ -3303,6 +3342,8 @@ bbf_ProcessUtility(PlannedStmt *pstmt, bbf_ExecDropStmt(drop_stmt); del_ns_ext_info(schemaname, drop_stmt->missing_ok); + if (logicalschema != NULL) + clean_up_bbf_schema(logicalschema, NULL, true); if (prev_ProcessUtility) prev_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, @@ -3540,6 +3581,233 @@ bbf_ProcessUtility(PlannedStmt *pstmt, } break; } + case T_GrantStmt: + { + GrantStmt *grant = (GrantStmt *) parsetree; + char *dbname = get_cur_db_name(); + const char *current_user = GetUserNameFromId(GetUserId(), false); + /* Ignore when GRANT statement has no specific named object. */ + if (sql_dialect != SQL_DIALECT_TSQL || grant->targtype != ACL_TARGET_OBJECT) + break; + Assert(list_length(grant->objects) == 1); + if (grant->objtype == OBJECT_SCHEMA) + break; + else if (grant->objtype == OBJECT_TABLE) + { + /* Ignore CREATE database subcommands */ + if (strcmp("(CREATE LOGICAL DATABASE )", queryString) != 0) + { + RangeVar *rv = (RangeVar *) linitial(grant->objects); + const char *logical_schema = NULL; + char *obj = rv->relname; + ListCell *lc; + ListCell *lc1; + const char *obj_type = "r"; + if (rv->schemaname != NULL) + logical_schema = get_logical_schema_name(rv->schemaname, true); + else + logical_schema = get_authid_user_ext_schema_name(dbname, current_user); + /* If ALL PRIVILEGES is granted/revoked. */ + if (list_length(grant->privileges) == 0) + { + if (grant->is_grant) + { + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + int i = 0; + char *permissions[] = {"select", "insert", "update", "references", "delete"}; + for(i = 0; i < 5; i++) + { + if ((rol_spec->rolename != NULL) && !check_bbf_schema_for_entry(logical_schema, obj, permissions[i], rol_spec->rolename)) + add_entry_to_bbf_schema(logical_schema, obj, permissions[i], rol_spec->rolename, obj_type); + } + } + break; + } + else + { + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + int i = 0; + bool has_schema_perms = false; + char *permissions[] = {"select", "insert", "update", "references", "delete"}; + for(i = 0; i < 5; i++) + { + if (check_bbf_schema_for_entry(logical_schema, "ALL", permissions[i], rol_spec->rolename) && !has_schema_perms) + has_schema_perms = true; + if ((rol_spec->rolename != NULL) && check_bbf_schema_for_entry(logical_schema, obj, permissions[i], rol_spec->rolename)) + del_from_bbf_schema(logical_schema, obj, permissions[i], rol_spec->rolename); + } + if (has_schema_perms) + return; + } + break; + } + } + foreach(lc1, grant->privileges) + { + AccessPriv *ap = (AccessPriv *) lfirst(lc1); + if (grant->is_grant) + { + /* + * 1. Execute the GRANT statement. + * 2. Add its corresponding entry in the catalog, if doesn't exist already. + * 3. Don't add an entry, if the permission is granted on column list. + */ + if (prev_ProcessUtility) + prev_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + else + standard_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + if ((ap->cols == NULL) && !check_bbf_schema_for_entry(logical_schema, obj, ap->priv_name, rol_spec->rolename)) + add_entry_to_bbf_schema(logical_schema, obj, ap->priv_name, rol_spec->rolename, obj_type); + } + } + else + { + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + /* + * 1. If GRANT on schema does not exist, execute REVOKE statement and remove the catalog entry if exists. + * 2. If GRANT on schema exist, only remove the entry from the catalog if exists. + */ + if ((logical_schema != NULL) && !check_bbf_schema_for_entry(logical_schema, "ALL", ap->priv_name, rol_spec->rolename)) + { + if (prev_ProcessUtility) + prev_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + else + standard_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + } + if ((ap->cols == NULL) && check_bbf_schema_for_entry(logical_schema, obj, ap->priv_name, rol_spec->rolename)) + del_from_bbf_schema(logical_schema, obj, ap->priv_name, rol_spec->rolename); + } + } + } + return; + } + } + else if ((grant->objtype == OBJECT_PROCEDURE) || (grant->objtype == OBJECT_FUNCTION)) + { + ObjectWithArgs *ob = (ObjectWithArgs *) linitial(grant->objects); + ListCell *lc; + ListCell *lc1; + const char *logicalschema = NULL; + char *funcname = NULL; + const char *obj_type = NULL; + if (grant->objtype == OBJECT_FUNCTION) + obj_type = "f"; + else + obj_type = "p"; + if (list_length(ob->objname) == 1) + { + Node *func = (Node *) linitial(ob->objname); + funcname = strVal(func); + logicalschema = get_authid_user_ext_schema_name(dbname, current_user); + } + else + { + Node *schema = (Node *) linitial(ob->objname); + char *schemaname = strVal(schema); + Node *func = (Node *) lsecond(ob->objname); + logicalschema = get_logical_schema_name(schemaname, true); + funcname = strVal(func); + } + /* + * Case: When ALL PRIVILEGES is revoked internally during create function. + * Check if schema entry exists in the catalog, do not revoke any permission if exists. + */ + if (pstmt->stmt_len == 0 && list_length(grant->privileges) == 0) + { + if(check_bbf_schema_for_schema(logicalschema, "ALL", "execute")) + return; + break; + } + /* If ALL PRIVILEGES is granted/revoked. */ + if (list_length(grant->privileges) == 0) + { + if (grant->is_grant) + { + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + if ((rol_spec->rolename != NULL) && !check_bbf_schema_for_entry(logicalschema, funcname, "execute", rol_spec->rolename)) + add_entry_to_bbf_schema(logicalschema, funcname, "execute", rol_spec->rolename, obj_type); + } + break; + } + else + { + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + bool has_schema_perms = false; + if ((rol_spec->rolename != NULL) && check_bbf_schema_for_entry(logicalschema, "ALL", "execute", rol_spec->rolename) && !has_schema_perms) + has_schema_perms = true; + if ((rol_spec->rolename != NULL) && check_bbf_schema_for_entry(logicalschema, funcname, "execute", rol_spec->rolename)) + del_from_bbf_schema(logicalschema, funcname, "execute", rol_spec->rolename); + if (has_schema_perms) + return; + } + break; + } + } + foreach(lc1, grant->privileges) + { + AccessPriv *ap = (AccessPriv *) lfirst(lc1); + if (grant->is_grant) + { + /* Execute the GRANT statement. */ + if (prev_ProcessUtility) + prev_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + else + standard_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + /* Add entry to the catalog if it doesn't exist already. */ + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + /* Don't store a row in catalog, if permission is granted for column */ + if (!check_bbf_schema_for_entry(logicalschema, funcname, ap->priv_name, rol_spec->rolename)) + add_entry_to_bbf_schema(logicalschema, funcname, ap->priv_name, rol_spec->rolename, obj_type); + } + } + else + { + foreach(lc, grant->grantees) + { + RoleSpec *rol_spec = (RoleSpec *) lfirst(lc); + /* + * 1. If GRANT on schema does not exist, execute REVOKE statement and remove the catalog entry if exists. + * 2. If GRANT on schema exist, only remove the entry from the catalog if exists. + */ + if (!check_bbf_schema_for_entry(logicalschema, "ALL", ap->priv_name, rol_spec->rolename)) + { + /* Execute REVOKE statement. */ + if (prev_ProcessUtility) + prev_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + else + standard_ProcessUtility(pstmt, queryString, readOnlyTree, context, params, + queryEnv, dest, qc); + } + if (check_bbf_schema_for_entry(logicalschema, funcname, ap->priv_name, rol_spec->rolename)) + del_from_bbf_schema(logicalschema, funcname, ap->priv_name, rol_spec->rolename); + } + } + } + return; + } + } default: break; } @@ -5598,6 +5866,7 @@ bbf_ExecDropStmt(DropStmt *stmt) Relation relation = NULL; Oid schema_oid; ListCell *cell; + const char *logicalschema = NULL; db_id = get_cur_db_id(); @@ -5638,6 +5907,7 @@ bbf_ExecDropStmt(DropStmt *stmt) schema_oid = get_object_namespace(&address); if (OidIsValid(schema_oid)) schema_name = get_namespace_name(schema_oid); + logicalschema = get_logical_schema_name(schema_name, true); if (schema_name && major_name) { @@ -5663,6 +5933,8 @@ bbf_ExecDropStmt(DropStmt *stmt) major_name, NULL); } } + if (logicalschema != NULL) + clean_up_bbf_schema(logicalschema, major_name, false); } } else if (stmt->removeType == OBJECT_PROCEDURE || @@ -5706,6 +5978,7 @@ bbf_ExecDropStmt(DropStmt *stmt) schema_oid = get_object_namespace(&address); if (OidIsValid(schema_oid)) schema_name = get_namespace_name(schema_oid); + logicalschema = get_logical_schema_name(schema_name, true); if (schema_name && major_name) { @@ -5719,6 +5992,8 @@ bbf_ExecDropStmt(DropStmt *stmt) delete_extended_property(db_id, type, schema_name, major_name, NULL); } + if (logicalschema != NULL) + clean_up_bbf_schema(logicalschema, major_name, false); } } } diff --git a/contrib/babelfishpg_tsql/src/pltsql.h b/contrib/babelfishpg_tsql/src/pltsql.h index 5df20d340e..e5cc3adfcb 100644 --- a/contrib/babelfishpg_tsql/src/pltsql.h +++ b/contrib/babelfishpg_tsql/src/pltsql.h @@ -185,7 +185,8 @@ typedef enum PLtsql_stmt_type PLTSQL_STMT_RESTORE_CTX_FULL, PLTSQL_STMT_RESTORE_CTX_PARTIAL, PLTSQL_STMT_INSERT_BULK, - PLTSQL_STMT_GRANTDB + PLTSQL_STMT_GRANTDB, + PLTSQL_STMT_GRANTSCHEMA } PLtsql_stmt_type; /* @@ -1000,6 +1001,20 @@ typedef struct PLtsql_stmt_grantdb List *grantees; /* list of users */ } PLtsql_stmt_grantdb; +/* + * Grant on schema stmt + */ +typedef struct PLtsql_stmt_grantschema +{ + PLtsql_stmt_type cmd_type; + int lineno; + bool is_grant; + List *privileges; /* list of privileges */ + List *grantees; /* list of users */ + bool with_grant_option; + char *schema_name; /* schema name */ +} PLtsql_stmt_grantschema; + /* * ASSERT statement */ @@ -1966,6 +1981,7 @@ extern void pltsql_scanner_finish(void); extern int pltsql_yyparse(void); /* functions in pltsql_utils.c */ +extern List *gen_grantschema_subcmds(const char *schema, const char *db_user, bool is_grant, bool with_grant_option, const char *privilege); extern int TsqlUTF8LengthInUTF16(const void *vin, int len); extern void TsqlCheckUTF16Length_bpchar(const char *s, int32 len, int32 maxlen, int charlen, bool isExplicit); extern void TsqlCheckUTF16Length_varchar(const char *s, int32 len, int32 maxlen, bool isExplicit); @@ -2004,7 +2020,8 @@ extern void update_DropOwnedStmt(Node *n, List *role_list); extern void update_DropRoleStmt(Node *n, const char *role); extern void update_DropStmt(Node *n, const char *object); extern void update_GrantRoleStmt(Node *n, List *privs, List *roles); -extern void update_GrantStmt(Node *n, const char *object, const char *obj_schema, const char *grantee); +extern void update_GrantStmt(Node *n, const char *object, const char *obj_schema, const char *grantee, const char *priv); +extern void update_AlterDefaultPrivilegesStmt(Node *n, const char *object, const char *grantee, const char *priv); extern void update_RenameStmt(Node *n, const char *old_name, const char *new_name); extern void update_ViewStmt(Node *n, const char *view_schema); extern void pltsql_check_or_set_default_typmod(TypeName *typeName, int32 *typmod, bool is_cast); diff --git a/contrib/babelfishpg_tsql/src/pltsql_utils.c b/contrib/babelfishpg_tsql/src/pltsql_utils.c index fc4f10e3a0..08199cd7a2 100644 --- a/contrib/babelfishpg_tsql/src/pltsql_utils.c +++ b/contrib/babelfishpg_tsql/src/pltsql_utils.c @@ -1012,7 +1012,7 @@ update_GrantRoleStmt(Node *n, List *privs, List *roles) } void -update_GrantStmt(Node *n, const char *object, const char *obj_schema, const char *grantee) +update_GrantStmt(Node *n, const char *object, const char *obj_schema, const char *grantee, const char *priv) { GrantStmt *stmt = (GrantStmt *) n; @@ -1034,6 +1034,39 @@ update_GrantStmt(Node *n, const char *object, const char *obj_schema, const char tmp->rolename = pstrdup(grantee); } + + if (priv && stmt->privileges) + { + AccessPriv *tmp = (AccessPriv *) llast(stmt->privileges); + + tmp->priv_name = pstrdup(priv); + } +} + +void +update_AlterDefaultPrivilegesStmt(Node *n, const char *object, const char *grantee, const char *priv) +{ + AlterDefaultPrivilegesStmt *stmt = (AlterDefaultPrivilegesStmt *) n; + + ListCell *lc; + + if (!IsA(stmt, AlterDefaultPrivilegesStmt)) + ereport(ERROR, (errcode(ERRCODE_SYNTAX_ERROR), errmsg("query is not a AlterDefaultPrivilegesStmt"))); + + if (grantee && priv && stmt->action) + { + update_GrantStmt((Node *)(stmt->action), NULL, NULL, grantee, priv); + } + + foreach(lc, stmt->options) + { + if (object) + { + DefElem *tmp = (DefElem *) lfirst(lc); + tmp->defname = pstrdup("schemas"); + tmp->arg = (Node *)list_make1(makeString((char *)object)); + } + } } void @@ -1683,4 +1716,69 @@ Oid get_sys_varcharoid(void) errmsg("Oid corresponding to sys.varchar datatype could not be found."))); } return sys_varcharoid; -} \ No newline at end of file +} + +List +*gen_grantschema_subcmds(const char *schema, const char *rolname, bool is_grant, bool with_grant_option, const char *privilege) +{ + StringInfoData query; + List *stmt_list; + Node *stmt; + int expected_stmts = 2; + int i = 0; + initStringInfo(&query); + if (is_grant) + { + if (strcmp(privilege, "execute") == 0) + { + if (with_grant_option) + { + appendStringInfo(&query, "GRANT dummy ON ALL FUNCTIONS IN SCHEMA dummy TO dummy WITH GRANT OPTION; "); + appendStringInfo(&query, "GRANT dummy ON ALL PROCEDURES IN SCHEMA dummy TO dummy WITH GRANT OPTION; "); + } + else + { + appendStringInfo(&query, "GRANT dummy ON ALL FUNCTIONS IN SCHEMA dummy TO dummy; "); + appendStringInfo(&query, "GRANT dummy ON ALL PROCEDURES IN SCHEMA dummy TO dummy; "); + } + } + else + { + if (with_grant_option) + appendStringInfo(&query, "GRANT dummy ON ALL TABLES IN SCHEMA dummy TO dummy WITH GRANT OPTION; "); + else + appendStringInfo(&query, "GRANT dummy ON ALL TABLES IN SCHEMA dummy TO dummy; "); + appendStringInfo(&query, "ALTER DEFAULT PRIVILEGES IN SCHEMA dummy GRANT dummy ON TABLES TO dummy; "); + } + } + else + { + if (strcmp(privilege, "execute") == 0) + { + appendStringInfo(&query, "REVOKE dummy ON ALL FUNCTIONS IN SCHEMA dummy FROM dummy; "); + appendStringInfo(&query, "REVOKE dummy ON ALL PROCEDURES IN SCHEMA dummy FROM dummy; "); + } + else + { + appendStringInfo(&query, "REVOKE dummy ON ALL TABLES IN SCHEMA dummy FROM dummy; "); + appendStringInfo(&query, "ALTER DEFAULT PRIVILEGES IN SCHEMA dummy REVOKE dummy ON TABLES FROM dummy; "); + } + } + stmt_list = raw_parser(query.data, RAW_PARSE_DEFAULT); + if (list_length(stmt_list) != expected_stmts) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Expected %d statements, but got %d statements after parsing", + expected_stmts, list_length(stmt_list)))); + /* Replace dummy elements in parsetree with real values */ + stmt = parsetree_nth_stmt(stmt_list, i++); + update_GrantStmt(stmt, schema, NULL, rolname, privilege); + + stmt = parsetree_nth_stmt(stmt_list, i++); + if (strcmp(privilege, "execute") == 0) + update_GrantStmt(stmt, schema, NULL, rolname, privilege); + else + update_AlterDefaultPrivilegesStmt(stmt, schema, rolname, privilege); + + return stmt_list; +} diff --git a/contrib/babelfishpg_tsql/src/special_keywords.c b/contrib/babelfishpg_tsql/src/special_keywords.c index f204025fc6..c608eb4f09 100644 --- a/contrib/babelfishpg_tsql/src/special_keywords.c +++ b/contrib/babelfishpg_tsql/src/special_keywords.c @@ -89,6 +89,7 @@ const char *pg_reserved_keywords_to_be_delimited[] = { "date_bucket", "datename", "datepart", + "datetrunc", "iif", "out", "output", diff --git a/contrib/babelfishpg_tsql/src/stmt_walker.c b/contrib/babelfishpg_tsql/src/stmt_walker.c index 6ecbcaf08f..b33cb42234 100644 --- a/contrib/babelfishpg_tsql/src/stmt_walker.c +++ b/contrib/babelfishpg_tsql/src/stmt_walker.c @@ -107,6 +107,7 @@ stmt_walker(PLtsql_stmt *stmt, WalkerFunc walker, void *context) case PLTSQL_STMT_INSERT_BULK: case PLTSQL_STMT_SET_EXPLAIN_MODE: case PLTSQL_STMT_GRANTDB: + case PLTSQL_STMT_GRANTSCHEMA: break; /* TSQL-only executable node */ case PLTSQL_STMT_SAVE_CTX: @@ -205,6 +206,7 @@ general_walker_func(PLtsql_stmt *stmt, void *context) DISPATCH(INSERT_BULK, insert_bulk) DISPATCH(SET_EXPLAIN_MODE, set_explain_mode) DISPATCH(GRANTDB, grantdb) + DISPATCH(GRANTSCHEMA, grantschema) /* TSQL-only executable node */ DISPATCH(SAVE_CTX, save_ctx) diff --git a/contrib/babelfishpg_tsql/src/stmt_walker.h b/contrib/babelfishpg_tsql/src/stmt_walker.h index 54b6db9697..98f143c5eb 100644 --- a/contrib/babelfishpg_tsql/src/stmt_walker.h +++ b/contrib/babelfishpg_tsql/src/stmt_walker.h @@ -87,6 +87,7 @@ typedef bool (*Stmt_usedb_act) ACTION_SIGNITURE(usedb); typedef bool (*Stmt_insert_bulk_act) ACTION_SIGNITURE(insert_bulk); typedef bool (*Stmt_set_explain_mode) ACTION_SIGNITURE(set_explain_mode); typedef bool (*Stmt_grantdb_act) ACTION_SIGNITURE(grantdb); +typedef bool (*Stmt_grantschema_act) ACTION_SIGNITURE(grantschema); /* TSQL-only executable node */ typedef bool (*Stmt_save_ctx) ACTION_SIGNITURE(save_ctx); @@ -137,6 +138,7 @@ typedef struct Walker_context Stmt_insert_bulk_act insert_bulk_act; Stmt_set_explain_mode set_explain_mode_act; Stmt_grantdb_act grantdb_act; + Stmt_grantschema_act grantschema_act; /* TSQL-only executable node */ Stmt_save_ctx save_ctx_act; diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 2efe330c62..ee0336cf78 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -1851,6 +1851,52 @@ class tsqlBuilder : public tsqlCommonMutator } } } + else if (ctx->grant_statement() && ctx->grant_statement()->ON() && ctx->grant_statement()->permission_object() + && ctx->grant_statement()->permission_object()->object_type() && ctx->grant_statement()->permission_object()->object_type()->SCHEMA()) + { + if (ctx->grant_statement()->TO() && ctx->grant_statement()->principals() && ctx->grant_statement()->permissions()) + { + for (auto perm: ctx->grant_statement()->permissions()->permission()) + { + auto single_perm = perm->single_permission(); + if (single_perm->EXECUTE() + || single_perm->EXEC() + || single_perm->SELECT() + || single_perm->INSERT() + || single_perm->UPDATE() + || single_perm->DELETE() + || single_perm->REFERENCES()) + { + clear_rewritten_query_fragment(); + return; + } + } + } + } + + else if (ctx->revoke_statement() && ctx->revoke_statement()->ON() && ctx->revoke_statement()->permission_object() + && ctx->revoke_statement()->permission_object()->object_type() && ctx->revoke_statement()->permission_object()->object_type()->SCHEMA()) + { + if (ctx->revoke_statement()->FROM() && ctx->revoke_statement()->principals() && ctx->revoke_statement()->permissions()) + { + for (auto perm: ctx->revoke_statement()->permissions()->permission()) + { + auto single_perm = perm->single_permission(); + if (single_perm->EXECUTE() + || single_perm->EXEC() + || single_perm->SELECT() + || single_perm->INSERT() + || single_perm->UPDATE() + || single_perm->DELETE() + || single_perm->REFERENCES()) + { + clear_rewritten_query_fragment(); + return; + } + } + } + } + PLtsql_stmt_execsql *stmt = (PLtsql_stmt_execsql *) getPLtsql_fragment(ctx); Assert(stmt); @@ -5357,6 +5403,108 @@ makeGrantdbStatement(TSqlParser::Security_statementContext *ctx) } } } + if (ctx->grant_statement() && ctx->grant_statement()->ON() && ctx->grant_statement()->permission_object() + && ctx->grant_statement()->permission_object()->object_type() && ctx->grant_statement()->permission_object()->object_type()->SCHEMA()) + { + if (ctx->grant_statement()->TO() && ctx->grant_statement()->principals() && ctx->grant_statement()->permissions()) + { + PLtsql_stmt_grantschema *result = (PLtsql_stmt_grantschema *) palloc0(sizeof(PLtsql_stmt_grantschema)); + result->cmd_type = PLTSQL_STMT_GRANTSCHEMA; + result->lineno = getLineNo(ctx->grant_statement()); + result->is_grant = true; + std::string schema_name; + if (ctx->grant_statement()->permission_object()->full_object_name()->object_name) + { + schema_name = stripQuoteFromId(ctx->grant_statement()->permission_object()->full_object_name()->object_name); + result->schema_name = pstrdup(downcase_truncate_identifier(schema_name.c_str(), schema_name.length(), true)); + } + List *grantee_list = NIL; + for (auto prin : ctx->grant_statement()->principals()->principal_id()) + { + if (prin->id()) + { + std::string id_str = ::getFullText(prin->id()); + char *grantee_name = pstrdup(downcase_truncate_identifier(id_str.c_str(), id_str.length(), true)); + grantee_list = lappend(grantee_list, grantee_name); + } + } + List *privilege_list = NIL; + for (auto perm: ctx->grant_statement()->permissions()->permission()) + { + auto single_perm = perm->single_permission(); + if (single_perm->EXECUTE()) + privilege_list = lappend(privilege_list, (void *)"execute"); + if (single_perm->EXEC()) + privilege_list = lappend(privilege_list, (void *)"execute"); + if (single_perm->SELECT()) + privilege_list = lappend(privilege_list, (void *)"select"); + if (single_perm->INSERT()) + privilege_list = lappend(privilege_list, (void *)"insert"); + if (single_perm->UPDATE()) + privilege_list = lappend(privilege_list, (void *)"update"); + if (single_perm->DELETE()) + privilege_list = lappend(privilege_list, (void *)"delete"); + if (single_perm->REFERENCES()) + privilege_list = lappend(privilege_list, (void *)"references"); + } + result->privileges = privilege_list; + if (ctx->grant_statement()->WITH()) + result->with_grant_option = true; + result->grantees = grantee_list; + return (PLtsql_stmt *) result; + } + } + + if (ctx->revoke_statement() && ctx->revoke_statement()->ON() && ctx->revoke_statement()->permission_object() + && ctx->revoke_statement()->permission_object()->object_type() && ctx->revoke_statement()->permission_object()->object_type()->SCHEMA()) + { + if (ctx->revoke_statement()->FROM() && ctx->revoke_statement()->principals() && ctx->revoke_statement()->permissions()) + { + PLtsql_stmt_grantschema *result = (PLtsql_stmt_grantschema *) palloc0(sizeof(PLtsql_stmt_grantschema)); + result->cmd_type = PLTSQL_STMT_GRANTSCHEMA; + result->lineno = getLineNo(ctx->revoke_statement()); + result->is_grant = false; + std::string schema_name; + if (ctx->revoke_statement()->permission_object()->full_object_name()->object_name) + { + schema_name = stripQuoteFromId(ctx->revoke_statement()->permission_object()->full_object_name()->object_name); + result->schema_name = pstrdup(downcase_truncate_identifier(schema_name.c_str(), schema_name.length(), true)); + } + List *grantee_list = NIL; + for (auto prin : ctx->revoke_statement()->principals()->principal_id()) + { + if (prin->id()) + { + std::string id_str = ::getFullText(prin->id()); + char *grantee_name = pstrdup(downcase_truncate_identifier(id_str.c_str(), id_str.length(), true)); + grantee_list = lappend(grantee_list, grantee_name); + } + } + List *privilege_list = NIL; + for (auto perm: ctx->revoke_statement()->permissions()->permission()) + { + auto single_perm = perm->single_permission(); + if (single_perm->EXECUTE()) + privilege_list = lappend(privilege_list, (void *)"execute"); + if (single_perm->EXEC()) + privilege_list = lappend(privilege_list, (void *)"execute"); + if (single_perm->SELECT()) + privilege_list = lappend(privilege_list, (void *)"select"); + if (single_perm->INSERT()) + privilege_list = lappend(privilege_list, (void *)"insert"); + if (single_perm->UPDATE()) + privilege_list = lappend(privilege_list, (void *)"update"); + if (single_perm->DELETE()) + privilege_list = lappend(privilege_list, (void *)"delete"); + if (single_perm->REFERENCES()) + privilege_list = lappend(privilege_list, (void *)"references"); + } + result->privileges = privilege_list; + result->grantees = grantee_list; + return (PLtsql_stmt *) result; + } + } + PLtsql_stmt *result; result = makeExecSql(ctx); attachPLtsql_fragment(ctx, result); diff --git a/contrib/babelfishpg_tsql/src/tsqlNodes.h b/contrib/babelfishpg_tsql/src/tsqlNodes.h index 2bdc6b4fda..cb0195dce0 100644 --- a/contrib/babelfishpg_tsql/src/tsqlNodes.h +++ b/contrib/babelfishpg_tsql/src/tsqlNodes.h @@ -48,7 +48,8 @@ typedef enum pltsql_stmt_type PLTSQL_STMT_ASSIGN_CURVAR, PLTSQL_STMT_DEALLOCATE, PLTSQL_STMT_INSERT_BULK, - PLTSQL_STMT_GRANTDB + PLTSQL_STMT_GRANTDB, + PLTSQL_STMT_GRANTSCHEMA } PLtsql_stmt_type; typedef struct PLtsql_expr diff --git a/contrib/babelfishpg_tsql/src/tsqlUnsupportedFeatureHandler.cpp b/contrib/babelfishpg_tsql/src/tsqlUnsupportedFeatureHandler.cpp index 2ce6d3ed40..a6897b1598 100644 --- a/contrib/babelfishpg_tsql/src/tsqlUnsupportedFeatureHandler.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlUnsupportedFeatureHandler.cpp @@ -1676,7 +1676,6 @@ void TsqlUnsupportedFeatureHandlerImpl::checkSupportedGrantStmt(TSqlParser::Gran unsupported_feature = "GRANT PERMISSION " + perm->getText(); handle(INSTR_UNSUPPORTED_TSQL_REVOKE_STMT, unsupported_feature.c_str(), getLineAndPos(perm)); } - } } @@ -1684,7 +1683,9 @@ void TsqlUnsupportedFeatureHandlerImpl::checkSupportedGrantStmt(TSqlParser::Gran { auto perm_obj = grant->permission_object(); auto obj_type = perm_obj->object_type(); - if (obj_type && !obj_type->OBJECT()) + if (grant->ALL() && obj_type && obj_type->SCHEMA()) + throw PGErrorWrapperException(ERROR, ERRCODE_FEATURE_NOT_SUPPORTED, "The all permission has been deprecated and is not available for this class of entity.", getLineAndPos(grant)); + if (obj_type && !(obj_type->OBJECT() || obj_type->SCHEMA())) { unsupported_feature = "GRANT ON " + obj_type->getText(); handle(INSTR_UNSUPPORTED_TSQL_REVOKE_STMT, unsupported_feature.c_str(), getLineAndPos(obj_type)); @@ -1769,7 +1770,6 @@ void TsqlUnsupportedFeatureHandlerImpl::checkSupportedRevokeStmt(TSqlParser::Rev unsupported_feature = "REVOKE PERMISSION " + perm->getText(); handle(INSTR_UNSUPPORTED_TSQL_REVOKE_STMT, unsupported_feature.c_str(), getLineAndPos(perm)); } - } } @@ -1777,7 +1777,9 @@ void TsqlUnsupportedFeatureHandlerImpl::checkSupportedRevokeStmt(TSqlParser::Rev { auto perm_obj = revoke->permission_object(); auto obj_type = perm_obj->object_type(); - if (obj_type && !obj_type->OBJECT()) + if (revoke->ALL() && obj_type && obj_type->SCHEMA()) + throw PGErrorWrapperException(ERROR, ERRCODE_FEATURE_NOT_SUPPORTED, "The all permission has been deprecated and is not available for this class of entity.", getLineAndPos(revoke)); + if (obj_type && !(obj_type->OBJECT() || obj_type->SCHEMA())) { unsupported_feature = "REVOKE ON " + obj_type->getText(); handle(INSTR_UNSUPPORTED_TSQL_REVOKE_STMT, unsupported_feature.c_str(), getLineAndPos(obj_type)); diff --git a/contrib/babelfishpg_tsql/src/tsql_for/forjson.c b/contrib/babelfishpg_tsql/src/tsql_for/forjson.c index b825037e06..360ae65d37 100644 --- a/contrib/babelfishpg_tsql/src/tsql_for/forjson.c +++ b/contrib/babelfishpg_tsql/src/tsql_for/forjson.c @@ -15,26 +15,57 @@ #include "parser/parser.h" #include "utils/builtins.h" #include "utils/json.h" +#include "utils/jsonb.h" #include "utils/syscache.h" #include "utils/typcache.h" +#include "utils/hsearch.h" #include "catalog/pg_type.h" #include "catalog/namespace.h" #include "tsql_for.h" -static void tsql_row_to_json(StringInfo state, Datum record, bool include_null_values); +#define TABLE_SIZE 100 + +// For holding information regarding the state of the FOR JSON call +// Necessary to pass information regarding root_name & without_array-wrappers +// to ffunc. +typedef struct { + bool without_array_wrapper; + char *root_name; + JsonbValue* jsonbArray; +} forjson_state; + +// Entry struct for use in HashTable +typedef struct { + char path[NAMEDATALEN]; + JsonbValue *value; + JsonbValue *parent; + int idx; +} JsonbEntry; + +static void tsql_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values); + +static char** determine_parts(const char* str, int *num); + +static char* build_key(char **parts, int currentIdx); + +static JsonbValue* create_json(char *part, JsonbValue* val, int *idx); + +static void insert_existing_json(JsonbValue *exists, JsonbValue* parent, JsonbValue *val, int idx, char *key); PG_FUNCTION_INFO_V1(tsql_query_to_json_sfunc); Datum tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) { - StringInfo state; + forjson_state *state; + JsonbValue *jsonbArray; + Datum record; - int mode; + int mode; bool include_null_values; bool without_array_wrapper; - char *root_name; + char *root_name; MemoryContext agg_context; MemoryContext old_context; @@ -58,25 +89,27 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) include_null_values = PG_GETARG_BOOL(3); if (PG_ARGISNULL(0)) { - /* first time setup */ - state = makeStringInfo(); + // First time setup for struct & JsonBValue + state = (forjson_state *) palloc(sizeof(forjson_state)); + + jsonbArray = palloc(sizeof(JsonbValue)); + jsonbArray->type = jbvArray; + jsonbArray->val.array.nElems = 0; + jsonbArray->val.array.rawScalar = false; + jsonbArray->val.array.elems = (JsonbValue *) palloc(sizeof(JsonbValue)); + + // Populate the struct without_array_wrapper = PG_GETARG_BOOL(4); root_name = PG_ARGISNULL(5) ? NULL : text_to_cstring(PG_GETARG_TEXT_PP(5)); - /* If root_name is present then WITHOUT_ARRAY_WRAPPER will be FALSE */ - if (root_name) - /* - * we need to add an extra token to the beginning so that the - * finalfunc knows to append "]}" to the end - */ - appendStringInfo(state, "<{\"%s\":[", root_name); - else if (!without_array_wrapper) - appendStringInfoChar(state, '['); + state->jsonbArray = jsonbArray; + state->without_array_wrapper = without_array_wrapper; + state->root_name = root_name; } else { - state = (StringInfo) PG_GETARG_POINTER(0); - appendStringInfoChar(state, ','); + state = (forjson_state*) PG_GETARG_POINTER(0); + jsonbArray = state->jsonbArray; } switch (mode) { @@ -93,7 +126,7 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) break; case TSQL_FORJSON_PATH: /* FOR JSON PATH */ /* add the current row to the state */ - tsql_row_to_json(state, record, include_null_values); + tsql_row_to_json(jsonbArray, record, include_null_values); break; default: /* Invalid mode, should not happen, report internal error */ @@ -103,45 +136,28 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) } MemoryContextSwitchTo(old_context); - PG_RETURN_POINTER(state); } -PG_FUNCTION_INFO_V1(tsql_query_to_json_ffunc); - -Datum -tsql_query_to_json_ffunc(PG_FUNCTION_ARGS) +// Main row to json function. +// Creates a Jsonb row object, processes the row, determines if it should be inserted as a nested json object +// inserts json object to row and then into the main jsonbArray. +static void +tsql_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values) { - StringInfo res = makeStringInfo(); - char *state = ((StringInfo) PG_GETARG_POINTER(0))->data; + // HashTable + HTAB *jsonbHash; + HASHCTL ct; - if (state[0] == '[') /* check for array wrapper */ - { - appendStringInfoString(res, state); - appendStringInfoChar(res, ']'); - } - else if (state[0] == '<') /* '<' indicates that root was specified */ - { - appendStringInfoString(res, state + 1); - appendStringInfoString(res, "]}"); - } - else - { - appendStringInfoString(res, state); - } - PG_RETURN_TEXT_P(cstring_to_text_with_len(res->data, res->len)); -} + // JsonbValue for the row + JsonbValue *jsonbRow; -static void -tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) -{ HeapTupleHeader td; Oid tupType; int32 tupTypmod; TupleDesc tupdesc; HeapTupleData tmptup; HeapTuple tuple; - char *sep = ""; td = DatumGetHeapTupleHeader(record); @@ -155,12 +171,35 @@ tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) tmptup.t_data = td; tuple = &tmptup; - /* each tuple is its own object */ - appendStringInfoChar(state, '{'); + // Initialize the JsonbValue for the row + jsonbRow = palloc(sizeof(JsonbValue)); + jsonbRow->type = jbvObject; + jsonbRow->val.object.nPairs = 0; + jsonbRow->val.object.pairs = palloc(sizeof(JsonbPair) * tupdesc->natts); + + // Initialize the hashTable to hold information regarding the nested json objects within the row + memset(&ct, 0, sizeof(ct)); + ct.keysize = NAMEDATALEN; + ct.entrysize = sizeof(JsonbEntry); + jsonbHash = hash_create("JsonbHash", TABLE_SIZE, &ct, HASH_ELEM | HASH_STRINGS); /* process the tuple into key/value pairs */ for (int i = 0; i < tupdesc->natts; i++) { + // Pair object that holds key-value + JsonbValue *key; + JsonbValue *value; + JsonbPair *jsonbPair; + + // Used for nested json Objects + JsonbEntry *hashEntry; + JsonbValue *nestedVal; + JsonbValue *current; + char **parts; + int num; + bool found; + char *hashKey; + char *colname; Datum colval; bool isnull; @@ -168,6 +207,7 @@ tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) Oid nspoid; Oid tsql_datatype_oid; char *typename; + Form_pg_attribute att = TupleDescAttr(tupdesc, i); if (att->attisdropped) @@ -265,12 +305,270 @@ tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) datatype_oid = NUMERICOID; } } + + // Check for NULL + if (isnull && include_null_values) { + value = palloc(sizeof(JsonbValue)); + value->type=jbvNull; + } + else { + // Extract the colummn value in the correct format + value = palloc(sizeof(JsonbValue)); + jsonb_get_value(colval, isnull, value, datatype_oid); + value = &value->val.array.elems[0]; + } + + // Determine if the value should be inserted as a nested json object + parts = determine_parts(colname, &num); + nestedVal = value; + + found = false; + if (num > 1) { + for (int i = num - 1; i >= 0; i--) { + hashKey = build_key(parts, i); + + // Check if the current key exists in the hashTable + hashEntry = (JsonbEntry *) hash_search(jsonbHash, hashKey, HASH_FIND, &found); + + // If it exists, we insert the value into the existing JsonbValue and break out of the loop + if (hashEntry) { + // function call + current = hashEntry->value; + insert_existing_json(current, hashEntry->parent, nestedVal, hashEntry->idx, colname); + pfree(hashKey); + break; + } + + // If it does not exist + hashEntry = (JsonbEntry *) hash_search(jsonbHash, (void *) hashKey, HASH_ENTER, NULL); + strlcpy(hashEntry->path, hashKey, NAMEDATALEN); + hashEntry->value = nestedVal; + nestedVal = create_json(parts[i], nestedVal, &hashEntry->idx); + + // if the nested json is not at the jsonbRow level + if (i != 0) + hashEntry->parent = nestedVal; + else { + hashEntry->parent = jsonbRow; + hashEntry->idx = jsonbRow->val.object.nPairs; + } + + pfree(hashKey); + } + + // Already inserted into existing json object (nested) + if (found) + continue; + + // JsonbValue was created in loop, insert and update structure. + jsonbRow->val.object.pairs[jsonbRow->val.object.nPairs] = nestedVal->val.object.pairs[0]; + jsonbRow->val.object.nPairs++; + } + + else { + // Increment nPairs in the row if it isnt inserted into an already existing json object. + jsonbRow->val.object.nPairs++; + colname = parts[0]; - appendStringInfoString(state, sep); - sep = ","; - tsql_json_build_object(state, CStringGetDatum(colname), colval, datatype_oid, isnull); + // Allocate memory for key and create it + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(colname); + key->val.string.val = pstrdup(colname); + // Create JsonbPair + jsonbPair = palloc(sizeof(JsonbPair)); + jsonbPair->key = *key; + jsonbPair->value = *nestedVal; + + // Assign it to the JsonbValue Row + jsonbRow->val.object.pairs[jsonbRow->val.object.nPairs - 1] = *jsonbPair; + } } - appendStringInfoChar(state, '}'); + + // Add the jsonb row to the jsonbArray + jsonbArray->val.array.nElems++; + jsonbArray->val.array.elems = (JsonbValue *) repalloc(jsonbArray->val.array.elems, sizeof(JsonbValue) * (jsonbArray->val.array.nElems)); + jsonbArray->val.array.elems[jsonbArray->val.array.nElems - 1] = *jsonbRow; + ReleaseTupleDesc(tupdesc); } + +PG_FUNCTION_INFO_V1(tsql_query_to_json_ffunc); + +Datum +tsql_query_to_json_ffunc(PG_FUNCTION_ARGS) +{ + forjson_state *state; + JsonbValue *res; + Jsonb *jsonOut; + StringInfo resStr; + + // Only used if a root_name is given + JsonbValue *root; + JsonbValue *key; + + // Get the processed JsonbValue array + state = (forjson_state*) PG_GETARG_POINTER(0); + resStr = makeStringInfo(); + + if (state->root_name) { + + // Key jsonBValue to store the root name + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(state->root_name); + key->val.string.val = state->root_name; + + // Root JsonbValue where the key is the root name and value is the processed jsonbVal array + root = palloc(sizeof(JsonbValue)); + root->type = jbvObject; + root->val.object.nPairs = 1; + root->val.object.pairs = (JsonbPair *) palloc(sizeof(JsonbPair)); + root->val.object.pairs[0].key = *key; + root->val.object.pairs[0].value = *state->jsonbArray; + + // Update the processed jsonbArray + state->jsonbArray = root; + } + + // Convert JsonbValue to StringInfo for array wrapper check and to return + res = state->jsonbArray; + jsonOut = JsonbValueToJsonb(res); + JsonbToCString(resStr, &jsonOut->root, 0); + + // if without array wrappers is true, remove the array wrappers + if (state->without_array_wrapper) { + if (resStr->data[0] == '[') { + resStr->data++; + resStr->len--; + } + if (resStr->data[resStr->len - 1] == ']') { + resStr->data[resStr->len - 1] = '\0'; + resStr->len--; + } + } + + PG_RETURN_TEXT_P(cstring_to_text_with_len(resStr->data, resStr->len)); +} + +// Function to determine how many nested json objects a column requires +// Splits a string into an array of strings by the "." +static char** +determine_parts(const char* str, int* num) +{ + int i; + char **parts; + char *copy_str; + char *token; + + // Determine how many parts there are (words seperated by ".") + *num = 1; + for (i = 0; str[i]; i++) { + if (str[i] == '.') + (*num)++; + } + + // Create a string array to hold each indiviual word + parts = (char **) palloc(sizeof(char *) * (*num + 1)); + copy_str = pstrdup(str); + token = strtok(copy_str, "."); + i = 0; + while (token != NULL) { + parts[i++] = pstrdup(token); + token = strtok(NULL, "."); + } + + parts[i] = NULL; + pfree(copy_str); + return parts; + +} + +// Function to build a key to use to search in the Hashtable +// Uses the parts** created from determine_parts to build a string +// that is used as a key/path. +static char* +build_key(char **parts, int currentIdx) +{ + StringInfo str; + str = makeStringInfo(); + + // Build a string up to the current path + for (int i = 0; i <= currentIdx; i++) { + appendStringInfoString(str, parts[i]); + if (i < currentIdx) { + appendStringInfoChar(str, '.'); + } + } + + return str->data; +} + +// Function to create the nested json output for a col if required +// Used when created nested json objects +static JsonbValue* +create_json(char *part, JsonbValue* val, int *idx) +{ + JsonbValue *obj; + JsonbValue *key; + JsonbPair *pair; + + // Create key + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(part); + key->val.string.val = pstrdup(part); + + // Create pair to hold key and value + pair = palloc(sizeof(JsonbPair)); + pair->key = *key; + pair->value = *val; + + // If we are not inserting into an already existing json object + + obj = palloc(sizeof(JsonbValue)); + obj->type = jbvObject; + obj->val.object.nPairs = 1; + obj->val.object.pairs = palloc(sizeof(JsonbPair)); + + + obj->val.object.pairs[obj->val.object.nPairs - 1] = *pair; + *idx = obj->val.object.nPairs - 1; + return obj; + +} + +// Function to append into existing JsonbValue +// Used when the path to insert a json object is already found in the HashTable. +static void +insert_existing_json(JsonbValue *current, JsonbValue* parent, JsonbValue *nestedVal, int idx, char *key) +{ + JsonbPair* newPairs; + // Make sure both current and nestedVal are non-null and are objects + if (!current || !nestedVal || current->type != jbvObject || nestedVal->type != jbvObject) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Property %s cannot be generated in JSON output due to a conflict with another column name or alias. Use different names and aliases for each column in SELECT list.", key))); + } + + // Allocate space for the new pairs + newPairs = (JsonbPair *) repalloc( + current->val.object.pairs, + sizeof(JsonbPair) * (current->val.object.nPairs + nestedVal->val.object.nPairs) + ); + + // Append the pairs from nestedVal to the new pair array + for (int i = 0; i < nestedVal->val.object.nPairs; i++) { + newPairs[current->val.object.nPairs + i] = nestedVal->val.object.pairs[i]; + } + + // Point the current's pairs to the newPairs + current->val.object.pairs = newPairs; + + // Update the pair count + current->val.object.nPairs += nestedVal->val.object.nPairs; + + // update parent pointer + parent->val.object.pairs[idx].value = *current; +} diff --git a/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..a23e01a771 --- /dev/null +++ b/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,35 @@ +DROP VIEW babel_3696_1 +GO + +DROP VIEW babel_3696_2 +GO + +DROP VIEW babel_3696_3 +GO + +DROP VIEW babel_3696_4 +GO + +DROP VIEW babel_3696_5 +GO + +DROP VIEW babel_3696_6 +GO + +DROP VIEW babel_3696_7 +GO + +DROP VIEW babel_3696_8 +GO + +DROP TABLE t1 +GO + +DROP VIEW babel_3696_9 +GO + +DROP PROCEDURE babel_3696_10 +GO + +DROP PROCEDURE babel_3696_11 +GO diff --git a/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..41fef7608b --- /dev/null +++ b/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,82 @@ +create view babel_3696_1 as +SELECT json_modify('{"Brand":"HP","Product":"Laptop","Accessories":["Keyboard","Mouse","Monitor"]}', '$.Accessories', JSON_QUERY('["Mouse","Monitor"]')) +go + +create view babel_3696_2 as +SELECT json_modify('{"Brand":"HP","Product":"Laptop"}', '$.Accessories', JSON_Query('["Keyboard","Mouse","Monitor"]')) +go + +create view babel_3696_3 as +select JSON_MODIFY(JSON_MODIFY('{"Brand":"HP","Product":"Laptop"}', '$.Parts', JSON_VALUE('{"Brand":"HP","Product":"Laptop"}','$.Product')), '$.Product',NULL) +go + +create view babel_3696_4 as +select JSON_MODIFY(JSON_MODIFY('{"Brand":"HP","Product":"Laptop","Accessories":["Keyboard","Mouse","Monitor"]}', '$.Accessories', JSON_QUERY('["HDMI","USB"]')), '$.Brand', 'Lenovo') +go + + +create view babel_3696_5 as +select JSON_MODIFY('{"name":"John","skills":["C#","SQL"]}','$.skills',JSON_QUERY('["C#","T-SQL","Azure"]')) +go + + +create table t1 (x nvarchar(20)) +insert into t1 values ('some string') +go +~~ROW COUNT: 1~~ + + +create view babel_3696_6 as +select json_modify('{"a":"b"}', '$.a', x) from (select * from t1 for json path) a ([x]) +go + +create view babel_3696_7 as +select json_modify('{"a":"b"}', '$.a', x) from (select * from t1 for json path, without_array_wrapper) a ([x]) +go + +create view babel_3696_8 as +select json_modify('{"a":"b"}', '$.a', json_modify('{"a":"b"}', '$.a', 'c')) +go + + +create view babel_3696_9 as +select json_modify('{"a":"b"}', '$.a', json_modify('{"a":"b"}', 'STRICT $.a', 'c')) +go + +create procedure babel_3696_10 +as +begin +DECLARE @data NVARCHAR(4000) +SET @data=N'{ + "Suspect": { + "Name": "Homer Simpson", + "Address": { + "City": "Dunedin", + "Region": "Otago", + "Country": "New Zealand" + }, + "Hobbies": ["Eating", "Sleeping", "Base Jumping"] + } + }' +select JSON_MODIFY(@data,'$.Suspect.Address.City', 'Timaru') AS 'Modified Array'; +end; +go + +create procedure babel_3696_11 +as +begin +DECLARE @data NVARCHAR(4000) +SET @data=N'{ + "Suspect": { + "Name": "Homer Simpson", + "Address": { + "City": "Dunedin", + "Region": "Otago", + "Country": "New Zealand" + }, + "Hobbies": ["Eating", "Sleeping", "Base Jumping"] + } + }' +select JSON_MODIFY(@data,'$.Suspect.Hobbies', JSON_QUERY('["Chess", "Brain Surgery"]')) AS 'Updated Hobbies'; +end; +go diff --git a/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..9aaf10c9dd --- /dev/null +++ b/test/JDBC/expected/BABEL-3696-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,87 @@ +SELECT * FROM babel_3696_1 +GO +~~START~~ +nvarchar +{"Brand": "HP", "Product": "Laptop", "Accessories": ["Mouse", "Monitor"]} +~~END~~ + + +SELECT * FROM babel_3696_2 +GO +~~START~~ +nvarchar +{"Brand": "HP", "Product": "Laptop", "Accessories": ["Keyboard", "Mouse", "Monitor"]} +~~END~~ + + +SELECT * FROM babel_3696_3 +GO +~~START~~ +nvarchar +{"Brand": "HP", "Parts": "Laptop"} +~~END~~ + + +SELECT * FROM babel_3696_4 +GO +~~START~~ +nvarchar +{"Brand": "Lenovo", "Product": "Laptop", "Accessories": ["HDMI", "USB"]} +~~END~~ + + +SELECT * FROM babel_3696_5 +GO +~~START~~ +nvarchar +{"name": "John", "skills": ["C#", "T-SQL", "Azure"]} +~~END~~ + + +SELECT * FROM babel_3696_6 +GO +~~START~~ +nvarchar +{"a": [{"x": "some string"}]} +~~END~~ + + +SELECT * FROM babel_3696_7 +GO +~~START~~ +nvarchar +{"a": "{\"x\":\"some string\"}"} +~~END~~ + + +SELECT * FROM babel_3696_8 +GO +~~START~~ +nvarchar +{"a": {"a": "c"}} +~~END~~ + + +SELECT * FROM babel_3696_9 +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: JSON path is not properly formatted)~~ + + +EXEC babel_3696_10 +GO +~~START~~ +nvarchar +{"Suspect": {"Name": "Homer Simpson", "Address": {"City": "Timaru", "Region": "Otago", "Country": "New Zealand"}, "Hobbies": ["Eating", "Sleeping", "Base Jumping"]}} +~~END~~ + + +EXEC babel_3696_11 +GO +~~START~~ +nvarchar +{"Suspect": {"Name": "Homer Simpson", "Address": {"City": "Dunedin", "Region": "Otago", "Country": "New Zealand"}, "Hobbies": ["Chess", "Brain Surgery"]}} +~~END~~ diff --git a/test/JDBC/expected/BABEL-3696-vu-verify.out b/test/JDBC/expected/BABEL-3696-vu-verify.out index e18207aa73..035edd1a4b 100644 --- a/test/JDBC/expected/BABEL-3696-vu-verify.out +++ b/test/JDBC/expected/BABEL-3696-vu-verify.out @@ -50,7 +50,7 @@ SELECT * FROM babel_3696_7 GO ~~START~~ nvarchar -{"a": "{\"x\":\"some string\"}"} +{"a": "{\"x\": \"some string\"}"} ~~END~~ diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out new file mode 100644 index 0000000000..53d3e86cb9 --- /dev/null +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out @@ -0,0 +1,59 @@ +DROP VIEW DATETRUNC_vu_prepare_v1 +GO + +DROP VIEW DATETRUNC_vu_prepare_v2 +GO + +DROP VIEW DATETRUNC_vu_prepare_v3 +GO + +DROP VIEW DATETRUNC_vu_prepare_v4 +GO + +DROP VIEW DATETRUNC_vu_prepare_v5 +GO + +DROP VIEW DATETRUNC_vu_prepare_v6 +GO + +DROP VIEW DATETRUNC_vu_prepare_v7 +GO + +DROP VIEW DATETRUNC_vu_prepare_v8 +GO + +DROP VIEW DATETRUNC_vu_prepare_v9 +GO + +DROP VIEW DATETRUNC_vu_prepare_v10 +GO + +DROP VIEW DATETRUNC_vu_prepare_v11 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p1 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p2 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p3 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p4 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p5 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p6 +GO + +DROP FUNCTION BABEL_3953_vu_prepare_f1 +GO + +DROP FUNCTION BABEL_3953_vu_prepare_f2 +GO + +DROP FUNCTION BABEL_3953_vu_prepare_f3 +GO diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-prepare.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-prepare.out new file mode 100644 index 0000000000..51dc0df6e2 --- /dev/null +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-prepare.out @@ -0,0 +1,233 @@ +-- Test with date datatype +CREATE VIEW DATETRUNC_vu_prepare_v1 AS ( + select + datetrunc(year, cast('2020-04-15' as date)) as dt1, + datetrunc(yy, cast('2020-04-15' as date)) as dt2, + datetrunc(yyyy, cast('2020-04-15' as date)) as dt3, + datetrunc(quarter, cast('2020-04-15' as date)) as dt4, + datetrunc(qq, cast('2020-04-15' as date)) as dt5, + datetrunc(q, cast('2020-04-15' as date)) as dt6, + datetrunc(month, cast('2020-04-15' as date)) as dt7, + datetrunc(mm, cast('2020-04-15' as date)) as dt8, + datetrunc(m, cast('2020-04-15' as date)) as dt9, + datetrunc(dayofyear, cast('2020-04-15' as date)) as dt10, + datetrunc(dy, cast('2020-04-15' as date)) as dt11, + datetrunc(y, cast('2020-04-15' as date)) as dt12, + datetrunc(day, cast('2020-04-15' as date)) as dt13, + datetrunc(dd, cast('2020-04-15' as date)) as dt14, + datetrunc(d, cast('2020-04-15' as date)) as dt15, + datetrunc(week, cast('2020-04-15' as date)) as dt16, + datetrunc(wk, cast('2020-04-15' as date)) as dt17, + datetrunc(ww, cast('2020-04-15' as date)) as dt18, + datetrunc(iso_week, cast('2020-04-15' as date)) as dt19, + datetrunc(isowk, cast('2020-04-15' as date)) as dt20, + datetrunc(isoww, cast('2020-04-15' as date)) as dt21 + ); +GO + +-- Test with time datatype +CREATE VIEW DATETRUNC_vu_prepare_v2 AS ( + select + datetrunc(hour, cast('12:32:45.5647311' as time)) as dt1, + datetrunc(hh, cast('12:32:45.5647311' as time)) as dt2, + datetrunc(minute, cast('12:32:45.5647311' as time)) as dt3, + datetrunc(mi, cast('12:32:45.5647311' as time)) as dt4, + datetrunc(n, cast('12:32:45.5647311' as time)) as dt5, + datetrunc(second, cast('12:32:45.5647311' as time)) as dt6, + datetrunc(ss, cast('12:32:45.5647311' as time)) as dt7, + datetrunc(s, cast('12:32:45.5647311' as time)) as dt8, + datetrunc(millisecond, cast('12:32:45.5647311' as time)) as dt9, + datetrunc(ms, cast('12:32:45.5647311' as time)) as dt10, + datetrunc(microsecond, cast('12:32:45.5647311' as time)) as dt11, + datetrunc(mcs, cast('12:32:45.5647311' as time)) as dt12 + ); +GO + + +-- Test with datetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v3 AS ( + select + datetrunc(year, cast('2004-06-17 09:32:42.566' as datetime)) as dt1, + datetrunc(quarter, cast('2004-06-17 09:32:42.566' as datetime)) as dt2, + datetrunc(month, cast('2004-06-17 09:32:42.566' as datetime)) as dt3, + datetrunc(dayofyear, cast('2004-06-17 09:32:42.566' as datetime)) as dt4, + datetrunc(day, cast('2004-06-17 09:32:42.566' as datetime)) as dt5, + datetrunc(week, cast('2004-06-17 09:32:42.566' as datetime)) as dt6, + datetrunc(hour, cast('2004-06-17 09:32:42.566' as datetime)) as dt7, + datetrunc(minute, cast('2004-06-17 09:32:42.566' as datetime)) as dt8, + datetrunc(second, cast('2004-06-17 09:32:42.566' as datetime)) as dt9, + datetrunc(millisecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt10 + ); +GO +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''datetime''. +CREATE VIEW DATETRUNC_vu_prepare_v4 AS ( + select + datetrunc(microsecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt1 +); +GO + +-- Test with smalldatetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v5 AS ( + select + datetrunc(year, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(quarter, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2, + datetrunc(month, cast('2004-08-14 22:34:20' as smalldatetime)) as dt3, + datetrunc(dayofyear, cast('2004-08-14 22:34:20' as smalldatetime)) as dt4, + datetrunc(day, cast('2004-08-14 22:34:20' as smalldatetime)) as dt5, + datetrunc(week, cast('2004-08-14 22:34:20' as smalldatetime)) as dt6, + datetrunc(hour, cast('2004-08-14 22:34:20' as smalldatetime)) as dt7, + datetrunc(minute, cast('2004-08-14 22:34:20' as smalldatetime)) as dt8, + datetrunc(second, cast('2004-08-14 22:34:20' as smalldatetime)) as dt9 + ); +GO + +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''smalldatetime''. +CREATE VIEW DATETRUNC_vu_prepare_v6 AS ( + select + datetrunc(microsecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(millisecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2 +); +GO + +-- Test with datetime2 datatype +CREATE VIEW DATETRUNC_vu_prepare_v7 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt11 + ); +GO + +-- Test with datetimeoffset datatype +CREATE VIEW DATETRUNC_vu_prepare_v8 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893 +10:42' as datetimeoffset)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893 +02:42' as datetimeoffset)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893 +05:42' as datetimeoffset)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893 +13:42' as datetimeoffset)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893 -12:43' as datetimeoffset)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893 +12:22' as datetimeoffset)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893 -10:42' as datetimeoffset)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt11 + ); +GO + +-- Test with expression input that can be converted to datetime2 datatype. +CREATE VIEW DATETRUNC_vu_prepare_v9 AS ( + select + datetrunc(year, '2021-Jan-01') as dt1, + datetrunc(year, '2021/Jan/01') as dt2, + datetrunc(year, '2021-1-1') as dt3, + datetrunc(year, '20210101') as dt4, + datetrunc(hour, cast('2020-01-01' as varchar)) as dt5, + datetrunc(minute, cast('1980-09-08' as char)) as dt6, + datetrunc(day, '12:32:42') as dt7, + datetrunc(day, '12:32:42.46378') as dt8, + datetrunc(week, '1990-09-09 12:32:09.546') as dt9, + datetrunc(week, '1990-09-09 12:32:09') as dt10, + datetrunc(week, '1990-09-09 12:32:09.546788') as dt11 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale +-- babelfish will always give answer that will include fractional seconds till 7 digits. +CREATE VIEW DATETRUNC_vu_prepare_v10 AS ( + select + datetrunc(hour, cast('12:32:43.4635' as time(3))) dt1, + datetrunc(month, cast('2020-12-23 20:20:20.2222' as datetime2(2))) as dt2, + datetrunc(week, cast('1989-09-23 05:36:43.2930 +12:37' as datetimeoffset(5))) as dt3, + datetrunc(minute, cast('2027-12-13 10:13:20.12236' as datetime2(4))) as dt4, + datetrunc(year, cast('2027-12-13 10:13:20.537478' as datetimeoffset(6))) as dt5 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale which is less then the specified datepart milliseocond, microsecond. +-- Babelfish always give answer to these with fractional seconds till 7 digits, babelfish do not throw an error similar to sql server in this case. +CREATE VIEW DATETRUNC_vu_prepare_v11 AS ( + select + datetrunc(millisecond, cast('2002-01-01 12:33:43.435354' as datetime2(2))) as dt1, + datetrunc(millisecond, cast('2020-01-01 12:33:32.4324' as datetimeoffset(1))) as dt2, + datetrunc(millisecond, cast('12:23:43.464774' as time(0))) as dt3, + datetrunc(microsecond, cast('2002-01-01 12:33:43.435354' as datetime2(5))) as dt4, + datetrunc(microsecond, cast('2020-01-01 12:33:32.437724' as datetimeoffset(4))) as dt5 + ); +GO + + +-- Procedures +-- Test with upper/lower limit of date/time. +CREATE PROCEDURE BABEL_3953_vu_prepare_p1 as ( + SELECT + datetrunc(month, cast('0001-01-01' as date)) as dt1, + datetrunc(month, cast('9999-12-31' as date)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p2 as ( + SELECT + datetrunc(month, cast('1753-01-01 00:00:00 ' as datetime)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.997' as datetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p3 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00' as datetime2)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999999' as datetime2)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p4 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00 -14:00' as datetimeoffset)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999 +14:00' as datetimeoffset)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p5 as ( + SELECT + datetrunc(month, cast('1900-01-01 00:00:00' as smalldatetime)) as dt1, + datetrunc(day, cast('2007-06-05 23:59:59' as smalldatetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p6 as ( + SELECT + datetrunc(hour, cast('00:00:00.0000000' as time)) as dt1, + datetrunc(second, cast('23:59:59.999999' as time)) as dt2 + ); +GO + + +-- functions +CREATE FUNCTION BABEL_3953_vu_prepare_f1() +RETURNS DATETIME2 AS +BEGIN +RETURN (SELECT datetrunc(iso_week, cast('2012-01-23 12:32:23.324' as datetime2))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f2() +RETURNS time AS +BEGIN +RETURN (select datetrunc(second, cast('12:32:53.23' as time))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f3() +RETURNS date AS +BEGIN +RETURN (select datetrunc(week, cast('2001-11-14' as date))); +END +GO diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out new file mode 100644 index 0000000000..4c15424174 --- /dev/null +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out @@ -0,0 +1,561 @@ +SELECT * FROM DATETRUNC_vu_prepare_v1 +GO +~~START~~ +date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date +2020-01-01#!#2020-01-01#!#2020-01-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-12#!#2020-04-12#!#2020-04-12#!#2020-04-13#!#2020-04-13#!#2020-04-13 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v2 +GO +~~START~~ +time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time +12:00:00.0000000#!#12:00:00.0000000#!#12:32:00.0000000#!#12:32:00.0000000#!#12:32:00.0000000#!#12:32:45.0000000#!#12:32:45.0000000#!#12:32:45.0000000#!#12:32:45.5640000#!#12:32:45.5640000#!#12:32:45.5647310#!#12:32:45.5647310 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v3 +GO +~~START~~ +datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime +2004-01-01 00:00:00.0#!#2004-04-01 00:00:00.0#!#2004-06-01 00:00:00.0#!#2004-06-17 00:00:00.0#!#2004-06-17 00:00:00.0#!#2004-06-13 00:00:00.0#!#2004-06-17 09:00:00.0#!#2004-06-17 09:32:00.0#!#2004-06-17 09:32:42.0#!#2004-06-17 09:32:42.567 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v4 +GO +~~START~~ +datetime +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart 'microsecond' is not supported by date function datetrunc for data type 'datetime'.)~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v5 +GO +~~START~~ +smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime +2004-01-01 00:00:00.0#!#2004-07-01 00:00:00.0#!#2004-08-01 00:00:00.0#!#2004-08-14 00:00:00.0#!#2004-08-14 00:00:00.0#!#2004-08-08 00:00:00.0#!#2004-08-14 22:00:00.0#!#2004-08-14 22:34:00.0#!#2004-08-14 22:34:00.0 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v6 +GO +~~START~~ +smalldatetime#!#smalldatetime +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart 'microsecond' is not supported by date function datetrunc for data type 'smalldatetime'.)~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v7 +GO +~~START~~ +datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2 +2015-01-01 00:00:00.0000000#!#2015-10-01 00:00:00.0000000#!#2015-11-01 00:00:00.0000000#!#2015-11-30 00:00:00.0000000#!#2015-11-30 00:00:00.0000000#!#2015-11-29 00:00:00.0000000#!#2015-11-30 09:00:00.0000000#!#2015-11-30 09:34:00.0000000#!#2015-11-30 09:34:56.0000000#!#2015-11-30 09:34:56.6570000#!#2015-11-30 09:34:56.6574890 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v8 +GO +~~START~~ +datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset +2015-01-01 00:00:00.0000000 +12:42#!#2015-10-01 00:00:00.0000000 +10:42#!#2015-11-01 00:00:00.0000000 +02:42#!#2015-11-30 00:00:00.0000000 +05:42#!#2015-11-30 00:00:00.0000000 +12:42#!#2015-11-29 00:00:00.0000000 +13:42#!#2015-11-30 09:00:00.0000000 +12:42#!#2015-11-30 09:34:00.0000000 -12:43#!#2015-11-30 09:34:56.0000000 +12:22#!#2015-11-30 09:34:56.6570000 -10:42#!#2015-11-30 09:34:56.6574890 +12:42 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v9 +GO +~~START~~ +datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2 +2021-01-01 00:00:00.0000000#!#2021-01-01 00:00:00.0000000#!#2021-01-01 00:00:00.0000000#!#2021-01-01 00:00:00.0000000#!#2020-01-01 00:00:00.0000000#!#1980-09-08 00:00:00.0000000#!#1900-01-01 00:00:00.0000000#!#1900-01-01 00:00:00.0000000#!#1990-09-09 00:00:00.0000000#!#1990-09-09 00:00:00.0000000#!#1990-09-09 00:00:00.0000000 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v10 +GO +~~START~~ +time#!#datetime2#!#datetimeoffset#!#datetime2#!#datetimeoffset +12:00:00.0000000#!#2020-12-01 00:00:00.0000000#!#1989-09-17 00:00:00.0000000 +12:37#!#2027-12-13 10:13:00.0000000#!#2027-01-01 00:00:00.0000000 +00:00 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v11 +GO +~~START~~ +datetime2#!#datetimeoffset#!#time#!#datetime2#!#datetimeoffset +2002-01-01 12:33:43.4400000#!#2020-01-01 12:33:32.4000000 +00:00#!#12:23:43.0000000#!#2002-01-01 12:33:43.4353500#!#2020-01-01 12:33:32.4377000 +00:00 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p1 +GO +~~START~~ +date#!#date +0001-01-01#!#9999-12-01 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p2 +GO +~~START~~ +datetime#!#datetime +1753-01-01 00:00:00.0#!#9999-12-01 00:00:00.0 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p3 +GO +~~START~~ +datetime2#!#datetime2 +0001-01-01 00:00:00.0000000#!#9999-12-01 00:00:00.0000000 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p4 +GO +~~START~~ +datetimeoffset#!#datetimeoffset +0001-01-01 00:00:00.0000000 -14:00#!#9999-12-01 00:00:00.0000000 +14:00 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p5 +GO +~~START~~ +smalldatetime#!#smalldatetime +1900-01-01 00:00:00.0#!#2007-06-06 00:00:00.0 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p6 +GO +~~START~~ +time#!#time +00:00:00.0000000#!#23:59:59.0000000 +~~END~~ + + +SELECT BABEL_3953_vu_prepare_f1() +GO +~~START~~ +datetime2 +2012-01-23 00:00:00.0000000 +~~END~~ + + +SELECT BABEL_3953_vu_prepare_f2() +GO +~~START~~ +time +12:32:53.0000000 +~~END~~ + + +SELECT BABEL_3953_vu_prepare_f3() +GO +~~START~~ +date +2001-11-11 +~~END~~ + + +select datetrunc(null, CAST('2020-01-01' as date)) as dt1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "null")~~ + +select datetrunc(null, null) as dt1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "null")~~ + +select datetrunc(null, 'NULL') as dt1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "null")~~ + +select datetrunc('NULL', null) as dt1 +GO +~~START~~ +datetime2 +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'NULL' is not a recognized datetrunc option.)~~ + +select datetrunc('NULL', 'NULL') as dt1 +GO +~~START~~ +datetime2 +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'NULL' is not a recognized datetrunc option.)~~ + +select datetrunc('year',CAST('2020-01-01' as date)) +go +~~START~~ +date +2020-01-01 +~~END~~ + +select datetrunc(year, null) as dt3 +GO +~~START~~ +datetime2 + +~~END~~ + +select datetrunc(years, null) as dt4 +GO +~~START~~ +datetime2 +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'years' is not a recognized datetrunc option.)~~ + +select datetrunc(nanosecond ,null) as dt5 +GO +~~START~~ +datetime2 + +~~END~~ + +SELECT datetrunc(nanosecond, 2020) +GO +~~START~~ +int +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Argument data type 'integer' is invalid for argument 2 of datetrunc function.)~~ + +select datetrunc(invalid_datepart, 2020) +GO +~~START~~ +int +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'invalid_datepart' is not a recognized datetrunc option.)~~ + +select datetrunc(hour, 2020.0) +GO +~~START~~ +numeric +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Argument data type 'numeric' is invalid for argument 2 of datetrunc function.)~~ + + +-- postgres support 6 digits of fractional time-scale so the bbf output will differ +-- in the last fractional second digit from t-sql. bbf- 2021-12-08 11:30:15.1234570 +-- tsql- 2021-12-08 11:30:15.1234560 +DECLARE @d datetime2 = '2021-12-08 11:30:15.1234567'; +SELECT 'Microsecond', DATETRUNC(microsecond, @d); +Go +~~START~~ +varchar#!#datetime2 +Microsecond#!#2021-12-08 11:30:15.1234570 +~~END~~ + + +DECLARE @test_date date; +SET @test_date = '1998-09-12'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +date +1998-09-06 +~~END~~ + + +DECLARE @test_date datetime; +SET @test_date = '2010-09-12 12:23:12.564'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +datetime +2010-09-12 00:00:00.0 +~~END~~ + + +DECLARE @test_date datetime2; +SET @test_date = '2010-09-12 12:23:12.56443'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +datetime2 +2010-09-12 00:00:00.0000000 +~~END~~ + + +DECLARE @test_date smalldatetime; +SET @test_date = '2010-09-12 12:23:12'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +smalldatetime +2010-09-12 00:00:00.0 +~~END~~ + + +DECLARE @test_date datetimeoffset; +SET @test_date = '2010-09-12 12:23:12.56443 +10:12'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +datetimeoffset +2010-09-12 00:00:00.0000000 +10:12 +~~END~~ + + +DECLARE @test_date time; +SET @test_date = '12:23:12.56443'; +SELECT datetrunc(hour, @test_date); +GO +~~START~~ +time +12:00:00.0000000 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23' as datetime))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +datetime +2020-01-09 00:00:00.0 +~~END~~ + +~~START~~ +datetime +2020-01-05 00:00:00.0 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a date) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09' as date))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +date +2020-01-09 +~~END~~ + +~~START~~ +date +2020-01-05 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime2) +insert into dtrunc (a) values(datetrunc(day, '2020-01-09 12:32:23.23')) +Select * from dtrunc +Select datetrunc(day, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +datetime2 +2020-01-09 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-01-09 00:00:00.0000000 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetimeoffset) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23 -10:23' as datetimeoffset))) +Select * from dtrunc +Select datetrunc(month, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +datetimeoffset +2020-01-09 00:00:00.0000000 -10:23 +~~END~~ + +~~START~~ +datetimeoffset +2020-01-01 00:00:00.0000000 -10:23 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a smalldatetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23' as smalldatetime))) +Select * from dtrunc +Select datetrunc(hour, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +smalldatetime +2020-01-09 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2020-01-09 00:00:00.0 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a time) +insert into dtrunc (a) values(datetrunc(minute, CAST('12:32:23.23' as time))) +Select * from dtrunc +Select datetrunc(second, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +time +12:32:00.0000000 +~~END~~ + +~~START~~ +time +12:32:00.0000000 +~~END~~ + + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +GO +~~START~~ +datetime2 +2020-09-07 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-09-07 00:00:00.0000000 +~~END~~ + + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +GO +~~START~~ +datetime2 +2020-08-10 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-08-10 00:00:00.0000000 +~~END~~ + + +SET DATEFIRST 2 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +GO +~~START~~ +datetime +2020-01-06 00:00:00.0 +~~END~~ + +~~START~~ +datetime +2020-01-07 00:00:00.0 +~~END~~ + + +SET DATEFIRST 3 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12' as date)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12' as date)) +GO +~~START~~ +date +2020-01-06 +~~END~~ + +~~START~~ +date +2020-01-08 +~~END~~ + + +SET DATEFIRST 4 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as smalldatetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as smalldatetime)) +GO +~~START~~ +smalldatetime +2020-01-06 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2020-01-09 00:00:00.0 +~~END~~ + + +SET DATEFIRST 5 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as datetime2)) +GO +~~START~~ +datetime2 +2020-01-06 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-01-10 00:00:00.0000000 +~~END~~ + + +SET DATEFIRST 6 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO +~~START~~ +datetimeoffset +2020-01-06 00:00:00.0000000 +12:32 +~~END~~ + +~~START~~ +datetimeoffset +2020-01-11 00:00:00.0000000 -09:43 +~~END~~ + + +SET DATEFIRST 7 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO +~~START~~ +datetimeoffset +2020-01-06 00:00:00.0000000 +12:32 +~~END~~ + +~~START~~ +datetimeoffset +2020-01-12 00:00:00.0000000 -09:43 +~~END~~ + diff --git a/test/JDBC/expected/BABEL-4231-vu-cleanup.out b/test/JDBC/expected/BABEL-4231-vu-cleanup.out index 58ab90f5ef..c949c9b902 100644 --- a/test/JDBC/expected/BABEL-4231-vu-cleanup.out +++ b/test/JDBC/expected/BABEL-4231-vu-cleanup.out @@ -154,3 +154,6 @@ DROP VIEW view_babel_4231_40; GO DROP TABLE table18_babel_4231; GO + +DROP VIEW view_babel_4231_41; +GO diff --git a/test/JDBC/expected/BABEL-4231-vu-prepare.out b/test/JDBC/expected/BABEL-4231-vu-prepare.out index fd62c8b297..a2a9664c5d 100644 --- a/test/JDBC/expected/BABEL-4231-vu-prepare.out +++ b/test/JDBC/expected/BABEL-4231-vu-prepare.out @@ -238,22 +238,22 @@ CREATE VIEW view_babel_4231_35 AS SELECT * FROM table17_babel_4231 AS "αΒβΓ GO -- tsql --- table aliases which are not delimited by double quote, square bracket and length is less than 64 +-- column aliases which are not delimited by double quote, square bracket and length is less than 64 CREATE VIEW view_babel_4231_36 AS SELECT 1 AS ABCD; GO -- tsql --- table aliases with single byte characters which are not delimited by double quote, square bracket and length is more than or equals to 64 +-- column aliases with single byte characters which are not delimited by double quote, square bracket and length is more than or equals to 64 CREATE VIEW view_babel_4231_37 AS SELECT 1 AS ABCDbdjaBFWFGRUWlgrefwfiwuegfdvfwefgvggfedfudywtitewutgfdWUIF; GO -- tsql --- table aliases with single byte characters which are delimited by single quote and length is more than or equals to 64 +-- column aliases with single byte characters which are delimited by single quote and length is more than or equals to 64 CREATE VIEW view_babel_4231_38 AS SELECT 1 AS 'ABCDbdjaBFWFGRUWlgrefwfiwuegfdvfwefgvggfedfudywtitewutgfdWUIF'; GO -- tsql --- table aliases with single byte characters which are delimited by single quote and length is less than 64 +-- column aliases with single byte characters which are delimited by single quote and length is less than 64 CREATE VIEW view_babel_4231_39 AS SELECT 1 AS N'ANfjws'; GO @@ -264,5 +264,7 @@ GO CREATE VIEW view_babel_4231_40 AS SELECT 您您对您对您对您对您对您对您对您对您对您您您.* FROM table18_babel_4231 AS 您您对您对您对您对您对您对您对您对您对您您您; GO - - +-- tsql +-- column aliases with multibyte characters which are delimited by single quote and length is more than 128 +CREATE VIEW view_babel_4231_41 AS SELECT 1 AS '您对“数据一览“中的车型,颜色,内饰,选装, 您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,'; +GO diff --git a/test/JDBC/expected/BABEL-4231-vu-verify.out b/test/JDBC/expected/BABEL-4231-vu-verify.out index c0f120357a..895108d30f 100644 --- a/test/JDBC/expected/BABEL-4231-vu-verify.out +++ b/test/JDBC/expected/BABEL-4231-vu-verify.out @@ -357,3 +357,21 @@ text SELECT "您您对您对您对您对您d60211ff7d947ff09db87babbf0cb9de".a, "您您对您对您对您对您d60211ff7d947ff09db87babbf0cb9de".b FROM master_dbo.table18_babel_4231 "您您对您对您对您对您d60211ff7d947ff09db87babbf0cb9de"; ~~END~~ + +-- psql +SELECT pg_catalog.pg_get_viewdef(oid, true) FROM pg_class WHERE relname = 'view_babel_4231_41'; +GO +~~START~~ +text + SELECT 1 AS "您对“数据一览“中的e06f302024afe951b33a0978fde84988"; +~~END~~ + + +-- tsql +select 1 as '您对“数据一览“中的车型,颜色,内饰,选装, 您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,'; +GO +~~START~~ +int +1 +~~END~~ + diff --git a/test/JDBC/expected/BABEL-CROSS-DB.out b/test/JDBC/expected/BABEL-CROSS-DB.out index bf13b5f26f..2273c92e4f 100644 --- a/test/JDBC/expected/BABEL-CROSS-DB.out +++ b/test/JDBC/expected/BABEL-CROSS-DB.out @@ -522,6 +522,12 @@ DROP PROCEDURE p1 GO -- tsql +USE db1; +GO + +DROP TABLE db1_t1; +GO + USE master; GO diff --git a/test/JDBC/expected/BABEL-GRANT.out b/test/JDBC/expected/BABEL-GRANT.out index e1c4007985..4e8a1695a1 100644 --- a/test/JDBC/expected/BABEL-GRANT.out +++ b/test/JDBC/expected/BABEL-GRANT.out @@ -20,6 +20,10 @@ GO --- --- Prepare Objects --- +---- SCHEMA +CREATE SCHEMA scm; +GO + ---- TABLE CREATE TABLE t1 ( a int, b int); GO @@ -57,6 +61,12 @@ GO --- --- Basic Grant / Revoke --- +GRANT SELECT ON SCHEMA::scm TO guest; +GO + +GRANT INSERT ON SCHEMA::scm TO guest; +GO + GRANT ALL ON OBJECT::t1 TO guest WITH GRANT OPTION; GO @@ -143,6 +153,9 @@ GO ~~ERROR (Message: 'REVOKE ALL on Database' is not currently supported in Babelfish)~~ +REVOKE SELECT ON SCHEMA::scm FROM guest; -- unsupported permission +GO + GRANT SHOWPLAN ON OBJECT::t1 TO guest; -- unsupported permission GO ~~ERROR (Code: 33557097)~~ @@ -161,14 +174,14 @@ GRANT ALL ON SCHEMA::scm TO guest; -- unsupported class GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: 'GRANT ON SCHEMA' is not currently supported in Babelfish)~~ +~~ERROR (Message: The all permission has been deprecated and is not available for this class of entity.)~~ REVOKE ALL ON SCHEMA::scm TO guest; -- unsupported class GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: 'REVOKE ON SCHEMA' is not currently supported in Babelfish)~~ +~~ERROR (Message: The all permission has been deprecated and is not available for this class of entity.)~~ GRANT ALL ON OBJECT::t1 TO guest WITH GRANT OPTION AS superuser; @@ -189,6 +202,9 @@ GO --- --- Clean Up --- +DROP SCHEMA scm; +GO + DROP VIEW IF EXISTS my_view; GO diff --git a/test/JDBC/expected/BABEL-SESSION.out b/test/JDBC/expected/BABEL-SESSION.out index 87d51024a5..6e9888edd5 100644 --- a/test/JDBC/expected/BABEL-SESSION.out +++ b/test/JDBC/expected/BABEL-SESSION.out @@ -153,6 +153,21 @@ USE master; GO -- tsql +USE db1; +GO + +DROP TABLE tb1; +GO + +DROP TABLE janedoe_schema.t1; +GO + +DROP SCHEMA janedoe_schema; +GO + +USE master; +go + DROP DATABASE db1; GO diff --git a/test/JDBC/expected/BABEL_4442.out b/test/JDBC/expected/BABEL_4442.out new file mode 100644 index 0000000000..fc63a02cad --- /dev/null +++ b/test/JDBC/expected/BABEL_4442.out @@ -0,0 +1,184 @@ +CREATE SCHEMA babel_4442_s1 +GO +CREATE SCHEMA babel_4442_s2 +GO + +CREATE TABLE babel_4442_t (id INT) +GO +CREATE TABLE babel_4442_s1.babel_4442_t (id INT) +GO +CREATE TABLE babel_4442_s2.babel_4442_t (id INT) +GO + +INSERT INTO babel_4442_t VALUES (1) +GO +~~ROW COUNT: 1~~ + +INSERT INTO babel_4442_s1.babel_4442_t VALUES (2), (3) +GO +~~ROW COUNT: 2~~ + +INSERT INTO babel_4442_s2.babel_4442_t VALUES (3), (4), (5) +GO +~~ROW COUNT: 3~~ + + +CREATE FUNCTION babel_4442_f() RETURNS INT AS +BEGIN + RETURN (SELECT COUNT(*) FROM babel_4442_t) +END +GO + +CREATE FUNCTION babel_4442_s1.babel_4442_f() RETURNS INT AS +BEGIN + RETURN (SELECT COUNT(*) FROM babel_4442_t) +END +GO + +CREATE FUNCTION babel_4442_s2.babel_4442_f() RETURNS INT AS +BEGIN + RETURN (SELECT COUNT(*) FROM babel_4442_t) +END +GO + +SELECT TABLE_NAME, TABLE_TYPE FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = SCHEMA_NAME() and TABLE_NAME = 'babel_4442_t' +GO +~~START~~ +varchar#!#varchar +babel_4442_t#!#BASE TABLE +~~END~~ + + +SELECT babel_4442_f(), * FROM babel_4442_s1.babel_4442_t +GO +~~START~~ +int#!#int +1#!#2 +1#!#3 +~~END~~ + + +SELECT babel_4442_f(), babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_s1.babel_4442_t +GO +~~START~~ +int#!#int#!#int#!#int +1#!#2#!#3#!#2 +1#!#2#!#3#!#3 +~~END~~ + + +SELECT babel_4442_f(), babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +~~START~~ +int#!#int#!#int#!#int +1#!#2#!#3#!#1 +~~END~~ + + +SELECT babel_4442_f(), current_setting('search_path'), babel_4442_s1.babel_4442_f(), current_setting('search_path'), + babel_4442_s2.babel_4442_f(), 1, current_setting('search_path'), * FROM babel_4442_t +GO +~~START~~ +int#!#text#!#int#!#text#!#int#!#int#!#text#!#int +1#!#master_dbo, "$user", sys, pg_catalog#!#2#!#master_dbo, "$user", sys, pg_catalog#!#3#!#1#!#master_dbo, "$user", sys, pg_catalog#!#1 +~~END~~ + + +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + + +BEGIN TRANSACTION +GO +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +~~START~~ +int#!#int#!#int +2#!#3#!#1 +~~END~~ + +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +~~START~~ +int#!#int#!#int +2#!#3#!#1 +~~END~~ + +COMMIT +GO + +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + + +BEGIN TRANSACTION +GO +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +~~START~~ +int#!#int#!#int +2#!#3#!#1 +~~END~~ + +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +~~START~~ +int#!#int#!#int +2#!#3#!#1 +~~END~~ + +ROLLBACK +GO + +SELECT current_setting('search_path') +GO +~~START~~ +text +master_dbo, "$user", sys, pg_catalog +~~END~~ + + +DROP TABLE IF EXISTS babel_4442_t, babel_4442_s1.babel_4442_t, babel_4442_s2.babel_4442_t +GO +DROP FUNCTION IF EXISTS babel_4442_f, babel_4442_s1.babel_4442_f, babel_4442_s2.babel_4442_f +GO +DROP SCHEMA babel_4442_s1 +GO +DROP SCHEMA babel_4442_s2 +GO diff --git a/test/JDBC/expected/GRANT_SCHEMA-vu-cleanup.out b/test/JDBC/expected/GRANT_SCHEMA-vu-cleanup.out new file mode 100644 index 0000000000..af83d2ea36 --- /dev/null +++ b/test/JDBC/expected/GRANT_SCHEMA-vu-cleanup.out @@ -0,0 +1,75 @@ +-- tsql +-- Drop objects +use grant_schema_d1; +go + +drop table grant_schema_s1.grant_schema_t1; +go + +drop table grant_schema_s1.grant_schema_t2; +go + +drop table grant_schema_s1.grant_schema_t3; +go + +drop view grant_schema_s1.grant_schema_v1; +go + +drop view grant_schema_s1.grant_schema_v2; +go + +drop proc grant_schema_s1.grant_schema_p1; +go + +drop proc grant_schema_s1.grant_schema_p2; +go + +drop function grant_schema_s1.grant_schema_f1; +go + +drop function grant_schema_s1.grant_schema_f2; +go + +drop schema grant_schema_s1; +go + +drop table grant_schema_s2.grant_schema_t1; +go + +drop table grant_schema_s2.grant_schema_t2; +go + +drop schema grant_schema_s2; +go + +drop user grant_schema_u1; +go + +use master; +go + +drop database grant_schema_d1; +go + +-- psql +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'grant_schema_l1' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +go +~~START~~ +bool +~~END~~ + + +-- Wait to sync with another session +SELECT pg_sleep(1); +go +~~START~~ +void + +~~END~~ + + +-- tsql +drop login grant_schema_l1; +go diff --git a/test/JDBC/expected/GRANT_SCHEMA-vu-prepare.out b/test/JDBC/expected/GRANT_SCHEMA-vu-prepare.out new file mode 100644 index 0000000000..069a323b57 --- /dev/null +++ b/test/JDBC/expected/GRANT_SCHEMA-vu-prepare.out @@ -0,0 +1,74 @@ +-- tsql +-- create objects +create database grant_schema_d1; +go + +use grant_schema_d1; +go + +create login grant_schema_l1 with password = '12345678' +go + +create user grant_schema_u1 for login grant_schema_l1; +go + +create schema grant_schema_s1; +go + +create table grant_schema_s1.grant_schema_t1(a int); +go + +create table grant_schema_s1.grant_schema_t2(b int); +go + +create table grant_schema_s1.grant_schema_t3(c int); +go + +create view grant_schema_s1.grant_schema_v1 as select 2; +go + +create view grant_schema_s1.grant_schema_v2 as select 2; +go + +create proc grant_schema_s1.grant_schema_p1 as select 2; +go + +create proc grant_schema_s1.grant_schema_p2 as select 2; +go + +CREATE FUNCTION grant_schema_s1.grant_schema_f1() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go + +CREATE FUNCTION grant_schema_s1.grant_schema_f2() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go + +create schema grant_schema_s2; +go + +create table grant_schema_s2.grant_schema_t1(a int); +go + +create table grant_schema_s2.grant_schema_t2(a int); +go + +-- GRANT OBJECT privilege +grant select on grant_schema_s1.grant_schema_t1 to grant_schema_u1; +go +grant select on grant_schema_s1.grant_schema_t3 to grant_schema_u1; +go +grant select on grant_schema_s1.grant_schema_v1 to grant_schema_u1; +go +grant select on grant_schema_s1.grant_schema_v2 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_p1 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_p2 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_f1 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_f2 to grant_schema_u1; +go +grant select on grant_schema_s2.grant_schema_t1 to grant_schema_u1; +go +grant select on grant_schema_s2.grant_schema_t2 to grant_schema_u1; +go diff --git a/test/JDBC/expected/GRANT_SCHEMA-vu-verify.out b/test/JDBC/expected/GRANT_SCHEMA-vu-verify.out new file mode 100644 index 0000000000..16a45233e2 --- /dev/null +++ b/test/JDBC/expected/GRANT_SCHEMA-vu-verify.out @@ -0,0 +1,291 @@ +-- tsql user=grant_schema_l1 password=12345678 +-- User has OBJECT privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t1; +go +~~START~~ +int +~~END~~ + + +select * from grant_schema_s1.grant_schema_t2; -- case 1: has no permission +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table grant_schema_t2)~~ + + +select * from grant_schema_s1.grant_schema_v1; +go +~~START~~ +int +2 +~~END~~ + + +exec grant_schema_s1.grant_schema_p1; +go +~~START~~ +int +2 +~~END~~ + + +select * from grant_schema_s1.grant_schema_f1(); +go +~~START~~ +int +10 +~~END~~ + + +-- tsql +-- REVOKE OBJECT privilege +use grant_schema_d1; +go +revoke select on grant_schema_s1.grant_schema_t1 from grant_schema_u1; +go +revoke select on grant_schema_s1.grant_schema_v1 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_p1 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_f1 from grant_schema_u1; +go + +-- tsql user=grant_schema_l1 password=12345678 +-- User has no privileges, should not be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table grant_schema_t1)~~ + + +select * from grant_schema_s1.grant_schema_v1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view grant_schema_v1)~~ + + +exec grant_schema_s1.grant_schema_p1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure grant_schema_p1)~~ + + +select * from grant_schema_s1.grant_schema_f1(); +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function grant_schema_f1)~~ + + +-- tsql +-- GRANT SCHEMA privilege +use grant_schema_d1; +go +grant select, execute on schema::grant_schema_s1 to grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +-- User has SCHEMA privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t1; +go +~~START~~ +int +~~END~~ + + +select * from grant_schema_s1.grant_schema_t2; +go +~~START~~ +int +~~END~~ + + +select * from grant_schema_s1.grant_schema_v1; +go +~~START~~ +int +2 +~~END~~ + + +exec grant_schema_s1.grant_schema_p1; +go +~~START~~ +int +2 +~~END~~ + + +select * from grant_schema_s1.grant_schema_f1(); +go +~~START~~ +int +11 +~~END~~ + + +-- User has OBJECT and SCHEMA privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t3; +go +~~START~~ +int +~~END~~ + + +select * from grant_schema_s1.grant_schema_v2; +go +~~START~~ +int +2 +~~END~~ + + +exec grant_schema_s1.grant_schema_p2; +go +~~START~~ +int +2 +~~END~~ + + +select * from grant_schema_s1.grant_schema_f2(); +go +~~START~~ +int +11 +~~END~~ + + +-- tsql +-- Case 6: User has SCHEMA privilege, REVOKE OBJECT privilege +use grant_schema_d1; +go +revoke select on grant_schema_s1.grant_schema_t3 from grant_schema_u1; +go +revoke select on grant_schema_s1.grant_schema_v2 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_p2 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_f2 from grant_schema_u1; +go + +-- tsql user=grant_schema_l1 password=12345678 +-- User has SCHEMA privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t3; +go +~~START~~ +int +~~END~~ + + +select * from grant_schema_s1.grant_schema_v2; +go +~~START~~ +int +2 +~~END~~ + + +exec grant_schema_s1.grant_schema_p2; +go +~~START~~ +int +2 +~~END~~ + + +select * from grant_schema_s1.grant_schema_f2(); +go +~~START~~ +int +11 +~~END~~ + + +-- tsql +-- User has OBJECT privilege, REVOKE OBJECT privilege +-- case 7: User has no privileges, should not be accessible. +use grant_schema_d1; +go +revoke select on grant_schema_s2.grant_schema_t2 from grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +use grant_schema_d1; +go + +select * from grant_schema_s2.grant_schema_t2; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table grant_schema_t2)~~ + + +-- tsql +-- User has OBJECT privilege, REVOKE SCHEMA privilege +-- case 8: User has OBJECT privileges, would not be accessible. +use grant_schema_d1; +go +revoke select on schema::grant_schema_s2 from grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +use grant_schema_d1; +go + +select * from grant_schema_s2.grant_schema_t1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table grant_schema_t1)~~ + + +-- tsql +-- User has OBJECT privilege, GRANT and REVOKE SCHEMA privilege +-- case 5: User has OBJECT privileges, would not be accessible. +use grant_schema_d1; +go +grant select on schema::grant_schema_s2 to grant_schema_u1; +go + +revoke select on schema::grant_schema_s2 from grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +use grant_schema_d1; +go + +select * from grant_schema_s2.grant_schema_t1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table grant_schema_t1)~~ + + diff --git a/test/JDBC/expected/GRANT_SCHEMA.out b/test/JDBC/expected/GRANT_SCHEMA.out new file mode 100644 index 0000000000..efa0a7e428 --- /dev/null +++ b/test/JDBC/expected/GRANT_SCHEMA.out @@ -0,0 +1,631 @@ +-- tsql +-- create objects +create database babel_4344_d1; +go + +use babel_4344_d1; +go + +create login babel_4344_l1 with password = '12345678' +go + +create user babel_4344_u1 for login babel_4344_l1; +go + +create schema babel_4344_s1; +go + +create schema babel_4344_s2 authorization babel_4344_u1; +go + +create table babel_4344_t1(a int); +go + +create table babel_4344_s1.babel_4344_t1(a int); +go + +create table babel_4344_s2.babel_4344_t1(a int); +go + +create table babel_4344_t3(a int, b int); +go + +create table babel_4344_s1.babel_4344_t3(a int, b int); +go + +create view babel_4344_v1 as select 1; +go + +create view babel_4344_s1.babel_4344_v1 as select 2; +go + +create proc babel_4344_p1 as select 1; +go + +create proc babel_4344_s1.babel_4344_p1 as select 2; +go + +CREATE FUNCTION babel_4344_f1() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.tables) END +go + +CREATE FUNCTION babel_4344_s1.babel_4344_f1() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go + +-- tsql user=babel_4344_l1 password=12345678 +use babel_4344_d1; +go + +-- User doesn't have any privileges, objects should not be accessible +select * from babel_4344_t1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t1)~~ + +select * from babel_4344_s1.babel_4344_t1 +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t1)~~ + +insert into babel_4344_s1.babel_4344_t1 values(1); +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t1)~~ + +select * from babel_4344_v1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_4344_v1)~~ + +select * from babel_4344_s1.babel_4344_v1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_4344_v1)~~ + +exec babel_4344_p1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_4344_p1)~~ + +exec babel_4344_s1.babel_4344_p1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_4344_p1)~~ + +select * from babel_4344_f1(); +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_4344_f1)~~ + +select * from babel_4344_s1.babel_4344_f1(); +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_4344_f1)~~ + +use master; +go + +-- tsql +-- GRANT OBJECT privilege +use babel_4344_d1; +go +grant select on babel_4344_t1 to babel_4344_u1; +go +grant select on babel_4344_s1.babel_4344_t1 to babel_4344_u1; +go +grant all on babel_4344_s1.babel_4344_t1 to babel_4344_u1; +go +grant select on babel_4344_t3(a) to babel_4344_u1; -- column privilege +go +grant select on babel_4344_s1.babel_4344_t3(a) to babel_4344_u1; -- column privilege +go +grant select on babel_4344_v1 to babel_4344_u1; +go +grant select on babel_4344_s1.babel_4344_v1 to babel_4344_u1; +go +grant execute on babel_4344_p1 to babel_4344_u1; +go +grant execute on babel_4344_s1.babel_4344_p1 to babel_4344_u1; +go +grant execute on babel_4344_f1 to babel_4344_u1; +go +grant execute on babel_4344_s1.babel_4344_f1 to babel_4344_u1; +go +-- Grant schema permission to its owner, should fail +grant select on schema::babel_4344_s2 to babel_4344_u1; -- should fail +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny, or revoke permissions to sa, dbo, entity owner, information_schema, sys, or yourself.)~~ + +grant select on schema::babel_4344_s2 to jdbc_user; -- should fail +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny, or revoke permissions to sa, dbo, entity owner, information_schema, sys, or yourself.)~~ + +grant select on schema::babel_4344_s2 to guest; -- should pass +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has OBJECT privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_t1; +go +~~START~~ +int +~~END~~ + +select * from babel_4344_s1.babel_4344_t1 +go +~~START~~ +int +~~END~~ + +insert into babel_4344_s1.babel_4344_t1 values(2); +go +~~ROW COUNT: 1~~ + +select * from babel_4344_t3; -- not accessible, only column privilege is granted +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t3)~~ + +select * from babel_4344_s1.babel_4344_t3 -- not accessible, only column privilege is granted +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t3)~~ + +select * from babel_4344_v1; +go +~~START~~ +int +1 +~~END~~ + +select * from babel_4344_s1.babel_4344_v1; +go +~~START~~ +int +2 +~~END~~ + +exec babel_4344_p1; +go +~~START~~ +int +1 +~~END~~ + +exec babel_4344_s1.babel_4344_p1; +go +~~START~~ +int +2 +~~END~~ + +select * from babel_4344_f1(); +go +~~START~~ +int +3 +~~END~~ + +select * from babel_4344_s1.babel_4344_f1(); +go +~~START~~ +int +9 +~~END~~ + +-- Grant schema permission to its owner +grant select on schema::babel_4344_s2 to babel_4344_u1; -- should fail +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny, or revoke permissions to sa, dbo, entity owner, information_schema, sys, or yourself.)~~ + +grant select on schema::babel_4344_s2 to guest; -- should pass +go +grant select on schema::babel_4344_s1 to babel_4344_u1; -- should fail +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the schema "babel_4344_s1", because it does not exist or you do not have permission.)~~ + +use master; +go + +-- tsql +-- GRANT SCHEMA privilege +use babel_4344_d1; +go +grant select, insert, execute on schema::babel_4344_s1 to babel_4344_u1; +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has OBJECT and SCHEMA privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1 +go +~~START~~ +int +2 +~~END~~ + +insert into babel_4344_s1.babel_4344_t1 values(3); +go +~~ROW COUNT: 1~~ + +select * from babel_4344_s1.babel_4344_t3 +go +~~START~~ +int#!#int +~~END~~ + +select * from babel_4344_s1.babel_4344_v1; +go +~~START~~ +int +2 +~~END~~ + +exec babel_4344_s1.babel_4344_p1; +go +~~START~~ +int +2 +~~END~~ + +select * from babel_4344_s1.babel_4344_f1(); +go +~~START~~ +int +10 +~~END~~ + +use master; +go + +-- tsql +-- REVOKE SCHEMA privilege +use babel_4344_d1; +go +revoke select, insert, execute on schema::babel_4344_s1 from babel_4344_u1; +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has OBJECT privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1 +go +~~START~~ +int +2 +3 +~~END~~ + +insert into babel_4344_s1.babel_4344_t1 values(3); +go +~~ROW COUNT: 1~~ + +select * from babel_4344_s1.babel_4344_t3 -- not accessible +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t3)~~ + +select * from babel_4344_s1.babel_4344_v1; +go +~~START~~ +int +2 +~~END~~ + +exec babel_4344_s1.babel_4344_p1; -- TODO: should be accessible +go +~~START~~ +int +2 +~~END~~ + +select * from babel_4344_s1.babel_4344_f1(); -- TODO: should be accessible +go +~~START~~ +int +9 +~~END~~ + +select * from babel_4344_s2.babel_4344_t1; +go +~~START~~ +int +~~END~~ + +use master; +go + +-- tsql +-- create new objects in same schema +use babel_4344_d1; +go +-- Grant the permissions again +grant select, insert, execute on schema::babel_4344_s1 to babel_4344_u1; +go +create table babel_4344_s1.babel_4344_t2(a int); +go +create view babel_4344_s1.babel_4344_v2 as select 2; +go +create proc babel_4344_s1.babel_4344_p2 as select 2; +go +CREATE FUNCTION babel_4344_s1.babel_4344_f2() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has SCHEMA privileges,objects should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t2 +go +~~START~~ +int +~~END~~ + +insert into babel_4344_s1.babel_4344_t1 values(4); +go +~~ROW COUNT: 1~~ + +select * from babel_4344_s1.babel_4344_v2; +go +~~START~~ +int +2 +~~END~~ + +exec babel_4344_s1.babel_4344_p2; +go +~~START~~ +int +2 +~~END~~ + +select * from babel_4344_s1.babel_4344_f2(); +go +~~START~~ +int +14 +~~END~~ + +use master; +go + +-- tsql +-- REVOKE OBJECT privileges +use babel_4344_d1; +go +REVOKE all on babel_4344_s1.babel_4344_t1 FROM babel_4344_u1; +go +REVOKE select on babel_4344_s1.babel_4344_t3(a) FROM babel_4344_u1; +go +REVOKE select on babel_4344_s1.babel_4344_v1 FROM babel_4344_u1; +go +REVOKE execute on babel_4344_s1.babel_4344_p1 FROM babel_4344_u1; +go +REVOKE execute on babel_4344_s1.babel_4344_f1 FROM babel_4344_u1; +go +REVOKE all on babel_4344_s1.babel_4344_f1 FROM babel_4344_u1; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has SCHEMA privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1 +go +~~START~~ +int +2 +3 +3 +4 +~~END~~ + +insert into babel_4344_s1.babel_4344_t1 values(5); +go +~~ROW COUNT: 1~~ + +select * from babel_4344_s1.babel_4344_t3; +go +~~START~~ +int#!#int +~~END~~ + +select * from babel_4344_s1.babel_4344_v1; +go +~~START~~ +int +2 +~~END~~ + +exec babel_4344_s1.babel_4344_p1; +go +~~START~~ +int +2 +~~END~~ + +select * from babel_4344_s1.babel_4344_f1(); +go +~~START~~ +int +14 +~~END~~ + +select * from babel_4344_s2.babel_4344_t1; +go +~~START~~ +int +~~END~~ + +use master; +go + +-- tsql +-- REVOKE SCHEMA privileges +use babel_4344_d1; +go +revoke select, insert, execute on schema::babel_4344_s1 from babel_4344_u1; +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has no privileges, shouldn't be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t1)~~ + +insert into babel_4344_s1.babel_4344_t1 values(5); +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t1)~~ + +select * from babel_4344_s1.babel_4344_t3; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_4344_t3)~~ + +select * from babel_4344_s1.babel_4344_v1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_4344_v1)~~ + +exec babel_4344_s1.babel_4344_p1; +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_4344_p1)~~ + +select * from babel_4344_s1.babel_4344_f1(); +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_4344_f1)~~ + +use master; +go + +-- tsql +-- Drop objects +use babel_4344_d1; +go + +drop table babel_4344_t1; +go + +drop table babel_4344_s1.babel_4344_t1; +go + +drop table babel_4344_t3; +go + +drop table babel_4344_s1.babel_4344_t3; +go + +drop table babel_4344_s1.babel_4344_t2; +go + +drop view babel_4344_v1; +go + +drop view babel_4344_s1.babel_4344_v1; +go + +drop view babel_4344_s1.babel_4344_v2; +go + +drop proc babel_4344_p1; +go + +drop proc babel_4344_s1.babel_4344_p1; +go + +drop proc babel_4344_s1.babel_4344_p2; +go + +drop function babel_4344_f1; +go + +drop function babel_4344_s1.babel_4344_f1; +go + +drop function babel_4344_s1.babel_4344_f2; +go + +drop schema babel_4344_s1; +go + +drop table babel_4344_s2.babel_4344_t1; +go + +drop schema babel_4344_s2; +go + +drop user babel_4344_u1; +go + +use master; +go + +drop database babel_4344_d1; +go + +-- psql +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'babel_4344_l1' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +go +~~START~~ +bool +t +~~END~~ + + +-- Wait to sync with another session +SELECT pg_sleep(1); +go +~~START~~ +void + +~~END~~ + + +-- tsql +drop login babel_4344_l1; +go diff --git a/test/JDBC/expected/babel_datatype_sqlvariant-vu-cleanup.out b/test/JDBC/expected/babel_datatype_sqlvariant-vu-cleanup.out index afb26036de..8ae54e1a03 100644 --- a/test/JDBC/expected/babel_datatype_sqlvariant-vu-cleanup.out +++ b/test/JDBC/expected/babel_datatype_sqlvariant-vu-cleanup.out @@ -5,6 +5,8 @@ drop table babel_datatype_sqlvariant_vu_prepare_t2; go drop table babel_datatype_sqlvariant_vu_prepare_t3; go +drop table babel_datatype_sqlvariant_vu_prepare_t4; +go drop table babel_datatype_sqlvariant_vu_prepare_t5; go drop table babel_datatype_sqlvariant_vu_prepare_t6; @@ -25,9 +27,5 @@ drop sequence babel_datatype_sqlvariant_vu_prepare_t2_sec; go drop sequence babel_datatype_sqlvariant_vu_prepare_t4_sec; go -~~ERROR (Code: 3732)~~ - -~~ERROR (Message: cannot drop sequence babel_datatype_sqlvariant_vu_prepare_t4_sec because other objects depend on it)~~ - drop sequence babel_datatype_sqlvariant_vu_prepare_t5_sec; go diff --git a/test/JDBC/expected/col_length-vu-cleanup.out b/test/JDBC/expected/col_length-vu-cleanup.out index 97b139d464..d6a6590e21 100644 --- a/test/JDBC/expected/col_length-vu-cleanup.out +++ b/test/JDBC/expected/col_length-vu-cleanup.out @@ -60,3 +60,38 @@ DROP FUNCTION IF EXISTS col_length_prepare_f14(); DROP FUNCTION IF EXISTS col_length_prepare_f15(); DROP FUNCTION IF EXISTS col_length_prepare_f16(); GO + +-- Drop types +DROP TYPE IF EXISTS custom_char_10; +DROP TYPE IF EXISTS custom_varchar_20; +DROP TYPE IF EXISTS custom_binary_5; +DROP TYPE IF EXISTS custom_varbinary_15; +DROP TYPE IF EXISTS custom_nchar_8; +DROP TYPE IF EXISTS custom_nvarchar_16; +DROP TYPE IF EXISTS custom_text; +DROP TYPE IF EXISTS custom_image; +DROP TYPE IF EXISTS custom_ntext; +DROP TYPE IF EXISTS custom_sysname; +DROP TYPE IF EXISTS custom_sql_variant; +DROP TYPE IF EXISTS custom_xml; +DROP TYPE IF EXISTS custom_varcharmax; +DROP TYPE IF EXISTS custom_nvarcharmax; +DROP TYPE IF EXISTS custom_varbinarymax; +DROP TYPE IF EXISTS custom_bit; +DROP TYPE IF EXISTS custom_tinyint; +DROP TYPE IF EXISTS custom_bigint; +DROP TYPE IF EXISTS custom_smallint; +DROP TYPE IF EXISTS custom_smallmoney; +DROP TYPE IF EXISTS custom_money; +DROP TYPE IF EXISTS custom_smalldatetime; +DROP TYPE IF EXISTS custom_real; +DROP TYPE IF EXISTS custom_float; +DROP TYPE IF EXISTS custom_time; +DROP TYPE IF EXISTS custom_datetime; +DROP TYPE IF EXISTS custom_datetime2; +DROP TYPE IF EXISTS custom_datetimeoffset; +DROP TYPE IF EXISTS custom_uniqueidentifier; +DROP TYPE IF EXISTS custom_date; +DROP TYPE IF EXISTS custom_decimal_10_5; +DROP TYPE IF EXISTS custom_numeric_3_0; +GO diff --git a/test/JDBC/expected/col_length-vu-prepare.out b/test/JDBC/expected/col_length-vu-prepare.out index d158bba536..e2dcc42408 100644 --- a/test/JDBC/expected/col_length-vu-prepare.out +++ b/test/JDBC/expected/col_length-vu-prepare.out @@ -51,11 +51,140 @@ CREATE TABLE sys_col_length_test_schema.test_table( ); GO -INSERT INTO sys_col_length_test_schema.test_table (col_char, col_varchar, col_varbinary) -VALUES ('ABCDEF', 'Hello, World!', 0x0123456789ABCDEF) +-- for user defined data types +-- Create User-Defined Types +CREATE TYPE custom_char_10 FROM CHAR(10); GO -~~ROW COUNT: 1~~ +CREATE TYPE custom_varchar_20 FROM VARCHAR(20); +GO + +CREATE TYPE custom_binary_5 FROM BINARY(5); +GO + +CREATE TYPE custom_varbinary_15 FROM VARBINARY(15); +GO + +CREATE TYPE custom_nchar_8 FROM NCHAR(8); +GO + +CREATE TYPE custom_nvarchar_16 FROM NVARCHAR(16); +GO + +CREATE TYPE custom_text FROM TEXT; +GO + +CREATE TYPE custom_image FROM IMAGE; +GO + +CREATE TYPE custom_ntext FROM NTEXT; +GO + +CREATE TYPE custom_sysname FROM sysname; +GO + +CREATE TYPE custom_sql_variant FROM SQL_VARIANT; +GO + +CREATE TYPE custom_xml FROM XML; +GO + +CREATE TYPE custom_varcharmax FROM VARCHAR(MAX); +GO + +CREATE TYPE custom_nvarcharmax FROM NVARCHAR(MAX); +GO + +CREATE TYPE custom_varbinarymax FROM VARBINARY(MAX); +GO + +CREATE TYPE custom_bit FROM BIT; +GO + +CREATE TYPE custom_tinyint FROM TINYINT; +GO + +CREATE TYPE custom_bigint FROM BIGINT; +GO + +CREATE TYPE custom_smallint FROM SMALLINT; +GO + +CREATE TYPE custom_smallmoney FROM SMALLMONEY; +GO + +CREATE TYPE custom_money FROM MONEY; +GO + +CREATE TYPE custom_smalldatetime FROM SMALLDATETIME; +GO + +CREATE TYPE custom_real FROM REAL; +GO + +CREATE TYPE custom_float FROM FLOAT; +GO + +CREATE TYPE custom_time FROM TIME; +GO + +CREATE TYPE custom_datetime FROM DATETIME; +GO + +CREATE TYPE custom_datetime2 FROM DATETIME2; +GO + +CREATE TYPE custom_datetimeoffset FROM DATETIMEOFFSET; +GO + +CREATE TYPE custom_uniqueidentifier FROM UNIQUEIDENTIFIER; +GO + +CREATE TYPE custom_date FROM DATE; +GO + +CREATE TYPE custom_decimal_10_5 FROM DECIMAL(10,5); +GO + +CREATE TYPE custom_numeric_3_0 FROM NUMERIC(3,0); +GO + +-- Create Table with User-Defined Data Types +CREATE TABLE udd_test_table ( + col_customchar custom_char_10, + col_customvarchar custom_varchar_20, + col_custombinary custom_binary_5, + col_customvarbinary custom_varbinary_15, + col_customnchar custom_nchar_8, + col_customnvarchar custom_nvarchar_16, + col_customtext custom_text, + col_customimage custom_image, + col_customntext custom_ntext, + col_customsysname custom_sysname, + col_customsqlvariant custom_sql_variant, + col_customxml custom_xml, + col_customvarcharmax custom_varcharmax, + col_customnvarcharmax custom_nvarcharmax, + col_customvarbinarymax custom_varbinarymax, + col_custombit custom_bit, + col_customtinyint custom_tinyint, + col_custombigint custom_bigint, + col_customsmallint custom_smallint, + col_customsmallmoney custom_smallmoney, + col_custommoney custom_money, + col_customsmalldatetime custom_smalldatetime, + col_customreal custom_real, + col_customfloat custom_float, + col_customtime custom_time, + col_customdatetime custom_datetime, + col_customdatetime2 custom_datetime2, + col_customdatetimeoffset custom_datetimeoffset, + col_customuniqueidentifier custom_uniqueidentifier, + col_customdate custom_date, + col_customdecimal custom_decimal_10_5, + col_customnumeric custom_numeric_3_0 +); +GO CREATE VIEW col_length_prepare_v1 AS (SELECT COL_LENGTH('sys_column_length_test_table', 'ID')); GO @@ -120,84 +249,84 @@ CREATE PROCEDURE col_length_prepare_p10 AS (SELECT COL_LENGTH('sys_column_length GO CREATE FUNCTION col_length_prepare_f1() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_xml')); END GO CREATE FUNCTION col_length_prepare_f2() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_varcharmax')); END GO CREATE FUNCTION col_length_prepare_f3() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_nvarcharmax')); END GO CREATE FUNCTION col_length_prepare_f4() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_varbinarymax')); END GO CREATE FUNCTION col_length_prepare_f5() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_bit')); END GO CREATE FUNCTION col_length_prepare_f6() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_tinyint')); END GO CREATE FUNCTION col_length_prepare_f7() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_bigint')); END GO CREATE FUNCTION col_length_prepare_f8() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_smallint')); END GO CREATE FUNCTION col_length_prepare_f9() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_smallmoney')); END GO CREATE FUNCTION col_length_prepare_f10() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_money')); END GO CREATE FUNCTION col_length_prepare_f11() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_smalldatetime')); END GO CREATE FUNCTION col_length_prepare_f12() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_real')); END @@ -205,7 +334,7 @@ GO -- Invalid column, should return NULL CREATE FUNCTION col_length_prepare_f13() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 1)); END @@ -213,7 +342,7 @@ GO -- Invalid column, should return NULL CREATE FUNCTION col_length_prepare_f14() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', -1)); END @@ -221,7 +350,7 @@ GO -- Invalid table, should return NULL CREATE FUNCTION col_length_prepare_f15() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH(NULL, 'col_char')); END @@ -229,7 +358,7 @@ GO -- NULL column, should return NULL CREATE FUNCTION col_length_prepare_f16() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', NULL)); END diff --git a/test/JDBC/expected/col_length-vu-verify.out b/test/JDBC/expected/col_length-vu-verify.out index 9ccf584b7f..a5cae67a16 100644 --- a/test/JDBC/expected/col_length-vu-verify.out +++ b/test/JDBC/expected/col_length-vu-verify.out @@ -164,7 +164,7 @@ smallint SELECT col_length_prepare_f1() GO ~~START~~ -int +smallint -1 ~~END~~ @@ -172,7 +172,7 @@ int SELECT col_length_prepare_f2() GO ~~START~~ -int +smallint -1 ~~END~~ @@ -180,7 +180,7 @@ int SELECT col_length_prepare_f3() GO ~~START~~ -int +smallint -1 ~~END~~ @@ -188,7 +188,7 @@ int SELECT col_length_prepare_f4() GO ~~START~~ -int +smallint -1 ~~END~~ @@ -196,7 +196,7 @@ int SELECT col_length_prepare_f5() GO ~~START~~ -int +smallint 1 ~~END~~ @@ -204,7 +204,7 @@ int SELECT col_length_prepare_f6() GO ~~START~~ -int +smallint 1 ~~END~~ @@ -212,7 +212,7 @@ int SELECT col_length_prepare_f7() GO ~~START~~ -int +smallint 8 ~~END~~ @@ -220,7 +220,7 @@ int SELECT col_length_prepare_f8() GO ~~START~~ -int +smallint 2 ~~END~~ @@ -228,7 +228,7 @@ int SELECT col_length_prepare_f9() GO ~~START~~ -int +smallint 4 ~~END~~ @@ -236,7 +236,7 @@ int SELECT col_length_prepare_f10() GO ~~START~~ -int +smallint 8 ~~END~~ @@ -244,7 +244,7 @@ int SELECT col_length_prepare_f11() GO ~~START~~ -int +smallint 4 ~~END~~ @@ -252,7 +252,7 @@ int SELECT col_length_prepare_f12() GO ~~START~~ -int +smallint 4 ~~END~~ @@ -260,7 +260,7 @@ int SELECT col_length_prepare_f13() GO ~~START~~ -int +smallint ~~END~~ @@ -268,7 +268,7 @@ int SELECT col_length_prepare_f14() GO ~~START~~ -int +smallint ~~END~~ @@ -276,7 +276,7 @@ int SELECT col_length_prepare_f15() GO ~~START~~ -int +smallint ~~END~~ @@ -284,7 +284,7 @@ int SELECT col_length_prepare_f16() GO ~~START~~ -int +smallint ~~END~~ @@ -453,3 +453,259 @@ SQL Variant Column ~~END~~ +-- Test Cases for User-Defined Data Types +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customchar'); +GO +~~START~~ +smallint +10 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarchar'); +GO +~~START~~ +smallint +20 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custombinary'); +GO +~~START~~ +smallint +5 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarbinary'); +GO +~~START~~ +smallint +15 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnchar'); +GO +~~START~~ +smallint +16 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnvarchar'); +GO +~~START~~ +smallint +32 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customtext'); +GO +~~START~~ +smallint +16 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customimage'); +GO +~~START~~ +smallint +16 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customntext'); +GO +~~START~~ +smallint +16 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsysname'); +GO +~~START~~ +smallint +256 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsqlvariant'); +GO +~~START~~ +smallint +8016 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customxml'); +GO +~~START~~ +smallint +-1 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarcharmax'); +GO +~~START~~ +smallint +-1 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnvarcharmax'); +GO +~~START~~ +smallint +-1 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarbinarymax'); +GO +~~START~~ +smallint +-1 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custombit'); +GO +~~START~~ +smallint +1 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customtinyint'); +GO +~~START~~ +smallint +1 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custombigint'); +GO +~~START~~ +smallint +8 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsmallint'); +GO +~~START~~ +smallint +2 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsmallmoney'); +GO +~~START~~ +smallint +4 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custommoney'); +GO +~~START~~ +smallint +8 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsmalldatetime'); +GO +~~START~~ +smallint +4 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customreal'); +GO +~~START~~ +smallint +4 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customfloat'); +GO +~~START~~ +smallint +8 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customtime'); +GO +~~START~~ +smallint +5 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdatetime'); +GO +~~START~~ +smallint +8 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdatetime2'); +GO +~~START~~ +smallint +8 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdatetimeoffset'); +GO +~~START~~ +smallint +10 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customuniqueidentifier'); +GO +~~START~~ +smallint +16 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdate'); +GO +~~START~~ +smallint +3 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdecimal'); +GO +~~START~~ +smallint +9 +~~END~~ + + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnumeric'); +GO +~~START~~ +smallint +5 +~~END~~ + diff --git a/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..4d1247a5c1 --- /dev/null +++ b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,63 @@ +-- FOR JSON PATH clause without nested support +DROP VIEW forjson_vu_v_people +GO + +DROP VIEW forjson_vu_v_countries +GO + +-- Multiple tables without nested support +DROP VIEW forjson_vu_v_join +GO + +-- ROOT directive without specifying value +DROP VIEW forjson_vu_v_root +GO + +-- ROOT directive with specifying ROOT value +DROP VIEW forjson_vu_v_root_value +GO + +-- ROOT directive with specifying ROOT value with empty string +DROP VIEW forjson_vu_v_empty_root +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +DROP VIEW forjson_vu_v_without_array_wrapper +GO + +-- INCLUDE_NULL_VALUES directive +DROP VIEW forjson_vu_v_include_null_values +GO + +-- Multiple Directives +DROP VIEW forjson_vu_v_root_include_null_values +GO + +DROP VIEW forjson_vu_v_without_array_wrapper_include_null_values +GO + + +-- Test case with parameters +DROP PROCEDURE forjson_vu_p_params1 +GO + +DROP PROCEDURE forjson_vu_p_params2 +GO + +-- All null values test +DROP VIEW forjson_vu_v_nulls +GO + +-- Test for all parser rules +DROP VIEW forjson_vu_v_order_by +GO + +-- Display Table Contents +DROP TABLE forjson_vu_t_people +GO + +DROP TABLE forjson_vu_t_countries +GO + +DROP TABLE forjson_vu_t_values +GO diff --git a/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..486838fe84 --- /dev/null +++ b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,208 @@ +CREATE TABLE forjson_vu_t_people ( +[Id] INT, +[FirstName] VARCHAR(25), +[LastName] VARCHAR(25), +[State] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_people values +(1,'Divya','Kumar',NULL), +(2,NULL,'Khanna','Bengaluru'), +(3,'Tom','Mehta','Kolkata'), +(4,'Kane',NULL,'Delhi') +GO +~~ROW COUNT: 4~~ + + +CREATE TABLE forjson_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO +~~ROW COUNT: 5~~ + + +CREATE TABLE forjson_vu_t_values ( +[Id] INT, +[value] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_values values +(1,NULL), +(2,NULL), +(3,NULL) +GO +~~ROW COUNT: 3~~ + + +-- FOR JSON PATH clause without nested support +CREATE VIEW forjson_vu_v_people AS +SELECT ( + SELECT Id AS EmpId, + FirstName AS "Name.FirstName", + LastName AS "Name.LastName", + State + FROM forjson_vu_t_people + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_vu_v_countries AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH +) c1 +GO + +-- Multiple tables without nested support +CREATE VIEW forjson_vu_v_join AS +SELECT ( + SELECT E.FirstName AS 'Person.Name', + E.LastName AS 'Person.Surname', + D.Age AS 'Employee.Price', + D.Country AS 'Employee.Quantity' + FROM forjson_vu_t_people E + INNER JOIN forjson_vu_t_countries D + ON E.Id = D.Id + FOR JSON PATH +) c1 +GO + +-- ROOT directive without specifying value +CREATE VIEW forjson_vu_v_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT +) c1 +GO + +-- ROOT directive with specifying ROOT value +CREATE VIEW forjson_vu_v_root_value AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('Employee') +) c1 +GO + +-- ROOT directive with specifying ROOT value with empty string +CREATE VIEW forjson_vu_v_empty_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('') +) c1 +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +CREATE VIEW forjson_vu_v_without_array_wrapper AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER +) c1 +GO + +-- INCLUDE_NULL_VALUES directive +CREATE VIEW forjson_vu_v_include_null_values AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, INCLUDE_NULL_VALUES +) c1 +GO + +-- Multiple Directives +CREATE VIEW forjson_vu_v_root_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT('Employee'), INCLUDE_NULL_VALUES +) c1 +GO + +CREATE VIEW forjson_vu_v_without_array_wrapper_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER, INCLUDE_NULL_VALUES +) c1 +GO + +-- Throws error as ROOT and WITHOUT_ARRAY_WRAPPER cannot be used together +CREATE VIEW forjson_vu_v_root_and_without_array_wrapper AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT, WITHOUT_ARRAY_WRAPPER +) c1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: ROOT option and WITHOUT_ARRAY_WRAPPER option cannot be used together in FOR JSON. Remove one of these options)~~ + + +-- Test case with parameters +CREATE PROCEDURE forjson_vu_p_params1 @id int AS +SELECT ( + SELECT Firstname AS [Name], + State + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_params2 @id int AS +SELECT ( + SELECT Firstname AS [nam"@e], + State AS [State"@] + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +-- All null values test +CREATE VIEW forjson_vu_v_nulls AS +SELECT ( + SELECT value + FROM forjson_vu_t_values + FOR JSON PATH +) c1 +GO + +-- Test for all parser rules +CREATE VIEW forjson_vu_v_order_by AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + ORDER BY Age + FOR JSON PATH +) C1 +GO diff --git a/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..9b5f226477 --- /dev/null +++ b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,157 @@ +-- Display Table Contents +SELECT * FROM forjson_vu_t_people +GO +~~START~~ +int#!#varchar#!#varchar#!#varchar +1#!#Divya#!#Kumar#!# +2#!##!#Khanna#!#Bengaluru +3#!#Tom#!#Mehta#!#Kolkata +4#!#Kane#!##!#Delhi +~~END~~ + + +SELECT * FROM forjson_vu_t_countries +GO +~~START~~ +int#!#int#!#varchar +1#!#25#!#India +2#!#40#!#USA +3#!#30#!#India +4#!#20#!# +5#!#10#!#USA +~~END~~ + + +SELECT * FROM forjson_vu_t_values +GO +~~START~~ +int#!#varchar +1#!# +2#!# +3#!# +~~END~~ + + +-- FOR JSON PATH clause without nested support +SELECT * FROM forjson_vu_v_people +GO +~~START~~ +nvarchar +[{"EmpId":1,"Name.FirstName":"Divya","Name.LastName":"Kumar"},{"EmpId":2,"Name.LastName":"Khanna","State":"Bengaluru"},{"EmpId":3,"Name.FirstName":"Tom","Name.LastName":"Mehta","State":"Kolkata"},{"EmpId":4,"Name.FirstName":"Kane","State":"Delhi"}] +~~END~~ + + +SELECT * FROM forjson_vu_v_countries +GO +~~START~~ +nvarchar +[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20},{"Id":5,"Age":10,"Country":"USA"}] +~~END~~ + + +-- Multiple tables without nested support +SELECT * FROM forjson_vu_v_join +GO +~~START~~ +nvarchar +[{"Person.Name":"Divya","Person.Surname":"Kumar","Employee.Price":25,"Employee.Quantity":"India"},{"Person.Surname":"Khanna","Employee.Price":40,"Employee.Quantity":"USA"},{"Person.Name":"Tom","Person.Surname":"Mehta","Employee.Price":30,"Employee.Quantity":"India"},{"Person.Name":"Kane","Employee.Price":20}] +~~END~~ + + +-- ROOT directive without specifying value +SELECT * FROM forjson_vu_v_root +GO +~~START~~ +nvarchar +{"root":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +~~END~~ + + +-- ROOT directive with specifying ROOT value +SELECT * FROM forjson_vu_v_root_value +GO +~~START~~ +nvarchar +{"Employee":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +~~END~~ + + +-- ROOT directive with specifying ROOT value with empty string +SELECT * FROM forjson_vu_v_empty_root +GO +~~START~~ +nvarchar +{"":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +~~END~~ + + +-- WITHOUT_ARRAY_WRAPPERS directive +SELECT * FROM forjson_vu_v_without_array_wrapper +GO +~~START~~ +nvarchar +{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"} +~~END~~ + + +-- INCLUDE_NULL_VALUES directive +SELECT * FROM forjson_vu_v_include_null_values +GO +~~START~~ +nvarchar +[{"FirstName":"Divya","LastName":"Kumar"},{"FirstName":null,"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane","LastName":null}] +~~END~~ + + +-- Multiple Directives +SELECT * FROM forjson_vu_v_root_include_null_values +GO +~~START~~ +nvarchar +{"Employee":[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"}]} +~~END~~ + + +SELECT * FROM forjson_vu_v_without_array_wrapper_include_null_values +GO +~~START~~ +nvarchar +{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"} +~~END~~ + + + +-- Test case with parameters +EXECUTE forjson_vu_p_params1 @id = 2 +GO +~~START~~ +nvarchar +[{"State": "Bengaluru"}] +~~END~~ + + +EXECUTE forjson_vu_p_params2 @id = 3 +GO +~~START~~ +nvarchar +[{"nam\"@e": "Tom", "State\"@": "Kolkata"}] +~~END~~ + + +-- All null values test +SELECT * FROM forjson_vu_v_nulls +GO +~~START~~ +nvarchar +[{},{},{}] +~~END~~ + + +-- Test for all parser rules +SELECT * FROM forjson_vu_v_order_by +GO +~~START~~ +nvarchar +[{"Id":5,"Age":10,"Country":"USA"},{"Id":4,"Age":20},{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +~~END~~ + diff --git a/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..859f23a74e --- /dev/null +++ b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,74 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +DROP VIEW forjson_datatypes_vu_v_numerics +GO + +DROP VIEW forjson_datatypes_vu_v_bit +GO + +DROP VIEW forjson_datatypes_vu_v_money +GO + +DROP VIEW forjson_datatypes_vu_v_smallmoney +GO + +-- Approximate numerics +DROP VIEW forjson_datatypes_vu_v_approx_numerics +GO + +-- Date and time +DROP VIEW forjson_datatypes_vu_v_time_date +GO + +DROP VIEW forjson_datatypes_vu_v_smalldatetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime2 +GO + +DROP VIEW forjson_datatypes_vu_v_datetimeoffset +GO + +-- Character strings +DROP VIEW forjson_datatypes_vu_v_strings +GO + +-- Unicode character strings +DROP VIEW forjson_datatypes_vu_v_unicode_strings +GO + +-- NULL datetimes +DROP VIEW forjson_datatypes_vu_v_nulldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nullsmalldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetime2; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetimeoffset; +go + +-- DROP TABLE +DROP TABLE forjson_datatypes_vu_t_exact_numerics +GO + +-- Approximate numerics +DROP TABLE forjson_datatypes_vu_t_approx_numerics +GO + +-- Date and time +DROP TABLE forjson_datatypes_vu_t_date_and_time +GO + +-- Character strings +DROP TABLE forjson_datatypes_vu_t_strings +GO + +-- Unicode character strings +DROP TABLE forjson_datatypes_vu_t_unicode_strings +GO diff --git a/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..0f84cd53da --- /dev/null +++ b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,182 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +CREATE TABLE forjson_datatypes_vu_t_exact_numerics(abigint bigint, abit bit, adecimal decimal, aint int, amoney money, anumeric numeric, asmallint smallint, asmallmoney smallmoney, atinyint tinyint) +GO +INSERT forjson_datatypes_vu_t_exact_numerics VALUES(9223372036854775807, 1, 123.2, 2147483647, 3148.29, 12345.12, 32767, 3148.29, 255) +GO +~~ROW COUNT: 1~~ + + +-- Approximate numerics +CREATE TABLE forjson_datatypes_vu_t_approx_numerics(afloat float, areal real) +GO +INSERT forjson_datatypes_vu_t_approx_numerics VALUES(12.05, 120.53) +GO +~~ROW COUNT: 1~~ + + +-- Date and time +CREATE TABLE forjson_datatypes_vu_t_date_and_time(atime time, adate date, asmalldatetime smalldatetime, adatetime datetime, adatetime2 datetime2, adatetimeoffset datetimeoffset, adatetimeoffset_2 datetimeoffset) +GO +INSERT forjson_datatypes_vu_t_date_and_time VALUES('2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560', '2012-10-12 12:34:56 +02:30') +GO +~~ROW COUNT: 1~~ + + +-- Character strings +CREATE TABLE forjson_datatypes_vu_t_strings(achar char, avarchar varchar(3), atext text) +GO +INSERT forjson_datatypes_vu_t_strings VALUES('a','abc','abc') +GO +~~ROW COUNT: 1~~ + + +-- Unicode character strings +CREATE TABLE forjson_datatypes_vu_t_unicode_strings(anchar nchar(5), anvarchar nvarchar(5), antext ntext) +GO +INSERT forjson_datatypes_vu_t_unicode_strings VALUES('abc','abc','abc') +GO +~~ROW COUNT: 1~~ + + +-- T-SQL does not allow raw scalars as the output of a view, so surround the FOR JSON call with a SELECT to avoid a syntax error +-- Exact Numerics +CREATE VIEW forjson_datatypes_vu_v_numerics AS +SELECT +( + SELECT abigint, adecimal, aint, anumeric, asmallint, atinyint + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_bit AS +SELECT +( + SELECT abit + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_money AS +SELECT +( + SELECT amoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smallmoney AS +SELECT +( + SELECT asmallmoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +-- Approximate numerics +CREATE VIEW forjson_datatypes_vu_v_approx_numerics AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_approx_numerics + FOR JSON PATH +) as c1; +GO + +-- Date and time +CREATE VIEW forjson_datatypes_vu_v_time_date AS +SELECT +( + SELECT atime,adate + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smalldatetime AS +SELECT +( + SELECT asmalldatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime AS +SELECT +( + SELECT adatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime2 AS +SELECT +( + SELECT adatetime2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetimeoffset AS +SELECT +( + SELECT adatetimeoffset, adatetimeoffset_2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +-- Character strings +CREATE VIEW forjson_datatypes_vu_v_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_strings + FOR JSON PATH +) as c1; +GO + +-- Unicode character strings +CREATE VIEW forjson_datatypes_vu_v_unicode_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_unicode_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime AS +SELECT +( + select cast(null as datetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nullsmalldatetime AS +SELECT +( + select cast(null as smalldatetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime2 AS +SELECT +( + select cast(null as datetime2) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetimeoffset AS +SELECT +( + select cast(null as datetimeoffset) for JSON PATH +) as c1; +GO diff --git a/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..81d555646a --- /dev/null +++ b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,135 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +SELECT * FROM forjson_datatypes_vu_v_numerics +GO +~~START~~ +nvarchar +[{"abigint":9223372036854775807,"adecimal":123,"aint":2147483647,"anumeric":12345,"asmallint":32767,"atinyint":255}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_bit +GO +~~START~~ +nvarchar +[{"abit":true}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_money +GO +~~START~~ +nvarchar +[{"amoney":3148.2900}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_smallmoney +GO +~~START~~ +nvarchar +[{"asmallmoney":3148.2900}] +~~END~~ + + +-- Approximate numerics +SELECT * FROM forjson_datatypes_vu_v_approx_numerics +GO +~~START~~ +nvarchar +[{"afloat":12.05,"areal":120.53}] +~~END~~ + + +-- Date and time +SELECT * FROM forjson_datatypes_vu_v_time_date +GO +~~START~~ +nvarchar +[{"atime":"23:17:08.56","adate":"2022-11-11"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_smalldatetime +GO +~~START~~ +nvarchar +[{"asmalldatetime":"2022-11-11T23:17:00"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_datetime +GO +~~START~~ +nvarchar +[{"adatetime":"2022-11-11T23:17:08.56"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_datetime2 +GO +~~START~~ +nvarchar +[{"adatetime2":"2022-11-11T23:17:08.56"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_datetimeoffset +GO +~~START~~ +nvarchar +[{"adatetimeoffset":"2022-11-11T23:17:08.56Z","adatetimeoffset_2":"2012-10-12T12:34:56+02:30"}] +~~END~~ + + +-- Character strings +SELECT * FROM forjson_datatypes_vu_v_strings +GO +~~START~~ +nvarchar +[{"achar":"a","avarchar":"abc","atext":"abc"}] +~~END~~ + + +-- Unicode character strings +SELECT * FROM forjson_datatypes_vu_v_unicode_strings +GO +~~START~~ +nvarchar +[{"anchar":"abc ","anvarchar":"abc","antext":"abc"}] +~~END~~ + + + +-- NULL datetime and datetimeoffset +SELECT * FROM forjson_datatypes_vu_v_nulldatetime +GO +~~START~~ +nvarchar +[{}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_nullsmalldatetime +GO +~~START~~ +nvarchar +[{}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_nulldatetime2 +GO +~~START~~ +nvarchar +[{}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_nulldatetimeoffset +GO +~~START~~ +nvarchar +[{}] +~~END~~ + diff --git a/test/JDBC/expected/forjson-datatypes-vu-verify.out b/test/JDBC/expected/forjson-datatypes-vu-verify.out index 81d555646a..425eef8bbf 100644 --- a/test/JDBC/expected/forjson-datatypes-vu-verify.out +++ b/test/JDBC/expected/forjson-datatypes-vu-verify.out @@ -4,7 +4,7 @@ SELECT * FROM forjson_datatypes_vu_v_numerics GO ~~START~~ nvarchar -[{"abigint":9223372036854775807,"adecimal":123,"aint":2147483647,"anumeric":12345,"asmallint":32767,"atinyint":255}] +[{"abigint": 9223372036854775807, "adecimal": 123, "aint": 2147483647, "anumeric": 12345, "asmallint": 32767, "atinyint": 255}] ~~END~~ @@ -12,7 +12,7 @@ SELECT * FROM forjson_datatypes_vu_v_bit GO ~~START~~ nvarchar -[{"abit":true}] +[{"abit": true}] ~~END~~ @@ -20,7 +20,7 @@ SELECT * FROM forjson_datatypes_vu_v_money GO ~~START~~ nvarchar -[{"amoney":3148.2900}] +[{"amoney": 3148.2900}] ~~END~~ @@ -28,7 +28,7 @@ SELECT * FROM forjson_datatypes_vu_v_smallmoney GO ~~START~~ nvarchar -[{"asmallmoney":3148.2900}] +[{"asmallmoney": 3148.2900}] ~~END~~ @@ -37,7 +37,7 @@ SELECT * FROM forjson_datatypes_vu_v_approx_numerics GO ~~START~~ nvarchar -[{"afloat":12.05,"areal":120.53}] +[{"afloat": 12.05, "areal": 120.53}] ~~END~~ @@ -46,7 +46,7 @@ SELECT * FROM forjson_datatypes_vu_v_time_date GO ~~START~~ nvarchar -[{"atime":"23:17:08.56","adate":"2022-11-11"}] +[{"atime": "23:17:08.56", "adate": "2022-11-11"}] ~~END~~ @@ -54,7 +54,7 @@ SELECT * FROM forjson_datatypes_vu_v_smalldatetime GO ~~START~~ nvarchar -[{"asmalldatetime":"2022-11-11T23:17:00"}] +[{"asmalldatetime": "2022-11-11T23:17:00"}] ~~END~~ @@ -62,7 +62,7 @@ SELECT * FROM forjson_datatypes_vu_v_datetime GO ~~START~~ nvarchar -[{"adatetime":"2022-11-11T23:17:08.56"}] +[{"adatetime": "2022-11-11T23:17:08.56"}] ~~END~~ @@ -70,7 +70,7 @@ SELECT * FROM forjson_datatypes_vu_v_datetime2 GO ~~START~~ nvarchar -[{"adatetime2":"2022-11-11T23:17:08.56"}] +[{"adatetime2": "2022-11-11T23:17:08.56"}] ~~END~~ @@ -78,7 +78,7 @@ SELECT * FROM forjson_datatypes_vu_v_datetimeoffset GO ~~START~~ nvarchar -[{"adatetimeoffset":"2022-11-11T23:17:08.56Z","adatetimeoffset_2":"2012-10-12T12:34:56+02:30"}] +[{"adatetimeoffset": "2022-11-11T23:17:08.56Z", "adatetimeoffset_2": "2012-10-12T12:34:56+02:30"}] ~~END~~ @@ -87,7 +87,7 @@ SELECT * FROM forjson_datatypes_vu_v_strings GO ~~START~~ nvarchar -[{"achar":"a","avarchar":"abc","atext":"abc"}] +[{"achar": "a", "avarchar": "abc", "atext": "abc"}] ~~END~~ @@ -96,7 +96,7 @@ SELECT * FROM forjson_datatypes_vu_v_unicode_strings GO ~~START~~ nvarchar -[{"anchar":"abc ","anvarchar":"abc","antext":"abc"}] +[{"anchar": "abc ", "anvarchar": "abc", "antext": "abc"}] ~~END~~ diff --git a/test/JDBC/expected/forjson-nesting-vu-cleanup.out b/test/JDBC/expected/forjson-nesting-vu-cleanup.out new file mode 100644 index 0000000000..202343737b --- /dev/null +++ b/test/JDBC/expected/forjson-nesting-vu-cleanup.out @@ -0,0 +1,45 @@ +-- FOR JSON PATH CLAUSE with nested json support for existing objects +DROP VIEW forjson_nesting_vu_v_users +GO + +DROP VIEW forjson_nesting_vu_v_products +GO + +DROP VIEW forjson_nesting_vu_v_orders +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +DROP VIEW forjson_nesting_vu_v_deep +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +DROP VIEW forjson_nesting_vu_v_join_deep +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +DROP VIEW forjson_nesting_vu_v_layered_insert +GO + +-- Error related to inserting value at Json object location +DROP VIEW forjson_nesting_vu_v_error +GO + +-- Queries that check NULL nested json object insert +DROP VIEW forjson_nesting_vu_v_no_null +GO + +DROP VIEW forjson_nesting_vu_v_with_null +GO + +-- DROP Tables +DROP TABLE forjson_nesting_vu_t_users +GO + +DROP TABLE forjson_nesting_vu_t_products +GO + +DROP TABLE forjson_nesting_vu_t_orders +GO + +DROP TABLE forjson_nesting_vu_t_null_users +GO diff --git a/test/JDBC/expected/forjson-nesting-vu-prepare.out b/test/JDBC/expected/forjson-nesting-vu-prepare.out new file mode 100644 index 0000000000..4f4f1ea1f3 --- /dev/null +++ b/test/JDBC/expected/forjson-nesting-vu-prepare.out @@ -0,0 +1,176 @@ +CREATE TABLE forjson_nesting_vu_t_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), +); +GO +CREATE TABLE forjson_nesting_vu_t_products ( + [Id] int, + [name] varchar(50), + [price] varchar (25) +); +GO +CREATE TABLE forjson_nesting_vu_t_orders ( + [Id] int, + [userid] int, + [productid] int, + [quantity] int, + [orderdate] Date +); +GO +CREATE TABLE forjson_nesting_vu_t_null_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), + [phone] varchar(25) +); +GO + +INSERT INTO forjson_nesting_vu_t_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com'), + (3, 'Mike', 'Johnson', 'mikejohnson'); +GO +~~ROW COUNT: 3~~ + + +INSERT INTO forjson_nesting_vu_t_products +VALUES + (1, 'Product A', '10.99'), + (2, 'Product B', '19.99'), + (3, 'Product C', '5.99'); +GO +~~ROW COUNT: 3~~ + + +INSERT INTO forjson_nesting_vu_t_orders +VALUES + (1, 1, 1, 2, '2023-06-25'), + (2, 1, 2, 1, '2023-06-25'), + (3, 2, 3, 3, '2023-06-26'); +GO +~~ROW COUNT: 3~~ + + +INSERT INTO forjson_nesting_vu_t_null_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com', '123-456-7890'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com', NULL), + (3, NULL, NULL, 'mikejohnson@myspace.com', '098-765-4321'), + (4, 'Sergio', 'Giavanni', NULL, NULL); +GO +~~ROW COUNT: 4~~ + + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +CREATE VIEW forjson_nesting_vu_v_users AS +SELECT ( + SELECT Id, + firstname AS "Name.first", + lastname AS "Name.last", + email + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_products AS +SELECT ( + SELECT Id, + name AS "Info.name", + price AS "Info.price" + FROM forjson_nesting_vu_t_products + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_orders AS +SELECT ( + SELECT Id AS "Id.orderid", + userid AS "Id.userid", + productid AS "Id.productid", + quantity AS "orderinfo.quantity", + orderdate AS "orderinfo.orderdate" + FROM forjson_nesting_vu_t_orders + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +CREATE VIEW forjson_nesting_vu_v_deep AS +SELECT ( + SELECT Id, + firstname AS "User.info.name.first", + lastname AS "User.info.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +CREATE VIEW forjson_nesting_vu_v_join_deep AS +SELECT ( + SELECT U.Id "User.id", + O.quantity AS "User.order.info.quantity", + O.orderdate AS "User.order.info.orderdate" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +CREATE VIEW forjson_nesting_vu_v_layered_insert AS +SELECT ( + SELECT U.id, + O.id AS "Order.Orderid", + P.id AS "Order.Product.Productid", + O.orderdate AS "Order.date" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + JOIN forjson_nesting_vu_t_products P + ON (P.id = O.productid) + FOR JSON PATH +) c1 +GO + +-- Error related to inserting value at Json object location +CREATE VIEW forjson_nesting_vu_v_error AS +SELECT ( + SELECT id, + firstname AS "user.name", + lastname AS "user.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) +GO + +-- Queries that check NULL nested json object insert +CREATE VIEW forjson_nesting_vu_v_no_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH +) +GO + +CREATE VIEW forjson_nesting_vu_v_with_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH, INCLUDE_NULL_VALUES +) +GO diff --git a/test/JDBC/expected/forjson-nesting-vu-verify.out b/test/JDBC/expected/forjson-nesting-vu-verify.out new file mode 100644 index 0000000000..277e0bfb88 --- /dev/null +++ b/test/JDBC/expected/forjson-nesting-vu-verify.out @@ -0,0 +1,110 @@ +-- Display Table Contents +SELECT * FROM forjson_nesting_vu_t_users +GO +~~START~~ +int#!#varchar#!#varchar#!#varchar +1#!#John#!#Doe#!#johndoe@gmail.com +2#!#Jane#!#Smith#!#janesmith@yahoo.com +3#!#Mike#!#Johnson#!#mikejohnson +~~END~~ + + +SELECT * FROM forjson_nesting_vu_t_products +GO +~~START~~ +int#!#varchar#!#varchar +1#!#Product A#!#10.99 +2#!#Product B#!#19.99 +3#!#Product C#!#5.99 +~~END~~ + + +SELECT * FROM forjson_nesting_vu_t_orders +GO +~~START~~ +int#!#int#!#int#!#int#!#date +1#!#1#!#1#!#2#!#2023-06-25 +2#!#1#!#2#!#1#!#2023-06-25 +3#!#2#!#3#!#3#!#2023-06-26 +~~END~~ + + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +SELECT * FROM forjson_nesting_vu_v_users +GO +~~START~~ +nvarchar +[{"Id": 1, "Name": {"first": "John", "last": "Doe"}, "email": "johndoe@gmail.com"}, {"Id": 2, "Name": {"first": "Jane", "last": "Smith"}, "email": "janesmith@yahoo.com"}, {"Id": 3, "Name": {"first": "Mike", "last": "Johnson"}, "email": "mikejohnson"}] +~~END~~ + + +SELECT * FROM forjson_nesting_vu_v_products +GO +~~START~~ +nvarchar +[{"Id": 1, "Info": {"name": "Product A", "price": "10.99"}}, {"Id": 2, "Info": {"name": "Product B", "price": "19.99"}}, {"Id": 3, "Info": {"name": "Product C", "price": "5.99"}}] +~~END~~ + + +SELECT * FROM forjson_nesting_vu_v_orders +GO +~~START~~ +nvarchar +[{"Id": {"orderid": 1, "userid": 1, "productid": 1}, "orderinfo": {"quantity": 2, "orderdate": "2023-06-25"}}, {"Id": {"orderid": 2, "userid": 1, "productid": 2}, "orderinfo": {"quantity": 1, "orderdate": "2023-06-25"}}, {"Id": {"orderid": 3, "userid": 2, "productid": 3}, "orderinfo": {"quantity": 3, "orderdate": "2023-06-26"}}] +~~END~~ + + +-- FOR JSON PATH support for multiple layers of nested JSON objects +SELECT * FROM forjson_nesting_vu_v_deep +GO +~~START~~ +nvarchar +[{"Id": 1, "User": {"info": {"name": {"first": "John", "last": "Doe"}}}}, {"Id": 2, "User": {"info": {"name": {"first": "Jane", "last": "Smith"}}}}, {"Id": 3, "User": {"info": {"name": {"first": "Mike", "last": "Johnson"}}}}] +~~END~~ + + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +SELECT * FROM forjson_nesting_vu_v_join_deep +GO +~~START~~ +nvarchar +[{"User": {"id": 1, "order": {"info": {"quantity": 2, "orderdate": "2023-06-25"}}}}, {"User": {"id": 1, "order": {"info": {"quantity": 1, "orderdate": "2023-06-25"}}}}, {"User": {"id": 2, "order": {"info": {"quantity": 3, "orderdate": "2023-06-26"}}}}] +~~END~~ + + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +SELECT * FROM forjson_nesting_vu_v_layered_insert +GO +~~START~~ +nvarchar +[{"id": 1, "Order": {"Orderid": 1, "Product": {"Productid": 1}, "date": "2023-06-25"}}, {"id": 1, "Order": {"Orderid": 2, "Product": {"Productid": 2}, "date": "2023-06-25"}}, {"id": 2, "Order": {"Orderid": 3, "Product": {"Productid": 3}, "date": "2023-06-26"}}] +~~END~~ + + +-- Error related to inserting value at Json object location +SELECT * FROM forjson_nesting_vu_v_error +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Property user.name.last cannot be generated in JSON output due to a conflict with another column name or alias. Use different names and aliases for each column in SELECT list.)~~ + + +-- Queries that check NULL nested json object insert +SELECT * FROM forjson_nesting_vu_v_no_null +GO +~~START~~ +nvarchar +[{"id": 1, "user": {"name": {"first": "John", "last": "Doe"}}, "contact": {"email": "johndoe@gmail.com", "phone": "123-456-7890"}}, {"id": 2, "user": {"name": {"first": "Jane", "last": "Smith"}}, "contact": {"email": "janesmith@yahoo.com"}}, {"id": 3, "contact": {"email": "mikejohnson@myspace.com", "phone": "098-765-4321"}}, {"id": 4, "user": {"name": {"first": "Sergio", "last": "Giavanni"}}}] +~~END~~ + + +SELECT * FROM forjson_nesting_vu_v_with_null +GO +~~START~~ +nvarchar +[{"id": 1, "user": {"name": {"first": "John", "last": "Doe"}}, "contact": {"email": "johndoe@gmail.com", "phone": "123-456-7890"}}, {"id": 2, "user": {"name": {"first": "Jane", "last": "Smith"}}, "contact": {"email": "janesmith@yahoo.com", "phone": null}}, {"id": 3, "user": {"name": {"first": null, "last": null}}, "contact": {"email": "mikejohnson@myspace.com", "phone": "098-765-4321"}}, {"id": 4, "user": {"name": {"first": "Sergio", "last": "Giavanni"}}, "contact": {"email": null, "phone": null}}] +~~END~~ + + diff --git a/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..8cb72c506f --- /dev/null +++ b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,59 @@ +-- FOR JSON AUTO clause not supported +DROP VIEW forjson_subquery_vu_v_auto +GO +~~ERROR (Code: 3701)~~ + +~~ERROR (Message: view "forjson_subquery_vu_v_auto" does not exist)~~ + + +-- Alias/colname is not present +DROP VIEW forjson_subquery_vu_v_no_alias +GO + +DROP VIEW forjson_subquery_vu_v_with +GO + +DROP VIEW forjson_subquery_vu_v_with_order_by +GO + +-- Binary strings +DROP VIEW forjson_subquery_vu_v_binary_strings +GO + +DROP VIEW forjson_subquery_vu_v_varbinary_strings +GO + +-- Rowversion and timestamp +DROP VIEW forjson_subquery_vu_v_rowversion +GO + +DROP VIEW forjson_subquery_vu_v_timestamp +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +DROP PROCEDURE forjson_subquery_vu_p_empty +GO + +-- exercise tsql_select_for_json_result internal function +DROP VIEW forjson_subquery_vu_v_internal +GO + +DROP TABLE forjson_subquery_vu_t_countries +GO + +DROP TABLE forjson_subquery_vu_t1 +GO + +-- Binary strings +DROP TABLE forjson_subquery_vu_t_binary_strings +GO + +-- Rowversion and timestamp +DROP TABLE forjson_subquery_vu_t_rowversion +GO + +DROP TABLE forjson_subquery_vu_t_timestamp +GO + +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'strict'; +GO diff --git a/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..47f572490d --- /dev/null +++ b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,151 @@ + +-- 14.7 (aka extension version 2.4.0) has a major change to how FOR JSON +-- has been implemented, which slightly changes the behavior around some old error +-- messages as well, so we need to move those tests to a new test file that separately +-- exercises them outside of the pre-14.6 upgrade tests. +CREATE TABLE forjson_subquery_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_subquery_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO +~~ROW COUNT: 5~~ + + +create table forjson_subquery_vu_t1 (x int) +insert into forjson_subquery_vu_t1 values (1) +go +~~ROW COUNT: 1~~ + + +-- FOR JSON AUTO clause not supported +CREATE VIEW forjson_subquery_vu_v_auto AS +SELECT ( + SELECT Id, + State + FROM forjson_subquery_vu_t1 + FOR JSON AUTO +) c1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: column "id" does not exist)~~ + + +-- Alias/colname not present +CREATE VIEW forjson_subquery_vu_v_no_alias AS +SELECT ( + SELECT 2 + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_subquery_vu_v_with AS +WITH forjson_subquery_vu_with1(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with1 + WHERE Age >= forjson_subquery_vu_with1.avg_age + FOR JSON PATH +) C1 +GO + +CREATE VIEW forjson_subquery_vu_v_with_order_by AS +WITH forjson_subquery_vu_with2(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with2 + WHERE Age >= forjson_subquery_vu_with2.avg_age + ORDER BY Country + FOR JSON PATH +) c1 +GO + +-- Binary strings +CREATE TABLE forjson_subquery_vu_t_binary_strings(abinary binary, avarbinary varbinary(10)) +GO +INSERT forjson_subquery_vu_t_binary_strings VALUES (123456,0x0a0b0c0d0e) +GO +~~ROW COUNT: 1~~ + + +-- Rowversion and timestamp +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'ignore'; +GO + +CREATE TABLE forjson_subquery_vu_t_rowversion (myKey int, myValue int,RV rowversion); +GO +INSERT INTO forjson_subquery_vu_t_rowversion (myKey, myValue) VALUES (1, 0); +GO +~~ROW COUNT: 1~~ + + +CREATE TABLE forjson_subquery_vu_t_timestamp (myKey int, myValue int, timestamp); +GO +INSERT INTO forjson_subquery_vu_t_timestamp (myKey, myValue) VALUES (1, 0); +GO +~~ROW COUNT: 1~~ + + +-- Binary strings +CREATE VIEW forjson_subquery_vu_v_binary_strings AS +SELECT +( + SELECT abinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_varbinary_strings AS +SELECT +( + SELECT avarbinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +-- Rowversion and timestamp +CREATE VIEW forjson_subquery_vu_v_rowversion AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_rowversion + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_timestamp AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_timestamp + FOR JSON PATH +) as c1; +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +CREATE PROCEDURE forjson_subquery_vu_p_empty AS +SELECT * FROM forjson_subquery_vu_t_countries + WHERE 1 = 0 + FOR JSON PATH +GO + +-- exercise tsql_select_for_json_result internal function +CREATE VIEW forjson_subquery_vu_v_internal AS +SELECT * FROM tsql_select_for_json_result('abcd') +GO diff --git a/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..c4553b14cd --- /dev/null +++ b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,95 @@ +-- FOR JSON AUTO clause not supported +SELECT * FROM forjson_subquery_vu_v_auto +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: relation "forjson_subquery_vu_v_auto" does not exist)~~ + + +-- Alias/colname is not present +SELECT * FROM forjson_subquery_vu_v_no_alias +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: column expressions and data sources without names or aliases cannot be formatted as JSON text using FOR JSON clause. Add alias to the unnamed column or table)~~ + + +SELECT * FROM forjson_subquery_vu_v_with +GO +~~START~~ +nvarchar +[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"}] +~~END~~ + + +SELECT * FROM forjson_subquery_vu_v_with_order_by +GO +~~START~~ +nvarchar +[{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +~~END~~ + + +-- Binary strings +SELECT * FROM forjson_subquery_vu_v_binary_strings +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +SELECT * FROM forjson_subquery_vu_v_varbinary_strings +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +-- Rowversion and timestamp +SELECT * FROM forjson_subquery_vu_v_rowversion +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +SELECT * FROM forjson_subquery_vu_v_timestamp +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +EXEC forjson_subquery_vu_p_empty +GO +~~START~~ +nvarchar +~~END~~ + + +SELECT @@rowcount +GO +~~START~~ +int +0 +~~END~~ + + +-- exercise tsql_select_for_json_result internal function +SELECT * FROM forjson_subquery_vu_v_internal +GO +~~START~~ +nvarchar +abcd +~~END~~ diff --git a/test/JDBC/expected/forjson-subquery-vu-verify.out b/test/JDBC/expected/forjson-subquery-vu-verify.out index 89f76f3dd5..e9e82cce6c 100644 --- a/test/JDBC/expected/forjson-subquery-vu-verify.out +++ b/test/JDBC/expected/forjson-subquery-vu-verify.out @@ -20,7 +20,7 @@ SELECT * FROM forjson_subquery_vu_v_with GO ~~START~~ nvarchar -[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"}] +[{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}] ~~END~~ @@ -28,7 +28,7 @@ SELECT * FROM forjson_subquery_vu_v_with_order_by GO ~~START~~ nvarchar -[{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +[{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}] ~~END~~ diff --git a/test/JDBC/expected/forjson-vu-verify.out b/test/JDBC/expected/forjson-vu-verify.out index 4f8a705dba..ce8d2391eb 100644 --- a/test/JDBC/expected/forjson-vu-verify.out +++ b/test/JDBC/expected/forjson-vu-verify.out @@ -32,12 +32,12 @@ int#!#varchar ~~END~~ --- FOR JSON PATH clause without nested support +-- FOR JSON PATH clause with nested support SELECT * FROM forjson_vu_v_people GO ~~START~~ nvarchar -[{"EmpId":1,"Name.FirstName":"Divya","Name.LastName":"Kumar"},{"EmpId":2,"Name.LastName":"Khanna","State":"Bengaluru"},{"EmpId":3,"Name.FirstName":"Tom","Name.LastName":"Mehta","State":"Kolkata"},{"EmpId":4,"Name.FirstName":"Kane","State":"Delhi"}] +[{"EmpId": 1, "Name": {"FirstName": "Divya", "LastName": "Kumar"}}, {"EmpId": 2, "Name": {"LastName": "Khanna"}, "State": "Bengaluru"}, {"EmpId": 3, "Name": {"FirstName": "Tom", "LastName": "Mehta"}, "State": "Kolkata"}, {"EmpId": 4, "Name": {"FirstName": "Kane"}, "State": "Delhi"}] ~~END~~ @@ -45,16 +45,16 @@ SELECT * FROM forjson_vu_v_countries GO ~~START~~ nvarchar -[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20},{"Id":5,"Age":10,"Country":"USA"}] +[{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 4, "Age": 20}, {"Id": 5, "Age": 10, "Country": "USA"}] ~~END~~ --- Multiple tables without nested support +-- Multiple tables with nested support SELECT * FROM forjson_vu_v_join GO ~~START~~ nvarchar -[{"Person.Name":"Divya","Person.Surname":"Kumar","Employee.Price":25,"Employee.Quantity":"India"},{"Person.Surname":"Khanna","Employee.Price":40,"Employee.Quantity":"USA"},{"Person.Name":"Tom","Person.Surname":"Mehta","Employee.Price":30,"Employee.Quantity":"India"},{"Person.Name":"Kane","Employee.Price":20}] +[{"Person": {"Name": "Divya", "Surname": "Kumar"}, "Employee": {"Price": 25, "Quantity": "India"}}, {"Person": {"Surname": "Khanna"}, "Employee": {"Price": 40, "Quantity": "USA"}}, {"Person": {"Name": "Tom", "Surname": "Mehta"}, "Employee": {"Price": 30, "Quantity": "India"}}, {"Person": {"Name": "Kane"}, "Employee": {"Price": 20}}] ~~END~~ @@ -63,7 +63,7 @@ SELECT * FROM forjson_vu_v_root GO ~~START~~ nvarchar -{"root":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +{"root": [{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"}]} ~~END~~ @@ -72,7 +72,7 @@ SELECT * FROM forjson_vu_v_root_value GO ~~START~~ nvarchar -{"Employee":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +{"Employee": [{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"}]} ~~END~~ @@ -81,7 +81,7 @@ SELECT * FROM forjson_vu_v_empty_root GO ~~START~~ nvarchar -{"":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +{"": [{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"}]} ~~END~~ @@ -90,7 +90,7 @@ SELECT * FROM forjson_vu_v_without_array_wrapper GO ~~START~~ nvarchar -{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"} +{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"} ~~END~~ @@ -99,7 +99,7 @@ SELECT * FROM forjson_vu_v_include_null_values GO ~~START~~ nvarchar -[{"FirstName":"Divya","LastName":"Kumar"},{"FirstName":null,"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane","LastName":null}] +[{"FirstName": "Divya", "LastName": "Kumar"}, {"FirstName": null, "LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane", "LastName": null}] ~~END~~ @@ -108,7 +108,7 @@ SELECT * FROM forjson_vu_v_root_include_null_values GO ~~START~~ nvarchar -{"Employee":[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"}]} +{"Employee": [{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 4, "Age": 20, "Country": null}, {"Id": 5, "Age": 10, "Country": "USA"}]} ~~END~~ @@ -116,7 +116,7 @@ SELECT * FROM forjson_vu_v_without_array_wrapper_include_null_values GO ~~START~~ nvarchar -{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"} +{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 4, "Age": 20, "Country": null}, {"Id": 5, "Age": 10, "Country": "USA"} ~~END~~ @@ -126,7 +126,7 @@ EXECUTE forjson_vu_p_params1 @id = 2 GO ~~START~~ nvarchar -[{"State":"Bengaluru"}] +[{"State": "Bengaluru"}] ~~END~~ @@ -134,7 +134,7 @@ EXECUTE forjson_vu_p_params2 @id = 3 GO ~~START~~ nvarchar -[{"nam\"@e":"Tom","State\"@":"Kolkata"}] +[{"nam\"@e": "Tom", "State\"@": "Kolkata"}] ~~END~~ @@ -143,7 +143,7 @@ SELECT * FROM forjson_vu_v_nulls GO ~~START~~ nvarchar -[{},{},{}] +[{}, {}, {}] ~~END~~ @@ -152,6 +152,6 @@ SELECT * FROM forjson_vu_v_order_by GO ~~START~~ nvarchar -[{"Id":5,"Age":10,"Country":"USA"},{"Id":4,"Age":20},{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +[{"Id": 5, "Age": 10, "Country": "USA"}, {"Id": 4, "Age": 20}, {"Id": 1, "Age": 25, "Country": "India"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}] ~~END~~ diff --git a/test/JDBC/expected/sys_sequences-vu-cleanup.out b/test/JDBC/expected/sys_sequences-vu-cleanup.out new file mode 100644 index 0000000000..de5f33a723 --- /dev/null +++ b/test/JDBC/expected/sys_sequences-vu-cleanup.out @@ -0,0 +1,27 @@ +USE master +GO + +DROP VIEW sys_sequences_vu_prepare_view +GO + +DROP PROC sys_sequences_vu_prepare_proc +GO + +DROP FUNCTION sys_sequences_vu_prepare_func +GO + +DROP FUNCTION sys_sequences_vu_prepare_func1 +GO + +DROP FUNCTION sys_sequences_vu_prepare_func2 +GO + +DROP sequence IF EXISTS test_seq +GO + +DROP sequence IF EXISTS sch.ははははははははははははははははは +GO + +DROP schema IF EXISTS sch +GO + diff --git a/test/JDBC/expected/sys_sequences-vu-prepare.out b/test/JDBC/expected/sys_sequences-vu-prepare.out new file mode 100644 index 0000000000..5d75e42632 --- /dev/null +++ b/test/JDBC/expected/sys_sequences-vu-prepare.out @@ -0,0 +1,91 @@ +USE master +GO + +Create sequence test_seq as int +GO + +Create schema sch +GO + +Create sequence sch.ははははははははははははははははは +GO + +CREATE VIEW sys_sequences_vu_prepare_view AS +select + name + , principal_id + , parent_object_id + , type + , type_desc + , create_date + , modify_date + , is_ms_shipped + , is_published + , is_schema_published + , start_value + , increment + , minimum_value + , maximum_value + , is_cycling + , is_cached + , cache_size + , system_type_id + , user_type_id + , precision + , scale + , current_value + , is_exhausted + , last_used_value FROM sys.sequences +GO + +CREATE PROC sys_sequences_vu_prepare_proc AS +SELECT + name + , principal_id + , parent_object_id + , type + , type_desc + , create_date + , modify_date + , is_ms_shipped + , is_published + , is_schema_published + , start_value + , increment + , minimum_value + , maximum_value + , is_cycling + , is_cached + , cache_size + , system_type_id + , user_type_id + , precision + , scale + , current_value + , is_exhausted + , last_used_value FROM sys.sequences +GO + +CREATE FUNCTION sys_sequences_vu_prepare_func() +RETURNS INT +AS +BEGIN + RETURN (SELECT COUNT(*) FROM sys.sequences WHERE is_cycling= 0) +END +GO + +CREATE FUNCTION sys_sequences_vu_prepare_func1() +RETURNS INT +AS +BEGIN + RETURN (SELECT COUNT(*) FROM sys.sequences WHERE name='TEST_SEq'); +END +GO + +CREATE FUNCTION sys_sequences_vu_prepare_func2() +RETURNS INT +AS +BEGIN + RETURN (SELECT COUNT(*) FROM sys.sequences WHERE name='ははははははははははははははははは'); +END +GO diff --git a/test/JDBC/expected/sys_sequences-vu-verify.out b/test/JDBC/expected/sys_sequences-vu-verify.out new file mode 100644 index 0000000000..d25fc91980 --- /dev/null +++ b/test/JDBC/expected/sys_sequences-vu-verify.out @@ -0,0 +1,44 @@ +USE master +GO + +SELECT * FROM sys_sequences_vu_prepare_view +GO +~~START~~ +nvarchar#!#int#!#int#!#char#!#nvarchar#!#datetime#!#datetime#!#bit#!#bit#!#bit#!#sql_variant#!#sql_variant#!#sql_variant#!#sql_variant#!#bit#!#bit#!#int#!#int#!#int#!#tinyint#!#tinyint#!#sql_variant#!#bit#!#sql_variant +test_seq#!##!#0#!#SO#!#SEQUENCE_OBJECT#!##!##!#0#!#0#!#0#!#1#!#1#!#1#!#2147483647#!#0#!#0#!#1#!#23#!#23#!#0#!#0#!#ABC#!#0#!#ABC +ははははははははははははははははは#!##!#0#!#SO#!#SEQUENCE_OBJECT#!##!##!#0#!#0#!#0#!#1#!#1#!#1#!#9223372036854775807#!#0#!#0#!#1#!#20#!#20#!#0#!#0#!#ABC#!#0#!#ABC +~~END~~ + + +EXEC sys_sequences_vu_prepare_proc +GO +~~START~~ +nvarchar#!#int#!#int#!#char#!#nvarchar#!#datetime#!#datetime#!#bit#!#bit#!#bit#!#sql_variant#!#sql_variant#!#sql_variant#!#sql_variant#!#bit#!#bit#!#int#!#int#!#int#!#tinyint#!#tinyint#!#sql_variant#!#bit#!#sql_variant +test_seq#!##!#0#!#SO#!#SEQUENCE_OBJECT#!##!##!#0#!#0#!#0#!#1#!#1#!#1#!#2147483647#!#0#!#0#!#1#!#23#!#23#!#0#!#0#!#ABC#!#0#!#ABC +ははははははははははははははははは#!##!#0#!#SO#!#SEQUENCE_OBJECT#!##!##!#0#!#0#!#0#!#1#!#1#!#1#!#9223372036854775807#!#0#!#0#!#1#!#20#!#20#!#0#!#0#!#ABC#!#0#!#ABC +~~END~~ + + +SELECT sys_sequences_vu_prepare_func() +GO +~~START~~ +int +2 +~~END~~ + + +SELECT sys_sequences_vu_prepare_func1() +GO +~~START~~ +int +1 +~~END~~ + + +SELECT sys_sequences_vu_prepare_func2() +GO +~~START~~ +int +1 +~~END~~ + diff --git a/test/JDBC/input/BABEL-4231-vu-cleanup.mix b/test/JDBC/input/BABEL-4231-vu-cleanup.mix index 14b3637f08..c949c9b902 100644 --- a/test/JDBC/input/BABEL-4231-vu-cleanup.mix +++ b/test/JDBC/input/BABEL-4231-vu-cleanup.mix @@ -153,4 +153,7 @@ GO DROP VIEW view_babel_4231_40; GO DROP TABLE table18_babel_4231; -GO \ No newline at end of file +GO + +DROP VIEW view_babel_4231_41; +GO diff --git a/test/JDBC/input/BABEL-4231-vu-prepare.mix b/test/JDBC/input/BABEL-4231-vu-prepare.mix index fd62c8b297..a2a9664c5d 100644 --- a/test/JDBC/input/BABEL-4231-vu-prepare.mix +++ b/test/JDBC/input/BABEL-4231-vu-prepare.mix @@ -238,22 +238,22 @@ CREATE VIEW view_babel_4231_35 AS SELECT * FROM table17_babel_4231 AS "αΒβΓ GO -- tsql --- table aliases which are not delimited by double quote, square bracket and length is less than 64 +-- column aliases which are not delimited by double quote, square bracket and length is less than 64 CREATE VIEW view_babel_4231_36 AS SELECT 1 AS ABCD; GO -- tsql --- table aliases with single byte characters which are not delimited by double quote, square bracket and length is more than or equals to 64 +-- column aliases with single byte characters which are not delimited by double quote, square bracket and length is more than or equals to 64 CREATE VIEW view_babel_4231_37 AS SELECT 1 AS ABCDbdjaBFWFGRUWlgrefwfiwuegfdvfwefgvggfedfudywtitewutgfdWUIF; GO -- tsql --- table aliases with single byte characters which are delimited by single quote and length is more than or equals to 64 +-- column aliases with single byte characters which are delimited by single quote and length is more than or equals to 64 CREATE VIEW view_babel_4231_38 AS SELECT 1 AS 'ABCDbdjaBFWFGRUWlgrefwfiwuegfdvfwefgvggfedfudywtitewutgfdWUIF'; GO -- tsql --- table aliases with single byte characters which are delimited by single quote and length is less than 64 +-- column aliases with single byte characters which are delimited by single quote and length is less than 64 CREATE VIEW view_babel_4231_39 AS SELECT 1 AS N'ANfjws'; GO @@ -264,5 +264,7 @@ GO CREATE VIEW view_babel_4231_40 AS SELECT 您您对您对您对您对您对您对您对您对您对您您您.* FROM table18_babel_4231 AS 您您对您对您对您对您对您对您对您对您对您您您; GO - - +-- tsql +-- column aliases with multibyte characters which are delimited by single quote and length is more than 128 +CREATE VIEW view_babel_4231_41 AS SELECT 1 AS '您对“数据一览“中的车型,颜色,内饰,选装, 您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,'; +GO diff --git a/test/JDBC/input/BABEL-4231-vu-verify.mix b/test/JDBC/input/BABEL-4231-vu-verify.mix index 8388198e52..c29272baae 100644 --- a/test/JDBC/input/BABEL-4231-vu-verify.mix +++ b/test/JDBC/input/BABEL-4231-vu-verify.mix @@ -156,4 +156,12 @@ GO -- psql SELECT pg_catalog.pg_get_viewdef(oid, true) FROM pg_class WHERE relname = 'view_babel_4231_40'; -GO \ No newline at end of file +GO + +-- psql +SELECT pg_catalog.pg_get_viewdef(oid, true) FROM pg_class WHERE relname = 'view_babel_4231_41'; +GO + +-- tsql +select 1 as '您对“数据一览“中的车型,颜色,内饰,选装, 您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,您对“数据一览“中的车型,颜色,内饰,选装,'; +GO diff --git a/test/JDBC/input/BABEL-CROSS-DB.mix b/test/JDBC/input/BABEL-CROSS-DB.mix index 594fcd1b0e..630af3bad3 100644 --- a/test/JDBC/input/BABEL-CROSS-DB.mix +++ b/test/JDBC/input/BABEL-CROSS-DB.mix @@ -338,6 +338,12 @@ DROP PROCEDURE p1 GO -- tsql +USE db1; +GO + +DROP TABLE db1_t1; +GO + USE master; GO diff --git a/test/JDBC/input/BABEL-GRANT.sql b/test/JDBC/input/BABEL-GRANT.sql index fb53d93209..76909fb8e4 100644 --- a/test/JDBC/input/BABEL-GRANT.sql +++ b/test/JDBC/input/BABEL-GRANT.sql @@ -20,6 +20,10 @@ GO --- Prepare Objects --- +---- SCHEMA +CREATE SCHEMA scm; +GO + ---- TABLE CREATE TABLE t1 ( a int, b int); GO @@ -55,6 +59,12 @@ GO --- Basic Grant / Revoke --- +GRANT SELECT ON SCHEMA::scm TO guest; +GO + +GRANT INSERT ON SCHEMA::scm TO guest; +GO + GRANT ALL ON OBJECT::t1 TO guest WITH GRANT OPTION; GO @@ -133,6 +143,9 @@ GO REVOKE ALL TO alogin; -- database permission GO +REVOKE SELECT ON SCHEMA::scm FROM guest; -- unsupported permission +GO + GRANT SHOWPLAN ON OBJECT::t1 TO guest; -- unsupported permission GO @@ -155,6 +168,9 @@ GO --- Clean Up --- +DROP SCHEMA scm; +GO + DROP VIEW IF EXISTS my_view; GO diff --git a/test/JDBC/input/BABEL-SESSION.mix b/test/JDBC/input/BABEL-SESSION.mix index 41c1c85398..d9f7be4a8c 100644 --- a/test/JDBC/input/BABEL-SESSION.mix +++ b/test/JDBC/input/BABEL-SESSION.mix @@ -99,6 +99,21 @@ USE master; GO -- tsql +USE db1; +GO + +DROP TABLE tb1; +GO + +DROP TABLE janedoe_schema.t1; +GO + +DROP SCHEMA janedoe_schema; +GO + +USE master; +go + DROP DATABASE db1; GO diff --git a/test/JDBC/input/BABEL_4442.sql b/test/JDBC/input/BABEL_4442.sql new file mode 100644 index 0000000000..75cdd4726d --- /dev/null +++ b/test/JDBC/input/BABEL_4442.sql @@ -0,0 +1,96 @@ +CREATE SCHEMA babel_4442_s1 +GO +CREATE SCHEMA babel_4442_s2 +GO + +CREATE TABLE babel_4442_t (id INT) +GO +CREATE TABLE babel_4442_s1.babel_4442_t (id INT) +GO +CREATE TABLE babel_4442_s2.babel_4442_t (id INT) +GO + +INSERT INTO babel_4442_t VALUES (1) +GO +INSERT INTO babel_4442_s1.babel_4442_t VALUES (2), (3) +GO +INSERT INTO babel_4442_s2.babel_4442_t VALUES (3), (4), (5) +GO + +CREATE FUNCTION babel_4442_f() RETURNS INT AS +BEGIN + RETURN (SELECT COUNT(*) FROM babel_4442_t) +END +GO + +CREATE FUNCTION babel_4442_s1.babel_4442_f() RETURNS INT AS +BEGIN + RETURN (SELECT COUNT(*) FROM babel_4442_t) +END +GO + +CREATE FUNCTION babel_4442_s2.babel_4442_f() RETURNS INT AS +BEGIN + RETURN (SELECT COUNT(*) FROM babel_4442_t) +END +GO + +SELECT TABLE_NAME, TABLE_TYPE FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = SCHEMA_NAME() and TABLE_NAME = 'babel_4442_t' +GO + +SELECT babel_4442_f(), * FROM babel_4442_s1.babel_4442_t +GO + +SELECT babel_4442_f(), babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_s1.babel_4442_t +GO + +SELECT babel_4442_f(), babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO + +SELECT babel_4442_f(), current_setting('search_path'), babel_4442_s1.babel_4442_f(), current_setting('search_path'), + babel_4442_s2.babel_4442_f(), 1, current_setting('search_path'), * FROM babel_4442_t +GO + +SELECT current_setting('search_path') +GO + +BEGIN TRANSACTION +GO +SELECT current_setting('search_path') +GO +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +SELECT current_setting('search_path') +GO +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +COMMIT +GO + +SELECT current_setting('search_path') +GO + +BEGIN TRANSACTION +GO +SELECT current_setting('search_path') +GO +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +SELECT current_setting('search_path') +GO +SELECT babel_4442_s1.babel_4442_f(), babel_4442_s2.babel_4442_f(), * FROM babel_4442_t +GO +ROLLBACK +GO + +SELECT current_setting('search_path') +GO + +DROP TABLE IF EXISTS babel_4442_t, babel_4442_s1.babel_4442_t, babel_4442_s2.babel_4442_t +GO +DROP FUNCTION IF EXISTS babel_4442_f, babel_4442_s1.babel_4442_f, babel_4442_s2.babel_4442_f +GO +DROP SCHEMA babel_4442_s1 +GO +DROP SCHEMA babel_4442_s2 +GO diff --git a/test/JDBC/input/GRANT_SCHEMA-vu-cleanup.mix b/test/JDBC/input/GRANT_SCHEMA-vu-cleanup.mix new file mode 100644 index 0000000000..156b92c61e --- /dev/null +++ b/test/JDBC/input/GRANT_SCHEMA-vu-cleanup.mix @@ -0,0 +1,66 @@ +-- tsql +-- Drop objects +use grant_schema_d1; +go + +drop table grant_schema_s1.grant_schema_t1; +go + +drop table grant_schema_s1.grant_schema_t2; +go + +drop table grant_schema_s1.grant_schema_t3; +go + +drop view grant_schema_s1.grant_schema_v1; +go + +drop view grant_schema_s1.grant_schema_v2; +go + +drop proc grant_schema_s1.grant_schema_p1; +go + +drop proc grant_schema_s1.grant_schema_p2; +go + +drop function grant_schema_s1.grant_schema_f1; +go + +drop function grant_schema_s1.grant_schema_f2; +go + +drop schema grant_schema_s1; +go + +drop table grant_schema_s2.grant_schema_t1; +go + +drop table grant_schema_s2.grant_schema_t2; +go + +drop schema grant_schema_s2; +go + +drop user grant_schema_u1; +go + +use master; +go + +drop database grant_schema_d1; +go + +-- psql +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'grant_schema_l1' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +go + +-- Wait to sync with another session +SELECT pg_sleep(1); +go + +-- tsql +drop login grant_schema_l1; +go \ No newline at end of file diff --git a/test/JDBC/input/GRANT_SCHEMA-vu-prepare.mix b/test/JDBC/input/GRANT_SCHEMA-vu-prepare.mix new file mode 100644 index 0000000000..306cd64d58 --- /dev/null +++ b/test/JDBC/input/GRANT_SCHEMA-vu-prepare.mix @@ -0,0 +1,74 @@ +-- tsql +-- create objects +create database grant_schema_d1; +go + +use grant_schema_d1; +go + +create login grant_schema_l1 with password = '12345678' +go + +create user grant_schema_u1 for login grant_schema_l1; +go + +create schema grant_schema_s1; +go + +create table grant_schema_s1.grant_schema_t1(a int); +go + +create table grant_schema_s1.grant_schema_t2(b int); +go + +create table grant_schema_s1.grant_schema_t3(c int); +go + +create view grant_schema_s1.grant_schema_v1 as select 2; +go + +create view grant_schema_s1.grant_schema_v2 as select 2; +go + +create proc grant_schema_s1.grant_schema_p1 as select 2; +go + +create proc grant_schema_s1.grant_schema_p2 as select 2; +go + +CREATE FUNCTION grant_schema_s1.grant_schema_f1() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go + +CREATE FUNCTION grant_schema_s1.grant_schema_f2() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go + +create schema grant_schema_s2; +go + +create table grant_schema_s2.grant_schema_t1(a int); +go + +create table grant_schema_s2.grant_schema_t2(a int); +go + +-- GRANT OBJECT privilege +grant select on grant_schema_s1.grant_schema_t1 to grant_schema_u1; +go +grant select on grant_schema_s1.grant_schema_t3 to grant_schema_u1; +go +grant select on grant_schema_s1.grant_schema_v1 to grant_schema_u1; +go +grant select on grant_schema_s1.grant_schema_v2 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_p1 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_p2 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_f1 to grant_schema_u1; +go +grant execute on grant_schema_s1.grant_schema_f2 to grant_schema_u1; +go +grant select on grant_schema_s2.grant_schema_t1 to grant_schema_u1; +go +grant select on grant_schema_s2.grant_schema_t2 to grant_schema_u1; +go \ No newline at end of file diff --git a/test/JDBC/input/GRANT_SCHEMA-vu-verify.mix b/test/JDBC/input/GRANT_SCHEMA-vu-verify.mix new file mode 100644 index 0000000000..09e9a23336 --- /dev/null +++ b/test/JDBC/input/GRANT_SCHEMA-vu-verify.mix @@ -0,0 +1,179 @@ +-- tsql user=grant_schema_l1 password=12345678 +-- User has OBJECT privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t1; +go + +select * from grant_schema_s1.grant_schema_t2; -- case 1: has no permission +go + +select * from grant_schema_s1.grant_schema_v1; +go + +exec grant_schema_s1.grant_schema_p1; +go + +select * from grant_schema_s1.grant_schema_f1(); +go + +-- tsql +-- REVOKE OBJECT privilege +use grant_schema_d1; +go +revoke select on grant_schema_s1.grant_schema_t1 from grant_schema_u1; +go +revoke select on grant_schema_s1.grant_schema_v1 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_p1 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_f1 from grant_schema_u1; +go + +-- tsql user=grant_schema_l1 password=12345678 +-- User has no privileges, should not be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t1; +go + +select * from grant_schema_s1.grant_schema_v1; +go + +exec grant_schema_s1.grant_schema_p1; +go + +select * from grant_schema_s1.grant_schema_f1(); +go + +-- tsql +-- GRANT SCHEMA privilege +use grant_schema_d1; +go +grant select, execute on schema::grant_schema_s1 to grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +-- User has SCHEMA privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t1; +go + +select * from grant_schema_s1.grant_schema_t2; +go + +select * from grant_schema_s1.grant_schema_v1; +go + +exec grant_schema_s1.grant_schema_p1; +go + +select * from grant_schema_s1.grant_schema_f1(); +go + +-- User has OBJECT and SCHEMA privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t3; +go + +select * from grant_schema_s1.grant_schema_v2; +go + +exec grant_schema_s1.grant_schema_p2; +go + +select * from grant_schema_s1.grant_schema_f2(); +go + +-- tsql +-- Case 6: User has SCHEMA privilege, REVOKE OBJECT privilege +use grant_schema_d1; +go +revoke select on grant_schema_s1.grant_schema_t3 from grant_schema_u1; +go +revoke select on grant_schema_s1.grant_schema_v2 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_p2 from grant_schema_u1; +go +revoke execute on grant_schema_s1.grant_schema_f2 from grant_schema_u1; +go + +-- tsql user=grant_schema_l1 password=12345678 +-- User has SCHEMA privileges, should be accessible. +use grant_schema_d1; +go + +select * from grant_schema_s1.grant_schema_t3; +go + +select * from grant_schema_s1.grant_schema_v2; +go + +exec grant_schema_s1.grant_schema_p2; +go + +select * from grant_schema_s1.grant_schema_f2(); +go + +-- tsql +-- User has OBJECT privilege, REVOKE OBJECT privilege +-- case 7: User has no privileges, should not be accessible. +use grant_schema_d1; +go +revoke select on grant_schema_s2.grant_schema_t2 from grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +use grant_schema_d1; +go + +select * from grant_schema_s2.grant_schema_t2; +go + +-- tsql +-- User has OBJECT privilege, REVOKE SCHEMA privilege +-- case 8: User has OBJECT privileges, would not be accessible. +use grant_schema_d1; +go +revoke select on schema::grant_schema_s2 from grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +use grant_schema_d1; +go + +select * from grant_schema_s2.grant_schema_t1; +go + +-- tsql +-- User has OBJECT privilege, GRANT and REVOKE SCHEMA privilege +-- case 5: User has OBJECT privileges, would not be accessible. +use grant_schema_d1; +go +grant select on schema::grant_schema_s2 to grant_schema_u1; +go + +revoke select on schema::grant_schema_s2 from grant_schema_u1; +go +use master; +go + +-- tsql user=grant_schema_l1 password=12345678 +use grant_schema_d1; +go + +select * from grant_schema_s2.grant_schema_t1; +go + diff --git a/test/JDBC/input/GRANT_SCHEMA.mix b/test/JDBC/input/GRANT_SCHEMA.mix new file mode 100644 index 0000000000..1572bea803 --- /dev/null +++ b/test/JDBC/input/GRANT_SCHEMA.mix @@ -0,0 +1,386 @@ +-- tsql +-- create objects +create database babel_4344_d1; +go + +use babel_4344_d1; +go + +create login babel_4344_l1 with password = '12345678' +go + +create user babel_4344_u1 for login babel_4344_l1; +go + +create schema babel_4344_s1; +go + +create schema babel_4344_s2 authorization babel_4344_u1; +go + +create table babel_4344_t1(a int); +go + +create table babel_4344_s1.babel_4344_t1(a int); +go + +create table babel_4344_s2.babel_4344_t1(a int); +go + +create table babel_4344_t3(a int, b int); +go + +create table babel_4344_s1.babel_4344_t3(a int, b int); +go + +create view babel_4344_v1 as select 1; +go + +create view babel_4344_s1.babel_4344_v1 as select 2; +go + +create proc babel_4344_p1 as select 1; +go + +create proc babel_4344_s1.babel_4344_p1 as select 2; +go + +CREATE FUNCTION babel_4344_f1() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.tables) END +go + +CREATE FUNCTION babel_4344_s1.babel_4344_f1() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go + +-- tsql user=babel_4344_l1 password=12345678 +use babel_4344_d1; +go + +-- User doesn't have any privileges, objects should not be accessible +select * from babel_4344_t1; +go +select * from babel_4344_s1.babel_4344_t1 +go +insert into babel_4344_s1.babel_4344_t1 values(1); +go +select * from babel_4344_v1; +go +select * from babel_4344_s1.babel_4344_v1; +go +exec babel_4344_p1; +go +exec babel_4344_s1.babel_4344_p1; +go +select * from babel_4344_f1(); +go +select * from babel_4344_s1.babel_4344_f1(); +go +use master; +go + +-- tsql +-- GRANT OBJECT privilege +use babel_4344_d1; +go +grant select on babel_4344_t1 to babel_4344_u1; +go +grant select on babel_4344_s1.babel_4344_t1 to babel_4344_u1; +go +grant all on babel_4344_s1.babel_4344_t1 to babel_4344_u1; +go +grant select on babel_4344_t3(a) to babel_4344_u1; -- column privilege +go +grant select on babel_4344_s1.babel_4344_t3(a) to babel_4344_u1; -- column privilege +go +grant select on babel_4344_v1 to babel_4344_u1; +go +grant select on babel_4344_s1.babel_4344_v1 to babel_4344_u1; +go +grant execute on babel_4344_p1 to babel_4344_u1; +go +grant execute on babel_4344_s1.babel_4344_p1 to babel_4344_u1; +go +grant execute on babel_4344_f1 to babel_4344_u1; +go +grant execute on babel_4344_s1.babel_4344_f1 to babel_4344_u1; +go +-- Grant schema permission to its owner, should fail +grant select on schema::babel_4344_s2 to babel_4344_u1; -- should fail +go +grant select on schema::babel_4344_s2 to jdbc_user; -- should fail +go +grant select on schema::babel_4344_s2 to guest; -- should pass +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has OBJECT privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_t1; +go +select * from babel_4344_s1.babel_4344_t1 +go +insert into babel_4344_s1.babel_4344_t1 values(2); +go +select * from babel_4344_t3; -- not accessible, only column privilege is granted +go +select * from babel_4344_s1.babel_4344_t3 -- not accessible, only column privilege is granted +go +select * from babel_4344_v1; +go +select * from babel_4344_s1.babel_4344_v1; +go +exec babel_4344_p1; +go +exec babel_4344_s1.babel_4344_p1; +go +select * from babel_4344_f1(); +go +select * from babel_4344_s1.babel_4344_f1(); +go +-- Grant schema permission to its owner +grant select on schema::babel_4344_s2 to babel_4344_u1; -- should fail +go +grant select on schema::babel_4344_s2 to guest; -- should pass +go +grant select on schema::babel_4344_s1 to babel_4344_u1; -- should fail +go +use master; +go + +-- tsql +-- GRANT SCHEMA privilege +use babel_4344_d1; +go +grant select, insert, execute on schema::babel_4344_s1 to babel_4344_u1; +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has OBJECT and SCHEMA privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1 +go +insert into babel_4344_s1.babel_4344_t1 values(3); +go +select * from babel_4344_s1.babel_4344_t3 +go +select * from babel_4344_s1.babel_4344_v1; +go +exec babel_4344_s1.babel_4344_p1; +go +select * from babel_4344_s1.babel_4344_f1(); +go +use master; +go + +-- tsql +-- REVOKE SCHEMA privilege +use babel_4344_d1; +go +revoke select, insert, execute on schema::babel_4344_s1 from babel_4344_u1; +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has OBJECT privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1 +go +insert into babel_4344_s1.babel_4344_t1 values(3); +go +select * from babel_4344_s1.babel_4344_t3 -- not accessible +go +select * from babel_4344_s1.babel_4344_v1; +go +exec babel_4344_s1.babel_4344_p1; -- TODO: should be accessible +go +select * from babel_4344_s1.babel_4344_f1(); -- TODO: should be accessible +go +select * from babel_4344_s2.babel_4344_t1; +go +use master; +go + +-- tsql +-- create new objects in same schema +use babel_4344_d1; +go +-- Grant the permissions again +grant select, insert, execute on schema::babel_4344_s1 to babel_4344_u1; +go +create table babel_4344_s1.babel_4344_t2(a int); +go +create view babel_4344_s1.babel_4344_v2 as select 2; +go +create proc babel_4344_s1.babel_4344_p2 as select 2; +go +CREATE FUNCTION babel_4344_s1.babel_4344_f2() RETURNS INT AS BEGIN RETURN (SELECT COUNT(*) FROM sys.objects) END +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has SCHEMA privileges,objects should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t2 +go +insert into babel_4344_s1.babel_4344_t1 values(4); +go +select * from babel_4344_s1.babel_4344_v2; +go +exec babel_4344_s1.babel_4344_p2; +go +select * from babel_4344_s1.babel_4344_f2(); +go +use master; +go + +-- tsql +-- REVOKE OBJECT privileges +use babel_4344_d1; +go +REVOKE all on babel_4344_s1.babel_4344_t1 FROM babel_4344_u1; +go +REVOKE select on babel_4344_s1.babel_4344_t3(a) FROM babel_4344_u1; +go +REVOKE select on babel_4344_s1.babel_4344_v1 FROM babel_4344_u1; +go +REVOKE execute on babel_4344_s1.babel_4344_p1 FROM babel_4344_u1; +go +REVOKE execute on babel_4344_s1.babel_4344_f1 FROM babel_4344_u1; +go +REVOKE all on babel_4344_s1.babel_4344_f1 FROM babel_4344_u1; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has SCHEMA privileges, should be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1 +go +insert into babel_4344_s1.babel_4344_t1 values(5); +go +select * from babel_4344_s1.babel_4344_t3; +go +select * from babel_4344_s1.babel_4344_v1; +go +exec babel_4344_s1.babel_4344_p1; +go +select * from babel_4344_s1.babel_4344_f1(); +go +select * from babel_4344_s2.babel_4344_t1; +go +use master; +go + +-- tsql +-- REVOKE SCHEMA privileges +use babel_4344_d1; +go +revoke select, insert, execute on schema::babel_4344_s1 from babel_4344_u1; +go +use master; +go + +-- tsql user=babel_4344_l1 password=12345678 +-- User has no privileges, shouldn't be accessible. +use babel_4344_d1; +go +select * from babel_4344_s1.babel_4344_t1; +go +insert into babel_4344_s1.babel_4344_t1 values(5); +go +select * from babel_4344_s1.babel_4344_t3; +go +select * from babel_4344_s1.babel_4344_v1; +go +exec babel_4344_s1.babel_4344_p1; +go +select * from babel_4344_s1.babel_4344_f1(); +go +use master; +go + +-- tsql +-- Drop objects +use babel_4344_d1; +go + +drop table babel_4344_t1; +go + +drop table babel_4344_s1.babel_4344_t1; +go + +drop table babel_4344_t3; +go + +drop table babel_4344_s1.babel_4344_t3; +go + +drop table babel_4344_s1.babel_4344_t2; +go + +drop view babel_4344_v1; +go + +drop view babel_4344_s1.babel_4344_v1; +go + +drop view babel_4344_s1.babel_4344_v2; +go + +drop proc babel_4344_p1; +go + +drop proc babel_4344_s1.babel_4344_p1; +go + +drop proc babel_4344_s1.babel_4344_p2; +go + +drop function babel_4344_f1; +go + +drop function babel_4344_s1.babel_4344_f1; +go + +drop function babel_4344_s1.babel_4344_f2; +go + +drop schema babel_4344_s1; +go + +drop table babel_4344_s2.babel_4344_t1; +go + +drop schema babel_4344_s2; +go + +drop user babel_4344_u1; +go + +use master; +go + +drop database babel_4344_d1; +go + +-- psql +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'babel_4344_l1' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +go + +-- Wait to sync with another session +SELECT pg_sleep(1); +go + +-- tsql +drop login babel_4344_l1; +go diff --git a/test/JDBC/input/col_length-vu-cleanup.sql b/test/JDBC/input/col_length-vu-cleanup.sql index 97b139d464..d6a6590e21 100644 --- a/test/JDBC/input/col_length-vu-cleanup.sql +++ b/test/JDBC/input/col_length-vu-cleanup.sql @@ -60,3 +60,38 @@ DROP FUNCTION IF EXISTS col_length_prepare_f14(); DROP FUNCTION IF EXISTS col_length_prepare_f15(); DROP FUNCTION IF EXISTS col_length_prepare_f16(); GO + +-- Drop types +DROP TYPE IF EXISTS custom_char_10; +DROP TYPE IF EXISTS custom_varchar_20; +DROP TYPE IF EXISTS custom_binary_5; +DROP TYPE IF EXISTS custom_varbinary_15; +DROP TYPE IF EXISTS custom_nchar_8; +DROP TYPE IF EXISTS custom_nvarchar_16; +DROP TYPE IF EXISTS custom_text; +DROP TYPE IF EXISTS custom_image; +DROP TYPE IF EXISTS custom_ntext; +DROP TYPE IF EXISTS custom_sysname; +DROP TYPE IF EXISTS custom_sql_variant; +DROP TYPE IF EXISTS custom_xml; +DROP TYPE IF EXISTS custom_varcharmax; +DROP TYPE IF EXISTS custom_nvarcharmax; +DROP TYPE IF EXISTS custom_varbinarymax; +DROP TYPE IF EXISTS custom_bit; +DROP TYPE IF EXISTS custom_tinyint; +DROP TYPE IF EXISTS custom_bigint; +DROP TYPE IF EXISTS custom_smallint; +DROP TYPE IF EXISTS custom_smallmoney; +DROP TYPE IF EXISTS custom_money; +DROP TYPE IF EXISTS custom_smalldatetime; +DROP TYPE IF EXISTS custom_real; +DROP TYPE IF EXISTS custom_float; +DROP TYPE IF EXISTS custom_time; +DROP TYPE IF EXISTS custom_datetime; +DROP TYPE IF EXISTS custom_datetime2; +DROP TYPE IF EXISTS custom_datetimeoffset; +DROP TYPE IF EXISTS custom_uniqueidentifier; +DROP TYPE IF EXISTS custom_date; +DROP TYPE IF EXISTS custom_decimal_10_5; +DROP TYPE IF EXISTS custom_numeric_3_0; +GO diff --git a/test/JDBC/input/col_length-vu-prepare.sql b/test/JDBC/input/col_length-vu-prepare.sql index a602c7a69c..1f777a404f 100644 --- a/test/JDBC/input/col_length-vu-prepare.sql +++ b/test/JDBC/input/col_length-vu-prepare.sql @@ -51,8 +51,139 @@ CREATE TABLE sys_col_length_test_schema.test_table( ); GO -INSERT INTO sys_col_length_test_schema.test_table (col_char, col_varchar, col_varbinary) -VALUES ('ABCDEF', 'Hello, World!', 0x0123456789ABCDEF) +-- for user defined data types +-- Create User-Defined Types +CREATE TYPE custom_char_10 FROM CHAR(10); +GO + +CREATE TYPE custom_varchar_20 FROM VARCHAR(20); +GO + +CREATE TYPE custom_binary_5 FROM BINARY(5); +GO + +CREATE TYPE custom_varbinary_15 FROM VARBINARY(15); +GO + +CREATE TYPE custom_nchar_8 FROM NCHAR(8); +GO + +CREATE TYPE custom_nvarchar_16 FROM NVARCHAR(16); +GO + +CREATE TYPE custom_text FROM TEXT; +GO + +CREATE TYPE custom_image FROM IMAGE; +GO + +CREATE TYPE custom_ntext FROM NTEXT; +GO + +CREATE TYPE custom_sysname FROM sysname; +GO + +CREATE TYPE custom_sql_variant FROM SQL_VARIANT; +GO + +CREATE TYPE custom_xml FROM XML; +GO + +CREATE TYPE custom_varcharmax FROM VARCHAR(MAX); +GO + +CREATE TYPE custom_nvarcharmax FROM NVARCHAR(MAX); +GO + +CREATE TYPE custom_varbinarymax FROM VARBINARY(MAX); +GO + +CREATE TYPE custom_bit FROM BIT; +GO + +CREATE TYPE custom_tinyint FROM TINYINT; +GO + +CREATE TYPE custom_bigint FROM BIGINT; +GO + +CREATE TYPE custom_smallint FROM SMALLINT; +GO + +CREATE TYPE custom_smallmoney FROM SMALLMONEY; +GO + +CREATE TYPE custom_money FROM MONEY; +GO + +CREATE TYPE custom_smalldatetime FROM SMALLDATETIME; +GO + +CREATE TYPE custom_real FROM REAL; +GO + +CREATE TYPE custom_float FROM FLOAT; +GO + +CREATE TYPE custom_time FROM TIME; +GO + +CREATE TYPE custom_datetime FROM DATETIME; +GO + +CREATE TYPE custom_datetime2 FROM DATETIME2; +GO + +CREATE TYPE custom_datetimeoffset FROM DATETIMEOFFSET; +GO + +CREATE TYPE custom_uniqueidentifier FROM UNIQUEIDENTIFIER; +GO + +CREATE TYPE custom_date FROM DATE; +GO + +CREATE TYPE custom_decimal_10_5 FROM DECIMAL(10,5); +GO + +CREATE TYPE custom_numeric_3_0 FROM NUMERIC(3,0); +GO + +-- Create Table with User-Defined Data Types +CREATE TABLE udd_test_table ( + col_customchar custom_char_10, + col_customvarchar custom_varchar_20, + col_custombinary custom_binary_5, + col_customvarbinary custom_varbinary_15, + col_customnchar custom_nchar_8, + col_customnvarchar custom_nvarchar_16, + col_customtext custom_text, + col_customimage custom_image, + col_customntext custom_ntext, + col_customsysname custom_sysname, + col_customsqlvariant custom_sql_variant, + col_customxml custom_xml, + col_customvarcharmax custom_varcharmax, + col_customnvarcharmax custom_nvarcharmax, + col_customvarbinarymax custom_varbinarymax, + col_custombit custom_bit, + col_customtinyint custom_tinyint, + col_custombigint custom_bigint, + col_customsmallint custom_smallint, + col_customsmallmoney custom_smallmoney, + col_custommoney custom_money, + col_customsmalldatetime custom_smalldatetime, + col_customreal custom_real, + col_customfloat custom_float, + col_customtime custom_time, + col_customdatetime custom_datetime, + col_customdatetime2 custom_datetime2, + col_customdatetimeoffset custom_datetimeoffset, + col_customuniqueidentifier custom_uniqueidentifier, + col_customdate custom_date, + col_customdecimal custom_decimal_10_5, + col_customnumeric custom_numeric_3_0 +); GO CREATE VIEW col_length_prepare_v1 AS (SELECT COL_LENGTH('sys_column_length_test_table', 'ID')); @@ -118,84 +249,84 @@ CREATE PROCEDURE col_length_prepare_p10 AS (SELECT COL_LENGTH('sys_column_length GO CREATE FUNCTION col_length_prepare_f1() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_xml')); END GO CREATE FUNCTION col_length_prepare_f2() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_varcharmax')); END GO CREATE FUNCTION col_length_prepare_f3() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_nvarcharmax')); END GO CREATE FUNCTION col_length_prepare_f4() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_varbinarymax')); END GO CREATE FUNCTION col_length_prepare_f5() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_bit')); END GO CREATE FUNCTION col_length_prepare_f6() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_tinyint')); END GO CREATE FUNCTION col_length_prepare_f7() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_bigint')); END GO CREATE FUNCTION col_length_prepare_f8() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_smallint')); END GO CREATE FUNCTION col_length_prepare_f9() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_smallmoney')); END GO CREATE FUNCTION col_length_prepare_f10() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_money')); END GO CREATE FUNCTION col_length_prepare_f11() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_smalldatetime')); END GO CREATE FUNCTION col_length_prepare_f12() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 'col_real')); END @@ -203,7 +334,7 @@ GO -- Invalid column, should return NULL CREATE FUNCTION col_length_prepare_f13() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', 1)); END @@ -211,7 +342,7 @@ GO -- Invalid column, should return NULL CREATE FUNCTION col_length_prepare_f14() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', -1)); END @@ -219,7 +350,7 @@ GO -- Invalid table, should return NULL CREATE FUNCTION col_length_prepare_f15() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH(NULL, 'col_char')); END @@ -227,7 +358,7 @@ GO -- NULL column, should return NULL CREATE FUNCTION col_length_prepare_f16() -RETURNS INT AS +RETURNS SMALLINT AS BEGIN RETURN (SELECT COL_LENGTH('sys_column_length_test_table', NULL)); END diff --git a/test/JDBC/input/col_length-vu-verify.sql b/test/JDBC/input/col_length-vu-verify.sql index 60a9a77d52..856eab8448 100644 --- a/test/JDBC/input/col_length-vu-verify.sql +++ b/test/JDBC/input/col_length-vu-verify.sql @@ -174,3 +174,99 @@ SELECT END AS ColumnStatus; GO +-- Test Cases for User-Defined Data Types +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customchar'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarchar'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custombinary'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarbinary'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnchar'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnvarchar'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customtext'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customimage'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customntext'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsysname'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsqlvariant'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customxml'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarcharmax'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnvarcharmax'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customvarbinarymax'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custombit'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customtinyint'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custombigint'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsmallint'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsmallmoney'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_custommoney'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customsmalldatetime'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customreal'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customfloat'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customtime'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdatetime'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdatetime2'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdatetimeoffset'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customuniqueidentifier'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdate'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customdecimal'); +GO + +SELECT * FROM sys.COL_LENGTH('udd_test_table', 'col_customnumeric'); +GO diff --git a/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..5be5342d57 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,63 @@ +-- FOR JSON PATH clause without nested support +DROP VIEW forjson_vu_v_people +GO + +DROP VIEW forjson_vu_v_countries +GO + +-- Multiple tables without nested support +DROP VIEW forjson_vu_v_join +GO + +-- ROOT directive without specifying value +DROP VIEW forjson_vu_v_root +GO + +-- ROOT directive with specifying ROOT value +DROP VIEW forjson_vu_v_root_value +GO + +-- ROOT directive with specifying ROOT value with empty string +DROP VIEW forjson_vu_v_empty_root +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +DROP VIEW forjson_vu_v_without_array_wrapper +GO + +-- INCLUDE_NULL_VALUES directive +DROP VIEW forjson_vu_v_include_null_values +GO + +-- Multiple Directives +DROP VIEW forjson_vu_v_root_include_null_values +GO + +DROP VIEW forjson_vu_v_without_array_wrapper_include_null_values +GO + + +-- Test case with parameters +DROP PROCEDURE forjson_vu_p_params1 +GO + +DROP PROCEDURE forjson_vu_p_params2 +GO + +-- All null values test +DROP VIEW forjson_vu_v_nulls +GO + +-- Test for all parser rules +DROP VIEW forjson_vu_v_order_by +GO + +-- Display Table Contents +DROP TABLE forjson_vu_t_people +GO + +DROP TABLE forjson_vu_t_countries +GO + +DROP TABLE forjson_vu_t_values +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..3947821204 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,198 @@ +CREATE TABLE forjson_vu_t_people ( +[Id] INT, +[FirstName] VARCHAR(25), +[LastName] VARCHAR(25), +[State] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_people values +(1,'Divya','Kumar',NULL), +(2,NULL,'Khanna','Bengaluru'), +(3,'Tom','Mehta','Kolkata'), +(4,'Kane',NULL,'Delhi') +GO + +CREATE TABLE forjson_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO + +CREATE TABLE forjson_vu_t_values ( +[Id] INT, +[value] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_values values +(1,NULL), +(2,NULL), +(3,NULL) +GO + +-- FOR JSON PATH clause without nested support +CREATE VIEW forjson_vu_v_people AS +SELECT ( + SELECT Id AS EmpId, + FirstName AS "Name.FirstName", + LastName AS "Name.LastName", + State + FROM forjson_vu_t_people + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_vu_v_countries AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH +) c1 +GO + +-- Multiple tables without nested support +CREATE VIEW forjson_vu_v_join AS +SELECT ( + SELECT E.FirstName AS 'Person.Name', + E.LastName AS 'Person.Surname', + D.Age AS 'Employee.Price', + D.Country AS 'Employee.Quantity' + FROM forjson_vu_t_people E + INNER JOIN forjson_vu_t_countries D + ON E.Id = D.Id + FOR JSON PATH +) c1 +GO + +-- ROOT directive without specifying value +CREATE VIEW forjson_vu_v_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT +) c1 +GO + +-- ROOT directive with specifying ROOT value +CREATE VIEW forjson_vu_v_root_value AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('Employee') +) c1 +GO + +-- ROOT directive with specifying ROOT value with empty string +CREATE VIEW forjson_vu_v_empty_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('') +) c1 +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +CREATE VIEW forjson_vu_v_without_array_wrapper AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER +) c1 +GO + +-- INCLUDE_NULL_VALUES directive +CREATE VIEW forjson_vu_v_include_null_values AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, INCLUDE_NULL_VALUES +) c1 +GO + +-- Multiple Directives +CREATE VIEW forjson_vu_v_root_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT('Employee'), INCLUDE_NULL_VALUES +) c1 +GO + +CREATE VIEW forjson_vu_v_without_array_wrapper_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER, INCLUDE_NULL_VALUES +) c1 +GO + +-- Throws error as ROOT and WITHOUT_ARRAY_WRAPPER cannot be used together +CREATE VIEW forjson_vu_v_root_and_without_array_wrapper AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT, WITHOUT_ARRAY_WRAPPER +) c1 +GO + +-- Test case with parameters +CREATE PROCEDURE forjson_vu_p_params1 @id int AS +SELECT ( + SELECT Firstname AS [Name], + State + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_params2 @id int AS +SELECT ( + SELECT Firstname AS [nam"@e], + State AS [State"@] + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +-- All null values test +CREATE VIEW forjson_vu_v_nulls AS +SELECT ( + SELECT value + FROM forjson_vu_t_values + FOR JSON PATH +) c1 +GO + +-- Test for all parser rules +CREATE VIEW forjson_vu_v_order_by AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + ORDER BY Age + FOR JSON PATH +) C1 +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..e0c3879c41 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,63 @@ +-- Display Table Contents +SELECT * FROM forjson_vu_t_people +GO + +SELECT * FROM forjson_vu_t_countries +GO + +SELECT * FROM forjson_vu_t_values +GO + +-- FOR JSON PATH clause without nested support +SELECT * FROM forjson_vu_v_people +GO + +SELECT * FROM forjson_vu_v_countries +GO + +-- Multiple tables without nested support +SELECT * FROM forjson_vu_v_join +GO + +-- ROOT directive without specifying value +SELECT * FROM forjson_vu_v_root +GO + +-- ROOT directive with specifying ROOT value +SELECT * FROM forjson_vu_v_root_value +GO + +-- ROOT directive with specifying ROOT value with empty string +SELECT * FROM forjson_vu_v_empty_root +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +SELECT * FROM forjson_vu_v_without_array_wrapper +GO + +-- INCLUDE_NULL_VALUES directive +SELECT * FROM forjson_vu_v_include_null_values +GO + +-- Multiple Directives +SELECT * FROM forjson_vu_v_root_include_null_values +GO + +SELECT * FROM forjson_vu_v_without_array_wrapper_include_null_values +GO + + +-- Test case with parameters +EXECUTE forjson_vu_p_params1 @id = 2 +GO + +EXECUTE forjson_vu_p_params2 @id = 3 +GO + +-- All null values test +SELECT * FROM forjson_vu_v_nulls +GO + +-- Test for all parser rules +SELECT * FROM forjson_vu_v_order_by +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..1b793f1fca --- /dev/null +++ b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,74 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +DROP VIEW forjson_datatypes_vu_v_numerics +GO + +DROP VIEW forjson_datatypes_vu_v_bit +GO + +DROP VIEW forjson_datatypes_vu_v_money +GO + +DROP VIEW forjson_datatypes_vu_v_smallmoney +GO + +-- Approximate numerics +DROP VIEW forjson_datatypes_vu_v_approx_numerics +GO + +-- Date and time +DROP VIEW forjson_datatypes_vu_v_time_date +GO + +DROP VIEW forjson_datatypes_vu_v_smalldatetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime2 +GO + +DROP VIEW forjson_datatypes_vu_v_datetimeoffset +GO + +-- Character strings +DROP VIEW forjson_datatypes_vu_v_strings +GO + +-- Unicode character strings +DROP VIEW forjson_datatypes_vu_v_unicode_strings +GO + +-- NULL datetimes +DROP VIEW forjson_datatypes_vu_v_nulldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nullsmalldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetime2; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetimeoffset; +go + +-- DROP TABLE +DROP TABLE forjson_datatypes_vu_t_exact_numerics +GO + +-- Approximate numerics +DROP TABLE forjson_datatypes_vu_t_approx_numerics +GO + +-- Date and time +DROP TABLE forjson_datatypes_vu_t_date_and_time +GO + +-- Character strings +DROP TABLE forjson_datatypes_vu_t_strings +GO + +-- Unicode character strings +DROP TABLE forjson_datatypes_vu_t_unicode_strings +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..fcf3d1f0d2 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,172 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +CREATE TABLE forjson_datatypes_vu_t_exact_numerics(abigint bigint, abit bit, adecimal decimal, aint int, amoney money, anumeric numeric, asmallint smallint, asmallmoney smallmoney, atinyint tinyint) +GO +INSERT forjson_datatypes_vu_t_exact_numerics VALUES(9223372036854775807, 1, 123.2, 2147483647, 3148.29, 12345.12, 32767, 3148.29, 255) +GO + +-- Approximate numerics +CREATE TABLE forjson_datatypes_vu_t_approx_numerics(afloat float, areal real) +GO +INSERT forjson_datatypes_vu_t_approx_numerics VALUES(12.05, 120.53) +GO + +-- Date and time +CREATE TABLE forjson_datatypes_vu_t_date_and_time(atime time, adate date, asmalldatetime smalldatetime, adatetime datetime, adatetime2 datetime2, adatetimeoffset datetimeoffset, adatetimeoffset_2 datetimeoffset) +GO +INSERT forjson_datatypes_vu_t_date_and_time VALUES('2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560', '2012-10-12 12:34:56 +02:30') +GO + +-- Character strings +CREATE TABLE forjson_datatypes_vu_t_strings(achar char, avarchar varchar(3), atext text) +GO +INSERT forjson_datatypes_vu_t_strings VALUES('a','abc','abc') +GO + +-- Unicode character strings +CREATE TABLE forjson_datatypes_vu_t_unicode_strings(anchar nchar(5), anvarchar nvarchar(5), antext ntext) +GO +INSERT forjson_datatypes_vu_t_unicode_strings VALUES('abc','abc','abc') +GO + +-- T-SQL does not allow raw scalars as the output of a view, so surround the FOR JSON call with a SELECT to avoid a syntax error +-- Exact Numerics +CREATE VIEW forjson_datatypes_vu_v_numerics AS +SELECT +( + SELECT abigint, adecimal, aint, anumeric, asmallint, atinyint + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_bit AS +SELECT +( + SELECT abit + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_money AS +SELECT +( + SELECT amoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smallmoney AS +SELECT +( + SELECT asmallmoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +-- Approximate numerics +CREATE VIEW forjson_datatypes_vu_v_approx_numerics AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_approx_numerics + FOR JSON PATH +) as c1; +GO + +-- Date and time +CREATE VIEW forjson_datatypes_vu_v_time_date AS +SELECT +( + SELECT atime,adate + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smalldatetime AS +SELECT +( + SELECT asmalldatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime AS +SELECT +( + SELECT adatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime2 AS +SELECT +( + SELECT adatetime2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetimeoffset AS +SELECT +( + SELECT adatetimeoffset, adatetimeoffset_2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +-- Character strings +CREATE VIEW forjson_datatypes_vu_v_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_strings + FOR JSON PATH +) as c1; +GO + +-- Unicode character strings +CREATE VIEW forjson_datatypes_vu_v_unicode_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_unicode_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime AS +SELECT +( + select cast(null as datetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nullsmalldatetime AS +SELECT +( + select cast(null as smalldatetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime2 AS +SELECT +( + select cast(null as datetime2) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetimeoffset AS +SELECT +( + select cast(null as datetimeoffset) for JSON PATH +) as c1; +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..fb02ca4b70 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,55 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +SELECT * FROM forjson_datatypes_vu_v_numerics +GO + +SELECT * FROM forjson_datatypes_vu_v_bit +GO + +SELECT * FROM forjson_datatypes_vu_v_money +GO + +SELECT * FROM forjson_datatypes_vu_v_smallmoney +GO + +-- Approximate numerics +SELECT * FROM forjson_datatypes_vu_v_approx_numerics +GO + +-- Date and time +SELECT * FROM forjson_datatypes_vu_v_time_date +GO + +SELECT * FROM forjson_datatypes_vu_v_smalldatetime +GO + +SELECT * FROM forjson_datatypes_vu_v_datetime +GO + +SELECT * FROM forjson_datatypes_vu_v_datetime2 +GO + +SELECT * FROM forjson_datatypes_vu_v_datetimeoffset +GO + +-- Character strings +SELECT * FROM forjson_datatypes_vu_v_strings +GO + +-- Unicode character strings +SELECT * FROM forjson_datatypes_vu_v_unicode_strings +GO + +-- NULL datetime and datetimeoffset + +SELECT * FROM forjson_datatypes_vu_v_nulldatetime +GO + +SELECT * FROM forjson_datatypes_vu_v_nullsmalldatetime +GO + +SELECT * FROM forjson_datatypes_vu_v_nulldatetime2 +GO + +SELECT * FROM forjson_datatypes_vu_v_nulldatetimeoffset +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql new file mode 100644 index 0000000000..d91d5577e7 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql @@ -0,0 +1,45 @@ +-- FOR JSON PATH CLAUSE with nested json support for existing objects +DROP VIEW forjson_nesting_vu_v_users +GO + +DROP VIEW forjson_nesting_vu_v_products +GO + +DROP VIEW forjson_nesting_vu_v_orders +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +DROP VIEW forjson_nesting_vu_v_deep +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +DROP VIEW forjson_nesting_vu_v_join_deep +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +DROP VIEW forjson_nesting_vu_v_layered_insert +GO + +-- Error related to inserting value at Json object location +DROP VIEW forjson_nesting_vu_v_error +GO + +-- Queries that check NULL nested json object insert +DROP VIEW forjson_nesting_vu_v_no_null +GO + +DROP VIEW forjson_nesting_vu_v_with_null +GO + +-- DROP Tables +DROP TABLE forjson_nesting_vu_t_users +GO + +DROP TABLE forjson_nesting_vu_t_products +GO + +DROP TABLE forjson_nesting_vu_t_orders +GO + +DROP TABLE forjson_nesting_vu_t_null_users +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql b/test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql new file mode 100644 index 0000000000..013af8d17b --- /dev/null +++ b/test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql @@ -0,0 +1,168 @@ +CREATE TABLE forjson_nesting_vu_t_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), +); +GO +CREATE TABLE forjson_nesting_vu_t_products ( + [Id] int, + [name] varchar(50), + [price] varchar (25) +); +GO +CREATE TABLE forjson_nesting_vu_t_orders ( + [Id] int, + [userid] int, + [productid] int, + [quantity] int, + [orderdate] Date +); +GO +CREATE TABLE forjson_nesting_vu_t_null_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), + [phone] varchar(25) +); +GO + +INSERT INTO forjson_nesting_vu_t_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com'), + (3, 'Mike', 'Johnson', 'mikejohnson'); +GO + +INSERT INTO forjson_nesting_vu_t_products +VALUES + (1, 'Product A', '10.99'), + (2, 'Product B', '19.99'), + (3, 'Product C', '5.99'); +GO + +INSERT INTO forjson_nesting_vu_t_orders +VALUES + (1, 1, 1, 2, '2023-06-25'), + (2, 1, 2, 1, '2023-06-25'), + (3, 2, 3, 3, '2023-06-26'); +GO + +INSERT INTO forjson_nesting_vu_t_null_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com', '123-456-7890'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com', NULL), + (3, NULL, NULL, 'mikejohnson@myspace.com', '098-765-4321'), + (4, 'Sergio', 'Giavanni', NULL, NULL); +GO + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +CREATE VIEW forjson_nesting_vu_v_users AS +SELECT ( + SELECT Id, + firstname AS "Name.first", + lastname AS "Name.last", + email + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_products AS +SELECT ( + SELECT Id, + name AS "Info.name", + price AS "Info.price" + FROM forjson_nesting_vu_t_products + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_orders AS +SELECT ( + SELECT Id AS "Id.orderid", + userid AS "Id.userid", + productid AS "Id.productid", + quantity AS "orderinfo.quantity", + orderdate AS "orderinfo.orderdate" + FROM forjson_nesting_vu_t_orders + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +CREATE VIEW forjson_nesting_vu_v_deep AS +SELECT ( + SELECT Id, + firstname AS "User.info.name.first", + lastname AS "User.info.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +CREATE VIEW forjson_nesting_vu_v_join_deep AS +SELECT ( + SELECT U.Id "User.id", + O.quantity AS "User.order.info.quantity", + O.orderdate AS "User.order.info.orderdate" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +CREATE VIEW forjson_nesting_vu_v_layered_insert AS +SELECT ( + SELECT U.id, + O.id AS "Order.Orderid", + P.id AS "Order.Product.Productid", + O.orderdate AS "Order.date" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + JOIN forjson_nesting_vu_t_products P + ON (P.id = O.productid) + FOR JSON PATH +) c1 +GO + +-- Error related to inserting value at Json object location +CREATE VIEW forjson_nesting_vu_v_error AS +SELECT ( + SELECT id, + firstname AS "user.name", + lastname AS "user.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) +GO + +-- Queries that check NULL nested json object insert +CREATE VIEW forjson_nesting_vu_v_no_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH +) +GO + +CREATE VIEW forjson_nesting_vu_v_with_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH, INCLUDE_NULL_VALUES +) +GO diff --git a/test/JDBC/input/forjson/forjson-nesting-vu-verify.sql b/test/JDBC/input/forjson/forjson-nesting-vu-verify.sql new file mode 100644 index 0000000000..efb10e7cb2 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-nesting-vu-verify.sql @@ -0,0 +1,43 @@ +-- Display Table Contents +SELECT * FROM forjson_nesting_vu_t_users +GO + +SELECT * FROM forjson_nesting_vu_t_products +GO + +SELECT * FROM forjson_nesting_vu_t_orders +GO + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +SELECT * FROM forjson_nesting_vu_v_users +GO + +SELECT * FROM forjson_nesting_vu_v_products +GO + +SELECT * FROM forjson_nesting_vu_v_orders +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +SELECT * FROM forjson_nesting_vu_v_deep +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +SELECT * FROM forjson_nesting_vu_v_join_deep +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +SELECT * FROM forjson_nesting_vu_v_layered_insert +GO + +-- Error related to inserting value at Json object location +SELECT * FROM forjson_nesting_vu_v_error +GO + +-- Queries that check NULL nested json object insert +SELECT * FROM forjson_nesting_vu_v_no_null +GO + +SELECT * FROM forjson_nesting_vu_v_with_null +GO + diff --git a/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..e30cb1bd5b --- /dev/null +++ b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,55 @@ +-- FOR JSON AUTO clause not supported +DROP VIEW forjson_subquery_vu_v_auto +GO + +-- Alias/colname is not present +DROP VIEW forjson_subquery_vu_v_no_alias +GO + +DROP VIEW forjson_subquery_vu_v_with +GO + +DROP VIEW forjson_subquery_vu_v_with_order_by +GO + +-- Binary strings +DROP VIEW forjson_subquery_vu_v_binary_strings +GO + +DROP VIEW forjson_subquery_vu_v_varbinary_strings +GO + +-- Rowversion and timestamp +DROP VIEW forjson_subquery_vu_v_rowversion +GO + +DROP VIEW forjson_subquery_vu_v_timestamp +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +DROP PROCEDURE forjson_subquery_vu_p_empty +GO + +-- exercise tsql_select_for_json_result internal function +DROP VIEW forjson_subquery_vu_v_internal +GO + +DROP TABLE forjson_subquery_vu_t_countries +GO + +DROP TABLE forjson_subquery_vu_t1 +GO + +-- Binary strings +DROP TABLE forjson_subquery_vu_t_binary_strings +GO + +-- Rowversion and timestamp +DROP TABLE forjson_subquery_vu_t_rowversion +GO + +DROP TABLE forjson_subquery_vu_t_timestamp +GO + +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'strict'; +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..9eeb1b1900 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,137 @@ +-- 14.7 (aka extension version 2.4.0) has a major change to how FOR JSON +-- has been implemented, which slightly changes the behavior around some old error +-- messages as well, so we need to move those tests to a new test file that separately +-- exercises them outside of the pre-14.6 upgrade tests. + +CREATE TABLE forjson_subquery_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_subquery_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO + +create table forjson_subquery_vu_t1 (x int) +insert into forjson_subquery_vu_t1 values (1) +go + +-- FOR JSON AUTO clause not supported +CREATE VIEW forjson_subquery_vu_v_auto AS +SELECT ( + SELECT Id, + State + FROM forjson_subquery_vu_t1 + FOR JSON AUTO +) c1 +GO + +-- Alias/colname not present +CREATE VIEW forjson_subquery_vu_v_no_alias AS +SELECT ( + SELECT 2 + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_subquery_vu_v_with AS +WITH forjson_subquery_vu_with1(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with1 + WHERE Age >= forjson_subquery_vu_with1.avg_age + FOR JSON PATH +) C1 +GO + +CREATE VIEW forjson_subquery_vu_v_with_order_by AS +WITH forjson_subquery_vu_with2(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with2 + WHERE Age >= forjson_subquery_vu_with2.avg_age + ORDER BY Country + FOR JSON PATH +) c1 +GO + +-- Binary strings +CREATE TABLE forjson_subquery_vu_t_binary_strings(abinary binary, avarbinary varbinary(10)) +GO +INSERT forjson_subquery_vu_t_binary_strings VALUES (123456,0x0a0b0c0d0e) +GO + +-- Rowversion and timestamp +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'ignore'; +GO + +CREATE TABLE forjson_subquery_vu_t_rowversion (myKey int, myValue int,RV rowversion); +GO +INSERT INTO forjson_subquery_vu_t_rowversion (myKey, myValue) VALUES (1, 0); +GO + +CREATE TABLE forjson_subquery_vu_t_timestamp (myKey int, myValue int, timestamp); +GO +INSERT INTO forjson_subquery_vu_t_timestamp (myKey, myValue) VALUES (1, 0); +GO + +-- Binary strings +CREATE VIEW forjson_subquery_vu_v_binary_strings AS +SELECT +( + SELECT abinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_varbinary_strings AS +SELECT +( + SELECT avarbinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +-- Rowversion and timestamp +CREATE VIEW forjson_subquery_vu_v_rowversion AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_rowversion + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_timestamp AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_timestamp + FOR JSON PATH +) as c1; +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +CREATE PROCEDURE forjson_subquery_vu_p_empty AS +SELECT * FROM forjson_subquery_vu_t_countries + WHERE 1 = 0 + FOR JSON PATH +GO + +-- exercise tsql_select_for_json_result internal function +CREATE VIEW forjson_subquery_vu_v_internal AS +SELECT * FROM tsql_select_for_json_result('abcd') +GO diff --git a/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..eec0a9ad98 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,38 @@ +-- FOR JSON AUTO clause not supported +SELECT * FROM forjson_subquery_vu_v_auto +GO + +-- Alias/colname is not present +SELECT * FROM forjson_subquery_vu_v_no_alias +GO + +SELECT * FROM forjson_subquery_vu_v_with +GO + +SELECT * FROM forjson_subquery_vu_v_with_order_by +GO + +-- Binary strings +SELECT * FROM forjson_subquery_vu_v_binary_strings +GO + +SELECT * FROM forjson_subquery_vu_v_varbinary_strings +GO + +-- Rowversion and timestamp +SELECT * FROM forjson_subquery_vu_v_rowversion +GO + +SELECT * FROM forjson_subquery_vu_v_timestamp +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +EXEC forjson_subquery_vu_p_empty +GO + +SELECT @@rowcount +GO + +-- exercise tsql_select_for_json_result internal function +SELECT * FROM forjson_subquery_vu_v_internal +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-vu-verify.sql b/test/JDBC/input/forjson/forjson-vu-verify.sql index e0c3879c41..b0fa58207a 100644 --- a/test/JDBC/input/forjson/forjson-vu-verify.sql +++ b/test/JDBC/input/forjson/forjson-vu-verify.sql @@ -8,14 +8,14 @@ GO SELECT * FROM forjson_vu_t_values GO --- FOR JSON PATH clause without nested support +-- FOR JSON PATH clause with nested support SELECT * FROM forjson_vu_v_people GO SELECT * FROM forjson_vu_v_countries GO --- Multiple tables without nested support +-- Multiple tables with nested support SELECT * FROM forjson_vu_v_join GO diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-cleanup.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-cleanup.sql new file mode 100644 index 0000000000..53d3e86cb9 --- /dev/null +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-cleanup.sql @@ -0,0 +1,59 @@ +DROP VIEW DATETRUNC_vu_prepare_v1 +GO + +DROP VIEW DATETRUNC_vu_prepare_v2 +GO + +DROP VIEW DATETRUNC_vu_prepare_v3 +GO + +DROP VIEW DATETRUNC_vu_prepare_v4 +GO + +DROP VIEW DATETRUNC_vu_prepare_v5 +GO + +DROP VIEW DATETRUNC_vu_prepare_v6 +GO + +DROP VIEW DATETRUNC_vu_prepare_v7 +GO + +DROP VIEW DATETRUNC_vu_prepare_v8 +GO + +DROP VIEW DATETRUNC_vu_prepare_v9 +GO + +DROP VIEW DATETRUNC_vu_prepare_v10 +GO + +DROP VIEW DATETRUNC_vu_prepare_v11 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p1 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p2 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p3 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p4 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p5 +GO + +DROP PROCEDURE BABEL_3953_vu_prepare_p6 +GO + +DROP FUNCTION BABEL_3953_vu_prepare_f1 +GO + +DROP FUNCTION BABEL_3953_vu_prepare_f2 +GO + +DROP FUNCTION BABEL_3953_vu_prepare_f3 +GO diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-prepare.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-prepare.sql new file mode 100644 index 0000000000..51dc0df6e2 --- /dev/null +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-prepare.sql @@ -0,0 +1,233 @@ +-- Test with date datatype +CREATE VIEW DATETRUNC_vu_prepare_v1 AS ( + select + datetrunc(year, cast('2020-04-15' as date)) as dt1, + datetrunc(yy, cast('2020-04-15' as date)) as dt2, + datetrunc(yyyy, cast('2020-04-15' as date)) as dt3, + datetrunc(quarter, cast('2020-04-15' as date)) as dt4, + datetrunc(qq, cast('2020-04-15' as date)) as dt5, + datetrunc(q, cast('2020-04-15' as date)) as dt6, + datetrunc(month, cast('2020-04-15' as date)) as dt7, + datetrunc(mm, cast('2020-04-15' as date)) as dt8, + datetrunc(m, cast('2020-04-15' as date)) as dt9, + datetrunc(dayofyear, cast('2020-04-15' as date)) as dt10, + datetrunc(dy, cast('2020-04-15' as date)) as dt11, + datetrunc(y, cast('2020-04-15' as date)) as dt12, + datetrunc(day, cast('2020-04-15' as date)) as dt13, + datetrunc(dd, cast('2020-04-15' as date)) as dt14, + datetrunc(d, cast('2020-04-15' as date)) as dt15, + datetrunc(week, cast('2020-04-15' as date)) as dt16, + datetrunc(wk, cast('2020-04-15' as date)) as dt17, + datetrunc(ww, cast('2020-04-15' as date)) as dt18, + datetrunc(iso_week, cast('2020-04-15' as date)) as dt19, + datetrunc(isowk, cast('2020-04-15' as date)) as dt20, + datetrunc(isoww, cast('2020-04-15' as date)) as dt21 + ); +GO + +-- Test with time datatype +CREATE VIEW DATETRUNC_vu_prepare_v2 AS ( + select + datetrunc(hour, cast('12:32:45.5647311' as time)) as dt1, + datetrunc(hh, cast('12:32:45.5647311' as time)) as dt2, + datetrunc(minute, cast('12:32:45.5647311' as time)) as dt3, + datetrunc(mi, cast('12:32:45.5647311' as time)) as dt4, + datetrunc(n, cast('12:32:45.5647311' as time)) as dt5, + datetrunc(second, cast('12:32:45.5647311' as time)) as dt6, + datetrunc(ss, cast('12:32:45.5647311' as time)) as dt7, + datetrunc(s, cast('12:32:45.5647311' as time)) as dt8, + datetrunc(millisecond, cast('12:32:45.5647311' as time)) as dt9, + datetrunc(ms, cast('12:32:45.5647311' as time)) as dt10, + datetrunc(microsecond, cast('12:32:45.5647311' as time)) as dt11, + datetrunc(mcs, cast('12:32:45.5647311' as time)) as dt12 + ); +GO + + +-- Test with datetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v3 AS ( + select + datetrunc(year, cast('2004-06-17 09:32:42.566' as datetime)) as dt1, + datetrunc(quarter, cast('2004-06-17 09:32:42.566' as datetime)) as dt2, + datetrunc(month, cast('2004-06-17 09:32:42.566' as datetime)) as dt3, + datetrunc(dayofyear, cast('2004-06-17 09:32:42.566' as datetime)) as dt4, + datetrunc(day, cast('2004-06-17 09:32:42.566' as datetime)) as dt5, + datetrunc(week, cast('2004-06-17 09:32:42.566' as datetime)) as dt6, + datetrunc(hour, cast('2004-06-17 09:32:42.566' as datetime)) as dt7, + datetrunc(minute, cast('2004-06-17 09:32:42.566' as datetime)) as dt8, + datetrunc(second, cast('2004-06-17 09:32:42.566' as datetime)) as dt9, + datetrunc(millisecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt10 + ); +GO +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''datetime''. +CREATE VIEW DATETRUNC_vu_prepare_v4 AS ( + select + datetrunc(microsecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt1 +); +GO + +-- Test with smalldatetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v5 AS ( + select + datetrunc(year, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(quarter, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2, + datetrunc(month, cast('2004-08-14 22:34:20' as smalldatetime)) as dt3, + datetrunc(dayofyear, cast('2004-08-14 22:34:20' as smalldatetime)) as dt4, + datetrunc(day, cast('2004-08-14 22:34:20' as smalldatetime)) as dt5, + datetrunc(week, cast('2004-08-14 22:34:20' as smalldatetime)) as dt6, + datetrunc(hour, cast('2004-08-14 22:34:20' as smalldatetime)) as dt7, + datetrunc(minute, cast('2004-08-14 22:34:20' as smalldatetime)) as dt8, + datetrunc(second, cast('2004-08-14 22:34:20' as smalldatetime)) as dt9 + ); +GO + +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''smalldatetime''. +CREATE VIEW DATETRUNC_vu_prepare_v6 AS ( + select + datetrunc(microsecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(millisecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2 +); +GO + +-- Test with datetime2 datatype +CREATE VIEW DATETRUNC_vu_prepare_v7 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt11 + ); +GO + +-- Test with datetimeoffset datatype +CREATE VIEW DATETRUNC_vu_prepare_v8 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893 +10:42' as datetimeoffset)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893 +02:42' as datetimeoffset)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893 +05:42' as datetimeoffset)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893 +13:42' as datetimeoffset)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893 -12:43' as datetimeoffset)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893 +12:22' as datetimeoffset)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893 -10:42' as datetimeoffset)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt11 + ); +GO + +-- Test with expression input that can be converted to datetime2 datatype. +CREATE VIEW DATETRUNC_vu_prepare_v9 AS ( + select + datetrunc(year, '2021-Jan-01') as dt1, + datetrunc(year, '2021/Jan/01') as dt2, + datetrunc(year, '2021-1-1') as dt3, + datetrunc(year, '20210101') as dt4, + datetrunc(hour, cast('2020-01-01' as varchar)) as dt5, + datetrunc(minute, cast('1980-09-08' as char)) as dt6, + datetrunc(day, '12:32:42') as dt7, + datetrunc(day, '12:32:42.46378') as dt8, + datetrunc(week, '1990-09-09 12:32:09.546') as dt9, + datetrunc(week, '1990-09-09 12:32:09') as dt10, + datetrunc(week, '1990-09-09 12:32:09.546788') as dt11 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale +-- babelfish will always give answer that will include fractional seconds till 7 digits. +CREATE VIEW DATETRUNC_vu_prepare_v10 AS ( + select + datetrunc(hour, cast('12:32:43.4635' as time(3))) dt1, + datetrunc(month, cast('2020-12-23 20:20:20.2222' as datetime2(2))) as dt2, + datetrunc(week, cast('1989-09-23 05:36:43.2930 +12:37' as datetimeoffset(5))) as dt3, + datetrunc(minute, cast('2027-12-13 10:13:20.12236' as datetime2(4))) as dt4, + datetrunc(year, cast('2027-12-13 10:13:20.537478' as datetimeoffset(6))) as dt5 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale which is less then the specified datepart milliseocond, microsecond. +-- Babelfish always give answer to these with fractional seconds till 7 digits, babelfish do not throw an error similar to sql server in this case. +CREATE VIEW DATETRUNC_vu_prepare_v11 AS ( + select + datetrunc(millisecond, cast('2002-01-01 12:33:43.435354' as datetime2(2))) as dt1, + datetrunc(millisecond, cast('2020-01-01 12:33:32.4324' as datetimeoffset(1))) as dt2, + datetrunc(millisecond, cast('12:23:43.464774' as time(0))) as dt3, + datetrunc(microsecond, cast('2002-01-01 12:33:43.435354' as datetime2(5))) as dt4, + datetrunc(microsecond, cast('2020-01-01 12:33:32.437724' as datetimeoffset(4))) as dt5 + ); +GO + + +-- Procedures +-- Test with upper/lower limit of date/time. +CREATE PROCEDURE BABEL_3953_vu_prepare_p1 as ( + SELECT + datetrunc(month, cast('0001-01-01' as date)) as dt1, + datetrunc(month, cast('9999-12-31' as date)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p2 as ( + SELECT + datetrunc(month, cast('1753-01-01 00:00:00 ' as datetime)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.997' as datetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p3 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00' as datetime2)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999999' as datetime2)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p4 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00 -14:00' as datetimeoffset)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999 +14:00' as datetimeoffset)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p5 as ( + SELECT + datetrunc(month, cast('1900-01-01 00:00:00' as smalldatetime)) as dt1, + datetrunc(day, cast('2007-06-05 23:59:59' as smalldatetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p6 as ( + SELECT + datetrunc(hour, cast('00:00:00.0000000' as time)) as dt1, + datetrunc(second, cast('23:59:59.999999' as time)) as dt2 + ); +GO + + +-- functions +CREATE FUNCTION BABEL_3953_vu_prepare_f1() +RETURNS DATETIME2 AS +BEGIN +RETURN (SELECT datetrunc(iso_week, cast('2012-01-23 12:32:23.324' as datetime2))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f2() +RETURNS time AS +BEGIN +RETURN (select datetrunc(second, cast('12:32:53.23' as time))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f3() +RETURNS date AS +BEGIN +RETURN (select datetrunc(week, cast('2001-11-14' as date))); +END +GO diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql new file mode 100644 index 0000000000..ebefb27462 --- /dev/null +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql @@ -0,0 +1,209 @@ +SELECT * FROM DATETRUNC_vu_prepare_v1 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v2 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v3 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v4 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v5 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v6 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v7 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v8 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v9 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v10 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v11 +GO + +EXEC BABEL_3953_vu_prepare_p1 +GO + +EXEC BABEL_3953_vu_prepare_p2 +GO + +EXEC BABEL_3953_vu_prepare_p3 +GO + +EXEC BABEL_3953_vu_prepare_p4 +GO + +EXEC BABEL_3953_vu_prepare_p5 +GO + +EXEC BABEL_3953_vu_prepare_p6 +GO + +SELECT BABEL_3953_vu_prepare_f1() +GO + +SELECT BABEL_3953_vu_prepare_f2() +GO + +SELECT BABEL_3953_vu_prepare_f3() +GO + +select datetrunc(null, CAST('2020-01-01' as date)) as dt1 +GO +select datetrunc(null, null) as dt1 +GO +select datetrunc(null, 'NULL') as dt1 +GO +select datetrunc('NULL', null) as dt1 +GO +select datetrunc('NULL', 'NULL') as dt1 +GO +select datetrunc('year',CAST('2020-01-01' as date)) +go +select datetrunc(year, null) as dt3 +GO +select datetrunc(years, null) as dt4 +GO +select datetrunc(nanosecond ,null) as dt5 +GO +SELECT datetrunc(nanosecond, 2020) +GO +select datetrunc(invalid_datepart, 2020) +GO +select datetrunc(hour, 2020.0) +GO + +-- postgres support 6 digits of fractional time-scale so the bbf output will differ +-- in the last fractional second digit from t-sql. bbf- 2021-12-08 11:30:15.1234570 +-- tsql- 2021-12-08 11:30:15.1234560 +DECLARE @d datetime2 = '2021-12-08 11:30:15.1234567'; +SELECT 'Microsecond', DATETRUNC(microsecond, @d); +Go + +DECLARE @test_date date; +SET @test_date = '1998-09-12'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date datetime; +SET @test_date = '2010-09-12 12:23:12.564'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date datetime2; +SET @test_date = '2010-09-12 12:23:12.56443'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date smalldatetime; +SET @test_date = '2010-09-12 12:23:12'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date datetimeoffset; +SET @test_date = '2010-09-12 12:23:12.56443 +10:12'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date time; +SET @test_date = '12:23:12.56443'; +SELECT datetrunc(hour, @test_date); +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23' as datetime))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a date) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09' as date))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime2) +insert into dtrunc (a) values(datetrunc(day, '2020-01-09 12:32:23.23')) +Select * from dtrunc +Select datetrunc(day, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetimeoffset) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23 -10:23' as datetimeoffset))) +Select * from dtrunc +Select datetrunc(month, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a smalldatetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23' as smalldatetime))) +Select * from dtrunc +Select datetrunc(hour, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a time) +insert into dtrunc (a) values(datetrunc(minute, CAST('12:32:23.23' as time))) +Select * from dtrunc +Select datetrunc(second, a) from dtrunc +GO + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +GO + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +GO + +SET DATEFIRST 2 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +GO + +SET DATEFIRST 3 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12' as date)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12' as date)) +GO + +SET DATEFIRST 4 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as smalldatetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as smalldatetime)) +GO + +SET DATEFIRST 5 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as datetime2)) +GO + +SET DATEFIRST 6 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO + +SET DATEFIRST 7 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO diff --git a/test/JDBC/input/getdate-vu-verify.sql b/test/JDBC/input/getdate-vu-verify.sql index 3bc82df78b..7b9d22f949 100644 --- a/test/JDBC/input/getdate-vu-verify.sql +++ b/test/JDBC/input/getdate-vu-verify.sql @@ -1,4 +1,3 @@ --- sla 50000 exec sysdatetime_dep_proc go diff --git a/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..a23e01a771 --- /dev/null +++ b/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,35 @@ +DROP VIEW babel_3696_1 +GO + +DROP VIEW babel_3696_2 +GO + +DROP VIEW babel_3696_3 +GO + +DROP VIEW babel_3696_4 +GO + +DROP VIEW babel_3696_5 +GO + +DROP VIEW babel_3696_6 +GO + +DROP VIEW babel_3696_7 +GO + +DROP VIEW babel_3696_8 +GO + +DROP TABLE t1 +GO + +DROP VIEW babel_3696_9 +GO + +DROP PROCEDURE babel_3696_10 +GO + +DROP PROCEDURE babel_3696_11 +GO diff --git a/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..f7526d46a8 --- /dev/null +++ b/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,80 @@ +create view babel_3696_1 as +SELECT json_modify('{"Brand":"HP","Product":"Laptop","Accessories":["Keyboard","Mouse","Monitor"]}', '$.Accessories', JSON_QUERY('["Mouse","Monitor"]')) +go + +create view babel_3696_2 as +SELECT json_modify('{"Brand":"HP","Product":"Laptop"}', '$.Accessories', JSON_Query('["Keyboard","Mouse","Monitor"]')) +go + +create view babel_3696_3 as +select JSON_MODIFY(JSON_MODIFY('{"Brand":"HP","Product":"Laptop"}', '$.Parts', JSON_VALUE('{"Brand":"HP","Product":"Laptop"}','$.Product')), '$.Product',NULL) +go + +create view babel_3696_4 as +select JSON_MODIFY(JSON_MODIFY('{"Brand":"HP","Product":"Laptop","Accessories":["Keyboard","Mouse","Monitor"]}', '$.Accessories', JSON_QUERY('["HDMI","USB"]')), '$.Brand', 'Lenovo') +go + + +create view babel_3696_5 as +select JSON_MODIFY('{"name":"John","skills":["C#","SQL"]}','$.skills',JSON_QUERY('["C#","T-SQL","Azure"]')) +go + + +create table t1 (x nvarchar(20)) +insert into t1 values ('some string') +go + +create view babel_3696_6 as +select json_modify('{"a":"b"}', '$.a', x) from (select * from t1 for json path) a ([x]) +go + +create view babel_3696_7 as +select json_modify('{"a":"b"}', '$.a', x) from (select * from t1 for json path, without_array_wrapper) a ([x]) +go + +create view babel_3696_8 as +select json_modify('{"a":"b"}', '$.a', json_modify('{"a":"b"}', '$.a', 'c')) +go + + +create view babel_3696_9 as +select json_modify('{"a":"b"}', '$.a', json_modify('{"a":"b"}', 'STRICT $.a', 'c')) +go + +create procedure babel_3696_10 +as +begin +DECLARE @data NVARCHAR(4000) +SET @data=N'{ + "Suspect": { + "Name": "Homer Simpson", + "Address": { + "City": "Dunedin", + "Region": "Otago", + "Country": "New Zealand" + }, + "Hobbies": ["Eating", "Sleeping", "Base Jumping"] + } + }' +select JSON_MODIFY(@data,'$.Suspect.Address.City', 'Timaru') AS 'Modified Array'; +end; +go + +create procedure babel_3696_11 +as +begin +DECLARE @data NVARCHAR(4000) +SET @data=N'{ + "Suspect": { + "Name": "Homer Simpson", + "Address": { + "City": "Dunedin", + "Region": "Otago", + "Country": "New Zealand" + }, + "Hobbies": ["Eating", "Sleeping", "Base Jumping"] + } + }' +select JSON_MODIFY(@data,'$.Suspect.Hobbies', JSON_QUERY('["Chess", "Brain Surgery"]')) AS 'Updated Hobbies'; +end; +go diff --git a/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..ad7ea30a3d --- /dev/null +++ b/test/JDBC/input/json_modify/BABEL-3696-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,32 @@ +SELECT * FROM babel_3696_1 +GO + +SELECT * FROM babel_3696_2 +GO + +SELECT * FROM babel_3696_3 +GO + +SELECT * FROM babel_3696_4 +GO + +SELECT * FROM babel_3696_5 +GO + +SELECT * FROM babel_3696_6 +GO + +SELECT * FROM babel_3696_7 +GO + +SELECT * FROM babel_3696_8 +GO + +SELECT * FROM babel_3696_9 +GO + +EXEC babel_3696_10 +GO + +EXEC babel_3696_11 +GO diff --git a/test/JDBC/input/sql_variant/babel_datatype_sqlvariant-vu-cleanup.sql b/test/JDBC/input/sql_variant/babel_datatype_sqlvariant-vu-cleanup.sql index afecb5e34e..8ae54e1a03 100644 --- a/test/JDBC/input/sql_variant/babel_datatype_sqlvariant-vu-cleanup.sql +++ b/test/JDBC/input/sql_variant/babel_datatype_sqlvariant-vu-cleanup.sql @@ -5,6 +5,8 @@ drop table babel_datatype_sqlvariant_vu_prepare_t2; go drop table babel_datatype_sqlvariant_vu_prepare_t3; go +drop table babel_datatype_sqlvariant_vu_prepare_t4; +go drop table babel_datatype_sqlvariant_vu_prepare_t5; go drop table babel_datatype_sqlvariant_vu_prepare_t6; diff --git a/test/JDBC/input/views/sys_sequences-vu-cleanup.sql b/test/JDBC/input/views/sys_sequences-vu-cleanup.sql new file mode 100644 index 0000000000..de5f33a723 --- /dev/null +++ b/test/JDBC/input/views/sys_sequences-vu-cleanup.sql @@ -0,0 +1,27 @@ +USE master +GO + +DROP VIEW sys_sequences_vu_prepare_view +GO + +DROP PROC sys_sequences_vu_prepare_proc +GO + +DROP FUNCTION sys_sequences_vu_prepare_func +GO + +DROP FUNCTION sys_sequences_vu_prepare_func1 +GO + +DROP FUNCTION sys_sequences_vu_prepare_func2 +GO + +DROP sequence IF EXISTS test_seq +GO + +DROP sequence IF EXISTS sch.ははははははははははははははははは +GO + +DROP schema IF EXISTS sch +GO + diff --git a/test/JDBC/input/views/sys_sequences-vu-prepare.sql b/test/JDBC/input/views/sys_sequences-vu-prepare.sql new file mode 100644 index 0000000000..080946dd49 --- /dev/null +++ b/test/JDBC/input/views/sys_sequences-vu-prepare.sql @@ -0,0 +1,91 @@ +USE master +GO + +Create sequence test_seq as int +GO + +Create schema sch +GO + +Create sequence sch.ははははははははははははははははは +GO + +CREATE VIEW sys_sequences_vu_prepare_view AS +select + name + , principal_id + , parent_object_id + , type + , type_desc + , create_date + , modify_date + , is_ms_shipped + , is_published + , is_schema_published + , start_value + , increment + , minimum_value + , maximum_value + , is_cycling + , is_cached + , cache_size + , system_type_id + , user_type_id + , precision + , scale + , current_value + , is_exhausted + , last_used_value FROM sys.sequences +GO + +CREATE PROC sys_sequences_vu_prepare_proc AS +SELECT + name + , principal_id + , parent_object_id + , type + , type_desc + , create_date + , modify_date + , is_ms_shipped + , is_published + , is_schema_published + , start_value + , increment + , minimum_value + , maximum_value + , is_cycling + , is_cached + , cache_size + , system_type_id + , user_type_id + , precision + , scale + , current_value + , is_exhausted + , last_used_value FROM sys.sequences +GO + +CREATE FUNCTION sys_sequences_vu_prepare_func() +RETURNS INT +AS +BEGIN + RETURN (SELECT COUNT(*) FROM sys.sequences WHERE is_cycling= 0) +END +GO + +CREATE FUNCTION sys_sequences_vu_prepare_func1() +RETURNS INT +AS +BEGIN + RETURN (SELECT COUNT(*) FROM sys.sequences WHERE name='TEST_SEq'); +END +GO + +CREATE FUNCTION sys_sequences_vu_prepare_func2() +RETURNS INT +AS +BEGIN + RETURN (SELECT COUNT(*) FROM sys.sequences WHERE name='ははははははははははははははははは'); +END +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys_sequences-vu-verify.sql b/test/JDBC/input/views/sys_sequences-vu-verify.sql new file mode 100644 index 0000000000..fa0b3317c3 --- /dev/null +++ b/test/JDBC/input/views/sys_sequences-vu-verify.sql @@ -0,0 +1,17 @@ +USE master +GO + +SELECT * FROM sys_sequences_vu_prepare_view +GO + +EXEC sys_sequences_vu_prepare_proc +GO + +SELECT sys_sequences_vu_prepare_func() +GO + +SELECT sys_sequences_vu_prepare_func1() +GO + +SELECT sys_sequences_vu_prepare_func2() +GO \ No newline at end of file diff --git a/test/JDBC/jdbc_schedule b/test/JDBC/jdbc_schedule index 520643ad73..c21361e06f 100644 --- a/test/JDBC/jdbc_schedule +++ b/test/JDBC/jdbc_schedule @@ -33,6 +33,9 @@ ignore#!#BABEL-3117-vu-prepare ignore#!#BABEL-3117-vu-verify ignore#!#BABEL-3655-vu-prepare ignore#!#BABEL-3655-vu-verify +ignore#!#GRANT_SCHEMA-vu-prepare +ignore#!#GRANT_SCHEMA-vu-verify +ignore#!#GRANT_SCHEMA-vu-cleanup # These tests are meant for upgrade scenario prior to (potential) 14_5 release ignore#!#BABEL-3147-before-14_5-vu-prepare @@ -71,6 +74,18 @@ ignore#!#sys-all_sql_modules_before-14_7-or-15_2-vu-cleanup ignore#!#sys-sql_modules_before-14_7-or-15_2-vu-prepare ignore#!#sys-sql_modules_before-14_7-or-15_2-vu-verify ignore#!#sys-sql_modules_before-14_7-or-15_2-vu-cleanup +ignore#!#BABEL-3696-before-14_10-or-15_5-vu-prepare +ignore#!#BABEL-3696-before-14_10-or-15_5-vu-verify +ignore#!#BABEL-3696-before-14_10-or-15_5-vu-cleanup +ignore#!#forjson-before-14_10-or-15_5-vu-prepare +ignore#!#forjson-before-14_10-or-15_5-vu-verify +ignore#!#forjson-before-14_10-or-15_5-vu-cleanup +ignore#!#forjson-subquery-before-14_10-or-15_5-vu-prepare +ignore#!#forjson-subquery-before-14_10-or-15_5-vu-verify +ignore#!#forjson-subquery-before-14_10-or-15_5-vu-cleanup +ignore#!#forjson-datatypes-before-14_10-or-15_5-vu-prepare +ignore#!#forjson-datatypes-before-14_10-or-15_5-vu-verify +ignore#!#forjson-datatypes-before-14_10-or-15_5-vu-cleanup ignore#!#orderby-before-15_3-vu-prepare ignore#!#orderby-before-15_3-vu-verify ignore#!#orderby-before-15_3-vu-cleanup diff --git a/test/JDBC/upgrade/13_6/schedule b/test/JDBC/upgrade/13_6/schedule index c9d7237f72..3943bbadbb 100644 --- a/test/JDBC/upgrade/13_6/schedule +++ b/test/JDBC/upgrade/13_6/schedule @@ -324,3 +324,4 @@ triggers_with_transaction BABEL-4046 getdate BABEL-4410 +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/13_9/schedule b/test/JDBC/upgrade/13_9/schedule index 07d859c053..c606176c9a 100644 --- a/test/JDBC/upgrade/13_9/schedule +++ b/test/JDBC/upgrade/13_9/schedule @@ -320,3 +320,4 @@ triggers_with_transaction BABEL-4046 getdate BABEL-4410 +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index 0ac25aa228..a9897f774c 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -410,3 +410,4 @@ smalldatetimefromparts-dep BABEL_4330 BABEL-4231 BABEL-4384 +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/14_3/schedule b/test/JDBC/upgrade/14_3/schedule index 1526f6e541..f68c4e41fe 100644 --- a/test/JDBC/upgrade/14_3/schedule +++ b/test/JDBC/upgrade/14_3/schedule @@ -338,3 +338,4 @@ BABEL-4046 BABEL_4330 BABEL-2619 BABEL-4410 +GRANT_SCHEMA \ No newline at end of file diff --git a/test/JDBC/upgrade/14_5/schedule b/test/JDBC/upgrade/14_5/schedule index 9fad0e1636..c78b90e882 100644 --- a/test/JDBC/upgrade/14_5/schedule +++ b/test/JDBC/upgrade/14_5/schedule @@ -353,3 +353,4 @@ getdate BABEL_4330 BABEL-2619 BABEL-4410 +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index 30bd32bf35..61edb201b9 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -175,8 +175,8 @@ dateadd_internal_df datediff_internal_date-before-14_7-or-15_2 datepart datetime2fromparts -forjson -forjson-datatypes +forjson-before-14_10-or-15_5 +forjson-datatypes-before-14_10-or-15_5 format forxml fulltextserviceproperty @@ -387,3 +387,4 @@ getdate BABEL_4330 BABEL-2619 BABEL-4410 +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index 01f241a212..ff7db62fd1 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -415,3 +415,4 @@ BABEL-4046 getdate BABEL_4330 BABEL-4410 +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index fd5244d648..e7f12532e6 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -449,4 +449,4 @@ BABEL-4175 sp_who BABEL_4330 BABEL-4410 - +GRANT_SCHEMA diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 97bcac0f0d..42143cbd27 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -113,6 +113,7 @@ BABEL-3844 BABEL-3914 BABEL-3938 BABEL-3952 +BABEL-3953-datetrunc BABEL-404 BABEL-405 BABEL-4078 @@ -210,6 +211,7 @@ datetime2fromparts-after-15-2 forjson forjson-datatypes forjson-subquery +forjson-nesting format forxml forxml-subquery @@ -466,6 +468,7 @@ Test_ISNULL BABEL-4270 BABEL-4410 BABEL-4231 +sys_sequences sys_asymmetric_keys sys_certificates sys_database_permissions diff --git a/test/python/SMO_script.ps1 b/test/python/SMO_script.ps1 index 753ab495a3..0116d148ec 100644 --- a/test/python/SMO_script.ps1 +++ b/test/python/SMO_script.ps1 @@ -29,6 +29,7 @@ if($script_flag -eq $var_one) $Objects += $db.Views $Objects += $db.StoredProcedures $Objects += $db.UserDefinedFunctions + $Objects += $db.Sequences $Objects += $db.Tables.Indexes $Objects += $db.Tables.Triggers foreach ($CurrentObject in $Objects) @@ -54,7 +55,9 @@ else $Objects += $db.UserDefinedFunctions $SubObjects += $db.Tables.Indexes $SubObjects += $db.Tables.Triggers + $SubObjects += $db.Sequences $SubObjects += $db.Users + foreach ($CurrentObject in $Objects) { if ($CurrentObject.schema -ne $schm -and $CurrentObject.schema -ne $dtb -and $CurrentObject.schema -ne $null -and -not $CurrentObject.IsSystemObject ) diff --git a/test/python/expected/pyodbc/ddl_all_objects.out b/test/python/expected/pyodbc/ddl_all_objects.out index 29e0d7d419..d83312f059 100644 --- a/test/python/expected/pyodbc/ddl_all_objects.out +++ b/test/python/expected/pyodbc/ddl_all_objects.out @@ -139,6 +139,15 @@ SET QUOTED_IDENTIFIER ON create function routines_fc6(@fc6_a char) RETURNS char AS BEGIN return @fc6_a END; GO +CREATE SEQUENCE [dbo].[babel_1654_vu_prepare_t_id_seq] + AS [int] + START WITH 1 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 2147483647 + NO CACHE +GO + ALTER TABLE [dbo].[babel_1654_vu_prepare_t] ADD CONSTRAINT [babel_1654_vu_prepare_t_pkey] PRIMARY KEY NONCLUSTERED ( [id] diff --git a/test/python/expected/pyodbc/ddl_sequence.out b/test/python/expected/pyodbc/ddl_sequence.out new file mode 100644 index 0000000000..6f8eabc83a --- /dev/null +++ b/test/python/expected/pyodbc/ddl_sequence.out @@ -0,0 +1,74 @@ +CREATE SEQUENCE [dbo].[test] + AS [bigint] + START WITH 1 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 9223372036854775807 + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[isc_sequences_seq1] + AS [bigint] + START WITH 1 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 5 + CYCLE + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[isc_sequences_seq2] + AS [smallint] + START WITH 2 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 5 + CYCLE + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[isc_sequences_seq3] + AS [smallint] + START WITH 3 + INCREMENT BY 3 + MINVALUE 3 + MAXVALUE 10 + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[isc_sequences_seq4] + AS [int] + START WITH 4 + INCREMENT BY 2 + MINVALUE 2 + MAXVALUE 10 + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[test] + AS [bigint] + START WITH 1 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 9223372036854775807 + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[test1] + AS [bigint] + START WITH 5 + INCREMENT BY 5 + MINVALUE 1 + MAXVALUE 9223372036854775807 + NO CACHE +GO + +CREATE SEQUENCE [Test_Seq].[test2] + AS [bigint] + START WITH 24329 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 9223372036854775807 + NO CACHE +GO + diff --git a/test/python/expected/pyodbc/ddl_triggers.out b/test/python/expected/pyodbc/ddl_triggers.out index 034cae9ca5..b0fd8b87c6 100644 --- a/test/python/expected/pyodbc/ddl_triggers.out +++ b/test/python/expected/pyodbc/ddl_triggers.out @@ -73,3 +73,21 @@ CREATE TRIGGER babel_1654_vu_prepare_trig_t on babel_1654_vu_prepare_t after upd ALTER TABLE [dbo].[babel_1654_vu_prepare_t] ENABLE TRIGGER [babel_1654_vu_prepare_trig_t] GO +CREATE SEQUENCE [dbo].[babel_1654_vu_prepare_employeedata_id_seq] + AS [int] + START WITH 1 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 2147483647 + NO CACHE +GO + +CREATE SEQUENCE [dbo].[babel_1654_vu_prepare_t_id_seq] + AS [int] + START WITH 1 + INCREMENT BY 1 + MINVALUE 1 + MAXVALUE 2147483647 + NO CACHE +GO + diff --git a/test/python/expected/sql_validation_framework/expected_create.out b/test/python/expected/sql_validation_framework/expected_create.out index 6259aefdfd..0bd142e4ac 100644 --- a/test/python/expected/sql_validation_framework/expected_create.out +++ b/test/python/expected/sql_validation_framework/expected_create.out @@ -72,6 +72,7 @@ Could not find tests for procedure sys.printarg Could not find tests for procedure sys.sp_cursor_list Could not find tests for procedure sys.sp_describe_cursor Could not find tests for table sys.babelfish_helpcollation +Could not find tests for table sys.babelfish_schema_permissions Could not find tests for table sys.babelfish_syslanguages Could not find tests for table sys.service_settings Could not find tests for table sys.spt_datatype_info_table @@ -199,6 +200,7 @@ Could not find upgrade tests for procedure sys.sp_unprepare Could not find upgrade tests for procedure sys.sp_updatestats Could not find upgrade tests for table sys.babelfish_configurations Could not find upgrade tests for table sys.babelfish_helpcollation +Could not find upgrade tests for table sys.babelfish_schema_permissions Could not find upgrade tests for table sys.babelfish_syslanguages Could not find upgrade tests for table sys.service_settings Could not find upgrade tests for table sys.spt_datatype_info_table diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 0b8376494e..385115fae4 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -352,7 +352,6 @@ Function sys.datetimeoffset_hash(sys.datetimeoffset) Function sys.datetimeoffset_larger(sys.datetimeoffset,sys.datetimeoffset) Function sys.datetimeoffset_smaller(sys.datetimeoffset,sys.datetimeoffset) Function sys.datetimeoffset_sqlvariant(sys.datetimeoffset) -Function sys.datetimeoffsetscale(sys.datetimeoffset,integer) Function sys.db_id() Function sys.db_id(sys.nvarchar) Function sys.db_name() diff --git a/test/python/input/ddl_sequence.sql b/test/python/input/ddl_sequence.sql new file mode 100644 index 0000000000..757a23e022 --- /dev/null +++ b/test/python/input/ddl_sequence.sql @@ -0,0 +1,85 @@ +DROP sequence IF EXISTS Test_Seq.test +GO + +DROP sequence IF EXISTS Test_Seq.test1 +GO + +DROP sequence IF EXISTS Test_Seq.test2 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq1 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq2 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq3 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq4 +GO + +DROP sequence IF EXISTS test +GO + +DROP schema IF EXISTS Test_Seq +GO + + +Create sequence test +go + +Create schema Test_Seq +GO + +CREATE SEQUENCE Test_Seq.test START WITH 1 INCREMENT BY 1 ; +GO + +CREATE SEQUENCE Test_Seq.test1 START WITH 5 INCREMENT BY 5 ; +GO + +CREATE SEQUENCE Test_Seq.test2 START WITH 24329 INCREMENT BY 1 ; +GO + +create sequence Test_Seq.isc_sequences_seq1 start with 1 minvalue 1 maxvalue 5 cycle; +go + +create sequence Test_Seq.isc_sequences_seq2 as tinyint start with 2 minvalue 1 maxvalue 5 cycle; +go + +create sequence Test_Seq.isc_sequences_seq3 as smallint start with 3 increment by 3 minvalue 3 maxvalue 10; +go + +create sequence Test_Seq.isc_sequences_seq4 as int start with 4 increment by 2 minvalue 2 maxvalue 10; +go + +--DROP + +DROP sequence IF EXISTS Test_Seq.test +GO + +DROP sequence IF EXISTS test +GO + +DROP sequence IF EXISTS Test_Seq.test1 +GO + +DROP sequence IF EXISTS Test_Seq.test2 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq1 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq2 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq3 +GO + +DROP sequence IF EXISTS Test_Seq.isc_sequences_seq4 +GO + +DROP schema IF EXISTS Test_Seq +GO + +