From ac08cff8c5a09c64cc27e8c9172b51a89c35f88f Mon Sep 17 00:00:00 2001 From: Ashish Prasad <56514722+hash-16@users.noreply.github.com> Date: Tue, 31 Oct 2023 20:10:00 +0530 Subject: [PATCH] Support SSMS scripting for User defined datatypes and User defined Table type (#1880) To support scripting of User defined data type and User defined Table Type through SSMS. Also fixed the issue which caused error when opening the dropdown of User defined Data type in the explorer. Fix done as part of this commit -- 1/ Added a dummy typeproperty function (further implementation is tracked BABEL-802) 2/ Corrected the is_nullable data type in sys.types view. Task: BABEL-3834,BABEL-3924 Signed-off-by: Ashish Prasad --- .../babelfishpg_tsql/sql/sys_functions.sql | 12 + contrib/babelfishpg_tsql/sql/sys_views.sql | 6 +- .../babelfishpg_tsql--3.3.0--3.4.0.sql | 983 ++++++++++++++++++ .../sys-table_types-before-dep-vu-cleanup.out | 6 + .../sys-table_types-before-dep-vu-prepare.out | 23 + .../sys-table_types-before-dep-vu-verify.out | 32 + .../sys-table_types-dep-vu-cleanup.out | 3 + .../sys-table_types-dep-vu-prepare.out | 16 + .../sys-table_types-dep-vu-verify.out | 24 + .../expected/sys-table_types-vu-verify.out | 2 +- test/JDBC/expected/sys-table_types.out | 2 +- .../sys-types-before-dep-vu-cleanup.out | 2 + .../sys-types-before-dep-vu-prepare.out | 40 + .../sys-types-before-dep-vu-verify.out | 50 + .../expected/sys-types-dep-vu-prepare.out | 15 + .../JDBC/expected/sys-types-dep-vu-verify.out | 24 + .../expected/typeproperty-dep-vu-cleanup.out | 14 + .../expected/typeproperty-dep-vu-prepare.out | 22 + .../expected/typeproperty-dep-vu-verify.out | 23 + .../input/typeproperty-dep-vu-cleanup.sql | 14 + .../input/typeproperty-dep-vu-prepare.sql | 22 + .../JDBC/input/typeproperty-dep-vu-verify.sql | 8 + .../sys-table_types-before-dep-vu-cleanup.mix | 6 + .../sys-table_types-before-dep-vu-prepare.mix | 23 + .../sys-table_types-before-dep-vu-verify.mix | 12 + .../views/sys-table_types-dep-vu-cleanup.mix | 3 + .../views/sys-table_types-dep-vu-prepare.mix | 16 + .../views/sys-table_types-dep-vu-verify.mix | 9 + .../views/sys-types-before-dep-vu-cleanup.sql | 2 + .../views/sys-types-before-dep-vu-prepare.sql | 40 + .../views/sys-types-before-dep-vu-verify.sql | 20 + .../input/views/sys-types-dep-vu-prepare.sql | 15 + .../input/views/sys-types-dep-vu-verify.sql | 9 + test/JDBC/jdbc_schedule | 6 + test/JDBC/upgrade/13_4/schedule | 2 +- test/JDBC/upgrade/13_5/schedule | 4 +- test/JDBC/upgrade/13_6/schedule | 4 +- test/JDBC/upgrade/13_7/schedule | 4 +- test/JDBC/upgrade/13_8/schedule | 4 +- test/JDBC/upgrade/13_9/schedule | 4 +- test/JDBC/upgrade/14_10/schedule | 4 +- test/JDBC/upgrade/14_3/schedule | 4 +- test/JDBC/upgrade/14_5/schedule | 4 +- test/JDBC/upgrade/14_6/schedule | 4 +- test/JDBC/upgrade/14_7/schedule | 4 +- test/JDBC/upgrade/14_8/schedule | 4 +- test/JDBC/upgrade/14_9/schedule | 4 +- test/JDBC/upgrade/15_1/schedule | 4 +- test/JDBC/upgrade/15_2/schedule | 4 +- test/JDBC/upgrade/15_3/schedule | 4 +- test/JDBC/upgrade/15_4/schedule | 4 +- test/JDBC/upgrade/latest/schedule | 1 + test/python/SMO_script.ps1 | 4 + test/python/expected/pyodbc/ddl_UDDT_UDTT.out | 43 + test/python/expected/pyodbc/ddl_func_proc.out | 9 + test/python/input/ddl_UDDT_UDTT.sql | 78 ++ 56 files changed, 1667 insertions(+), 38 deletions(-) create mode 100644 test/JDBC/expected/sys-table_types-before-dep-vu-cleanup.out create mode 100644 test/JDBC/expected/sys-table_types-before-dep-vu-prepare.out create mode 100644 test/JDBC/expected/sys-table_types-before-dep-vu-verify.out create mode 100644 test/JDBC/expected/sys-types-before-dep-vu-cleanup.out create mode 100644 test/JDBC/expected/sys-types-before-dep-vu-prepare.out create mode 100644 test/JDBC/expected/sys-types-before-dep-vu-verify.out create mode 100644 test/JDBC/expected/typeproperty-dep-vu-cleanup.out create mode 100644 test/JDBC/expected/typeproperty-dep-vu-prepare.out create mode 100644 test/JDBC/expected/typeproperty-dep-vu-verify.out create mode 100644 test/JDBC/input/typeproperty-dep-vu-cleanup.sql create mode 100644 test/JDBC/input/typeproperty-dep-vu-prepare.sql create mode 100644 test/JDBC/input/typeproperty-dep-vu-verify.sql create mode 100644 test/JDBC/input/views/sys-table_types-before-dep-vu-cleanup.mix create mode 100644 test/JDBC/input/views/sys-table_types-before-dep-vu-prepare.mix create mode 100644 test/JDBC/input/views/sys-table_types-before-dep-vu-verify.mix create mode 100644 test/JDBC/input/views/sys-types-before-dep-vu-cleanup.sql create mode 100644 test/JDBC/input/views/sys-types-before-dep-vu-prepare.sql create mode 100644 test/JDBC/input/views/sys-types-before-dep-vu-verify.sql create mode 100644 test/python/expected/pyodbc/ddl_UDDT_UDTT.out create mode 100644 test/python/input/ddl_UDDT_UDTT.sql diff --git a/contrib/babelfishpg_tsql/sql/sys_functions.sql b/contrib/babelfishpg_tsql/sql/sys_functions.sql index d2536a13ab..a8acc6caf6 100644 --- a/contrib/babelfishpg_tsql/sql/sys_functions.sql +++ b/contrib/babelfishpg_tsql/sql/sys_functions.sql @@ -1066,6 +1066,18 @@ END; $BODY$ LANGUAGE 'plpgsql' STABLE; +CREATE OR REPLACE FUNCTION sys.typeproperty( + typename sys.VARCHAR, + property sys.VARCHAR + ) +RETURNS INT +AS $$ +DECLARE +BEGIN + RETURN NULL; +END; +$$ +LANGUAGE plpgsql STABLE; CREATE OR REPLACE FUNCTION sys.SWITCHOFFSET(IN input_expr PG_CATALOG.TEXT, diff --git a/contrib/babelfishpg_tsql/sql/sys_views.sql b/contrib/babelfishpg_tsql/sql/sys_views.sql index cc626cf14a..d743d857d1 100644 --- a/contrib/babelfishpg_tsql/sql/sys_views.sql +++ b/contrib/babelfishpg_tsql/sql/sys_views.sql @@ -1068,7 +1068,7 @@ select WHEN 'default' THEN default_collation_name ELSE c.collname END as collation_name - , case when typnotnull then 0 else 1 end as is_nullable + , case when typnotnull then cast(0 as sys.bit) else cast(1 as sys.bit) end as is_nullable , 0 as is_user_defined , 0 as is_assembly_type , 0 as default_object_id @@ -1097,8 +1097,8 @@ select cast(t.typname as text) as name WHEN 'default' THEN default_collation_name ELSE c.collname END as collation_name - , case when tt.typrelid is not null then 0 - else case when typnotnull then 0 else 1 end + , case when tt.typrelid is not null then cast(0 as sys.bit) + else case when typnotnull then cast(0 as sys.bit) else cast(1 as sys.bit) end end as is_nullable -- CREATE TYPE ... FROM is implemented as CREATE DOMAIN in babel 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 66c15a8e93..2caa7876f7 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 @@ -39,6 +39,7 @@ LANGUAGE plpgsql; */ + CREATE OR REPLACE VIEW sys.asymmetric_keys AS SELECT @@ -102,6 +103,7 @@ SELECT WHERE FALSE; GRANT SELECT ON sys.database_permissions TO PUBLIC; + CREATE OR REPLACE VIEW information_schema_tsql.key_column_usage AS SELECT CAST(nc.dbname AS sys.nvarchar(128)) AS "CONSTRAINT_CATALOG", @@ -126,6 +128,19 @@ CREATE OR REPLACE VIEW information_schema_tsql.key_column_usage AS ; GRANT SELECT ON information_schema_tsql.key_column_usage TO PUBLIC; +CREATE OR REPLACE FUNCTION sys.typeproperty( + typename sys.VARCHAR, + property sys.VARCHAR + ) +RETURNS INT +AS $$ +DECLARE +BEGIN + RETURN NULL; +END; +$$ +LANGUAGE plpgsql STABLE; + CREATE OR REPLACE FUNCTION sys.DATETIMEOFFSETFROMPARTS(IN p_year INTEGER, IN p_month INTEGER, IN p_day INTEGER, @@ -3033,6 +3048,974 @@ AS 'babelfishpg_tsql', 'update_user_catalog_for_guest_schema'; CALL sys.babelfish_update_user_catalog_for_guest_schema(); +ALTER VIEW sys.types RENAME TO types_deprecated_3_4_0; + +create or replace view sys.types As +-- For System types +select + tsql_type_name as name + , t.oid as system_type_id + , t.oid as user_type_id + , s.oid as schema_id + , cast(NULL as INT) as principal_id + , sys.tsql_type_max_length_helper(tsql_type_name, t.typlen, t.typtypmod, true) as max_length + , cast(sys.tsql_type_precision_helper(tsql_type_name, t.typtypmod) as int) as precision + , cast(sys.tsql_type_scale_helper(tsql_type_name, t.typtypmod, false) as int) as scale + , CASE c.collname + WHEN 'default' THEN default_collation_name + ELSE c.collname + END as collation_name + , case when typnotnull then cast(0 as sys.bit) else cast(1 as sys.bit) end as is_nullable + , 0 as is_user_defined + , 0 as is_assembly_type + , 0 as default_object_id + , 0 as rule_object_id + , 0 as is_table_type +from pg_type t +inner join pg_namespace s on s.oid = t.typnamespace +left join pg_collation c on c.oid = t.typcollation +, sys.translate_pg_type_to_tsql(t.oid) AS tsql_type_name +,cast(current_setting('babelfishpg_tsql.server_collation_name') as name) as default_collation_name +where +tsql_type_name IS NOT NULL +and pg_type_is_visible(t.oid) +and (s.nspname = 'pg_catalog' OR s.nspname = 'sys') +union all +-- For User Defined Types +select cast(t.typname as text) as name + , t.typbasetype as system_type_id + , t.oid as user_type_id + , t.typnamespace as schema_id + , null::integer as principal_id + , case when tt.typrelid is not null then -1::smallint else sys.tsql_type_max_length_helper(tsql_base_type_name, t.typlen, t.typtypmod) end as max_length + , case when tt.typrelid is not null then 0::smallint else cast(sys.tsql_type_precision_helper(tsql_base_type_name, t.typtypmod) as int) end as precision + , case when tt.typrelid is not null then 0::smallint else cast(sys.tsql_type_scale_helper(tsql_base_type_name, t.typtypmod, false) as int) end as scale + , CASE c.collname + WHEN 'default' THEN default_collation_name + ELSE c.collname + END as collation_name + , case when tt.typrelid is not null then cast(0 as sys.bit) + else case when typnotnull then cast(0 as sys.bit) else cast(1 as sys.bit) end + end + as is_nullable + -- CREATE TYPE ... FROM is implemented as CREATE DOMAIN in babel + , 1 as is_user_defined + , 0 as is_assembly_type + , 0 as default_object_id + , 0 as rule_object_id + , case when tt.typrelid is not null then 1 else 0 end as is_table_type +from pg_type t +join sys.schemas sch on t.typnamespace = sch.schema_id +left join pg_collation c on c.oid = t.typcollation +left join sys.table_types_internal tt on t.typrelid = tt.typrelid +, sys.translate_pg_type_to_tsql(t.oid) AS tsql_type_name +, sys.translate_pg_type_to_tsql(t.typbasetype) AS tsql_base_type_name +, cast(current_setting('babelfishpg_tsql.server_collation_name') as name) as default_collation_name +-- we want to show details of user defined datatypes created under babelfish database +where + tsql_type_name IS NULL +and + ( + -- show all user defined datatypes created under babelfish database except table types + t.typtype = 'd' + or + -- only for table types + tt.typrelid is not null + ); +GRANT SELECT ON sys.types TO PUBLIC; + + +ALTER VIEW sys.table_types RENAME TO table_types_deprecated_3_4_0; +create or replace view sys.table_types as +select st.* + , pt.typrelid::int as type_table_object_id + , 0::sys.bit as is_memory_optimized -- return 0 until we support in-memory tables +from sys.types st +inner join pg_catalog.pg_type pt on st.user_type_id = pt.oid +where is_table_type = 1; +GRANT SELECT ON sys.table_types TO PUBLIC; + + + +CREATE OR REPLACE VIEW sys.sp_special_columns_view AS +SELECT +CAST(1 AS SMALLINT) AS SCOPE, +CAST(coalesce (split_part(a.attoptions[1] COLLATE "C", '=', 2) ,a.attname) AS sys.sysname) AS COLUMN_NAME, -- get original column name if exists +CAST(t6.data_type AS SMALLINT) AS DATA_TYPE, + +CASE -- cases for when they are of type identity. + WHEN a.attidentity <> ''::"char" AND (t1.name = 'decimal' OR t1.name = 'numeric') + THEN CAST(CONCAT(t1.name, '() identity') AS sys.sysname) + WHEN a.attidentity <> ''::"char" AND (t1.name != 'decimal' AND t1.name != 'numeric') + THEN CAST(CONCAT(t1.name, ' identity') AS sys.sysname) + ELSE CAST(t1.name AS sys.sysname) +END AS TYPE_NAME, + +CAST(sys.sp_special_columns_precision_helper(COALESCE(tsql_type_name, tsql_base_type_name), c1.precision, c1.max_length, t6."PRECISION") AS INT) AS PRECISION, +CAST(sys.sp_special_columns_length_helper(coalesce(tsql_type_name, tsql_base_type_name), c1.precision, c1.max_length, t6."PRECISION") AS INT) AS LENGTH, +CAST(sys.sp_special_columns_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), c1.scale) AS SMALLINT) AS SCALE, +CAST(1 AS smallint) AS PSEUDO_COLUMN, +CASE + WHEN a.attnotnull + THEN CAST(0 AS INT) + ELSE CAST(1 AS INT) END +AS IS_NULLABLE, +CAST(nsp_ext.dbname AS sys.sysname) AS TABLE_QUALIFIER, +CAST(s1.name AS sys.sysname) AS TABLE_OWNER, +CAST(C.relname AS sys.sysname) AS TABLE_NAME, + +CASE + WHEN X.indisprimary + THEN CAST('p' AS sys.sysname) + ELSE CAST('u' AS sys.sysname) -- if it is a unique index, then we should cast it as 'u' for filtering purposes +END AS CONSTRAINT_TYPE, +CAST(I.relname AS sys.sysname) CONSTRAINT_NAME, +CAST(X.indexrelid AS int) AS INDEX_ID + +FROM( pg_index X +JOIN pg_class C ON X.indrelid = C.oid +JOIN pg_class I ON I.oid = X.indexrelid +CROSS JOIN LATERAL unnest(X.indkey) AS ak(k) + LEFT JOIN pg_attribute a + ON (a.attrelid = X.indrelid AND a.attnum = ak.k) +) +LEFT JOIN sys.pg_namespace_ext nsp_ext ON C.relnamespace = nsp_ext.oid +LEFT JOIN sys.schemas s1 ON s1.schema_id = C.relnamespace +LEFT JOIN sys.columns c1 ON c1.object_id = X.indrelid AND cast(a.attname AS sys.sysname) = c1.name COLLATE sys.database_default +LEFT JOIN pg_catalog.pg_type AS T ON T.oid = c1.system_type_id +LEFT JOIN sys.types AS t1 ON a.atttypid = t1.user_type_id +LEFT JOIN sys.sp_datatype_info_helper(2::smallint, false) AS t6 ON T.typname = t6.pg_type_name OR T.typname = t6.type_name --need in order to get accurate DATA_TYPE value +, sys.translate_pg_type_to_tsql(t1.user_type_id) AS tsql_type_name +, sys.translate_pg_type_to_tsql(t1.system_type_id) AS tsql_base_type_name +WHERE has_schema_privilege(s1.schema_id, 'USAGE') +AND X.indislive ; + +GRANT SELECT ON sys.sp_special_columns_view TO PUBLIC; + + +CREATE OR REPLACE VIEW sys.sp_sproc_columns_view +AS +SELECT +CAST(sys.db_name() AS sys.sysname) AS PROCEDURE_QUALIFIER -- This will always be objects in current database +, CAST(ss.schema_name AS sys.sysname) AS PROCEDURE_OWNER +, CAST( +CASE + WHEN ss.prokind = 'p' THEN CONCAT(ss.proname, ';1') + ELSE CONCAT(ss.proname, ';0') +END +AS sys.nvarchar(134)) AS PROCEDURE_NAME +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN '@TABLE_RETURN_VALUE' + ELSE '@RETURN_VALUE' + END +ELSE COALESCE(ss.proargnames[n], '') +END +AS sys.SYSNAME) AS COLUMN_NAME +, CAST( +CASE +WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 3 + ELSE 5 + END +WHEN ss.proargmodes[n] in ('o', 'b') THEN 2 +ELSE 1 +END +AS smallint) AS COLUMN_TYPE +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.prokind = 'p' THEN (SELECT data_type FROM sys.spt_datatype_info_table WHERE type_name = 'int') + WHEN ss.proretset THEN NULL + ELSE sdit.data_type + END + WHEN st.is_table_type = 1 THEN -153 + ELSE sdit.data_type +END +AS smallint) AS DATA_TYPE +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 'table' + WHEN ss.prokind = 'p' THEN 'int' + ELSE st.name + END + ELSE st.name +END +AS sys.sysname) AS TYPE_NAME +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 0 + WHEN ss.prokind = 'p' THEN (SELECT precision FROM sys.types WHERE name = 'int') + ELSE st.precision + END + WHEN st.is_table_type = 1 THEN 0 + ELSE st.precision +END +AS sys.int) AS PRECISION +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 0 + WHEN ss.prokind = 'p' THEN (SELECT max_length FROM sys.types WHERE name = 'int') + ELSE st.max_length + END + WHEN st.is_table_type = 1 THEN 2147483647 + ELSE st.max_length +END +AS sys.int) AS LENGTH +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 0 + WHEN ss.prokind = 'p' THEN (SELECT scale FROM sys.types WHERE name = 'int') + ELSE st.scale + END + WHEN st.is_table_type = 1 THEN NULL + ELSE st.scale +END +AS smallint) AS SCALE +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 0 + WHEN ss.prokind = 'p' THEN (SELECT num_prec_radix FROM sys.spt_datatype_info_table WHERE type_name = 'int') + ELSE sdit.num_prec_radix + END + WHEN st.is_table_type = 1 THEN NULL + ELSE sdit.num_prec_radix +END +AS smallint) AS RADIX +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset OR ss.prokind = 'p' THEN 0 + ELSE sdit.nullable + END + WHEN st.is_table_type = 1 THEN 1 + ELSE sdit.nullable +END +AS smallint) AS NULLABLE +, CAST( +CASE + WHEN ss.n IS NULL AND ss.proretset THEN 'Result table returned by table valued function' + ELSE NULL +END +AS sys.varchar(254)) COLLATE sys.database_default AS REMARKS +, CAST(NULL AS sys.nvarchar(4000)) AS COLUMN_DEF +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN NULL + WHEN ss.prokind = 'p' THEN (SELECT sql_data_type FROM sys.spt_datatype_info_table WHERE type_name = 'int') + ELSE sdit.sql_data_type + END + WHEN st.is_table_type = 1 THEN -153 + ELSE sdit.sql_data_type +END +AS smallint) AS SQL_DATA_TYPE +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 0 + WHEN ss.prokind = 'p' THEN (SELECT sql_datetime_sub FROM sys.spt_datatype_info_table WHERE type_name = 'int') + ELSE sdit.sql_datetime_sub + END + ELSE sdit.sql_datetime_sub +END +AS smallint) AS SQL_DATETIME_SUB +, CAST( +CASE + WHEN ss.n IS NOT NULL AND st.is_table_type = 1 THEN 2147483647 + ELSE NULL +END +AS sys.int) AS CHAR_OCTET_LENGTH +, CAST( +CASE + WHEN ss.n IS NULL THEN 0 + ELSE n +END +AS sys.int) AS ORDINAL_POSITION +, CAST( +CASE + WHEN ss.n IS NULL AND ss.proretset THEN 'NO' + WHEN st.is_table_type = 1 THEN 'YES' + WHEN sdit.nullable = 1 THEN 'YES' + ELSE 'NO' +END +AS sys.varchar(254)) COLLATE sys.database_default AS IS_NULLABLE +, CAST( +CASE + WHEN ss.n IS NULL THEN + CASE + WHEN ss.proretset THEN 0 + WHEN ss.prokind = 'p' THEN 56 + ELSE sdit.ss_data_type + END + WHEN st.is_table_type = 1 THEN 0 + ELSE sdit.ss_data_type +END +AS sys.tinyint) AS SS_DATA_TYPE +, CAST(ss.proname AS sys.sysname) AS original_procedure_name +FROM +( + -- CTE to query procedures related to bbf + WITH bbf_proc AS ( + SELECT + p.proname as proname, + p.proargnames as proargnames, + p.proargmodes as proargmodes, + p.prokind as prokind, + p.proretset as proretset, + p.prorettype as prorettype, + p.proallargtypes as proallargtypes, + p.proargtypes as proargtypes, + s.name as schema_name + FROM + pg_proc p + INNER JOIN ( + SELECT name as name, schema_id as id FROM sys.schemas + UNION ALL + SELECT CAST(nspname as sys.sysname) as name, CAST(oid as int) as id + from pg_namespace WHERE nspname in ('sys', 'information_schema') + ) as s ON p.pronamespace = s.id + WHERE ( + (pg_has_role(p.proowner, 'USAGE') OR has_function_privilege(p.oid, 'EXECUTE')) + AND (s.name != 'sys' + OR p.proname like 'sp\_%' -- filter out internal babelfish-specific procs in sys schema + OR p.proname like 'xp\_%' + OR p.proname like 'dm\_%' + OR p.proname like 'fn\_%')) + ) + + SELECT * + FROM ( + SELECT -- Selects all parameters (input and output), but NOT return values + p.proname as proname, + p.proargnames as proargnames, + p.proargmodes as proargmodes, + p.prokind as prokind, + p.proretset as proretset, + p.prorettype as prorettype, + p.schema_name as schema_name, + (information_schema._pg_expandarray( + COALESCE(p.proallargtypes, + CASE + WHEN p.prokind = 'f' THEN (CAST(p.proargtypes AS oid[])) + ELSE CAST(p.proargtypes AS oid[]) + END + ))).x AS x, + (information_schema._pg_expandarray( + COALESCE(p.proallargtypes, + CASE + WHEN p.prokind = 'f' THEN (CAST(p.proargtypes AS oid[])) + ELSE CAST(p.proargtypes AS oid[]) + END + ))).n AS n + FROM bbf_proc p) AS t + WHERE (t.proargmodes[t.n] in ('i', 'o', 'b') OR t.proargmodes is NULL) + + UNION ALL + + SELECT -- Selects all return values (this is because inline-table functions could cause duplicate outputs) + p.proname as proname, + p.proargnames as proargnames, + p.proargmodes as proargmodes, + p.prokind as prokind, + p.proretset as proretset, + p.prorettype as prorettype, + p.schema_name as schema_name, + p.prorettype AS x, + NULL AS n -- null value indicates that we are retrieving the return values of the proc/func + FROM bbf_proc p +) ss +LEFT JOIN sys.types st ON ss.x = st.user_type_id -- left joined because return type of table-valued functions may not have an entry in sys.types +-- Because spt_datatype_info_table does contain user-defind types and their names, +-- the join below allows us to retrieve the name of the base type of the user-defined type +LEFT JOIN sys.spt_datatype_info_table sdit ON sdit.type_name = sys.translate_pg_type_to_tsql(st.system_type_id); +GRANT SELECT ON sys.sp_sproc_columns_view TO PUBLIC; + + + +CREATE OR REPLACE VIEW sys.assembly_types +AS +SELECT + CAST(t.name as sys.sysname) AS name, + -- 'system_type_id' is specified as type INT here, and not TINYINT per SQL Server documentation. + -- This is because the IDs of generated SQL Server system type values generated by B + -- Babelfish installation will exceed the size of TINYINT. + CAST(t.system_type_id as int) AS system_type_id, + CAST(t.user_type_id as int) AS user_type_id, + CAST(t.schema_id as int) AS schema_id, + CAST(t.principal_id as int) AS principal_id, + CAST(t.max_length as smallint) AS max_length, + CAST(t.precision as sys.tinyint) AS precision, + CAST(t.scale as sys.tinyint) AS scale, + CAST(t.collation_name as sys.sysname) AS collation_name, + CAST(t.is_nullable as sys.bit) AS is_nullable, + CAST(t.is_user_defined as sys.bit) AS is_user_defined, + CAST(t.is_assembly_type as sys.bit) AS is_assembly_type, + CAST(t.default_object_id as int) AS default_object_id, + CAST(t.rule_object_id as int) AS rule_object_id, + CAST(NULL as int) AS assembly_id, + CAST(NULL as sys.sysname) AS assembly_class, + CAST(NULL as sys.bit) AS is_binary_ordered, + CAST(NULL as sys.bit) AS is_fixed_length, + CAST(NULL as sys.nvarchar(40)) AS prog_id, + CAST(NULL as sys.nvarchar(4000)) AS assembly_qualified_name, + CAST(t.is_table_type as sys.bit) AS is_table_type +FROM sys.types t +WHERE t.is_assembly_type = 1; +GRANT SELECT ON sys.assembly_types TO PUBLIC; + + + + +CREATE OR REPLACE VIEW sys.all_parameters +AS +SELECT + CAST(ss.p_oid AS INT) AS object_id + , CAST(COALESCE(ss.proargnames[(ss.x).n], '') AS sys.SYSNAME) AS name + , CAST( + CASE + WHEN is_out_scalar = 1 THEN 0 -- param_id = 0 for output of scalar function + ELSE (ss.x).n + END + AS INT) AS parameter_id + -- 'system_type_id' is specified as type INT here, and not TINYINT per SQL Server documentation. + -- This is because the IDs of system type values generated by + -- Babelfish installation will exceed the size of TINYINT + , CAST(st.system_type_id AS INT) AS system_type_id + , CAST(st.user_type_id AS INT) AS user_type_id + , CAST( + CASE + WHEN st.is_table_type = 1 THEN -1 -- TVP case + WHEN st.is_user_defined = 1 THEN st.max_length -- UDT case + ELSE sys.tsql_type_max_length_helper(st.name, t.typlen, typmod, true, true) + END + AS smallint) AS max_length + , CAST( + CASE + WHEN st.is_table_type = 1 THEN 0 -- TVP case + WHEN st.is_user_defined = 1 THEN st.precision -- UDT case + ELSE sys.tsql_type_precision_helper(st.name, typmod) + END + AS sys.tinyint) AS precision + , CAST( + CASE + WHEN st.is_table_type = 1 THEN 0 -- TVP case + WHEN st.is_user_defined = 1 THEN st.scale + ELSE sys.tsql_type_scale_helper(st.name, typmod,false) + END + AS sys.tinyint) AS scale + , CAST( + CASE + WHEN is_out_scalar = 1 THEN 1 -- Output of a scalar function + WHEN ss.proargmodes[(ss.x).n] in ('o', 'b', 't') THEN 1 + ELSE 0 + END + AS sys.bit) AS is_output + , CAST(0 AS sys.bit) AS is_cursor_ref + , CAST(0 AS sys.bit) AS has_default_value + , CAST(0 AS sys.bit) AS is_xml_document + , CAST(NULL AS sys.sql_variant) AS default_value + , CAST(0 AS int) AS xml_collection_id + , CAST(0 AS sys.bit) AS is_readonly + , CAST(1 AS sys.bit) AS is_nullable + , CAST(NULL AS int) AS encryption_type + , CAST(NULL AS sys.nvarchar(64)) AS encryption_type_desc + , CAST(NULL AS sys.sysname) AS encryption_algorithm_name + , CAST(NULL AS int) AS column_encryption_key_id + , CAST(NULL AS sys.sysname) AS column_encryption_key_database_name +FROM pg_type t + INNER JOIN sys.types st ON st.user_type_id = t.oid + INNER JOIN + ( + SELECT + p.oid AS p_oid, + p.proargnames, + p.proargmodes, + p.prokind, + json_extract_path(CAST(p.probin as json), 'typmod_array') AS typmod_array, + information_schema._pg_expandarray( + COALESCE(p.proallargtypes, + CASE + WHEN p.prokind = 'f' THEN (CAST( p.proargtypes AS oid[]) || p.prorettype) -- Adds return type if not present on proallargtypes + ELSE CAST(p.proargtypes AS oid[]) + END + )) AS x + FROM pg_proc p + WHERE ( + p.pronamespace in (select schema_id from sys.schemas union all select oid from pg_namespace where nspname = 'sys') + AND (pg_has_role(p.proowner, 'USAGE') OR has_function_privilege(p.oid, 'EXECUTE')) + AND p.probin like '{%typmod_array%}') -- Needs to have a typmod array in JSON format + ) ss ON t.oid = (ss.x).x, + COALESCE(pg_get_function_result(ss.p_oid), '') AS return_type, + CAST(ss.typmod_array->>(ss.x).n-1 AS INT) AS typmod, + CAST( + CASE + WHEN ss.prokind = 'f' AND ss.proargnames[(ss.x).n] IS NULL THEN 1 -- checks if param is output of scalar function + ELSE 0 + END + AS INT) AS is_out_scalar +WHERE ( -- If it is a Table function, we only want the inputs + return_type NOT LIKE 'TABLE(%' OR + (return_type LIKE 'TABLE(%' AND ss.proargmodes[(ss.x).n] = 'i')); +GRANT SELECT ON sys.all_parameters TO PUBLIC; + + +CREATE OR REPLACE VIEW sys.systypes AS +SELECT CAST(name as sys.sysname) as name + , CAST(system_type_id as int) as xtype + , CAST((case when is_nullable = 1 then 0 else 1 end) as sys.tinyint) as status + , CAST((case when user_type_id < 32767 then user_type_id::int else null end) as smallint) as xusertype + , max_length as length + , CAST(precision as sys.tinyint) as xprec + , CAST(scale as sys.tinyint) as xscale + , CAST(default_object_id as int) as tdefault + , CAST(rule_object_id as int) as domain + , CAST((case when schema_id < 32767 then schema_id::int else null end) as smallint) as uid + , CAST(0 as smallint) as reserved + , CAST(sys.CollationProperty(collation_name, 'CollationId') as int) as collationid + , CAST((case when user_type_id < 32767 then user_type_id::int else null end) as smallint) as usertype + , CAST((case when (coalesce(sys.translate_pg_type_to_tsql(system_type_id), sys.translate_pg_type_to_tsql(user_type_id)) + in ('nvarchar', 'varchar', 'sysname', 'varbinary')) then 1 + else 0 end) as sys.bit) as variable + , CAST(is_nullable as sys.bit) as allownulls + , CAST(system_type_id as int) as type + , CAST(null as sys.varchar(255)) as printfmt + , (case when precision <> 0::smallint then precision + else sys.systypes_precision_helper(sys.translate_pg_type_to_tsql(system_type_id), max_length) end) as prec + , CAST(scale as sys.tinyint) as scale + , CAST(collation_name as sys.sysname) as collation +FROM sys.types; +GRANT SELECT ON sys.systypes TO PUBLIC; + +create or replace view sys.all_objects as +select + cast (name as sys.sysname) collate sys.database_default + , cast (object_id as integer) + , cast ( principal_id as integer) + , cast (schema_id as integer) + , cast (parent_object_id as integer) + , cast (type as char(2)) collate sys.database_default + , cast (type_desc as sys.nvarchar(60)) + , cast (create_date as sys.datetime) + , cast (modify_date as sys.datetime) + , cast (case when (schema_id::regnamespace::text = 'sys') then 1 + when name in (select name from sys.shipped_objects_not_in_sys nis + where nis.name = name and nis.schemaid = schema_id and nis.type = type) then 1 + else 0 end as sys.bit) as is_ms_shipped + , cast (is_published as sys.bit) + , cast (is_schema_published as sys.bit) +from +( +-- details of user defined and system tables +select + t.relname as name + , t.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'U' as type + , 'USER_TABLE' as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_class t inner join pg_namespace s on s.oid = t.relnamespace +where t.relpersistence in ('p', 'u', 't') +and t.relkind = 'r' +and (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and not sys.is_table_type(t.oid) +and has_schema_privilege(s.oid, 'USAGE') +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +union all +-- details of user defined and system views +select + t.relname as name + , t.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'V'::varchar(2) as type + , 'VIEW'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_class t inner join pg_namespace s on s.oid = t.relnamespace +where t.relkind = 'v' +and (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(t.relname), 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +union all +-- details of user defined and system foreign key constraints +select + c.conname as name + , c.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , c.conrelid as parent_object_id + , 'F' as type + , 'FOREIGN_KEY_CONSTRAINT' + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_constraint c +inner join pg_namespace s on s.oid = c.connamespace +where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +and c.contype = 'f' +union all +-- details of user defined and system primary key constraints +select + c.conname as name + , c.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , c.conrelid as parent_object_id + , 'PK' as type + , 'PRIMARY_KEY_CONSTRAINT' as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_constraint c +inner join pg_namespace s on s.oid = c.connamespace +where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +and c.contype = 'p' +union all +-- details of user defined and system defined procedures +select + p.proname as name + , p.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , cast (case when tr.tgrelid is not null + then tr.tgrelid + else 0 end as int) + as parent_object_id + , case p.prokind + when 'p' then 'P'::varchar(2) + when 'a' then 'AF'::varchar(2) + else + case + when pg_catalog.format_type(p.prorettype, null) = 'trigger' + then 'TR'::varchar(2) + when p.proretset then + case + when t.typtype = 'c' + then 'TF'::varchar(2) + else 'IF'::varchar(2) + end + else 'FN'::varchar(2) + end + end as type + , case p.prokind + when 'p' then 'SQL_STORED_PROCEDURE'::varchar(60) + when 'a' then 'AGGREGATE_FUNCTION'::varchar(60) + else + case + when pg_catalog.format_type(p.prorettype, null) = 'trigger' + then 'SQL_TRIGGER'::varchar(60) + when p.proretset then + case + when t.typtype = 'c' + then 'SQL_TABLE_VALUED_FUNCTION'::varchar(60) + else 'SQL_INLINE_TABLE_VALUED_FUNCTION'::varchar(60) + end + else 'SQL_SCALAR_FUNCTION'::varchar(60) + end + end as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_proc p +inner join pg_namespace s on s.oid = p.pronamespace +inner join pg_catalog.pg_type t on t.oid = p.prorettype +left join pg_trigger tr on tr.tgfoid = p.oid +where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +and has_function_privilege(p.oid, 'EXECUTE') +union all +-- details of all default constraints +select + ('DF_' || o.relname || '_' || d.oid)::name as name + , d.oid as object_id + , null::int as principal_id + , o.relnamespace as schema_id + , d.adrelid as parent_object_id + , 'D'::char(2) as type + , 'DEFAULT_CONSTRAINT'::sys.nvarchar(60) AS type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_catalog.pg_attrdef d +inner join pg_attribute a on a.attrelid = d.adrelid and d.adnum = a.attnum +inner join pg_class o on d.adrelid = o.oid +inner join pg_namespace s on s.oid = o.relnamespace +where a.atthasdef = 't' and a.attgenerated = '' +and (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +and has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') +union all +-- details of all check constraints +select + c.conname::name + , c.oid::integer as object_id + , NULL::integer as principal_id + , c.connamespace::integer as schema_id + , c.conrelid::integer as parent_object_id + , 'C'::char(2) as type + , 'CHECK_CONSTRAINT'::sys.nvarchar(60) as type_desc + , null::sys.datetime as create_date + , null::sys.datetime as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_catalog.pg_constraint as c +inner join pg_namespace s on s.oid = c.connamespace +where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +and c.contype = 'c' and c.conrelid != 0 +union all +-- details of user defined and system defined sequence objects +select + p.relname as name + , p.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'SO'::varchar(2) as type + , 'SEQUENCE_OBJECT'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from pg_class p +inner join pg_namespace s on s.oid = p.relnamespace +where p.relkind = 'S' +and (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +and has_schema_privilege(s.oid, 'USAGE') +union all +-- details of user defined table types +select + ('TT_' || tt.name || '_' || tt.type_table_object_id)::name as name + , tt.type_table_object_id as object_id + , tt.principal_id as principal_id + , tt.schema_id as schema_id + , 0 as parent_object_id + , 'TT'::varchar(2) as type + , 'TABLE_TYPE'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 1 as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from sys.table_types tt +) ot; +GRANT SELECT ON sys.all_objects TO PUBLIC; + + + +create or replace view sys.objects as +select + CAST(t.name as sys.sysname) as name + , CAST(t.object_id as int) as object_id + , CAST(t.principal_id as int) as principal_id + , CAST(t.schema_id as int) as schema_id + , CAST(t.parent_object_id as int) as parent_object_id + , CAST('U' as char(2)) as type + , CAST('USER_TABLE' as sys.nvarchar(60)) as type_desc + , CAST(t.create_date as sys.datetime) as create_date + , CAST(t.modify_date as sys.datetime) as modify_date + , CAST(t.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(t.is_published as sys.bit) as is_published + , CAST(t.is_schema_published as sys.bit) as is_schema_published +from sys.tables t +union all +select + CAST(v.name as sys.sysname) as name + , CAST(v.object_id as int) as object_id + , CAST(v.principal_id as int) as principal_id + , CAST(v.schema_id as int) as schema_id + , CAST(v.parent_object_id as int) as parent_object_id + , CAST('V' as char(2)) as type + , CAST('VIEW' as sys.nvarchar(60)) as type_desc + , CAST(v.create_date as sys.datetime) as create_date + , CAST(v.modify_date as sys.datetime) as modify_date + , CAST(v.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(v.is_published as sys.bit) as is_published + , CAST(v.is_schema_published as sys.bit) as is_schema_published +from sys.views v +union all +select + CAST(f.name as sys.sysname) as name + , CAST(f.object_id as int) as object_id + , CAST(f.principal_id as int) as principal_id + , CAST(f.schema_id as int) as schema_id + , CAST(f.parent_object_id as int) as parent_object_id + , CAST('F' as char(2)) as type + , CAST('FOREIGN_KEY_CONSTRAINT' as sys.nvarchar(60)) as type_desc + , CAST(f.create_date as sys.datetime) as create_date + , CAST(f.modify_date as sys.datetime) as modify_date + , CAST(f.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(f.is_published as sys.bit) as is_published + , CAST(f.is_schema_published as sys.bit) as is_schema_published + from sys.foreign_keys f +union all +select + CAST(p.name as sys.sysname) as name + , CAST(p.object_id as int) as object_id + , CAST(p.principal_id as int) as principal_id + , CAST(p.schema_id as int) as schema_id + , CAST(p.parent_object_id as int) as parent_object_id + , CAST('PK' as char(2)) as type + , CAST('PRIMARY_KEY_CONSTRAINT' as sys.nvarchar(60)) as type_desc + , CAST(p.create_date as sys.datetime) as create_date + , CAST(p.modify_date as sys.datetime) as modify_date + , CAST(p.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(p.is_published as sys.bit) as is_published + , CAST(p.is_schema_published as sys.bit) as is_schema_published +from sys.key_constraints p +where p.type = 'PK' +union all +select + CAST(pr.name as sys.sysname) as name + , CAST(pr.object_id as int) as object_id + , CAST(pr.principal_id as int) as principal_id + , CAST(pr.schema_id as int) as schema_id + , CAST(pr.parent_object_id as int) as parent_object_id + , CAST(pr.type as char(2)) as type + , CAST(pr.type_desc as sys.nvarchar(60)) as type_desc + , CAST(pr.create_date as sys.datetime) as create_date + , CAST(pr.modify_date as sys.datetime) as modify_date + , CAST(pr.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(pr.is_published as sys.bit) as is_published + , CAST(pr.is_schema_published as sys.bit) as is_schema_published + from sys.procedures pr +union all +select + CAST(tr.name as sys.sysname) as name + , CAST(tr.object_id as int) as object_id + , CAST(NULL as int) as principal_id + , CAST(p.pronamespace as int) as schema_id + , CAST(tr.parent_id as int) as parent_object_id + , CAST(tr.type as char(2)) as type + , CAST(tr.type_desc as sys.nvarchar(60)) as type_desc + , CAST(tr.create_date as sys.datetime) as create_date + , CAST(tr.modify_date as sys.datetime) as modify_date + , CAST(tr.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(0 as sys.bit) as is_published + , CAST(0 as sys.bit) as is_schema_published + from sys.triggers tr + inner join pg_proc p on p.oid = tr.object_id +union all +select + CAST(def.name as sys.sysname) as name + , CAST(def.object_id as int) as object_id + , CAST(def.principal_id as int) as principal_id + , CAST(def.schema_id as int) as schema_id + , CAST(def.parent_object_id as int) as parent_object_id + , CAST(def.type as char(2)) as type + , CAST(def.type_desc as sys.nvarchar(60)) as type_desc + , CAST(def.create_date as sys.datetime) as create_date + , CAST(def.modified_date as sys.datetime) as modify_date + , CAST(def.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(def.is_published as sys.bit) as is_published + , CAST(def.is_schema_published as sys.bit) as is_schema_published + from sys.default_constraints def +union all +select + CAST(chk.name as sys.sysname) as name + , CAST(chk.object_id as int) as object_id + , CAST(chk.principal_id as int) as principal_id + , CAST(chk.schema_id as int) as schema_id + , CAST(chk.parent_object_id as int) as parent_object_id + , CAST(chk.type as char(2)) as type + , CAST(chk.type_desc as sys.nvarchar(60)) as type_desc + , CAST(chk.create_date as sys.datetime) as create_date + , CAST(chk.modify_date as sys.datetime) as modify_date + , CAST(chk.is_ms_shipped as sys.bit) as is_ms_shipped + , CAST(chk.is_published as sys.bit) as is_published + , CAST(chk.is_schema_published as sys.bit) as is_schema_published + from sys.check_constraints chk +union all +select + CAST(p.relname as sys.sysname) 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 +from pg_class p +inner join sys.schemas s on s.schema_id = p.relnamespace +and p.relkind = 'S' +and has_schema_privilege(s.schema_id, 'USAGE') +union all +select + CAST(('TT_' || tt.name collate "C" || '_' || tt.type_table_object_id) as sys.sysname) as name + , CAST(tt.type_table_object_id as int) as object_id + , CAST(tt.principal_id as int) as principal_id + , CAST(tt.schema_id as int) as schema_id + , CAST(0 as int) as parent_object_id + , CAST('TT' as char(2)) as type + , CAST('TABLE_TYPE' as sys.nvarchar(60)) as type_desc + , CAST((select string_agg( + case + when option like 'bbf_rel_create_date=%%' then substring(option, 21) + else NULL + end, ',') + from unnest(c.reloptions) as option) + as sys.datetime) as create_date + , CAST((select string_agg( + case + when option like 'bbf_rel_create_date=%%' then substring(option, 21) + else NULL + end, ',') + from unnest(c.reloptions) as option) + as sys.datetime) as modify_date + , CAST(1 as sys.bit) as is_ms_shipped + , CAST(0 as sys.bit) as is_published + , CAST(0 as sys.bit) as is_schema_published +from sys.table_types tt +inner join pg_class c on tt.type_table_object_id = c.oid; +GRANT SELECT ON sys.objects TO PUBLIC; + +CALL sys.babelfish_drop_deprecated_object('view', 'sys', 'types_deprecated_3_4_0'); +CALL sys.babelfish_drop_deprecated_object('view', 'sys', 'table_types_deprecated_3_4_0'); + -- Drop this procedure after it gets executed once. DROP PROCEDURE sys.babelfish_update_user_catalog_for_guest_schema(); diff --git a/test/JDBC/expected/sys-table_types-before-dep-vu-cleanup.out b/test/JDBC/expected/sys-table_types-before-dep-vu-cleanup.out new file mode 100644 index 0000000000..ef0a545b3c --- /dev/null +++ b/test/JDBC/expected/sys-table_types-before-dep-vu-cleanup.out @@ -0,0 +1,6 @@ +drop procedure sys_table_types_dep_vu_prepare_p1 +drop function sys_table_types_dep_vu_prepare_f1 +drop view sys_table_types_dep_vu_prepare_v1 +drop procedure sys_table_types_dep_vu_prepare_p2 +drop type sys_table_types_dep_vu_prepare_tt +GO diff --git a/test/JDBC/expected/sys-table_types-before-dep-vu-prepare.out b/test/JDBC/expected/sys-table_types-before-dep-vu-prepare.out new file mode 100644 index 0000000000..8a8350d4b4 --- /dev/null +++ b/test/JDBC/expected/sys-table_types-before-dep-vu-prepare.out @@ -0,0 +1,23 @@ +-- tsql +create type sys_table_types_dep_vu_prepare_tt as table(sys_table_types_vu_prepare_tt_a int, sys_table_types_vu_prepare_tt_b char); +GO + +create procedure sys_table_types_dep_vu_prepare_p1 as + select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create function sys_table_types_dep_vu_prepare_f1() +returns int +as +begin + return (select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt') +end +GO + +create view sys_table_types_dep_vu_prepare_v1 as + select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create procedure sys_table_types_dep_vu_prepare_p2 as + select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO diff --git a/test/JDBC/expected/sys-table_types-before-dep-vu-verify.out b/test/JDBC/expected/sys-table_types-before-dep-vu-verify.out new file mode 100644 index 0000000000..540b2f3c40 --- /dev/null +++ b/test/JDBC/expected/sys-table_types-before-dep-vu-verify.out @@ -0,0 +1,32 @@ +--tsql +exec sys_table_types_dep_vu_prepare_p1 +GO +~~START~~ +int +1 +~~END~~ + + +select * from sys_table_types_dep_vu_prepare_f1() +GO +~~START~~ +int +1 +~~END~~ + + +select * from sys_table_types_dep_vu_prepare_v1 +GO +~~START~~ +int +1 +~~END~~ + + +exec sys_table_types_dep_vu_prepare_p2 +GO +~~START~~ +bit +0 +~~END~~ + diff --git a/test/JDBC/expected/sys-table_types-dep-vu-cleanup.out b/test/JDBC/expected/sys-table_types-dep-vu-cleanup.out index b591d0dff6..e4a1f7864d 100644 --- a/test/JDBC/expected/sys-table_types-dep-vu-cleanup.out +++ b/test/JDBC/expected/sys-table_types-dep-vu-cleanup.out @@ -1,5 +1,8 @@ drop procedure sys_table_types_dep_vu_prepare_p1 drop function sys_table_types_dep_vu_prepare_f1 drop view sys_table_types_dep_vu_prepare_v1 +drop procedure sys_table_types_dep_vu_prepare_p2 +drop function sys_table_types_dep_vu_prepare_f2 +drop view sys_table_types_dep_vu_prepare_v2 drop type sys_table_types_dep_vu_prepare_tt GO diff --git a/test/JDBC/expected/sys-table_types-dep-vu-prepare.out b/test/JDBC/expected/sys-table_types-dep-vu-prepare.out index 20bfa9efbd..200f65b795 100644 --- a/test/JDBC/expected/sys-table_types-dep-vu-prepare.out +++ b/test/JDBC/expected/sys-table_types-dep-vu-prepare.out @@ -17,3 +17,19 @@ GO create view sys_table_types_dep_vu_prepare_v1 as select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' GO + +create procedure sys_table_types_dep_vu_prepare_p2 as + select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create view sys_table_types_dep_vu_prepare_v2 as + select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create function sys_table_types_dep_vu_prepare_f2() +returns sys.bit +as +begin + return (select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt') +end +GO diff --git a/test/JDBC/expected/sys-table_types-dep-vu-verify.out b/test/JDBC/expected/sys-table_types-dep-vu-verify.out index 6f08278187..75a5151326 100644 --- a/test/JDBC/expected/sys-table_types-dep-vu-verify.out +++ b/test/JDBC/expected/sys-table_types-dep-vu-verify.out @@ -22,3 +22,27 @@ int 1 ~~END~~ + +exec sys_table_types_dep_vu_prepare_p2 +GO +~~START~~ +bit +0 +~~END~~ + + +select * from sys_table_types_dep_vu_prepare_v2 +GO +~~START~~ +bit +0 +~~END~~ + + +select * from sys_table_types_dep_vu_prepare_f2() +GO +~~START~~ +bit +0 +~~END~~ + diff --git a/test/JDBC/expected/sys-table_types-vu-verify.out b/test/JDBC/expected/sys-table_types-vu-verify.out index 9a1572aaaf..7a009f0410 100644 --- a/test/JDBC/expected/sys-table_types-vu-verify.out +++ b/test/JDBC/expected/sys-table_types-vu-verify.out @@ -18,7 +18,7 @@ from sys.table_types where name = 'sys_table_types_vu_prepare_tt'; GO ~~START~~ -text#!#int#!#int#!#smallint#!#int#!#int#!#varchar#!#int#!#int#!#int#!#int#!#int#!#int#!#bit +text#!#int#!#int#!#smallint#!#int#!#int#!#varchar#!#bit#!#int#!#int#!#int#!#int#!#int#!#bit sys_table_types_vu_prepare_tt#!#0#!##!#-1#!#0#!#0#!##!#0#!#1#!#0#!#0#!#0#!#1#!#0 ~~END~~ diff --git a/test/JDBC/expected/sys-table_types.out b/test/JDBC/expected/sys-table_types.out index a97ed4f775..c4f34b547a 100644 --- a/test/JDBC/expected/sys-table_types.out +++ b/test/JDBC/expected/sys-table_types.out @@ -22,7 +22,7 @@ from sys.table_types where name = 'tt_type'; GO ~~START~~ -text#!#int#!#int#!#smallint#!#int#!#int#!#varchar#!#int#!#int#!#int#!#int#!#int#!#int#!#bit +text#!#int#!#int#!#smallint#!#int#!#int#!#varchar#!#bit#!#int#!#int#!#int#!#int#!#int#!#bit tt_type#!#0#!##!#-1#!#0#!#0#!##!#0#!#1#!#0#!#0#!#0#!#1#!#0 ~~END~~ diff --git a/test/JDBC/expected/sys-types-before-dep-vu-cleanup.out b/test/JDBC/expected/sys-types-before-dep-vu-cleanup.out new file mode 100644 index 0000000000..f5b7574a70 --- /dev/null +++ b/test/JDBC/expected/sys-types-before-dep-vu-cleanup.out @@ -0,0 +1,2 @@ +DROP DATABASE sys_types_dep_vu_prepare_db1 +GO diff --git a/test/JDBC/expected/sys-types-before-dep-vu-prepare.out b/test/JDBC/expected/sys-types-before-dep-vu-prepare.out new file mode 100644 index 0000000000..a0e538eb74 --- /dev/null +++ b/test/JDBC/expected/sys-types-before-dep-vu-prepare.out @@ -0,0 +1,40 @@ +CREATE DATABASE sys_types_dep_vu_prepare_db1; +GO + +USE sys_types_dep_vu_prepare_db1 +GO + +CREATE TYPE sys_types_dep_vu_prepare_ty1 FROM int +GO + +CREATE PROCEDURE sys_types_dep_vu_prepare_p1 AS + SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE FUNCTION sys_types_dep_vu_prepare_f1() +RETURNS INT +AS +BEGIN + RETURN (SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1') +END +GO + +CREATE VIEW sys_types_dep_vu_prepare_v1 AS + SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE VIEW sys_types_dep_vu_prepare_v2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE PROCEDURE sys_types_dep_vu_prepare_p2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE FUNCTION sys_types_dep_vu_prepare_f2() +RETURNS sys.bit +AS +BEGIN + RETURN (SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1') +END +GO diff --git a/test/JDBC/expected/sys-types-before-dep-vu-verify.out b/test/JDBC/expected/sys-types-before-dep-vu-verify.out new file mode 100644 index 0000000000..328eccb312 --- /dev/null +++ b/test/JDBC/expected/sys-types-before-dep-vu-verify.out @@ -0,0 +1,50 @@ +USE sys_types_dep_vu_prepare_db1 +GO + +EXEC sys_types_dep_vu_prepare_p1 +GO +~~START~~ +int +1 +~~END~~ + + +SELECT * FROM sys_types_dep_vu_prepare_f1() +GO +~~START~~ +int +1 +~~END~~ + + +SELECT * FROM sys_types_dep_vu_prepare_v1 +GO +~~START~~ +int +1 +~~END~~ + + +EXEC sys_types_dep_vu_prepare_p2 +GO +~~START~~ +bit +1 +~~END~~ + + +SELECT * FROM sys_types_dep_vu_prepare_v2 +GO +~~START~~ +int +1 +~~END~~ + + +SELECT * FROM sys_types_dep_vu_prepare_f2() +GO +~~START~~ +bit +1 +~~END~~ + diff --git a/test/JDBC/expected/sys-types-dep-vu-prepare.out b/test/JDBC/expected/sys-types-dep-vu-prepare.out index b42877e088..a0e538eb74 100644 --- a/test/JDBC/expected/sys-types-dep-vu-prepare.out +++ b/test/JDBC/expected/sys-types-dep-vu-prepare.out @@ -23,3 +23,18 @@ CREATE VIEW sys_types_dep_vu_prepare_v1 AS SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' GO +CREATE VIEW sys_types_dep_vu_prepare_v2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE PROCEDURE sys_types_dep_vu_prepare_p2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE FUNCTION sys_types_dep_vu_prepare_f2() +RETURNS sys.bit +AS +BEGIN + RETURN (SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1') +END +GO diff --git a/test/JDBC/expected/sys-types-dep-vu-verify.out b/test/JDBC/expected/sys-types-dep-vu-verify.out index 44b3224b58..5df1cae91a 100644 --- a/test/JDBC/expected/sys-types-dep-vu-verify.out +++ b/test/JDBC/expected/sys-types-dep-vu-verify.out @@ -24,3 +24,27 @@ int 1 ~~END~~ + +EXEC sys_types_dep_vu_prepare_p2 +GO +~~START~~ +bit +1 +~~END~~ + + +SELECT * FROM sys_types_dep_vu_prepare_v2 +GO +~~START~~ +bit +1 +~~END~~ + + +SELECT * FROM sys_types_dep_vu_prepare_f2() +GO +~~START~~ +bit +1 +~~END~~ + diff --git a/test/JDBC/expected/typeproperty-dep-vu-cleanup.out b/test/JDBC/expected/typeproperty-dep-vu-cleanup.out new file mode 100644 index 0000000000..6e72b89c13 --- /dev/null +++ b/test/JDBC/expected/typeproperty-dep-vu-cleanup.out @@ -0,0 +1,14 @@ +DROP VIEW typeproperty_vu_prepare_dep_view +GO + +DROP PROC typeproperty_vu_prepare_dep_proc +GO + +DROP FUNCTION typeproperty_vu_prepare_dep_func +GO + +DROP TYPE typeproperty_test1_dep_vu.null_check1_dep_vu +GO + +DROP SCHEMA typeproperty_test1_dep_vu +GO diff --git a/test/JDBC/expected/typeproperty-dep-vu-prepare.out b/test/JDBC/expected/typeproperty-dep-vu-prepare.out new file mode 100644 index 0000000000..eb3123981c --- /dev/null +++ b/test/JDBC/expected/typeproperty-dep-vu-prepare.out @@ -0,0 +1,22 @@ +CREATE SCHEMA typeproperty_test1_dep_vu +GO + +CREATE TYPE typeproperty_test1_dep_vu.null_check1_dep_vu FROM varchar(11) NOT NULL ; +GO + +CREATE VIEW typeproperty_vu_prepare_dep_view AS +SELECT TYPEPROPERTY('typeproperty_test1_dep_vu.null_check1_dep_vu', 'scale') +GO + +CREATE PROC typeproperty_vu_prepare_dep_proc AS +SELECT TYPEPROPERTY('typeproperty_test1_dep_vu.null_check1_dep_vu', 'allowsnull') +GO + +CREATE FUNCTION typeproperty_vu_prepare_dep_func() +RETURNS INT +AS +BEGIN +RETURN TYPEPROPERTY('typeproperty_test1_dep_vu.null_check1_dep_vu', 'precision') +END +GO + diff --git a/test/JDBC/expected/typeproperty-dep-vu-verify.out b/test/JDBC/expected/typeproperty-dep-vu-verify.out new file mode 100644 index 0000000000..fff9c4b8f7 --- /dev/null +++ b/test/JDBC/expected/typeproperty-dep-vu-verify.out @@ -0,0 +1,23 @@ +SELECT * FROM typeproperty_vu_prepare_dep_view +GO +~~START~~ +int + +~~END~~ + + +EXEC typeproperty_vu_prepare_dep_proc +GO +~~START~~ +int + +~~END~~ + + +SELECT * FROM typeproperty_vu_prepare_dep_func() +GO +~~START~~ +int + +~~END~~ + diff --git a/test/JDBC/input/typeproperty-dep-vu-cleanup.sql b/test/JDBC/input/typeproperty-dep-vu-cleanup.sql new file mode 100644 index 0000000000..1c9532c8e4 --- /dev/null +++ b/test/JDBC/input/typeproperty-dep-vu-cleanup.sql @@ -0,0 +1,14 @@ +DROP VIEW typeproperty_vu_prepare_dep_view +GO + +DROP PROC typeproperty_vu_prepare_dep_proc +GO + +DROP FUNCTION typeproperty_vu_prepare_dep_func +GO + +DROP TYPE typeproperty_test1_dep_vu.null_check1_dep_vu +GO + +DROP SCHEMA typeproperty_test1_dep_vu +GO \ No newline at end of file diff --git a/test/JDBC/input/typeproperty-dep-vu-prepare.sql b/test/JDBC/input/typeproperty-dep-vu-prepare.sql new file mode 100644 index 0000000000..eb3123981c --- /dev/null +++ b/test/JDBC/input/typeproperty-dep-vu-prepare.sql @@ -0,0 +1,22 @@ +CREATE SCHEMA typeproperty_test1_dep_vu +GO + +CREATE TYPE typeproperty_test1_dep_vu.null_check1_dep_vu FROM varchar(11) NOT NULL ; +GO + +CREATE VIEW typeproperty_vu_prepare_dep_view AS +SELECT TYPEPROPERTY('typeproperty_test1_dep_vu.null_check1_dep_vu', 'scale') +GO + +CREATE PROC typeproperty_vu_prepare_dep_proc AS +SELECT TYPEPROPERTY('typeproperty_test1_dep_vu.null_check1_dep_vu', 'allowsnull') +GO + +CREATE FUNCTION typeproperty_vu_prepare_dep_func() +RETURNS INT +AS +BEGIN +RETURN TYPEPROPERTY('typeproperty_test1_dep_vu.null_check1_dep_vu', 'precision') +END +GO + diff --git a/test/JDBC/input/typeproperty-dep-vu-verify.sql b/test/JDBC/input/typeproperty-dep-vu-verify.sql new file mode 100644 index 0000000000..00c7444522 --- /dev/null +++ b/test/JDBC/input/typeproperty-dep-vu-verify.sql @@ -0,0 +1,8 @@ +SELECT * FROM typeproperty_vu_prepare_dep_view +GO + +EXEC typeproperty_vu_prepare_dep_proc +GO + +SELECT * FROM typeproperty_vu_prepare_dep_func() +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-table_types-before-dep-vu-cleanup.mix b/test/JDBC/input/views/sys-table_types-before-dep-vu-cleanup.mix new file mode 100644 index 0000000000..780e1287c8 --- /dev/null +++ b/test/JDBC/input/views/sys-table_types-before-dep-vu-cleanup.mix @@ -0,0 +1,6 @@ +drop procedure sys_table_types_dep_vu_prepare_p1 +drop function sys_table_types_dep_vu_prepare_f1 +drop view sys_table_types_dep_vu_prepare_v1 +drop procedure sys_table_types_dep_vu_prepare_p2 +drop type sys_table_types_dep_vu_prepare_tt +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-table_types-before-dep-vu-prepare.mix b/test/JDBC/input/views/sys-table_types-before-dep-vu-prepare.mix new file mode 100644 index 0000000000..168830df85 --- /dev/null +++ b/test/JDBC/input/views/sys-table_types-before-dep-vu-prepare.mix @@ -0,0 +1,23 @@ +-- tsql +create type sys_table_types_dep_vu_prepare_tt as table(sys_table_types_vu_prepare_tt_a int, sys_table_types_vu_prepare_tt_b char); +GO + +create procedure sys_table_types_dep_vu_prepare_p1 as + select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create function sys_table_types_dep_vu_prepare_f1() +returns int +as +begin + return (select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt') +end +GO + +create view sys_table_types_dep_vu_prepare_v1 as + select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create procedure sys_table_types_dep_vu_prepare_p2 as + select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-table_types-before-dep-vu-verify.mix b/test/JDBC/input/views/sys-table_types-before-dep-vu-verify.mix new file mode 100644 index 0000000000..57d35c2f76 --- /dev/null +++ b/test/JDBC/input/views/sys-table_types-before-dep-vu-verify.mix @@ -0,0 +1,12 @@ +--tsql +exec sys_table_types_dep_vu_prepare_p1 +GO + +select * from sys_table_types_dep_vu_prepare_f1() +GO + +select * from sys_table_types_dep_vu_prepare_v1 +GO + +exec sys_table_types_dep_vu_prepare_p2 +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-table_types-dep-vu-cleanup.mix b/test/JDBC/input/views/sys-table_types-dep-vu-cleanup.mix index a7dd837bd0..58633953ed 100644 --- a/test/JDBC/input/views/sys-table_types-dep-vu-cleanup.mix +++ b/test/JDBC/input/views/sys-table_types-dep-vu-cleanup.mix @@ -1,5 +1,8 @@ drop procedure sys_table_types_dep_vu_prepare_p1 drop function sys_table_types_dep_vu_prepare_f1 drop view sys_table_types_dep_vu_prepare_v1 +drop procedure sys_table_types_dep_vu_prepare_p2 +drop function sys_table_types_dep_vu_prepare_f2 +drop view sys_table_types_dep_vu_prepare_v2 drop type sys_table_types_dep_vu_prepare_tt GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-table_types-dep-vu-prepare.mix b/test/JDBC/input/views/sys-table_types-dep-vu-prepare.mix index 20bfa9efbd..52c793757b 100644 --- a/test/JDBC/input/views/sys-table_types-dep-vu-prepare.mix +++ b/test/JDBC/input/views/sys-table_types-dep-vu-prepare.mix @@ -17,3 +17,19 @@ GO create view sys_table_types_dep_vu_prepare_v1 as select count(*) from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' GO + +create procedure sys_table_types_dep_vu_prepare_p2 as + select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create view sys_table_types_dep_vu_prepare_v2 as + select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt' +GO + +create function sys_table_types_dep_vu_prepare_f2() +returns sys.bit +as +begin + return (select is_nullable from sys.table_types where name = 'sys_table_types_dep_vu_prepare_tt') +end +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-table_types-dep-vu-verify.mix b/test/JDBC/input/views/sys-table_types-dep-vu-verify.mix index 3eccab8cf9..9e0ec6b34f 100644 --- a/test/JDBC/input/views/sys-table_types-dep-vu-verify.mix +++ b/test/JDBC/input/views/sys-table_types-dep-vu-verify.mix @@ -7,3 +7,12 @@ GO select * from sys_table_types_dep_vu_prepare_v1 GO + +exec sys_table_types_dep_vu_prepare_p2 +GO + +select * from sys_table_types_dep_vu_prepare_v2 +GO + +select * from sys_table_types_dep_vu_prepare_f2() +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-types-before-dep-vu-cleanup.sql b/test/JDBC/input/views/sys-types-before-dep-vu-cleanup.sql new file mode 100644 index 0000000000..f5b7574a70 --- /dev/null +++ b/test/JDBC/input/views/sys-types-before-dep-vu-cleanup.sql @@ -0,0 +1,2 @@ +DROP DATABASE sys_types_dep_vu_prepare_db1 +GO diff --git a/test/JDBC/input/views/sys-types-before-dep-vu-prepare.sql b/test/JDBC/input/views/sys-types-before-dep-vu-prepare.sql new file mode 100644 index 0000000000..a5f6864ab0 --- /dev/null +++ b/test/JDBC/input/views/sys-types-before-dep-vu-prepare.sql @@ -0,0 +1,40 @@ +CREATE DATABASE sys_types_dep_vu_prepare_db1; +GO + +USE sys_types_dep_vu_prepare_db1 +GO + +CREATE TYPE sys_types_dep_vu_prepare_ty1 FROM int +GO + +CREATE PROCEDURE sys_types_dep_vu_prepare_p1 AS + SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE FUNCTION sys_types_dep_vu_prepare_f1() +RETURNS INT +AS +BEGIN + RETURN (SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1') +END +GO + +CREATE VIEW sys_types_dep_vu_prepare_v1 AS + SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE VIEW sys_types_dep_vu_prepare_v2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE PROCEDURE sys_types_dep_vu_prepare_p2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE FUNCTION sys_types_dep_vu_prepare_f2() +RETURNS sys.bit +AS +BEGIN + RETURN (SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1') +END +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-types-before-dep-vu-verify.sql b/test/JDBC/input/views/sys-types-before-dep-vu-verify.sql new file mode 100644 index 0000000000..11c04da161 --- /dev/null +++ b/test/JDBC/input/views/sys-types-before-dep-vu-verify.sql @@ -0,0 +1,20 @@ +USE sys_types_dep_vu_prepare_db1 +GO + +EXEC sys_types_dep_vu_prepare_p1 +GO + +SELECT * FROM sys_types_dep_vu_prepare_f1() +GO + +SELECT * FROM sys_types_dep_vu_prepare_v1 +GO + +EXEC sys_types_dep_vu_prepare_p2 +GO + +SELECT * FROM sys_types_dep_vu_prepare_v2 +GO + +SELECT * FROM sys_types_dep_vu_prepare_f2() +GO diff --git a/test/JDBC/input/views/sys-types-dep-vu-prepare.sql b/test/JDBC/input/views/sys-types-dep-vu-prepare.sql index b42877e088..a5f6864ab0 100644 --- a/test/JDBC/input/views/sys-types-dep-vu-prepare.sql +++ b/test/JDBC/input/views/sys-types-dep-vu-prepare.sql @@ -23,3 +23,18 @@ CREATE VIEW sys_types_dep_vu_prepare_v1 AS SELECT count(*) FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' GO +CREATE VIEW sys_types_dep_vu_prepare_v2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE PROCEDURE sys_types_dep_vu_prepare_p2 AS + SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1' +GO + +CREATE FUNCTION sys_types_dep_vu_prepare_f2() +RETURNS sys.bit +AS +BEGIN + RETURN (SELECT is_nullable FROM sys.types WHERE name = 'sys_types_dep_vu_prepare_ty1') +END +GO \ No newline at end of file diff --git a/test/JDBC/input/views/sys-types-dep-vu-verify.sql b/test/JDBC/input/views/sys-types-dep-vu-verify.sql index 4752ee5513..11c04da161 100644 --- a/test/JDBC/input/views/sys-types-dep-vu-verify.sql +++ b/test/JDBC/input/views/sys-types-dep-vu-verify.sql @@ -9,3 +9,12 @@ GO SELECT * FROM sys_types_dep_vu_prepare_v1 GO + +EXEC sys_types_dep_vu_prepare_p2 +GO + +SELECT * FROM sys_types_dep_vu_prepare_v2 +GO + +SELECT * FROM sys_types_dep_vu_prepare_f2() +GO diff --git a/test/JDBC/jdbc_schedule b/test/JDBC/jdbc_schedule index b8c10100d5..eceedc262c 100644 --- a/test/JDBC/jdbc_schedule +++ b/test/JDBC/jdbc_schedule @@ -36,6 +36,12 @@ ignore#!#BABEL-3655-vu-verify ignore#!#GRANT_SCHEMA-vu-prepare ignore#!#GRANT_SCHEMA-vu-verify ignore#!#GRANT_SCHEMA-vu-cleanup +ignore#!#sys-types-before-dep-vu-prepare +ignore#!#sys-types-before-dep-vu-verify +ignore#!#sys-types-before-dep-vu-cleanup +ignore#!#sys-table_types-before-dep-vu-prepare +ignore#!#sys-table_types-before-dep-vu-verify +ignore#!#sys-table_types-before-dep-vu-cleanup # These tests are meant for upgrade scenario prior to (potential) 14_5 release ignore#!#BABEL-3147-before-14_5-vu-prepare diff --git a/test/JDBC/upgrade/13_4/schedule b/test/JDBC/upgrade/13_4/schedule index 6db03b7ddd..eec5aa1788 100644 --- a/test/JDBC/upgrade/13_4/schedule +++ b/test/JDBC/upgrade/13_4/schedule @@ -171,7 +171,7 @@ sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/13_5/schedule b/test/JDBC/upgrade/13_5/schedule index 5b9ea6e87f..1398b4e434 100644 --- a/test/JDBC/upgrade/13_5/schedule +++ b/test/JDBC/upgrade/13_5/schedule @@ -213,12 +213,12 @@ sys-system_sql_modules sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/13_6/schedule b/test/JDBC/upgrade/13_6/schedule index 1ca5658967..dba828acf2 100644 --- a/test/JDBC/upgrade/13_6/schedule +++ b/test/JDBC/upgrade/13_6/schedule @@ -265,13 +265,13 @@ sys-system_sql_modules sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-triggers sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/13_7/schedule b/test/JDBC/upgrade/13_7/schedule index 8fa2d14a42..e6ca20c6a5 100644 --- a/test/JDBC/upgrade/13_7/schedule +++ b/test/JDBC/upgrade/13_7/schedule @@ -259,13 +259,13 @@ sys-system_sql_modules sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-triggers sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/13_8/schedule b/test/JDBC/upgrade/13_8/schedule index 8fa2d14a42..e6ca20c6a5 100644 --- a/test/JDBC/upgrade/13_8/schedule +++ b/test/JDBC/upgrade/13_8/schedule @@ -259,13 +259,13 @@ sys-system_sql_modules sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-triggers sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/13_9/schedule b/test/JDBC/upgrade/13_9/schedule index 20d2d43624..2de570f7cc 100644 --- a/test/JDBC/upgrade/13_9/schedule +++ b/test/JDBC/upgrade/13_9/schedule @@ -261,13 +261,13 @@ sys-system_sql_modules sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-triggers sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index d0a5e4a79a..4fc2769232 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -227,7 +227,7 @@ sys-schemas-dep sys-sp_tables_view-dep sys-sysforeignkeys-dep sys-tables-dep -sys-types-dep +sys-types-before-dep sys-views-dep sys-check_constraints-dep sys-computed_columns-dep @@ -237,7 +237,7 @@ sys-sp_databases-dep sys-syscolumns-dep sys-dm_exec_connections-dep sys-dm_exec_sessions-dep -sys-table_types-dep +sys-table_types-before-dep sys-all_sql_modules-dep sys-sql_modules-dep sys-system_sql_modules-dep diff --git a/test/JDBC/upgrade/14_3/schedule b/test/JDBC/upgrade/14_3/schedule index b31084b277..e39514b70f 100644 --- a/test/JDBC/upgrade/14_3/schedule +++ b/test/JDBC/upgrade/14_3/schedule @@ -277,12 +277,12 @@ sys-system_sql_modules-dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_nestlevel sys-triggers -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/14_5/schedule b/test/JDBC/upgrade/14_5/schedule index 955e6bac03..7e05c80a42 100644 --- a/test/JDBC/upgrade/14_5/schedule +++ b/test/JDBC/upgrade/14_5/schedule @@ -291,14 +291,14 @@ sys-system_sql_modules-dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal SYSTEM_USER sys-trigger_events sys-trigger_nestlevel sys-triggers sys-triggers-dep -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index d0e3037f70..0e6237189e 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -322,7 +322,7 @@ sys-system_sql_modules-dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -331,7 +331,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/14_7/schedule b/test/JDBC/upgrade/14_7/schedule index 2cb9c23a6c..6ce3f1fb7d 100644 --- a/test/JDBC/upgrade/14_7/schedule +++ b/test/JDBC/upgrade/14_7/schedule @@ -340,7 +340,7 @@ sys-system_sql_modules-dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -349,7 +349,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/14_8/schedule b/test/JDBC/upgrade/14_8/schedule index 9a9446fab3..b969e4b36f 100644 --- a/test/JDBC/upgrade/14_8/schedule +++ b/test/JDBC/upgrade/14_8/schedule @@ -338,7 +338,7 @@ sys-system_sql_modules-dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -347,7 +347,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/14_9/schedule b/test/JDBC/upgrade/14_9/schedule index 3d8247c0e6..daa8cd6b44 100644 --- a/test/JDBC/upgrade/14_9/schedule +++ b/test/JDBC/upgrade/14_9/schedule @@ -227,7 +227,7 @@ sys-schemas-dep sys-sp_tables_view-dep sys-sysforeignkeys-dep sys-tables-dep -sys-types-dep +sys-types-before-dep sys-views-dep sys-check_constraints-dep sys-computed_columns-dep @@ -237,7 +237,7 @@ sys-sp_databases-dep sys-syscolumns-dep sys-dm_exec_connections-dep sys-dm_exec_sessions-dep -sys-table_types-dep +sys-table_types-before-dep sys-all_sql_modules-dep sys-sql_modules-dep sys-system_sql_modules-dep diff --git a/test/JDBC/upgrade/15_1/schedule b/test/JDBC/upgrade/15_1/schedule index 3f4fdd9eb7..bd87f4add8 100644 --- a/test/JDBC/upgrade/15_1/schedule +++ b/test/JDBC/upgrade/15_1/schedule @@ -321,7 +321,7 @@ sys-system_sql_modules-dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -330,7 +330,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index 98ce22cd94..9917500078 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -346,7 +346,7 @@ sys-systypes sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -355,7 +355,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid-dep sys-views sys-views-dep diff --git a/test/JDBC/upgrade/15_3/schedule b/test/JDBC/upgrade/15_3/schedule index 9285bcc8e4..869e23678d 100644 --- a/test/JDBC/upgrade/15_3/schedule +++ b/test/JDBC/upgrade/15_3/schedule @@ -361,7 +361,7 @@ sys_sysusers_dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -370,7 +370,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid sys-views sys-views-dep diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index 4cbcf4cea1..b3226fa5b8 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -368,7 +368,7 @@ sys_sysusers_dep sys-tables sys-tables-dep sys-table_types -sys-table_types-dep +sys-table_types-before-dep sys-table_types_internal sys-table_types_internal-dep SYSTEM_USER @@ -377,7 +377,7 @@ sys-trigger_nestlevel sys-triggers sys-triggers-dep sys-types -sys-types-dep +sys-types-before-dep sys-userid sys-views sys-views-dep diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 6b45825559..ed7fa8f11a 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -472,6 +472,7 @@ Test_ISNULL BABEL-4270 BABEL-4410 BABEL-4231 +typeproperty-dep sys_asymmetric_keys sys_certificates sys_database_permissions diff --git a/test/python/SMO_script.ps1 b/test/python/SMO_script.ps1 index 753ab495a3..eeee21283c 100644 --- a/test/python/SMO_script.ps1 +++ b/test/python/SMO_script.ps1 @@ -29,6 +29,8 @@ if($script_flag -eq $var_one) $Objects += $db.Views $Objects += $db.StoredProcedures $Objects += $db.UserDefinedFunctions + $Objects += $db.UserDefinedDataTypes + $Objects += $db.UserDefinedTableTypes $Objects += $db.Tables.Indexes $Objects += $db.Tables.Triggers foreach ($CurrentObject in $Objects) @@ -52,6 +54,8 @@ else $Objects += $db.Views $Objects += $db.StoredProcedures $Objects += $db.UserDefinedFunctions + $Objects += $db.UserDefinedDataTypes + $Objects += $db.UserDefinedTableTypes $SubObjects += $db.Tables.Indexes $SubObjects += $db.Tables.Triggers $SubObjects += $db.Users diff --git a/test/python/expected/pyodbc/ddl_UDDT_UDTT.out b/test/python/expected/pyodbc/ddl_UDDT_UDTT.out new file mode 100644 index 0000000000..6898672349 --- /dev/null +++ b/test/python/expected/pyodbc/ddl_UDDT_UDTT.out @@ -0,0 +1,43 @@ +SET ANSI_NULLS ON +SET QUOTED_IDENTIFIER ON +CREATE TABLE [dbo].[t_udd]( + [a] [shc_test].[test3] NULL +) ON [PRIMARY] + +GO + +CREATE TYPE [dbo].[test1] FROM [varchar](11) NOT NULL +GO + +CREATE TYPE [dbo].[test2] FROM [int] NULL +GO + +CREATE TYPE [dbo].[test4] FROM [numeric](15, 4) NULL +GO + +CREATE TYPE [shc_test].[test3] FROM [int] NOT NULL +GO + +CREATE TYPE [dbo].[inventoryitem] AS TABLE( + [name] [nvarchar](50) NOT NULL, + [supplierid] [bigint] NOT NULL, + [price] [decimal](18, 4) NULL, + PRIMARY KEY NONCLUSTERED +( + [name] +)WITH (IGNORE_DUP_KEY = OFF) +) +GO + +CREATE TYPE [dbo].[locationtabletype] AS TABLE( + [locationname] [varchar](50) NULL, + [costrate] [int] NULL +) +GO + +CREATE TYPE [shc_test].[locationtabletype] AS TABLE( + [locationname] [varchar](50) NULL, + [costrate] [int] NULL +) +GO + diff --git a/test/python/expected/pyodbc/ddl_func_proc.out b/test/python/expected/pyodbc/ddl_func_proc.out index b1825a2efd..e22f01ebaa 100644 --- a/test/python/expected/pyodbc/ddl_func_proc.out +++ b/test/python/expected/pyodbc/ddl_func_proc.out @@ -197,6 +197,15 @@ BEGIN END; GO +CREATE TYPE [dbo].[@myrettable_routines_fc7] AS TABLE( + [a] [int] NOT NULL, + PRIMARY KEY NONCLUSTERED +( + [a] +)WITH (IGNORE_DUP_KEY = OFF) +) +GO + ALTER TABLE [dbo].[routines_customers] ADD CONSTRAINT [customers_pkroutines_customers248e85dd01b015e3396e8567c240879b] PRIMARY KEY NONCLUSTERED ( [customer_id] diff --git a/test/python/input/ddl_UDDT_UDTT.sql b/test/python/input/ddl_UDDT_UDTT.sql new file mode 100644 index 0000000000..0cbd21c13d --- /dev/null +++ b/test/python/input/ddl_UDDT_UDTT.sql @@ -0,0 +1,78 @@ +DROP TYPE IF EXISTS test1 +GO +DROP TYPE IF EXISTS test2 +GO +DROP TYPE IF EXISTS test4 +GO +DROP TYPE IF EXISTS LocationTableType +GO +DROP TYPE IF EXISTS InventoryItem +GO +DROP TYPE IF EXISTS shc_test.LocationTableType +GO +DROP TABLE IF EXISTS t_udd +GO +DROP TYPE IF EXISTS shc_test.test3 +GO +DROP SCHEMA IF EXISTS shc_test +GO + +CREATE TYPE test1 FROM varchar(11) NOT NULL ; +GO + +CREATE TYPE test2 FROM int NULL ; +GO + +CREATE SCHEMA shc_test +GO + +Create type shc_test.test3 FROM int NOT NULL ; +GO + +Create type test4 from numeric(15,4) +GO + +create table t_udd( a shc_test.test3); +go + +CREATE TYPE LocationTableType AS TABLE + ( LocationName VARCHAR(50) + , CostRate INT ); +GO + +CREATE TYPE InventoryItem AS TABLE +( + [Name] NVARCHAR(50) NOT NULL, + SupplierId BIGINT NOT NULL, + Price DECIMAL (18, 4) NULL, + PRIMARY KEY ( + Name + ) +) +GO + +CREATE TYPE shc_test.LocationTableType AS TABLE + ( LocationName VARCHAR(50) + , CostRate INT ); +GO + +--DROP +DROP TYPE IF EXISTS test1 +GO +DROP TYPE IF EXISTS test2 +GO +DROP TYPE IF EXISTS test4 +GO +DROP TYPE IF EXISTS LocationTableType +GO +DROP TYPE IF EXISTS InventoryItem +GO +DROP TYPE IF EXISTS shc_test.LocationTableType +GO +DROP TABLE IF EXISTS t_udd +GO +DROP TYPE IF EXISTS shc_test.test3 +GO +DROP SCHEMA IF EXISTS shc_test +GO +