From 2bb7f7052149f7e0cfcd946c2b8a5ff889cce1c4 Mon Sep 17 00:00:00 2001 From: tanyagupta17 <59756970+tanyagupta17@users.noreply.github.com> Date: Fri, 27 Sep 2024 19:32:17 +0530 Subject: [PATCH] Performance improvements when query includes sys.indexes.is_primary_key predicate (#2917) Previously for a query we were observing a performance degradation when it included a join between sys.indexes, sys.index_columns, sys.columns, sys.tables, and sys.schemas views with sys.indexes.is_primary_key = 1 predicate in where clause. We identified that there was the issue with a case statement due to which there was an incorrect row estimation so we have implemented a direct cast by defining new IMPLICIT cast without function from boolean to sys.bit. Another issue was the use of redundant has_schema_privilege in sys views and functions, as we explicitly grant usage to public beforehand, so we have removed the redundant has_schema_privilege check. Issues Resolved: BABEL-5215 Signed-off-by: Tanya Gupta --- contrib/babelfishpg_common/sql/bit.sql | 3 + .../babelfish_common_helper--4.3.0--4.4.0.sql | 18 + .../babelfishpg_tsql/sql/babelfishpg_tsql.sql | 5 +- contrib/babelfishpg_tsql/sql/sys_views.sql | 153 +- .../babelfishpg_tsql--4.3.0--4.4.0.sql | 1865 +++++++++++++++++ test/JDBC/expected/TestBIT.out | 11 +- .../single_db/sys-views-vu-verify.out | 299 +++ test/JDBC/expected/sys-views-vu-cleanup.out | 12 + test/JDBC/expected/sys-views-vu-prepare.out | 3 + test/JDBC/expected/sys-views-vu-verify.out | 227 ++ test/JDBC/input/datatypes/TestBIT.txt | 5 +- ...u-cleanup.sql => sys-views-vu-cleanup.mix} | 12 + ...u-prepare.sql => sys-views-vu-prepare.mix} | 5 +- ...-vu-verify.sql => sys-views-vu-verify.mix} | 55 + 14 files changed, 2562 insertions(+), 111 deletions(-) create mode 100644 test/JDBC/expected/single_db/sys-views-vu-verify.out rename test/JDBC/input/views/{sys-views-vu-cleanup.sql => sys-views-vu-cleanup.mix} (52%) rename test/JDBC/input/views/{sys-views-vu-prepare.sql => sys-views-vu-prepare.mix} (81%) rename test/JDBC/input/views/{sys-views-vu-verify.sql => sys-views-vu-verify.mix} (50%) diff --git a/contrib/babelfishpg_common/sql/bit.sql b/contrib/babelfishpg_common/sql/bit.sql index 3ae7daebe1..73ee44a25c 100644 --- a/contrib/babelfishpg_common/sql/bit.sql +++ b/contrib/babelfishpg_common/sql/bit.sql @@ -501,3 +501,6 @@ LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; CREATE CAST (sys.VARCHAR AS sys.BIT) WITH FUNCTION sys.varchar2bit(sys.VARCHAR) AS IMPLICIT; + +CREATE CAST (bool AS sys.BIT) +WITHOUT FUNCTION AS IMPLICIT; diff --git a/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--4.3.0--4.4.0.sql b/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--4.3.0--4.4.0.sql index 68dc5ec4f4..b4e43096b1 100644 --- a/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--4.3.0--4.4.0.sql +++ b/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--4.3.0--4.4.0.sql @@ -63,6 +63,24 @@ WITH FUNCTION sys.varchar2time(sys.VARCHAR, INT4) AS IMPLICIT; CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'varchar2time_deprecated_4_4_0'); +-- bool bit cast +DO $$ +DECLARE + sys_oid Oid; + pg_catalog_oid Oid; + bool_oid Oid; + bit_oid Oid; +BEGIN + sys_oid := (SELECT oid FROM pg_namespace WHERE pg_namespace.nspname ='sys'); + pg_catalog_oid := (SELECT oid FROM pg_namespace WHERE pg_namespace.nspname ='pg_catalog'); + bool_oid := (SELECT oid FROM pg_type WHERE pg_type.typname ='bool' AND pg_type.typnamespace = pg_catalog_oid); + bit_oid := (SELECT oid FROM pg_type WHERE pg_type.typname ='bit' AND pg_type.typnamespace = sys_oid); + IF (SELECT COUNT(*) FROM pg_cast WHERE pg_cast.castsource = bool_oid AND pg_cast.casttarget = bit_oid) = 0 THEN + CREATE CAST (bool AS sys.BIT) + WITHOUT FUNCTION AS IMPLICIT; + END IF; +END $$; + -- Drops the temporary procedure used by the upgrade script. -- Please have this be one of the last statements executed in this upgrade script. DROP PROCEDURE sys.babelfish_drop_deprecated_object(varchar, varchar, varchar); diff --git a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql index 93bef048cb..e289bcc509 100644 --- a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql +++ b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql @@ -908,7 +908,6 @@ CAST(NULL AS varchar(254)) AS remarks FROM pg_catalog.pg_class AS t1, sys.pg_namespace_ext AS t2, sys.schemas AS t3 WHERE t1.relnamespace = t3.schema_id AND t1.relnamespace = t2.oid AND t1.relkind IN ('r','p','v','m') AND t1.relispartition = false -AND has_schema_privilege(t1.relnamespace, 'USAGE') AND has_table_privilege(t1.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); GRANT SELECT ON sys.sp_tables_view TO PUBLIC; @@ -1499,8 +1498,7 @@ 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 ; +WHERE X.indislive ; GRANT SELECT ON sys.sp_special_columns_view TO PUBLIC; @@ -1858,7 +1856,6 @@ FROM pg_catalog.pg_proc p INNER JOIN sys.schemas s1 ON p.pronamespace = s1.schema_id INNER JOIN sys.databases d ON d.database_id = sys.db_id() -WHERE has_schema_privilege(s1.schema_id, 'USAGE') UNION diff --git a/contrib/babelfishpg_tsql/sql/sys_views.sql b/contrib/babelfishpg_tsql/sql/sys_views.sql index 5bf44d8d11..d0fbfbea28 100644 --- a/contrib/babelfishpg_tsql/sql/sys_views.sql +++ b/contrib/babelfishpg_tsql/sql/sys_views.sql @@ -72,7 +72,6 @@ left join tt_internal tt on t.oid = tt.typrelid where tt.typrelid is null and (t.relkind = 'r' or t.relkind = 'p') and t.relispartition = false -and has_schema_privilege(t.relnamespace, 'USAGE') and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); GRANT SELECT ON sys.tables TO PUBLIC; @@ -132,7 +131,6 @@ left join sys.shipped_objects_not_in_sys nis on (nis.name = t.relname and nis.sc left outer join sys.babelfish_view_def vd on t.relname::sys.sysname = vd.object_name and sch.name = vd.schema_name and vd.dbid = sys.db_id() where t.relkind = 'v' and nis.name is null -and has_schema_privilege(sch.schema_id, 'USAGE') and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); GRANT SELECT ON sys.views TO PUBLIC; @@ -427,8 +425,8 @@ select CAST(c.oid as int) as object_id , case when a.attnotnull then CAST(0 as sys.bit) else CAST(1 as sys.bit) end as is_nullable , CAST(0 as sys.bit) as is_ansi_padded , CAST(0 as sys.bit) as is_rowguidcol - , CAST(case when a.attidentity <> ''::"char" then 1 else 0 end AS sys.bit) as is_identity - , CAST(case when a.attgenerated <> ''::"char" then 1 else 0 end AS sys.bit) as is_computed + , CAST(a.attidentity <> ''::"char" AS sys.bit) as is_identity + , CAST(a.attgenerated <> ''::"char" AS sys.bit) as is_computed , CAST(0 as sys.bit) as is_filestream , CAST(0 as sys.bit) as is_replicated , CAST(0 as sys.bit) as is_non_sql_subscribed @@ -456,7 +454,6 @@ and (s.nspname = 'sys' or ext.nspname is not null) -- r = ordinary table, i = index, S = sequence, t = TOAST table, v = view, m = materialized view, c = composite type, f = foreign table, p = partitioned table and c.relkind in ('r', 'v', 'm', 'f', 'p') and c.relispartition = false -and has_schema_privilege(s.oid, 'USAGE') and has_column_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') and a.attnum > 0; GRANT SELECT ON sys.all_columns TO PUBLIC; @@ -540,10 +537,10 @@ BEGIN CAST(a.attcollation AS int), CAST(a.attnum AS smallint), CAST(case when a.attnotnull then 0 else 1 end AS sys.bit), - CAST(case when t.typname in ('bpchar', 'nchar', 'binary') then 1 else 0 end AS sys.bit), + CAST(t.typname in ('bpchar', 'nchar', 'binary') AS sys.bit), CAST(0 AS sys.bit), - CAST(case when a.attidentity <> ''::"char" then 1 else 0 end AS sys.bit), - CAST(case when a.attgenerated <> ''::"char" then 1 else 0 end AS sys.bit), + CAST(a.attidentity <> ''::"char" AS sys.bit), + CAST(a.attgenerated <> ''::"char" AS sys.bit), CAST(0 AS sys.bit), CAST(0 AS sys.bit), CAST(0 AS sys.bit), @@ -581,7 +578,6 @@ BEGIN -- r = ordinary table, i = index, S = sequence, t = TOAST table, v = view, m = materialized view, c = composite type, f = foreign table, p = partitioned table AND c.relkind IN ('r', 'v', 'm', 'f', 'p') AND c.relispartition = false - AND has_schema_privilege(sch.schema_id, 'USAGE') AND has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') union all -- system tables information @@ -618,10 +614,10 @@ BEGIN CAST(a.attcollation AS int), CAST(a.attnum AS smallint), CAST(case when a.attnotnull then 0 else 1 end AS sys.bit), - CAST(case when t.typname in ('bpchar', 'nchar', 'binary') then 1 else 0 end AS sys.bit), + CAST(t.typname in ('bpchar', 'nchar', 'binary') AS sys.bit), CAST(0 AS sys.bit), - CAST(case when a.attidentity <> ''::"char" then 1 else 0 end AS sys.bit), - CAST(case when a.attgenerated <> ''::"char" then 1 else 0 end AS sys.bit), + CAST(a.attidentity <> ''::"char" AS sys.bit), + CAST(a.attgenerated <> ''::"char" AS sys.bit), CAST(0 AS sys.bit), CAST(0 AS sys.bit), CAST(0 AS sys.bit), @@ -656,7 +652,6 @@ BEGIN WHERE NOT a.attisdropped AND a.attnum > 0 AND c.relkind = 'r' - AND has_schema_privilege(nsp.oid, 'USAGE') AND has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES'); END; $$ @@ -712,8 +707,7 @@ SELECT DISTINCT ,CAST((UNNEST(c.confkey)) AS INT) AS referenced_column_id FROM pg_constraint c WHERE c.contype = 'f' -AND (c.connamespace IN (SELECT schema_id FROM sys.schemas)) -AND has_schema_privilege(c.connamespace, 'USAGE'); +AND (c.connamespace IN (SELECT schema_id FROM sys.schemas)); GRANT SELECT ON sys.foreign_key_columns TO PUBLIC; CREATE OR replace view sys.foreign_keys AS @@ -774,8 +768,7 @@ SELECT , CAST(1 AS sys.BIT) AS is_system_named FROM pg_constraint c INNER JOIN sys.schemas sch ON sch.schema_id = c.connamespace -WHERE has_schema_privilege(sch.schema_id, 'USAGE') -AND c.contype = 'f'; +WHERE c.contype = 'f'; GRANT SELECT ON sys.foreign_keys TO PUBLIC; CREATE OR replace view sys.identity_columns AS @@ -844,10 +837,10 @@ select , cast(I.relname as sys.sysname) as name , cast(case when X.indisclustered then 1 else 2 end as sys.tinyint) as type , cast(case when X.indisclustered then 'CLUSTERED' else 'NONCLUSTERED' end as sys.nvarchar(60)) as type_desc - , cast(case when X.indisunique then 1 else 0 end as sys.bit) as is_unique + , cast(X.indisunique as sys.bit) as is_unique , cast(case when ps.scheme_id is null then 1 else ps.scheme_id end as int) as data_space_id , cast(0 as sys.bit) as ignore_dup_key - , cast(case when X.indisprimary then 1 else 0 end as sys.bit) as is_primary_key + , cast(X.indisprimary as sys.bit) as is_primary_key , cast(case when const.oid is null then 0 else 1 end as sys.bit) as is_unique_constraint , cast(0 as sys.tinyint) as fill_factor , cast(case when X.indpred is null then 0 else 1 end as sys.bit) as is_padded @@ -871,9 +864,9 @@ left join sys.babelfish_partition_depend pd on left join sys.babelfish_partition_scheme ps on (ps.partition_scheme_name = pd.partition_scheme_name and ps.dbid = sys.db_id()) -- check if index is a unique constraint left join pg_constraint const on const.conindid = I.oid and const.contype = 'u' -where has_schema_privilege(I.relnamespace, 'USAGE') +where -- index is active -and X.indislive +X.indislive -- filter to get all the objects that belong to sys or babelfish schemas and (nsp.nspname = 'sys' or ext.nspname is not null) @@ -910,7 +903,6 @@ where (t.relkind = 'r' or t.relkind = 'p') and t.relispartition = false -- filter to get all the objects that belong to sys or babelfish schemas and (nsp.nspname = 'sys' or ext.nspname is not null) -and has_schema_privilege(t.relnamespace, 'USAGE') and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') order by object_id, type_desc; GRANT SELECT ON sys.indexes TO PUBLIC; @@ -943,8 +935,8 @@ SELECT , CAST(1 as sys.BIT) as is_system_named FROM pg_constraint c INNER JOIN sys.schemas sch ON sch.schema_id = c.connamespace -WHERE has_schema_privilege(sch.schema_id, 'USAGE') -AND c.contype IN ('p', 'u'); +WHERE +c.contype IN ('p', 'u'); GRANT SELECT ON sys.key_constraints TO PUBLIC; create or replace view sys.procedures as @@ -985,8 +977,8 @@ from pg_proc p inner join sys.schemas sch on sch.schema_id = p.pronamespace left join sys.babelfish_function_ext f on p.proname = f.funcname and sch.schema_id::regnamespace::name = f.nspname and sys.babelfish_get_pltsql_function_signature(p.oid) = f.funcsignature collate "C" -where has_schema_privilege(sch.schema_id, 'USAGE') -and format_type(p.prorettype, null) <> 'trigger' +where +format_type(p.prorettype, null) <> 'trigger' and has_function_privilege(p.oid, 'EXECUTE'); GRANT SELECT ON sys.procedures TO PUBLIC; @@ -1002,8 +994,7 @@ from pg_constraint c inner join pg_attribute a_con on a_con.attrelid = c.conrelid and a_con.attnum = any(c.conkey) inner join pg_attribute a_conf on a_conf.attrelid = c.confrelid and a_conf.attnum = any(c.confkey) where c.contype = 'f' -and (c.connamespace in (select schema_id from sys.schemas)) -and has_schema_privilege(c.connamespace, 'USAGE'); +and (c.connamespace in (select schema_id from sys.schemas)); GRANT SELECT ON sys.sysforeignkeys TO PUBLIC; create or replace view sys.sysindexes as @@ -1164,7 +1155,7 @@ select cast(t.typname as sys.sysname) as name END as is_assembly_type , CAST(0 as int) as default_object_id , CAST(0 as int) as rule_object_id - , case when tt.typrelid is not null then CAST(1 as sys.bit) else CAST(0 as sys.bit) end as is_table_type + , CAST(tt.typrelid is not null AS sys.bit) as is_table_type from pg_type t join sys.schemas sch on t.typnamespace = sch.schema_id left join type_code_list ti on t.typname = ti.pg_type_name @@ -1216,9 +1207,9 @@ SELECT name , 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((coalesce(sys.translate_pg_type_to_tsql(system_type_id), sys.translate_pg_type_to_tsql(user_type_id)) + in ('nvarchar', 'varchar', 'sysname', 'varbinary')) + 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 @@ -1259,7 +1250,6 @@ from pg_catalog.pg_attrdef as d inner join pg_attribute a on a.attrelid = d.adrelid and d.adnum = a.attnum inner join sys.tables tab on d.adrelid = tab.object_id WHERE a.atthasdef = 't' and a.attgenerated = '' -AND has_schema_privilege(tab.schema_id, 'USAGE') AND has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES'); GRANT SELECT ON sys.default_constraints TO PUBLIC; @@ -1285,8 +1275,8 @@ SELECT CAST(c.conname as sys.sysname) as name , CAST(0 as sys.bit) as is_system_named FROM pg_catalog.pg_constraint as c INNER JOIN sys.schemas s on c.connamespace = s.schema_id -WHERE has_schema_privilege(s.schema_id, 'USAGE') -AND c.contype = 'c' and c.conrelid != 0; +WHERE +c.contype = 'c' and c.conrelid != 0; GRANT SELECT ON sys.check_constraints TO PUBLIC; create or replace view sys.all_objects as @@ -1331,7 +1321,6 @@ where t.relpersistence in ('p', 'u', 't') and t.relkind = 'r' and (s.nspname = 'sys' or (nis.name is not null and ext.nspname is not null)) and tt.typrelid is null -and has_schema_privilege(s.oid, 'USAGE') and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') union all @@ -1359,7 +1348,6 @@ and t.relispartition = false and s.nspname <> 'sys' and nis.name is null and ext.nspname is not null and tt.typrelid is null -and has_schema_privilege(s.oid, 'USAGE') and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') union all @@ -1382,7 +1370,6 @@ left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.db left join sys.shipped_objects_not_in_sys nis on nis.name = t.relname and nis.schemaid = s.oid and nis.type = 'V' where t.relkind = 'v' and (s.nspname = 'sys' or (nis.name is not null and ext.nspname is not null)) -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 views @@ -1405,7 +1392,6 @@ left join sys.shipped_objects_not_in_sys nis on nis.name = t.relname and nis.sch where t.relkind = 'v' and s.nspname <> 'sys' and nis.name is null and ext.nspname is not null -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 foreign key constraints @@ -1419,16 +1405,15 @@ select , 'FOREIGN_KEY_CONSTRAINT' , null::timestamp as create_date , null::timestamp as modify_date - , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 - else 0 end as sys.bit ) as is_ms_shipped + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit ) 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 left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) left join sys.shipped_objects_not_in_sys nis on nis.name = c.conname and nis.schemaid = s.oid and nis.type = 'F' -where has_schema_privilege(s.oid, 'USAGE') -and c.contype = 'f' +where +c.contype = 'f' and (s.nspname = 'sys' or ext.nspname is not null) union all -- details of user defined and system primary key constraints @@ -1442,16 +1427,15 @@ select , 'PRIMARY_KEY_CONSTRAINT' as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 - else 0 end as sys.bit ) as is_ms_shipped + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit) 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 left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) left join sys.shipped_objects_not_in_sys nis on nis.name = c.conname and nis.schemaid = s.oid and nis.type = 'PK' -where has_schema_privilege(s.oid, 'USAGE') -and c.contype = 'p' +where +c.contype = 'p' and (s.nspname = 'sys' or ext.nspname is not null) union all -- details of system defined procedures @@ -1526,7 +1510,6 @@ and nis.type = (case p.prokind end end) where (s.nspname = 'sys' or (nis.name is not null and ext.nspname is not null)) -and has_schema_privilege(s.oid, 'USAGE') and has_function_privilege(p.oid, 'EXECUTE') and p.proname != 'pltsql_call_handler' @@ -1604,7 +1587,6 @@ and nis.type = (case p.prokind end) where s.nspname <> 'sys' and nis.name is null and ext.nspname is not null -and has_schema_privilege(s.oid, 'USAGE') and has_function_privilege(p.oid, 'EXECUTE') union all @@ -1619,8 +1601,7 @@ select , 'DEFAULT_CONSTRAINT'::sys.nvarchar(60) AS type_desc , null::timestamp as create_date , null::timestamp as modify_date - , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 - else 0 end as sys.bit ) as is_ms_shipped + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit) as is_ms_shipped , 0 as is_published , 0 as is_schema_published from pg_catalog.pg_attrdef d @@ -1631,7 +1612,6 @@ left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.db left join sys.shipped_objects_not_in_sys nis on nis.name = ('DF_' || o.relname || '_' || d.oid) and nis.schemaid = s.oid and nis.type = 'D' where a.atthasdef = 't' and a.attgenerated = '' and (s.nspname = 'sys' or ext.nspname is not null) -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 @@ -1645,16 +1625,15 @@ select , 'CHECK_CONSTRAINT'::sys.nvarchar(60) as type_desc , null::sys.datetime as create_date , null::sys.datetime as modify_date - , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 - else 0 end as sys.bit ) as is_ms_shipped + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit) 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 left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) left join sys.shipped_objects_not_in_sys nis on nis.name = c.conname and nis.schemaid = s.oid and nis.type = 'C' -where has_schema_privilege(s.oid, 'USAGE') -and c.contype = 'c' and c.conrelid != 0 +where +c.contype = 'c' and c.conrelid != 0 and (s.nspname = 'sys' or ext.nspname is not null) union all -- details of user defined and system defined sequence objects @@ -1668,8 +1647,7 @@ select , 'SEQUENCE_OBJECT'::varchar(60) as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 - else 0 end as sys.bit ) as is_ms_shipped + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit ) as is_ms_shipped , 0 as is_published , 0 as is_schema_published from pg_class p @@ -1678,7 +1656,6 @@ left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.db left join sys.shipped_objects_not_in_sys nis on nis.name = p.relname and nis.schemaid = s.oid and nis.type = 'SO' where p.relkind = 'S' and (s.nspname = 'sys' or ext.nspname is not null) -and has_schema_privilege(s.oid, 'USAGE') union all -- details of user defined table types select @@ -1691,8 +1668,7 @@ select , 'TABLE_TYPE'::varchar(60) as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , CAST (case when (tt.schema_id::regnamespace::text = 'sys' or nis.name is not null) then 1 - else 0 end as sys.bit ) as is_ms_shipped + , CAST ((tt.schema_id::regnamespace::text = 'sys' or nis.name is not null) as sys.bit ) as is_ms_shipped , 0 as is_published , 0 as is_schema_published from sys.table_types tt @@ -1721,10 +1697,10 @@ SELECT , CAST('VIEW'as sys.nvarchar(60)) as type_desc , CAST(null as sys.datetime) as create_date , CAST(null as sys.datetime) as modify_date - , CAST(case when (c.relnamespace::regnamespace::text = 'sys') then 1 - when c.relname in (select name from sys.shipped_objects_not_in_sys nis - where nis.name = c.relname and nis.schemaid = c.relnamespace and nis.type = 'V') then 1 - else 0 end as sys.bit) AS is_ms_shipped + , CAST(((c.relnamespace::regnamespace::text = 'sys') or + c.relname in (select name from sys.shipped_objects_not_in_sys nis + where nis.name = c.relname and nis.schemaid = c.relnamespace and nis.type = 'V')) + 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(0 as sys.BIT) AS is_replicated @@ -1764,13 +1740,7 @@ SELECT CAST(f.create_date as sys.datetime) AS create_date, CAST(f.create_date as sys.datetime) AS modify_date, CAST(0 as sys.bit) AS is_ms_shipped, - CAST( - CASE WHEN tr.tgenabled = 'D' - THEN 1 - ELSE 0 - END - AS sys.bit - ) AS is_disabled, + CAST(tr.tgenabled = 'D' AS sys.bit) AS is_disabled, CAST(0 as sys.bit) AS is_not_for_replication, CAST(get_bit(CAST(CAST(tr.tgtype as int) as bit(7)),0) as sys.bit) AS is_instead_of_trigger FROM pg_proc p @@ -1778,8 +1748,8 @@ inner join sys.schemas sch on sch.schema_id = p.pronamespace left join pg_trigger tr on tr.tgfoid = p.oid left join sys.babelfish_function_ext f on p.proname = f.funcname and sch.schema_id::regnamespace::name = f.nspname and sys.babelfish_get_pltsql_function_signature(p.oid) = f.funcsignature collate "C" -where has_schema_privilege(sch.schema_id, 'USAGE') -and has_function_privilege(p.oid, 'EXECUTE') +where +has_function_privilege(p.oid, 'EXECUTE') and p.prokind = 'f' and format_type(p.prorettype, null) = 'trigger'; GRANT SELECT ON sys.triggers TO PUBLIC; @@ -1923,7 +1893,6 @@ select 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 @@ -2002,13 +1971,8 @@ SELECT , CAST(0 as sys.bit) AS is_schema_bound , CAST(0 as sys.bit) AS uses_database_collation , CAST(0 as sys.bit) AS is_recompiled - , CAST( - CASE WHEN ao.type IN ('P', 'FN', 'IN', 'TF', 'RF', 'IF') THEN - CASE WHEN p.proisstrict THEN 1 - ELSE 0 - END - ELSE 0 - END + , CAST(ao.type IN ('P', 'FN', 'IN', 'TF', 'RF', 'IF') + AND p.proisstrict AS sys.bit) as null_on_null_input , null::integer as execute_as_principal_id , CAST(0 as sys.bit) as uses_native_compilation @@ -2192,11 +2156,8 @@ SELECT CAST(CASE WHEN i.indoption[a.index_column_id-1] & 1 = 1 THEN 1 ELSE 0 - END AS SYS.BIT) AS is_descending_key, - CAST(CASE - WHEN a.index_column_id > i.indnkeyatts THEN 1 - ELSE 0 - END AS SYS.BIT) AS is_included_column + END AS SYS.BIT) AS is_descending_key, + CAST((a.index_column_id > i.indnkeyatts) AS SYS.BIT) AS is_included_column FROM pg_index i INNER JOIN index_id_map imap ON imap.indexrelid = i.indexrelid @@ -2205,7 +2166,6 @@ FROM LEFT JOIN sys.babelfish_namespace_ext ext ON (nsp.nspname = ext.nspname AND ext.dbid = sys.db_id()) LEFT JOIN unnest(i.indkey) WITH ORDINALITY AS a(attnum, index_column_id) ON true WHERE - has_schema_privilege(c.relnamespace, 'USAGE') AND has_table_privilege(c.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') AND (nsp.nspname = 'sys' OR ext.nspname is not null) AND i.indislive @@ -2230,7 +2190,6 @@ FROM INNER JOIN pg_partitioned_table ppt ON ppt.partrelid = tbl.oid LEFT JOIN unnest(ppt.partattrs) WITH ORDINALITY AS a(attnum, ordinal_position) ON true WHERE - has_schema_privilege(tbl.relnamespace, 'USAGE') AND has_table_privilege(tbl.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') AND i.indislive UNION ALL @@ -2252,7 +2211,6 @@ FROM LEFT JOIN unnest(ppt.partattrs) WITH ORDINALITY AS a(attnum, ordinal_position) ON true WHERE t.relkind = 'p' - AND has_schema_privilege(t.relnamespace, 'USAGE') AND has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); GRANT SELECT ON sys.index_columns TO PUBLIC; @@ -2292,8 +2250,7 @@ left join information_schema.parameters params left join pg_collation coll on coll.collname = params.collation_name /* assuming routine.specific_name is constructed by concatenating procedure name and oid */ left join pg_proc pgproc on routine.specific_name = nameconcatoid(pgproc.proname, pgproc.oid) -left join sys.schemas sch on sch.schema_id = pgproc.pronamespace -where has_schema_privilege(sch.schema_id, 'USAGE'); +left join sys.schemas sch on sch.schema_id = pgproc.pronamespace; END; $$ LANGUAGE plpgsql STABLE; @@ -2390,7 +2347,7 @@ create or replace view sys.dm_exec_sessions , null::bigint as "reads" , null::bigint as "writes" , null::bigint as logical_reads - , case when a.client_port > 0 then 1::sys.bit else 0::sys.bit end as is_user_process + , CAST(a.client_port > 0 as sys.bit) as is_user_process , d.textsize as text_size , d.language::sys.nvarchar(128) as language , 'ymd'::sys.nvarchar(3) as date_format-- Bld 173 lacks support for SET DATEFORMAT and always expects ymd @@ -3305,7 +3262,6 @@ FROM information_schema.triggers tr JOIN pg_catalog.pg_namespace np ON tr.event_object_schema = np.nspname COLLATE sys.database_default JOIN pg_class pc ON pc.relname = tr.event_object_table COLLATE sys.database_default AND pc.relnamespace = np.oid JOIN pg_trigger pt ON pt.tgrelid = pc.oid AND tr.trigger_name = pt.tgname COLLATE sys.database_default -AND has_schema_privilege(pc.relnamespace, 'USAGE') AND has_table_privilege(pc.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); GRANT SELECT ON sys.events TO PUBLIC; @@ -3360,7 +3316,6 @@ LEFT JOIN tt_internal tt on t.oid = tt.typrelid WHERE tt.typrelid is null AND t.relkind = 'r' AND t.relispartition = false -AND has_schema_privilege(t.relnamespace, 'USAGE') AND has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') UNION ALL @@ -3383,7 +3338,6 @@ INNER JOIN pg_class t on t.oid = idx.indrelid and t.relkind = 'r' and t.relispar INNER JOIN pg_namespace nsp on t.relnamespace = nsp.oid INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) where idx.indislive -and has_schema_privilege(t.relnamespace, 'USAGE') UNION ALL -- entries for partitions of partitioned tables @@ -3403,8 +3357,8 @@ FROM pg_inherits pgi INNER JOIN pg_class ctbl on (ctbl.oid = pgi.inhrelid and ctbl.relkind = 'r' and ctbl.relispartition) INNER JOIN pg_namespace nsp on ctbl.relnamespace = nsp.oid INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) -WHERE has_schema_privilege(ctbl.relnamespace, 'USAGE') -AND has_table_privilege(ctbl.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +WHERE +has_table_privilege(ctbl.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') UNION ALL -- entries for partitions of partitioned indexes @@ -3426,8 +3380,7 @@ INNER JOIN index_id_map pidx on pidx.indexrelid = pgi.inhparent INNER JOIN pg_class ctbl on (ctbl.oid = cidx.indrelid and ctbl.relkind = 'r' and ctbl.relispartition) INNER JOIN pg_namespace nsp on ctbl.relnamespace = nsp.oid INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) -WHERE cidx.indislive -AND has_schema_privilege(ctbl.relnamespace, 'USAGE'); +WHERE cidx.indislive; GRANT SELECT ON sys.partitions TO PUBLIC; CREATE OR REPLACE VIEW sys.servers diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql index 2b96ab75ba..91cdcf9423 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql @@ -1927,6 +1927,1871 @@ $$ LANGUAGE 'pltsql'; GRANT EXECUTE ON PROCEDURE sys.sp_tables TO PUBLIC; +create or replace view sys.tables as +with tt_internal as MATERIALIZED +( + select * from sys.table_types_internal +) +select + CAST(t.relname as sys._ci_sysname) as name + , CAST(t.oid as int) as object_id + , CAST(NULL as int) as principal_id + , CAST(t.relnamespace as int) as schema_id + , 0 as parent_object_id + , CAST('U' as sys.bpchar(2)) as type + , CAST('USER_TABLE' 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(t.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(t.reloptions) as option) + 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 + , case reltoastrelid when 0 then 0 else 1 end as lob_data_space_id + , CAST(NULL as int) as filestream_data_space_id + , CAST(relnatts as int) as max_column_id_used + , CAST(0 as sys.bit) as lock_on_bulk_load + , CAST(1 as sys.bit) as uses_ansi_nulls + , CAST(0 as sys.bit) as is_replicated + , CAST(0 as sys.bit) as has_replication_filter + , CAST(0 as sys.bit) as is_merge_published + , CAST(0 as sys.bit) as is_sync_tran_subscribed + , CAST(0 as sys.bit) as has_unchecked_assembly_data + , 0 as text_in_row_limit + , CAST(0 as sys.bit) as large_value_types_out_of_row + , CAST(0 as sys.bit) as is_tracked_by_cdc + , CAST(0 as sys.tinyint) as lock_escalation + , CAST('TABLE' as sys.nvarchar(60)) as lock_escalation_desc + , CAST(0 as sys.bit) as is_filetable + , CAST(0 as sys.tinyint) as durability + , CAST('SCHEMA_AND_DATA' as sys.nvarchar(60)) as durability_desc + , CAST(0 as sys.bit) is_memory_optimized + , case relpersistence when 't' then CAST(2 as sys.tinyint) else CAST(0 as sys.tinyint) end as temporal_type + , case relpersistence when 't' then CAST('SYSTEM_VERSIONED_TEMPORAL_TABLE' as sys.nvarchar(60)) else CAST('NON_TEMPORAL_TABLE' as sys.nvarchar(60)) end as temporal_type_desc + , CAST(null as integer) as history_table_id + , CAST(0 as sys.bit) as is_remote_data_archive_enabled + , CAST(0 as sys.bit) as is_external +from pg_class t +inner join sys.schemas sch on sch.schema_id = t.relnamespace +left join tt_internal tt on t.oid = tt.typrelid +where tt.typrelid is null +and (t.relkind = 'r' or t.relkind = 'p') +and t.relispartition = false +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); +GRANT SELECT ON sys.tables TO PUBLIC; + +create or replace view sys.views as +select + CAST(t.relname as sys.sysname) as name + , t.oid::int as object_id + , null::integer as principal_id + , sch.schema_id::int as schema_id + , 0 as parent_object_id + , 'V'::sys.bpchar(2) as type + , 'VIEW'::sys.nvarchar(60) as type_desc + , vd.create_date::sys.datetime as create_date + , vd.create_date::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(0 as sys.BIT) as with_check_option + , CAST(0 as sys.BIT) as is_date_correlation_view + , CAST(0 as sys.BIT) as is_tracked_by_cdc +from pg_class t inner join sys.schemas sch on (t.relnamespace = sch.schema_id) +left join sys.shipped_objects_not_in_sys nis on (nis.name = t.relname and nis.schemaid = sch.schema_id and nis.type = 'V') +left outer join sys.babelfish_view_def vd on t.relname::sys.sysname = vd.object_name and sch.name = vd.schema_name and vd.dbid = sys.db_id() +where t.relkind = 'v' +and nis.name is null +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); +GRANT SELECT ON sys.views TO PUBLIC; + +create or replace view sys.all_columns as +select CAST(c.oid as int) as object_id + , CAST(a.attname as sys.sysname) as name + , CAST(a.attnum as int) as column_id + , CAST(t.oid as int) as system_type_id + , CAST(t.oid as int) as user_type_id + , CAST(sys.tsql_type_max_length_helper(coalesce(tsql_type_name, tsql_base_type_name), a.attlen, a.atttypmod) as smallint) as max_length + , CAST(case + when a.atttypmod != -1 then + sys.tsql_type_precision_helper(coalesce(tsql_type_name, tsql_base_type_name), a.atttypmod) + else + sys.tsql_type_precision_helper(coalesce(tsql_type_name, tsql_base_type_name), t.typtypmod) + end as sys.tinyint) as precision + , CAST(case + when a.atttypmod != -1 THEN + sys.tsql_type_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), a.atttypmod, false) + else + sys.tsql_type_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), t.typtypmod, false) + end as sys.tinyint) as scale + , CAST(coll.collname as sys.sysname) as collation_name + , case when a.attnotnull then CAST(0 as sys.bit) else CAST(1 as sys.bit) end as is_nullable + , CAST(0 as sys.bit) as is_ansi_padded + , CAST(0 as sys.bit) as is_rowguidcol + , CAST(a.attidentity <> ''::"char" AS sys.bit) as is_identity + , CAST(a.attgenerated <> ''::"char" AS sys.bit) as is_computed + , CAST(0 as sys.bit) as is_filestream + , CAST(0 as sys.bit) as is_replicated + , CAST(0 as sys.bit) as is_non_sql_subscribed + , CAST(0 as sys.bit) as is_merge_published + , CAST(0 as sys.bit) as is_dts_replicated + , CAST(0 as sys.bit) as is_xml_document + , CAST(0 as int) as xml_collection_id + , CAST(coalesce(d.oid, 0) as int) as default_object_id + , CAST(coalesce((select oid from pg_constraint where conrelid = t.oid and contype = 'c' and a.attnum = any(conkey) limit 1), 0) as int) as rule_object_id + , CAST(0 as sys.bit) as is_sparse + , CAST(0 as sys.bit) as is_column_set + , CAST(0 as sys.tinyint) as generated_always_type + , CAST('NOT_APPLICABLE' as sys.nvarchar(60)) as generated_always_type_desc +from pg_attribute a +inner join pg_class c on c.oid = a.attrelid +inner join pg_type t on t.oid = a.atttypid +inner join pg_namespace s on s.oid = c.relnamespace +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join pg_attrdef d on c.oid = d.adrelid and a.attnum = d.adnum +left join pg_collation coll on coll.oid = a.attcollation +, sys.translate_pg_type_to_tsql(a.atttypid) AS tsql_type_name +, sys.translate_pg_type_to_tsql(t.typbasetype) AS tsql_base_type_name +where not a.attisdropped +and (s.nspname = 'sys' or ext.nspname is not null) +-- r = ordinary table, i = index, S = sequence, t = TOAST table, v = view, m = materialized view, c = composite type, f = foreign table, p = partitioned table +and c.relkind in ('r', 'v', 'm', 'f', 'p') +and c.relispartition = false +and has_column_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') +and a.attnum > 0; +GRANT SELECT ON sys.all_columns TO PUBLIC; + +CREATE OR REPLACE FUNCTION sys.columns_internal() +RETURNS TABLE ( + out_object_id int, + out_name sys.sysname, + out_column_id int, + out_system_type_id int, + out_user_type_id int, + out_max_length smallint, + out_precision sys.tinyint, + out_scale sys.tinyint, + out_collation_name sys.sysname, + out_collation_id int, + out_offset smallint, + out_is_nullable sys.bit, + out_is_ansi_padded sys.bit, + out_is_rowguidcol sys.bit, + out_is_identity sys.bit, + out_is_computed sys.bit, + out_is_filestream sys.bit, + out_is_replicated sys.bit, + out_is_non_sql_subscribed sys.bit, + out_is_merge_published sys.bit, + out_is_dts_replicated sys.bit, + out_is_xml_document sys.bit, + out_xml_collection_id int, + out_default_object_id int, + out_rule_object_id int, + out_is_sparse sys.bit, + out_is_column_set sys.bit, + out_generated_always_type sys.tinyint, + out_generated_always_type_desc sys.nvarchar(60), + out_encryption_type int, + out_encryption_type_desc sys.nvarchar(64), + out_encryption_algorithm_name sys.sysname, + out_column_encryption_key_id int, + out_column_encryption_key_database_name sys.sysname, + out_is_hidden sys.bit, + out_is_masked sys.bit, + out_graph_type int, + out_graph_type_desc sys.nvarchar(60) +) +AS +$$ +BEGIN + RETURN QUERY + SELECT CAST(c.oid AS int), + CAST(a.attname AS sys.sysname), + CAST(a.attnum AS int), + CASE + WHEN tsql_type_name IS NOT NULL OR t.typbasetype = 0 THEN + -- either tsql or PG base type + CAST(a.atttypid AS int) + ELSE + CAST(t.typbasetype AS int) + END, + CAST(a.atttypid AS int), + CASE + WHEN a.atttypmod != -1 THEN + sys.tsql_type_max_length_helper(coalesce(tsql_type_name, tsql_base_type_name), a.attlen, a.atttypmod) + ELSE + sys.tsql_type_max_length_helper(coalesce(tsql_type_name, tsql_base_type_name), a.attlen, t.typtypmod) + END, + CASE + WHEN a.atttypmod != -1 THEN + sys.tsql_type_precision_helper(coalesce(tsql_type_name, tsql_base_type_name), a.atttypmod) + ELSE + sys.tsql_type_precision_helper(coalesce(tsql_type_name, tsql_base_type_name), t.typtypmod) + END, + CASE + WHEN a.atttypmod != -1 THEN + sys.tsql_type_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), a.atttypmod, false) + ELSE + sys.tsql_type_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), t.typtypmod, false) + END, + CAST(coll.collname AS sys.sysname), + CAST(a.attcollation AS int), + CAST(a.attnum AS smallint), + CAST(case when a.attnotnull then 0 else 1 end AS sys.bit), + CAST(t.typname in ('bpchar', 'nchar', 'binary') AS sys.bit), + CAST(0 AS sys.bit), + CAST(a.attidentity <> ''::"char" AS sys.bit), + CAST(a.attgenerated <> ''::"char" AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS int), + CAST(coalesce(d.oid, 0) AS int), + CAST(coalesce((select oid from pg_constraint where conrelid = t.oid + and contype = 'c' and a.attnum = any(conkey) limit 1), 0) AS int), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.tinyint), + CAST('NOT_APPLICABLE' AS sys.nvarchar(60)), + CAST(null AS int), + CAST(null AS sys.nvarchar(64)), + CAST(null AS sys.sysname), + CAST(null AS int), + CAST(null AS sys.sysname), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(null AS int), + CAST(null AS sys.nvarchar(60)) + FROM pg_attribute a + INNER JOIN pg_class c ON c.oid = a.attrelid + INNER JOIN pg_type t ON t.oid = a.atttypid + INNER JOIN sys.schemas sch on c.relnamespace = sch.schema_id + INNER JOIN sys.pg_namespace_ext ext on sch.schema_id = ext.oid + LEFT JOIN pg_attrdef d ON c.oid = d.adrelid AND a.attnum = d.adnum + LEFT JOIN pg_collation coll ON coll.oid = a.attcollation + , sys.translate_pg_type_to_tsql(a.atttypid) AS tsql_type_name + , sys.translate_pg_type_to_tsql(t.typbasetype) AS tsql_base_type_name + WHERE NOT a.attisdropped + AND a.attnum > 0 + -- r = ordinary table, i = index, S = sequence, t = TOAST table, v = view, m = materialized view, c = composite type, f = foreign table, p = partitioned table + AND c.relkind IN ('r', 'v', 'm', 'f', 'p') + AND c.relispartition = false + AND has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') + union all + -- system tables information + SELECT CAST(c.oid AS int), + CAST(a.attname AS sys.sysname), + CAST(a.attnum AS int), + CASE + WHEN tsql_type_name IS NOT NULL OR t.typbasetype = 0 THEN + -- either tsql or PG base type + CAST(a.atttypid AS int) + ELSE + CAST(t.typbasetype AS int) + END, + CAST(a.atttypid AS int), + CASE + WHEN a.atttypmod != -1 THEN + sys.tsql_type_max_length_helper(coalesce(tsql_type_name, tsql_base_type_name), a.attlen, a.atttypmod) + ELSE + sys.tsql_type_max_length_helper(coalesce(tsql_type_name, tsql_base_type_name), a.attlen, t.typtypmod) + END, + CASE + WHEN a.atttypmod != -1 THEN + sys.tsql_type_precision_helper(coalesce(tsql_type_name, tsql_base_type_name), a.atttypmod) + ELSE + sys.tsql_type_precision_helper(coalesce(tsql_type_name, tsql_base_type_name), t.typtypmod) + END, + CASE + WHEN a.atttypmod != -1 THEN + sys.tsql_type_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), a.atttypmod, false) + ELSE + sys.tsql_type_scale_helper(coalesce(tsql_type_name, tsql_base_type_name), t.typtypmod, false) + END, + CAST(coll.collname AS sys.sysname), + CAST(a.attcollation AS int), + CAST(a.attnum AS smallint), + CAST(case when a.attnotnull then 0 else 1 end AS sys.bit), + CAST(t.typname in ('bpchar', 'nchar', 'binary') AS sys.bit), + CAST(0 AS sys.bit), + CAST(a.attidentity <> ''::"char" AS sys.bit), + CAST(a.attgenerated <> ''::"char" AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS int), + CAST(coalesce(d.oid, 0) AS int), + CAST(coalesce((select oid from pg_constraint where conrelid = t.oid + and contype = 'c' and a.attnum = any(conkey) limit 1), 0) AS int), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(0 AS sys.tinyint), + CAST('NOT_APPLICABLE' AS sys.nvarchar(60)), + CAST(null AS int), + CAST(null AS sys.nvarchar(64)), + CAST(null AS sys.sysname), + CAST(null AS int), + CAST(null AS sys.sysname), + CAST(0 AS sys.bit), + CAST(0 AS sys.bit), + CAST(null AS int), + CAST(null AS sys.nvarchar(60)) + FROM pg_attribute a + INNER JOIN pg_class c ON c.oid = a.attrelid + INNER JOIN pg_type t ON t.oid = a.atttypid + INNER JOIN pg_namespace nsp ON (nsp.oid = c.relnamespace and nsp.nspname = 'sys') + LEFT JOIN pg_attrdef d ON c.oid = d.adrelid AND a.attnum = d.adnum + LEFT JOIN pg_collation coll ON coll.oid = a.attcollation + , sys.translate_pg_type_to_tsql(a.atttypid) AS tsql_type_name + , sys.translate_pg_type_to_tsql(t.typbasetype) AS tsql_base_type_name + WHERE NOT a.attisdropped + AND a.attnum > 0 + AND c.relkind = 'r' + AND has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES'); +END; +$$ +language plpgsql STABLE; + +CREATE OR replace view sys.foreign_key_columns as +SELECT DISTINCT + CAST(c.oid AS INT) AS constraint_object_id + ,CAST((generate_series(1,ARRAY_LENGTH(c.conkey,1))) AS INT) AS constraint_column_id + ,CAST(c.conrelid AS INT) AS parent_object_id + ,CAST((UNNEST (c.conkey)) AS INT) AS parent_column_id + ,CAST(c.confrelid AS INT) AS referenced_object_id + ,CAST((UNNEST(c.confkey)) AS INT) AS referenced_column_id +FROM pg_constraint c +WHERE c.contype = 'f' +AND (c.connamespace IN (SELECT schema_id FROM sys.schemas)); +GRANT SELECT ON sys.foreign_key_columns TO PUBLIC; + +CREATE OR replace view sys.foreign_keys AS +SELECT + CAST(c.conname AS sys.SYSNAME) AS name +, CAST(c.oid AS INT) AS object_id +, CAST(NULL AS INT) AS principal_id +, CAST(sch.schema_id AS INT) AS schema_id +, CAST(c.conrelid AS INT) AS parent_object_id +, CAST('F' AS sys.bpchar(2)) AS type +, CAST('FOREIGN_KEY_CONSTRAINT' AS 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(c.confrelid AS INT) AS referenced_object_id +, CAST(c.conindid AS INT) AS key_index_id +, CAST(0 AS sys.BIT) AS is_disabled +, CAST(0 AS sys.BIT) AS is_not_for_replication +, CAST(0 AS sys.BIT) AS is_not_trusted +, CAST( + (CASE c.confdeltype + WHEN 'a' THEN 0 + WHEN 'r' THEN 0 + WHEN 'c' THEN 1 + WHEN 'n' THEN 2 + WHEN 'd' THEN 3 + END) + AS sys.TINYINT) AS delete_referential_action +, CAST( + (CASE c.confdeltype + WHEN 'a' THEN 'NO_ACTION' + WHEN 'r' THEN 'NO_ACTION' + WHEN 'c' THEN 'CASCADE' + WHEN 'n' THEN 'SET_NULL' + WHEN 'd' THEN 'SET_DEFAULT' + END) + AS sys.NVARCHAR(60)) AS delete_referential_action_desc +, CAST( + (CASE c.confupdtype + WHEN 'a' THEN 0 + WHEN 'r' THEN 0 + WHEN 'c' THEN 1 + WHEN 'n' THEN 2 + WHEN 'd' THEN 3 + END) + AS sys.TINYINT) AS update_referential_action +, CAST( + (CASE c.confupdtype + WHEN 'a' THEN 'NO_ACTION' + WHEN 'r' THEN 'NO_ACTION' + WHEN 'c' THEN 'CASCADE' + WHEN 'n' THEN 'SET_NULL' + WHEN 'd' THEN 'SET_DEFAULT' + END) + AS sys.NVARCHAR(60)) update_referential_action_desc +, CAST(1 AS sys.BIT) AS is_system_named +FROM pg_constraint c +INNER JOIN sys.schemas sch ON sch.schema_id = c.connamespace +WHERE c.contype = 'f'; +GRANT SELECT ON sys.foreign_keys TO PUBLIC; + +create or replace view sys.indexes as +-- Get all indexes from all system and user tables +with index_id_map as MATERIALIZED( + select + indexrelid, + case + when indisclustered then 1 + else 1+row_number() over(partition by indrelid order by indexrelid) + end as index_id + from pg_index +) +select + cast(X.indrelid as int) as object_id + , cast(I.relname as sys.sysname) as name + , cast(case when X.indisclustered then 1 else 2 end as sys.tinyint) as type + , cast(case when X.indisclustered then 'CLUSTERED' else 'NONCLUSTERED' end as sys.nvarchar(60)) as type_desc + , cast(X.indisunique as sys.bit) as is_unique + , cast(case when ps.scheme_id is null then 1 else ps.scheme_id end as int) as data_space_id + , cast(0 as sys.bit) as ignore_dup_key + , cast(X.indisprimary as sys.bit) as is_primary_key + , cast(case when const.oid is null then 0 else 1 end as sys.bit) as is_unique_constraint + , cast(0 as sys.tinyint) as fill_factor + , cast(case when X.indpred is null then 0 else 1 end as sys.bit) as is_padded + , cast(case when X.indisready then 0 else 1 end as sys.bit) as is_disabled + , cast(0 as sys.bit) as is_hypothetical + , cast(1 as sys.bit) as allow_row_locks + , cast(1 as sys.bit) as allow_page_locks + , cast(0 as sys.bit) as has_filter + , cast(null as sys.nvarchar) as filter_definition + , cast(0 as sys.bit) as auto_created + , cast(imap.index_id as int) as index_id +from pg_index X +inner join index_id_map imap on imap.indexrelid = X.indexrelid +inner join pg_class I on I.oid = X.indexrelid +inner join pg_class ptbl on ptbl.oid = X.indrelid and ptbl.relispartition = false +inner join pg_namespace nsp on nsp.oid = I.relnamespace +left join sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.babelfish_partition_depend pd on + (ext.orig_name = pd.schema_name COLLATE sys.database_default + and CAST(ptbl.relname AS sys.nvarchar(128)) = pd.table_name COLLATE sys.database_default and pd.dbid = sys.db_id() and ptbl.relkind = 'p') +left join sys.babelfish_partition_scheme ps on (ps.partition_scheme_name = pd.partition_scheme_name and ps.dbid = sys.db_id()) +-- check if index is a unique constraint +left join pg_constraint const on const.conindid = I.oid and const.contype = 'u' +where +-- index is active +X.indislive +-- filter to get all the objects that belong to sys or babelfish schemas +and (nsp.nspname = 'sys' or ext.nspname is not null) + +union all +-- Create HEAP entries for each system and user table +select + cast(t.oid as int) as object_id + , cast(null as sys.sysname) as name + , cast(0 as sys.tinyint) as type + , cast('HEAP' as sys.nvarchar(60)) as type_desc + , cast(0 as sys.bit) as is_unique + , cast(case when ps.scheme_id is null then 1 else ps.scheme_id end as int) as data_space_id + , cast(0 as sys.bit) as ignore_dup_key + , cast(0 as sys.bit) as is_primary_key + , cast(0 as sys.bit) as is_unique_constraint + , cast(0 as sys.tinyint) as fill_factor + , cast(0 as sys.bit) as is_padded + , cast(0 as sys.bit) as is_disabled + , cast(0 as sys.bit) as is_hypothetical + , cast(1 as sys.bit) as allow_row_locks + , cast(1 as sys.bit) as allow_page_locks + , cast(0 as sys.bit) as has_filter + , cast(null as sys.nvarchar) as filter_definition + , cast(0 as sys.bit) as auto_created + , cast(0 as int) as index_id +from pg_class t +inner join pg_namespace nsp on nsp.oid = t.relnamespace +left join sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.babelfish_partition_depend pd on + (ext.orig_name = pd.schema_name COLLATE sys.database_default + and CAST(t.relname AS sys.nvarchar(128)) = pd.table_name COLLATE sys.database_default and pd.dbid = sys.db_id()) +left join sys.babelfish_partition_scheme ps on (ps.partition_scheme_name = pd.partition_scheme_name and ps.dbid = sys.db_id()) +where (t.relkind = 'r' or t.relkind = 'p') +and t.relispartition = false +-- filter to get all the objects that belong to sys or babelfish schemas +and (nsp.nspname = 'sys' or ext.nspname is not null) +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +order by object_id, type_desc; +GRANT SELECT ON sys.indexes TO PUBLIC; + +CREATE OR replace view sys.key_constraints AS +SELECT + CAST(c.conname AS SYSNAME) AS name + , CAST(c.oid AS INT) AS object_id + , CAST(0 AS INT) AS principal_id + , CAST(sch.schema_id AS INT) AS schema_id + , CAST(c.conrelid AS INT) AS parent_object_id + , CAST( + (CASE contype + WHEN 'p' THEN CAST('PK' as sys.bpchar(2)) + WHEN 'u' THEN CAST('UQ' as sys.bpchar(2)) + END) + AS sys.bpchar(2)) AS type + , CAST( + (CASE contype + WHEN 'p' THEN 'PRIMARY_KEY_CONSTRAINT' + WHEN 'u' THEN 'UNIQUE_CONSTRAINT' + END) + AS NVARCHAR(60)) AS type_desc + , CAST(NULL AS DATETIME) AS create_date + , CAST(NULL AS DATETIME) AS modify_date + , CAST(c.conindid AS INT) AS unique_index_id + , 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(1 as sys.BIT) as is_system_named +FROM pg_constraint c +INNER JOIN sys.schemas sch ON sch.schema_id = c.connamespace +WHERE +c.contype IN ('p', 'u'); +GRANT SELECT ON sys.key_constraints TO PUBLIC; + +create or replace view sys.procedures as +select + cast(p.proname as sys.sysname) as name + , cast(p.oid as int) as object_id + , cast(null as int) as principal_id + , cast(sch.schema_id as int) as schema_id + , cast (0 as int) as parent_object_id + , cast(case p.prokind + when 'p' then 'P' + when 'a' then 'AF' + else + case format_type(p.prorettype, null) when 'trigger' + then 'TR' + else 'FN' + end + end as sys.bpchar(2)) COLLATE sys.database_default as type + , cast(case p.prokind + when 'p' then 'SQL_STORED_PROCEDURE' + when 'a' then 'AGGREGATE_FUNCTION' + else + case format_type(p.prorettype, null) when 'trigger' + then 'SQL_TRIGGER' + else 'SQL_SCALAR_FUNCTION' + end + end as sys.nvarchar(60)) as type_desc + , cast(f.create_date as sys.datetime) as create_date + , cast(f.create_date 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(0 as sys.bit) as is_auto_executed + , cast(0 as sys.bit) as is_execution_replicated + , cast(0 as sys.bit) as is_repl_serializable_only + , cast(0 as sys.bit) as skips_repl_constraints +from pg_proc p +inner join sys.schemas sch on sch.schema_id = p.pronamespace +left join sys.babelfish_function_ext f on p.proname = f.funcname and sch.schema_id::regnamespace::name = f.nspname +and sys.babelfish_get_pltsql_function_signature(p.oid) = f.funcsignature collate "C" +where +format_type(p.prorettype, null) <> 'trigger' +and has_function_privilege(p.oid, 'EXECUTE'); +GRANT SELECT ON sys.procedures TO PUBLIC; + +create or replace view sys.sysforeignkeys as +select + CAST(c.oid as int) as constid + , CAST(c.conrelid as int) as fkeyid + , CAST(c.confrelid as int) as rkeyid + , a_con.attnum as fkey + , a_conf.attnum as rkey + , a_conf.attnum as keyno +from pg_constraint c +inner join pg_attribute a_con on a_con.attrelid = c.conrelid and a_con.attnum = any(c.conkey) +inner join pg_attribute a_conf on a_conf.attrelid = c.confrelid and a_conf.attnum = any(c.confkey) +where c.contype = 'f' +and (c.connamespace in (select schema_id from sys.schemas)); +GRANT SELECT ON sys.sysforeignkeys TO PUBLIC; + +create or replace view sys.types As +with RECURSIVE type_code_list as +( + select distinct pg_typname as pg_type_name, tsql_typname as tsql_type_name + from sys.babelfish_typecode_list() +), +tt_internal as MATERIALIZED +( + select * from sys.table_types_internal +) +-- For System types +select + CAST(ti.tsql_type_name as sys.sysname) as name + , cast(t.oid as int) as system_type_id + , cast(t.oid as int) as user_type_id + , cast(s.oid as int) as schema_id + , cast(NULL as INT) as principal_id + , sys.tsql_type_max_length_helper(ti.tsql_type_name, t.typlen, t.typtypmod, true) as max_length + , sys.tsql_type_precision_helper(ti.tsql_type_name, t.typtypmod) as precision + , sys.tsql_type_scale_helper(ti.tsql_type_name, t.typtypmod, false) as scale + , CASE + WHEN t.typcollation = 0 THEN CAST(NULL as sys.sysname) + ELSE CAST((SELECT default_collation FROM babelfish_sysdatabases WHERE name = db_name() COLLATE "C") as sys.sysname) + END as collation_name + , case when typnotnull then cast(0 as sys.bit) else cast(1 as sys.bit) end as is_nullable + , CAST(0 as sys.bit) as is_user_defined + , CASE ti.tsql_type_name + -- CLR UDT have is_assembly_type = 1 + WHEN 'geometry' THEN CAST(1 as sys.bit) + WHEN 'geography' THEN CAST(1 as sys.bit) + ELSE CAST(0 as sys.bit) + END as is_assembly_type + , CAST(0 as int) as default_object_id + , CAST(0 as int) as rule_object_id + , CAST(0 as sys.bit) as is_table_type +from pg_type t +inner join pg_namespace s on s.oid = t.typnamespace +inner join type_code_list ti on t.typname = ti.pg_type_name +left join pg_collation c on c.oid = t.typcollation +where +ti.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 sys.sysname) as name + , cast(t.typbasetype as int) as system_type_id + , cast(t.oid as int) as user_type_id + , cast(t.typnamespace as int) 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::sys.tinyint else sys.tsql_type_precision_helper(tsql_base_type_name, t.typtypmod) end as precision + , case when tt.typrelid is not null then 0::sys.tinyint else sys.tsql_type_scale_helper(tsql_base_type_name, t.typtypmod, false) end as scale + , CASE + WHEN t.typcollation = 0 THEN CAST(NULL as sys.sysname) + ELSE CAST((SELECT default_collation FROM babelfish_sysdatabases WHERE name = db_name() COLLATE "C") as sys.sysname) + 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 + , CAST(1 as sys.bit) as is_user_defined + , CASE tsql_base_type_name + -- CLR UDT have is_assembly_type = 1 + WHEN 'geometry' THEN CAST(1 as sys.bit) + WHEN 'geography' THEN CAST(1 as sys.bit) + ELSE CAST(0 as sys.bit) + END as is_assembly_type + , CAST(0 as int) as default_object_id + , CAST(0 as int) as rule_object_id + , CAST(tt.typrelid is not null AS sys.bit) as is_table_type +from pg_type t +join sys.schemas sch on t.typnamespace = sch.schema_id +left join type_code_list ti on t.typname = ti.pg_type_name +left join pg_collation c on c.oid = t.typcollation +left join tt_internal tt on t.typrelid = tt.typrelid +, sys.translate_pg_type_to_tsql(t.typbasetype) AS tsql_base_type_name +-- we want to show details of user defined datatypes created under babelfish database +where + ti.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; + +CREATE OR REPLACE VIEW sys.systypes AS +SELECT 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((coalesce(sys.translate_pg_type_to_tsql(system_type_id), sys.translate_pg_type_to_tsql(user_type_id)) + in ('nvarchar', 'varchar', 'sysname', 'varbinary')) + 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::sys.tinyint then precision::smallint + 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 + , collation_name as collation +FROM sys.types; +GRANT SELECT ON sys.systypes TO PUBLIC; + +create or replace view sys.default_constraints +AS +select CAST(('DF_' || tab.name || '_' || d.oid) as sys.sysname) as name + , CAST(d.oid as int) as object_id + , CAST(null as int) as principal_id + , CAST(tab.schema_id as int) as schema_id + , CAST(d.adrelid as int) as parent_object_id + , CAST('D' as sys.bpchar(2)) as type + , CAST('DEFAULT_CONSTRAINT' as sys.nvarchar(60)) AS type_desc + , CAST(null as sys.datetime) as create_date + , CAST(null as sys.datetime) as modified_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(d.adnum as int) as parent_column_id + , CAST(tsql_get_expr(d.adbin, d.adrelid) as sys.nvarchar) as definition + , CAST(1 as sys.bit) as is_system_named +from pg_catalog.pg_attrdef as d +inner join pg_attribute a on a.attrelid = d.adrelid and d.adnum = a.attnum +inner join sys.tables tab on d.adrelid = tab.object_id +WHERE a.atthasdef = 't' and a.attgenerated = '' +AND has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES'); +GRANT SELECT ON sys.default_constraints TO PUBLIC; + +CREATE or replace VIEW sys.check_constraints AS +SELECT CAST(c.conname as sys.sysname) as name + , CAST(oid as integer) as object_id + , CAST(NULL as integer) as principal_id + , CAST(c.connamespace as integer) as schema_id + , CAST(conrelid as integer) as parent_object_id + , CAST('C' as sys.bpchar(2)) as type + , CAST('CHECK_CONSTRAINT' 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(0 as sys.bit) as is_disabled + , CAST(0 as sys.bit) as is_not_for_replication + , CAST(0 as sys.bit) as is_not_trusted + , CAST(c.conkey[1] as integer) AS parent_column_id + , CAST(tsql_get_constraintdef(c.oid) as sys.nvarchar) AS definition + , CAST(1 as sys.bit) as uses_database_collation + , CAST(0 as sys.bit) as is_system_named +FROM pg_catalog.pg_constraint as c +INNER JOIN sys.schemas s on c.connamespace = s.schema_id +WHERE +c.contype = 'c' and c.conrelid != 0; +GRANT SELECT ON sys.check_constraints TO PUBLIC; + +create or replace view sys.all_objects as +select + name 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) + , type collate sys.database_default + , cast (type_desc as sys.nvarchar(60)) + , cast (create_date as sys.datetime) + , cast (modify_date as sys.datetime) + , is_ms_shipped + , cast (is_published as sys.bit) + , cast (is_schema_published as sys.bit) +from +( +-- Currently for pg_class, pg_proc UNIONs, we separated user defined objects and system objects because the +-- optimiser will be able to make a better estimation of number of rows(in case the query contains a filter on +-- is_ms_shipped column) and in turn chooses a better query plan. + +-- details of system tables +select + t.relname::sys.sysname as name + , t.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'U'::char(2) as type + , 'USER_TABLE' as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 1::sys.bit 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 +left join sys.table_types_internal tt on t.oid = tt.typrelid +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = t.relname and nis.schemaid = s.oid and nis.type = 'U' +where t.relpersistence in ('p', 'u', 't') +and t.relkind = 'r' +and (s.nspname = 'sys' or (nis.name is not null and ext.nspname is not null)) +and tt.typrelid is null +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') + +union all +-- details of user defined tables +select + t.relname::sys.sysname as name + , t.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'U'::char(2) as type + , 'USER_TABLE' as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0::sys.bit 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 +left join sys.table_types_internal tt on t.oid = tt.typrelid +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = t.relname and nis.schemaid = s.oid and nis.type = 'U' +where t.relpersistence in ('p', 'u', 't') +and (t.relkind = 'r' or t.relkind = 'p') +and t.relispartition = false +and s.nspname <> 'sys' and nis.name is null +and ext.nspname is not null +and tt.typrelid is null +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') + +union all +-- details of system views +select + t.relname::sys.sysname as name + , t.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'V'::char(2) as type + , 'VIEW'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 1::sys.bit 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = t.relname and nis.schemaid = s.oid and nis.type = 'V' +where t.relkind = 'v' +and (s.nspname = 'sys' or (nis.name is not null and ext.nspname is not null)) +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +union all +-- Details of user defined views +select + t.relname::sys.sysname as name + , t.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'V'::char(2) as type + , 'VIEW'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , 0::sys.bit 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = t.relname and nis.schemaid = s.oid and nis.type = 'V' +where t.relkind = 'v' +and s.nspname <> 'sys' and nis.name is null +and ext.nspname is not null +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +union all +-- details of user defined and system foreign key constraints +select + c.conname::sys.sysname as name + , c.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , c.conrelid as parent_object_id + , 'F'::char(2) as type + , 'FOREIGN_KEY_CONSTRAINT' + , null::timestamp as create_date + , null::timestamp as modify_date + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit ) 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = c.conname and nis.schemaid = s.oid and nis.type = 'F' +where +c.contype = 'f' +and (s.nspname = 'sys' or ext.nspname is not null) +union all +-- details of user defined and system primary key constraints +select + c.conname::sys.sysname as name + , c.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , c.conrelid as parent_object_id + , 'PK'::char(2) as type + , 'PRIMARY_KEY_CONSTRAINT' as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit) 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = c.conname and nis.schemaid = s.oid and nis.type = 'PK' +where +c.contype = 'p' +and (s.nspname = 'sys' or ext.nspname is not null) +union all +-- details of system defined procedures +select + p.proname::sys.sysname as name + , case + when t.typname = 'trigger' then tr.oid else p.oid + end 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'::char(2) + when 'a' then 'AF'::char(2) + else + case + when t.typname = 'trigger' + then 'TR'::char(2) + when p.proretset then + case + when t.typtype = 'c' + then 'TF'::char(2) + else 'IF'::char(2) + end + else 'FN'::char(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 t.typname = '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 + , 1::sys.bit 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = p.proname and nis.schemaid = s.oid +and nis.type = (case p.prokind + when 'p' then 'P'::char(2) + when 'a' then 'AF'::char(2) + else + case + when t.typname = 'trigger' + then 'TR'::char(2) + when p.proretset then + case + when t.typtype = 'c' + then 'TF'::char(2) + else 'IF'::char(2) + end + else 'FN'::char(2) + end + end) +where (s.nspname = 'sys' or (nis.name is not null and ext.nspname is not null)) +and has_function_privilege(p.oid, 'EXECUTE') +and p.proname != 'pltsql_call_handler' + +union all +-- details of user defined procedures +select + p.proname::sys.sysname as name + , case + when t.typname = 'trigger' then tr.oid else p.oid + end 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'::char(2) + when 'a' then 'AF'::char(2) + else + case + when t.typname = 'trigger' + then 'TR'::char(2) + when p.proretset then + case + when t.typtype = 'c' + then 'TF'::char(2) + else 'IF'::char(2) + end + else 'FN'::char(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 t.typname = '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::sys.bit 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = p.proname and nis.schemaid = s.oid +and nis.type = (case p.prokind + when 'p' then 'P'::char(2) + when 'a' then 'AF'::char(2) + else + case + when t.typname = 'trigger' + then 'TR'::char(2) + when p.proretset then + case + when t.typtype = 'c' + then 'TF'::char(2) + else 'IF'::char(2) + end + else 'FN'::char(2) + end + end) +where s.nspname <> 'sys' and nis.name is null +and ext.nspname is not null +and has_function_privilege(p.oid, 'EXECUTE') + +union all +-- details of all default constraints +select + ('DF_' || o.relname || '_' || d.oid)::sys.sysname 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 + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit) 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = ('DF_' || o.relname || '_' || d.oid) and nis.schemaid = s.oid and nis.type = 'D' +where a.atthasdef = 't' and a.attgenerated = '' +and (s.nspname = 'sys' or ext.nspname is not null) +and has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') +union all +-- details of all check constraints +select + c.conname::sys.sysname + , c.oid::integer as object_id + , NULL::integer as principal_id + , s.oid 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 + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit) 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = c.conname and nis.schemaid = s.oid and nis.type = 'C' +where +c.contype = 'c' and c.conrelid != 0 +and (s.nspname = 'sys' or ext.nspname is not null) +union all +-- details of user defined and system defined sequence objects +select + p.relname::sys.sysname as name + , p.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , 0 as parent_object_id + , 'SO'::char(2) as type + , 'SEQUENCE_OBJECT'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , CAST ((s.nspname = 'sys' or nis.name is not null) as sys.bit ) 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 +left join sys.babelfish_namespace_ext ext on (s.nspname = ext.nspname and ext.dbid = sys.db_id()) +left join sys.shipped_objects_not_in_sys nis on nis.name = p.relname and nis.schemaid = s.oid and nis.type = 'SO' +where p.relkind = 'S' +and (s.nspname = 'sys' or ext.nspname is not null) +union all +-- details of user defined table types +select + ('TT_' || tt.name || '_' || tt.type_table_object_id)::sys.sysname 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'::char(2) as type + , 'TABLE_TYPE'::varchar(60) as type_desc + , null::timestamp as create_date + , null::timestamp as modify_date + , CAST ((tt.schema_id::regnamespace::text = 'sys' or nis.name is not null) as sys.bit ) as is_ms_shipped + , 0 as is_published + , 0 as is_schema_published +from sys.table_types tt +left join sys.shipped_objects_not_in_sys nis on nis.name = ('TT_' || tt.name || '_' || tt.type_table_object_id)::name and nis.schemaid = tt.schema_id and nis.type = 'TT' +) ot; +GRANT SELECT ON sys.all_objects TO PUBLIC; + +create or replace view sys.all_views as +SELECT + CAST(c.relname AS sys.SYSNAME) as name + , CAST(c.oid AS INT) as object_id + , CAST(null AS INT) as principal_id + , CAST(c.relnamespace as INT) as schema_id + , CAST(0 as INT) as parent_object_id + , CAST('V' as sys.bpchar(2)) as type + , CAST('VIEW'as sys.nvarchar(60)) as type_desc + , CAST(null as sys.datetime) as create_date + , CAST(null as sys.datetime) as modify_date + , CAST(((c.relnamespace::regnamespace::text = 'sys') or + c.relname in (select name from sys.shipped_objects_not_in_sys nis + where nis.name = c.relname and nis.schemaid = c.relnamespace and nis.type = 'V')) + 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(0 as sys.BIT) AS is_replicated + , CAST(0 as sys.BIT) AS has_replication_filter + , CAST(0 as sys.BIT) AS has_opaque_metadata + , CAST(0 as sys.BIT) AS has_unchecked_assembly_data + , CAST( + CASE + WHEN (v.check_option = 'NONE') + THEN 0 + ELSE 1 + END + AS sys.BIT) AS with_check_option + , CAST(0 as sys.BIT) AS is_date_correlation_view +FROM pg_catalog.pg_namespace AS ns +INNER JOIN pg_class c ON ns.oid = c.relnamespace +INNER JOIN information_schema.views v ON c.relname = v.table_name AND ns.nspname = v.table_schema +WHERE c.relkind = 'v' AND ns.nspname in + (SELECT nspname from sys.babelfish_namespace_ext where dbid = sys.db_id() UNION ALL SELECT CAST('sys' AS NAME)) +AND pg_is_other_temp_schema(ns.oid) = false +AND (pg_has_role(c.relowner, 'USAGE') = true +OR has_table_privilege(c.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER') = true +OR has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES') = true); +GRANT SELECT ON sys.all_views TO PUBLIC; + +CREATE OR REPLACE VIEW sys.triggers +AS +SELECT + CAST(p.proname as sys.sysname) as name, + CAST(tr.oid as int) as object_id, + CAST(1 as sys.tinyint) as parent_class, + CAST('OBJECT_OR_COLUMN' as sys.nvarchar(60)) AS parent_class_desc, + CAST(tr.tgrelid as int) AS parent_id, + CAST('TR' as sys.bpchar(2)) AS type, + CAST('SQL_TRIGGER' as sys.nvarchar(60)) AS type_desc, + CAST(f.create_date as sys.datetime) AS create_date, + CAST(f.create_date as sys.datetime) AS modify_date, + CAST(0 as sys.bit) AS is_ms_shipped, + CAST(tr.tgenabled = 'D' AS sys.bit) AS is_disabled, + CAST(0 as sys.bit) AS is_not_for_replication, + CAST(get_bit(CAST(CAST(tr.tgtype as int) as bit(7)),0) as sys.bit) AS is_instead_of_trigger +FROM pg_proc p +inner join sys.schemas sch on sch.schema_id = p.pronamespace +left join pg_trigger tr on tr.tgfoid = p.oid +left join sys.babelfish_function_ext f on p.proname = f.funcname and sch.schema_id::regnamespace::name = f.nspname +and sys.babelfish_get_pltsql_function_signature(p.oid) = f.funcsignature collate "C" +where +has_function_privilege(p.oid, 'EXECUTE') +and p.prokind = 'f' +and format_type(p.prorettype, null) = 'trigger'; +GRANT SELECT ON sys.triggers 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.relnamespace 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_class p on p.oid = tr.parent_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' +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; + +CREATE OR REPLACE VIEW sys.all_sql_modules_internal AS +SELECT + ao.object_id AS object_id + , CAST( + CASE WHEN ao.type in ('P', 'FN', 'IN', 'TF', 'RF', 'IF') THEN COALESCE(f.definition, '') + WHEN ao.type = 'V' THEN COALESCE(bvd.definition, '') + ELSE NULL + END + AS sys.nvarchar) AS definition + , CAST(1 as sys.bit) AS uses_ansi_nulls + , CAST(1 as sys.bit) AS uses_quoted_identifier + , CAST(0 as sys.bit) AS is_schema_bound + , CAST(0 as sys.bit) AS uses_database_collation + , CAST(0 as sys.bit) AS is_recompiled + , CAST(ao.type IN ('P', 'FN', 'IN', 'TF', 'RF', 'IF') + AND p.proisstrict + AS sys.bit) as null_on_null_input + , null::integer as execute_as_principal_id + , CAST(0 as sys.bit) as uses_native_compilation + , CAST(ao.is_ms_shipped as INT) as is_ms_shipped +FROM sys.all_objects ao +LEFT OUTER JOIN sys.pg_namespace_ext nmext on ao.schema_id = nmext.oid +LEFT OUTER JOIN sys.babelfish_namespace_ext ext ON nmext.nspname = ext.nspname +LEFT OUTER JOIN sys.babelfish_view_def bvd + on ( + ext.orig_name = bvd.schema_name AND + ext.dbid = bvd.dbid AND + ao.name = bvd.object_name + ) +LEFT JOIN pg_proc p ON ao.object_id = CAST(p.oid AS INT) +LEFT JOIN sys.babelfish_function_ext f ON ao.name = f.funcname COLLATE "C" AND ao.schema_id::regnamespace::name = f.nspname +AND sys.babelfish_get_pltsql_function_signature(ao.object_id) = f.funcsignature COLLATE "C" +WHERE ao.type in ('P', 'RF', 'V', 'FN', 'IF', 'TF', 'R') +UNION ALL +SELECT + ao.object_id AS object_id + , CAST(COALESCE(f.definition, '') AS sys.nvarchar) AS definition + , CAST(1 as sys.bit) AS uses_ansi_nulls + , CAST(1 as sys.bit) AS uses_quoted_identifier + , CAST(0 as sys.bit) AS is_schema_bound + , CAST(0 as sys.bit) AS uses_database_collation + , CAST(0 as sys.bit) AS is_recompiled + , CAST(0 AS sys.bit) as null_on_null_input + , null::integer as execute_as_principal_id + , CAST(0 as sys.bit) as uses_native_compilation + , CAST(ao.is_ms_shipped as INT) as is_ms_shipped +FROM sys.all_objects ao +LEFT OUTER JOIN sys.pg_namespace_ext nmext on ao.schema_id = nmext.oid +LEFT JOIN pg_trigger tr ON ao.object_id = CAST(tr.oid AS INT) +LEFT JOIN sys.babelfish_function_ext f ON ao.name = f.funcname COLLATE "C" AND ao.schema_id::regnamespace::name = f.nspname +AND sys.babelfish_get_pltsql_function_signature(tr.tgfoid) = f.funcsignature COLLATE "C" +WHERE ao.type = 'TR'; +GRANT SELECT ON sys.all_sql_modules_internal TO PUBLIC; + +CREATE OR REPLACE VIEW sys.index_columns +AS +WITH index_id_map AS MATERIALIZED ( + SELECT + indexrelid, + CASE + WHEN indisclustered THEN 1 + ELSE 1+row_number() OVER(PARTITION BY indrelid ORDER BY indexrelid) + END AS index_id + FROM pg_index +) +SELECT + CAST(i.indrelid AS INT) AS object_id, + -- should match index_id of sys.indexes + CAST(imap.index_id AS INT) AS index_id, + CAST(a.index_column_id AS INT) AS index_column_id, + CAST(a.attnum AS INT) AS column_id, + CAST(CASE + WHEN a.index_column_id <= i.indnkeyatts THEN a.index_column_id + ELSE 0 + END AS SYS.TINYINT) AS key_ordinal, + CAST(0 AS SYS.TINYINT) AS partition_ordinal, + CAST(CASE + WHEN i.indoption[a.index_column_id-1] & 1 = 1 THEN 1 + ELSE 0 + END AS SYS.BIT) AS is_descending_key, + CAST((a.index_column_id > i.indnkeyatts) AS SYS.BIT) AS is_included_column +FROM + pg_index i + INNER JOIN index_id_map imap ON imap.indexrelid = i.indexrelid + INNER JOIN pg_class c ON i.indrelid = c.oid and c.relispartition = false + INNER JOIN pg_namespace nsp ON nsp.oid = c.relnamespace + LEFT JOIN sys.babelfish_namespace_ext ext ON (nsp.nspname = ext.nspname AND ext.dbid = sys.db_id()) + LEFT JOIN unnest(i.indkey) WITH ORDINALITY AS a(attnum, index_column_id) ON true +WHERE + has_table_privilege(c.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') AND + (nsp.nspname = 'sys' OR ext.nspname is not null) AND + i.indislive +UNION ALL +-- entries for index of partitioned table +SELECT + CAST(i.indrelid AS INT) AS object_id, + -- should match index_id of sys.indexes + CAST(imap.index_id AS INT) AS index_id, + CAST(ARRAY_LENGTH(i.indkey, 1) + 1 AS INT) AS index_column_id, + CAST(a.attnum AS INT) AS column_id, + CAST(0 AS SYS.TINYINT) AS key_ordinal, + CAST(a.ordinal_position AS SYS.TINYINT) AS partition_ordinal, + CAST(0 AS SYS.BIT) AS is_descending_key, + CAST(0 AS SYS.BIT) AS is_included_column +FROM + pg_index i + INNER JOIN index_id_map imap ON imap.indexrelid = i.indexrelid + INNER JOIN pg_class tbl on tbl.oid = i.indrelid and tbl.relkind = 'p' + INNER JOIN pg_namespace nsp on tbl.relnamespace = nsp.oid + INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) + INNER JOIN pg_partitioned_table ppt ON ppt.partrelid = tbl.oid + LEFT JOIN unnest(ppt.partattrs) WITH ORDINALITY AS a(attnum, ordinal_position) ON true +WHERE + has_table_privilege(tbl.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') AND + i.indislive +UNION ALL +-- Heap entries for partitioned table +SELECT + CAST(t.oid as int) as object_id, + CAST(0 AS INT) AS index_id, + CAST(a.ordinal_position AS INT) AS index_column_id, + CAST(a.attnum AS INT) AS column_id, + CAST(0 AS SYS.TINYINT) AS key_ordinal, + CAST(a.ordinal_position AS SYS.TINYINT) AS partition_ordinal, + CAST(0 AS SYS.BIT) AS is_descending_key, + CAST(0 AS SYS.BIT) AS is_included_column +FROM + pg_class t + INNER JOIN pg_namespace nsp on t.relnamespace = nsp.oid + INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) + INNER JOIN pg_partitioned_table ppt ON ppt.partrelid = t.oid + LEFT JOIN unnest(ppt.partattrs) WITH ORDINALITY AS a(attnum, ordinal_position) ON true +WHERE + t.relkind = 'p' + AND has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); +GRANT SELECT ON sys.index_columns TO PUBLIC; + +CREATE OR REPLACE FUNCTION sys.proc_param_helper() +RETURNS TABLE ( + name sys.sysname, + id int, + xtype int, + colid smallint, + collationid int, + prec smallint, + scale int, + isoutparam int, + collation sys.sysname +) +AS +$$ +BEGIN +RETURN QUERY +select params.parameter_name::sys.sysname + , pgproc.oid::int + , CAST(case when pgproc.proallargtypes is null then split_part(pgproc.proargtypes::varchar, ' ', params.ordinal_position) + else split_part(btrim(pgproc.proallargtypes::text,'{}'), ',', params.ordinal_position) end AS int) + , params.ordinal_position::smallint + , coll.oid::int + , params.numeric_precision::smallint + , params.numeric_scale::int + , case params.parameter_mode when 'OUT' then 1 when 'INOUT' then 1 else 0 end + , params.collation_name::sys.sysname +from information_schema.routines routine +left join information_schema.parameters params + on routine.specific_schema = params.specific_schema + and routine.specific_name = params.specific_name +left join pg_collation coll on coll.collname = params.collation_name +/* assuming routine.specific_name is constructed by concatenating procedure name and oid */ +left join pg_proc pgproc on routine.specific_name = nameconcatoid(pgproc.proname, pgproc.oid) +left join sys.schemas sch on sch.schema_id = pgproc.pronamespace; +END; +$$ +LANGUAGE plpgsql STABLE; + +create or replace view sys.dm_exec_sessions + as + select a.pid as session_id + , a.backend_start::sys.datetime as login_time + , d.host_name::sys.nvarchar(128) as host_name + , a.application_name::sys.nvarchar(128) as program_name + , d.client_pid as host_process_id + , d.client_version as client_version + , d.library_name::sys.nvarchar(32) as client_interface_name + , null::sys.varbinary(85) as security_id + , a.usename::sys.nvarchar(128) as login_name + , (select sys.default_domain())::sys.nvarchar(128) as nt_domain + , null::sys.nvarchar(128) as nt_user_name + , a.state::sys.nvarchar(30) as status + , d.context_info::sys.varbinary(128) as context_info + , null::integer as cpu_time + , null::integer as memory_usage + , null::integer as total_scheduled_time + , null::integer as total_elapsed_time + , a.client_port as endpoint_id + , a.query_start::sys.datetime as last_request_start_time + , a.state_change::sys.datetime as last_request_end_time + , null::bigint as "reads" + , null::bigint as "writes" + , null::bigint as logical_reads + , CAST(a.client_port > 0 as sys.bit) as is_user_process + , d.textsize as text_size + , d.language::sys.nvarchar(128) as language + , 'ymd'::sys.nvarchar(3) as date_format-- Bld 173 lacks support for SET DATEFORMAT and always expects ymd + , d.datefirst::smallint as date_first -- Bld 173 lacks support for SET DATEFIRST and always returns 7 + , CAST(CAST(d.quoted_identifier as integer) as sys.bit) as quoted_identifier + , CAST(CAST(d.arithabort as integer) as sys.bit) as arithabort + , CAST(CAST(d.ansi_null_dflt_on as integer) as sys.bit) as ansi_null_dflt_on + , CAST(CAST(d.ansi_defaults as integer) as sys.bit) as ansi_defaults + , CAST(CAST(d.ansi_warnings as integer) as sys.bit) as ansi_warnings + , CAST(CAST(d.ansi_padding as integer) as sys.bit) as ansi_padding + , CAST(CAST(d.ansi_nulls as integer) as sys.bit) as ansi_nulls + , CAST(CAST(d.concat_null_yields_null as integer) as sys.bit) as concat_null_yields_null + , d.transaction_isolation::smallint as transaction_isolation_level + , d.lock_timeout as lock_timeout + , 0 as deadlock_priority + , d.row_count as row_count + , d.error as prev_error + , null::sys.varbinary(85) as original_security_id + , a.usename::sys.nvarchar(128) as original_login_name + , null::sys.datetime as last_successful_logon + , null::sys.datetime as last_unsuccessful_logon + , null::bigint as unsuccessful_logons + , null::int as group_id + , d.database_id::smallint as database_id + , 0 as authenticating_database_id + , d.trancount as open_transaction_count + from pg_catalog.pg_stat_activity AS a + RIGHT JOIN sys.tsql_stat_get_activity('sessions') AS d ON (a.pid = d.procid); + GRANT SELECT ON sys.dm_exec_sessions TO PUBLIC; + +CREATE OR REPLACE VIEW sys.events +AS +SELECT + CAST(pt.oid as int) AS object_id + , CAST( + CASE + WHEN tr.event_manipulation='INSERT' THEN 1 + WHEN tr.event_manipulation='UPDATE' THEN 2 + WHEN tr.event_manipulation='DELETE' THEN 3 + ELSE 1 + END as int + ) AS type + , CAST(tr.event_manipulation as sys.nvarchar(60)) AS type_desc + , CAST(1 as sys.bit) AS is_trigger_event + , CAST(null as int) AS event_group_type + , CAST(null as sys.nvarchar(60)) AS event_group_type_desc +FROM information_schema.triggers tr +JOIN pg_catalog.pg_namespace np ON tr.event_object_schema = np.nspname COLLATE sys.database_default +JOIN pg_class pc ON pc.relname = tr.event_object_table COLLATE sys.database_default AND pc.relnamespace = np.oid +JOIN pg_trigger pt ON pt.tgrelid = pc.oid AND tr.trigger_name = pt.tgname COLLATE sys.database_default +AND has_table_privilege(pc.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); +GRANT SELECT ON sys.events TO PUBLIC; + +CREATE OR REPLACE VIEW sys.partitions AS +with index_id_map as MATERIALIZED( + select + *, + case + when indisclustered then 1 + else 1+row_number() over(partition by indrelid order by indexrelid) + end as index_id + from pg_index +), +tt_internal as MATERIALIZED +( + select * from sys.table_types_internal +) +-- entries for non-partitioned tables +SELECT + CAST(t.oid as sys.BIGINT) as partition_id, + CAST(t.oid as int) as object_id, + CAST(0 as int) as index_id, + CAST(1 as int) as partition_number, + CAST(0 as sys.bigint) AS hobt_id, + CAST(case when t.reltuples = -1 then 0 else t.reltuples end as sys.bigint) AS rows, + CAST(0 as smallint) as filestream_filegroup_id, + CAST(0 as sys.tinyint) as data_compression, + CAST('NONE' as sys.nvarchar(60)) as data_compression_desc, + CAST(0 as sys.bit) as xml_compression, + CAST('OFF' as sys.varchar(3)) as xml_compression_desc +FROM pg_class t +INNER JOIN pg_namespace nsp on t.relnamespace = nsp.oid +INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) +LEFT JOIN tt_internal tt on t.oid = tt.typrelid +WHERE tt.typrelid is null +AND t.relkind = 'r' +AND t.relispartition = false +AND has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') + +UNION ALL +-- entries for non-partitioned indexes +SELECT + CAST(idx.indexrelid as sys.BIGINT) as partition_id, + CAST(idx.indrelid as int) as object_id, + CAST(imap.index_id as int) as index_id, + CAST(1 as int) as partition_number, + CAST(0 as sys.bigint) AS hobt_id, + CAST(case when t.reltuples = -1 then 0 else t.reltuples end as sys.bigint) AS rows, + CAST(0 as smallint) as filestream_filegroup_id, + CAST(0 as sys.tinyint) as data_compression, + CAST('NONE' as sys.nvarchar(60)) as data_compression_desc, + CAST(0 as sys.bit) as xml_compression, + CAST('OFF' as sys.varchar(3)) as xml_compression_desc +FROM pg_index idx +INNER JOIN index_id_map imap on imap.indexrelid = idx.indexrelid +INNER JOIN pg_class t on t.oid = idx.indrelid and t.relkind = 'r' and t.relispartition = false +INNER JOIN pg_namespace nsp on t.relnamespace = nsp.oid +INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) +where idx.indislive + +UNION ALL +-- entries for partitions of partitioned tables +SELECT + CAST(pgi.inhrelid as sys.BIGINT) as partition_id, + CAST(pgi.inhparent as int) as object_id, + CAST(0 as int) as index_id, + CAST(row_number() over(partition by pgi.inhparent order by ctbl.relname) as int) as partition_number, + CAST(0 as sys.bigint) AS hobt_id, + CAST(case when ctbl.reltuples = -1 then 0 else ctbl.reltuples end as sys.bigint) AS rows, + CAST(0 as smallint) as filestream_filegroup_id, + CAST(0 as sys.tinyint) as data_compression, + CAST('NONE' as sys.nvarchar(60)) as data_compression_desc, + CAST(0 as sys.bit) as xml_compression, + CAST('OFF' as sys.varchar(3)) as xml_compression_desc +FROM pg_inherits pgi +INNER JOIN pg_class ctbl on (ctbl.oid = pgi.inhrelid and ctbl.relkind = 'r' and ctbl.relispartition) +INNER JOIN pg_namespace nsp on ctbl.relnamespace = nsp.oid +INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) +WHERE +has_table_privilege(ctbl.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') + +UNION ALL +-- entries for partitions of partitioned indexes +SELECT + CAST(pgi.inhrelid as sys.BIGINT) as partition_id, + CAST(pidx.indrelid as int) as object_id, + CAST(cidx.index_id as int) as index_id, + CAST(row_number() over(partition by pgi.inhparent order by ctbl.relname) as int) as partition_number, + CAST(0 as sys.bigint) AS hobt_id, + CAST(case when ctbl.reltuples = -1 then 0 else ctbl.reltuples end as sys.bigint) AS rows, + CAST(0 as smallint) as filestream_filegroup_id, + CAST(0 as sys.tinyint) as data_compression, + CAST('NONE' as sys.nvarchar(60)) as data_compression_desc, + CAST(0 as sys.bit) as xml_compression, + CAST('OFF' as sys.varchar(3)) as xml_compression_desc +FROM pg_inherits pgi +INNER JOIN index_id_map cidx on cidx.indexrelid = pgi.inhrelid +INNER JOIN index_id_map pidx on pidx.indexrelid = pgi.inhparent +INNER JOIN pg_class ctbl on (ctbl.oid = cidx.indrelid and ctbl.relkind = 'r' and ctbl.relispartition) +INNER JOIN pg_namespace nsp on ctbl.relnamespace = nsp.oid +INNER JOIN sys.babelfish_namespace_ext ext on (nsp.nspname = ext.nspname and ext.dbid = sys.db_id()) +WHERE cidx.indislive; +GRANT SELECT ON sys.partitions TO PUBLIC; + +CREATE OR REPLACE VIEW sys.sp_tables_view AS +SELECT +t2.dbname AS TABLE_QUALIFIER, +CAST(t3.name AS name) AS TABLE_OWNER, +t1.relname AS TABLE_NAME, + +CASE +WHEN t1.relkind = 'v' + THEN 'VIEW' +ELSE 'TABLE' +END AS TABLE_TYPE, + +CAST(NULL AS varchar(254)) AS remarks +FROM pg_catalog.pg_class AS t1, sys.pg_namespace_ext AS t2, sys.schemas AS t3 +WHERE t1.relnamespace = t3.schema_id AND t1.relnamespace = t2.oid AND t1.relkind IN ('r','p','v','m') +AND t1.relispartition = false +AND has_table_privilege(t1.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); +GRANT SELECT ON sys.sp_tables_view 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 X.indislive ; + +GRANT SELECT ON sys.sp_special_columns_view TO PUBLIC; + +CREATE OR REPLACE VIEW sys.sp_stored_procedures_view AS +SELECT +CAST(d.name AS sys.sysname) COLLATE sys.database_default AS PROCEDURE_QUALIFIER, +CAST(s1.name AS sys.sysname) AS PROCEDURE_OWNER, + +CASE + WHEN p.prokind = 'p' THEN CAST(concat(p.proname, ';1') AS sys.nvarchar(134)) + ELSE CAST(concat(p.proname, ';0') AS sys.nvarchar(134)) +END AS PROCEDURE_NAME, + +-1 AS NUM_INPUT_PARAMS, +-1 AS NUM_OUTPUT_PARAMS, +-1 AS NUM_RESULT_SETS, +CAST(NULL AS varchar(254)) COLLATE sys.database_default AS REMARKS, +cast(2 AS smallint) AS PROCEDURE_TYPE + +FROM pg_catalog.pg_proc p + +INNER JOIN sys.schemas s1 ON p.pronamespace = s1.schema_id +INNER JOIN sys.databases d ON d.database_id = sys.db_id() + +UNION + +SELECT CAST((SELECT sys.db_name()) AS sys.sysname) COLLATE sys.database_default AS PROCEDURE_QUALIFIER, +CAST(nspname AS sys.sysname) AS PROCEDURE_OWNER, + +CASE + WHEN prokind = 'p' THEN cast(concat(proname, ';1') AS sys.nvarchar(134)) + ELSE cast(concat(proname, ';0') AS sys.nvarchar(134)) +END AS PROCEDURE_NAME, + +-1 AS NUM_INPUT_PARAMS, +-1 AS NUM_OUTPUT_PARAMS, +-1 AS NUM_RESULT_SETS, +CAST(NULL AS varchar(254)) COLLATE sys.database_default AS REMARKS, +cast(2 AS smallint) AS PROCEDURE_TYPE + +FROM pg_catalog.pg_namespace n +JOIN pg_catalog.pg_proc p +ON pronamespace = n.oid +WHERE nspname = 'sys' AND (proname LIKE 'sp\_%' OR proname LIKE 'xp\_%' OR proname LIKE 'dm\_%' OR proname LIKE 'fn\_%'); + +GRANT SELECT ON sys.sp_stored_procedures_view TO PUBLIC; + ALTER FUNCTION sys.sp_tables_internal RENAME TO sp_tables_internal_deprecated_in_4_4_0; ALTER FUNCTION sys.sp_columns_100_internal RENAME TO sp_columns_100_internal_deprecated_in_4_4_0; diff --git a/test/JDBC/expected/TestBIT.out b/test/JDBC/expected/TestBIT.out index 3991e54bf2..9bc379709c 100644 --- a/test/JDBC/expected/TestBIT.out +++ b/test/JDBC/expected/TestBIT.out @@ -25,9 +25,12 @@ INSERT INTO BIT_dt(a) values(1) INSERT INTO BIT_dt(a) values(0) ~~ROW COUNT: 1~~ -#next two lines are not allowed -#INSERT INTO BIT_dt(a) values(false) -#INSERT INTO BIT_dt(a) values(true) +INSERT INTO BIT_dt(a) values(false) +~~ROW COUNT: 1~~ + +INSERT INTO BIT_dt(a) values(true) +~~ROW COUNT: 1~~ + INSERT INTO BIT_dt(a) values(NULL) ~~ROW COUNT: 1~~ @@ -39,6 +42,8 @@ bit 1 0 +0 +1 ~~END~~ diff --git a/test/JDBC/expected/single_db/sys-views-vu-verify.out b/test/JDBC/expected/single_db/sys-views-vu-verify.out new file mode 100644 index 0000000000..0810be0b49 --- /dev/null +++ b/test/JDBC/expected/single_db/sys-views-vu-verify.out @@ -0,0 +1,299 @@ +-- tsql +USE sys_views_vu_prepare_db1 +GO + +SELECT COUNT(*) FROM sys.views WHERE name = 'sys_views_vu_prepare_t1'; +GO +~~START~~ +int +1 +~~END~~ + + +-- Should not include sysdatabases +SELECT COUNT(*) FROM sys.views WHERE type = 'V' and name = 'sysdatabases' +GO +~~START~~ +int +0 +~~END~~ + + +SELECT COUNT(*) FROM sys.objects WHERE type='V' and name = 'sys_views_vu_prepare_t1'; +GO +~~START~~ +int +1 +~~END~~ + + +SELECT COUNT(*) FROM sys.all_objects WHERE type='V' and name = 'sys_views_vu_prepare_t1'; +GO +~~START~~ +int +1 +~~END~~ + + +USE master; +GO + +#view sys_views_vu_prepare_t1 should not be visible in master database. +SELECT COUNT(*) FROM sys.views WHERE name = 'sys_views_vu_prepare_t1'; +GO +~~START~~ +int +0 +~~END~~ + + +SELECT COUNT(*) FROM sys.objects WHERE type='V' and name = 'sys_views_vu_prepare_t1'; +GO +~~START~~ +int +0 +~~END~~ + + +SELECT COUNT(*) FROM sys.all_objects WHERE type='V' and name = 'sys_views_vu_prepare_t1'; +GO +~~START~~ +int +0 +~~END~~ + + +SELECT COUNT(*) FROM sys.views WHERE name = 'sys_views_vu_prepare_t2'; +GO +~~START~~ +int +1 +~~END~~ + + +SELECT COUNT(*) FROM sys.objects WHERE type='V' and name = 'sys_views_vu_prepare_t2'; +GO +~~START~~ +int +1 +~~END~~ + + +SELECT COUNT(*) FROM sys.all_objects WHERE type='V' and name = 'sys_views_vu_prepare_t2'; +GO +~~START~~ +int +1 +~~END~~ + + +USE sys_views_vu_prepare_db1 +GO + +#view sys_views_vu_prepare_t2 should not be visible in sys_views_vu_prepare_db1 database. +SELECT COUNT(*) FROM sys.views WHERE name = 'sys_views_vu_prepare_t2'; +GO +~~START~~ +int +0 +~~END~~ + + +SELECT COUNT(*) FROM sys.objects WHERE type='V' and name = 'sys_views_vu_prepare_t2'; +GO +~~START~~ +int +0 +~~END~~ + + +SELECT COUNT(*) FROM sys.all_objects WHERE type='V' and name = 'sys_views_vu_prepare_t2'; +GO +~~START~~ +int +0 +~~END~~ + + +USE master ; +GO + +create login sys_views_login_l1 WITH PASSWORD = '12345678'; +GO + +create user sys_views_user_u1 for login sys_views_login_l1; +GO + +CREATE schema sys_views_vu_prepare_s1; +GO + +USE sys_views_vu_prepare_db1 +GO + +create user sys_views_user_u2 for login sys_views_login_l1; +GO + +CREATE DATABASE sys_views_vu_prepare_db2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Only one user database allowed under single-db mode. User database "sys_views_vu_prepare_db1" already exists)~~ + + +USE sys_views_vu_prepare_db2 +GO +~~ERROR (Code: 911)~~ + +~~ERROR (Message: database "sys_views_vu_prepare_db2" does not exist)~~ + + +CREATE schema sys_views_vu_prepare_s3; +GO + +create user sys_views_user_u3 for login sys_views_login_l1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Existing user already maps to login 'sys_views_login_l1' in current database.)~~ + + +USE master; +GO + +-- psql +-- checking to make sure that all tsql users have USAGE privilege on tsql schemas. +SELECT n.nspname, r.rolname, has_schema_privilege(r.rolname, n.nspname, 'USAGE') +FROM sys.babelfish_namespace_ext n +INNER JOIN sys.babelfish_sysdatabases db on n.dbid = db.dbid +CROSS JOIN sys.babelfish_authid_user_ext r +WHERE db.name in ('master', 'tempdb', 'msdb', 'sys_views_vu_prepare_db1', 'sys_views_vu_prepare_db2') +and r.database_name in ('master', 'tempdb', 'msdb', 'sys_views_vu_prepare_db1', 'sys_views_vu_prepare_db2') +and n.orig_name in ('dbo', 'guest', 'sys_views_vu_prepare_s1', 'sys_views_vu_prepare_s2', 'sys_views_vu_prepare_s3') +and r.orig_username in ('dbo', 'dbo_owner', 'guest', 'sys_views_user_u1', 'sys_views_user_u2', 'sys_views_user_u3') +ORDER by n.nspname, r.rolname; +GO +~~START~~ +name#!#name#!#bool +dbo#!#dbo#!#t +dbo#!#master_dbo#!#t +dbo#!#master_guest#!#t +dbo#!#master_sys_views_user_u1#!#t +dbo#!#msdb_dbo#!#t +dbo#!#msdb_guest#!#t +dbo#!#sys_views_vu_prepare_db1_guest#!#t +dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +dbo#!#tempdb_dbo#!#t +dbo#!#tempdb_guest#!#t +guest#!#dbo#!#t +guest#!#master_dbo#!#t +guest#!#master_guest#!#t +guest#!#master_sys_views_user_u1#!#t +guest#!#msdb_dbo#!#t +guest#!#msdb_guest#!#t +guest#!#sys_views_vu_prepare_db1_guest#!#t +guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +guest#!#tempdb_dbo#!#t +guest#!#tempdb_guest#!#t +master_dbo#!#dbo#!#t +master_dbo#!#master_dbo#!#t +master_dbo#!#master_guest#!#t +master_dbo#!#master_sys_views_user_u1#!#t +master_dbo#!#msdb_dbo#!#t +master_dbo#!#msdb_guest#!#t +master_dbo#!#sys_views_vu_prepare_db1_guest#!#t +master_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +master_dbo#!#tempdb_dbo#!#t +master_dbo#!#tempdb_guest#!#t +master_guest#!#dbo#!#t +master_guest#!#master_dbo#!#t +master_guest#!#master_guest#!#t +master_guest#!#master_sys_views_user_u1#!#t +master_guest#!#msdb_dbo#!#t +master_guest#!#msdb_guest#!#t +master_guest#!#sys_views_vu_prepare_db1_guest#!#t +master_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +master_guest#!#tempdb_dbo#!#t +master_guest#!#tempdb_guest#!#t +master_sys_views_vu_prepare_s1#!#dbo#!#t +master_sys_views_vu_prepare_s1#!#master_dbo#!#t +master_sys_views_vu_prepare_s1#!#master_guest#!#t +master_sys_views_vu_prepare_s1#!#master_sys_views_user_u1#!#t +master_sys_views_vu_prepare_s1#!#msdb_dbo#!#t +master_sys_views_vu_prepare_s1#!#msdb_guest#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db1_guest#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +master_sys_views_vu_prepare_s1#!#tempdb_dbo#!#t +master_sys_views_vu_prepare_s1#!#tempdb_guest#!#t +msdb_dbo#!#dbo#!#t +msdb_dbo#!#master_dbo#!#t +msdb_dbo#!#master_guest#!#t +msdb_dbo#!#master_sys_views_user_u1#!#t +msdb_dbo#!#msdb_dbo#!#t +msdb_dbo#!#msdb_guest#!#t +msdb_dbo#!#sys_views_vu_prepare_db1_guest#!#t +msdb_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +msdb_dbo#!#tempdb_dbo#!#t +msdb_dbo#!#tempdb_guest#!#t +msdb_guest#!#dbo#!#t +msdb_guest#!#master_dbo#!#t +msdb_guest#!#master_guest#!#t +msdb_guest#!#master_sys_views_user_u1#!#t +msdb_guest#!#msdb_dbo#!#t +msdb_guest#!#msdb_guest#!#t +msdb_guest#!#sys_views_vu_prepare_db1_guest#!#t +msdb_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +msdb_guest#!#tempdb_dbo#!#t +msdb_guest#!#tempdb_guest#!#t +sys_views_vu_prepare_s2#!#dbo#!#t +sys_views_vu_prepare_s2#!#master_dbo#!#t +sys_views_vu_prepare_s2#!#master_guest#!#t +sys_views_vu_prepare_s2#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_s2#!#msdb_dbo#!#t +sys_views_vu_prepare_s2#!#msdb_guest#!#t +sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_s2#!#tempdb_dbo#!#t +sys_views_vu_prepare_s2#!#tempdb_guest#!#t +sys_views_vu_prepare_s3#!#dbo#!#t +sys_views_vu_prepare_s3#!#master_dbo#!#t +sys_views_vu_prepare_s3#!#master_guest#!#t +sys_views_vu_prepare_s3#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_s3#!#msdb_dbo#!#t +sys_views_vu_prepare_s3#!#msdb_guest#!#t +sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_s3#!#tempdb_dbo#!#t +sys_views_vu_prepare_s3#!#tempdb_guest#!#t +tempdb_dbo#!#dbo#!#t +tempdb_dbo#!#master_dbo#!#t +tempdb_dbo#!#master_guest#!#t +tempdb_dbo#!#master_sys_views_user_u1#!#t +tempdb_dbo#!#msdb_dbo#!#t +tempdb_dbo#!#msdb_guest#!#t +tempdb_dbo#!#sys_views_vu_prepare_db1_guest#!#t +tempdb_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +tempdb_dbo#!#tempdb_dbo#!#t +tempdb_dbo#!#tempdb_guest#!#t +tempdb_guest#!#dbo#!#t +tempdb_guest#!#master_dbo#!#t +tempdb_guest#!#master_guest#!#t +tempdb_guest#!#master_sys_views_user_u1#!#t +tempdb_guest#!#msdb_dbo#!#t +tempdb_guest#!#msdb_guest#!#t +tempdb_guest#!#sys_views_vu_prepare_db1_guest#!#t +tempdb_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +tempdb_guest#!#tempdb_dbo#!#t +tempdb_guest#!#tempdb_guest#!#t +~~END~~ + + +-- tsql +USE master; +GO + +DROP DATABASE sys_views_vu_prepare_db2; +GO +~~ERROR (Code: 911)~~ + +~~ERROR (Message: database "sys_views_vu_prepare_db2" does not exist)~~ + diff --git a/test/JDBC/expected/sys-views-vu-cleanup.out b/test/JDBC/expected/sys-views-vu-cleanup.out index 9b8ce3c125..2b30067c52 100644 --- a/test/JDBC/expected/sys-views-vu-cleanup.out +++ b/test/JDBC/expected/sys-views-vu-cleanup.out @@ -4,9 +4,21 @@ GO DROP VIEW sys_views_vu_prepare_t1; GO +DROP schema sys_views_vu_prepare_s2; +GO + USE master; GO +DROP user sys_views_user_u1; +GO + +DROP login sys_views_login_l1; +GO + +DROP SCHEMA sys_views_vu_prepare_s1; +GO + DROP DATABASE sys_views_vu_prepare_db1; GO diff --git a/test/JDBC/expected/sys-views-vu-prepare.out b/test/JDBC/expected/sys-views-vu-prepare.out index 1a8b5aaf78..cebcb30e9a 100644 --- a/test/JDBC/expected/sys-views-vu-prepare.out +++ b/test/JDBC/expected/sys-views-vu-prepare.out @@ -7,6 +7,9 @@ GO CREATE VIEW sys_views_vu_prepare_t1 AS select 1; GO +CREATE schema sys_views_vu_prepare_s2; +GO + USE master; GO diff --git a/test/JDBC/expected/sys-views-vu-verify.out b/test/JDBC/expected/sys-views-vu-verify.out index 86bb2e13a3..6f37118cc0 100644 --- a/test/JDBC/expected/sys-views-vu-verify.out +++ b/test/JDBC/expected/sys-views-vu-verify.out @@ -1,3 +1,4 @@ +-- tsql USE sys_views_vu_prepare_db1 GO @@ -113,3 +114,229 @@ int 0 ~~END~~ + +USE master ; +GO + +create login sys_views_login_l1 WITH PASSWORD = '12345678'; +GO + +create user sys_views_user_u1 for login sys_views_login_l1; +GO + +CREATE schema sys_views_vu_prepare_s1; +GO + +USE sys_views_vu_prepare_db1 +GO + +create user sys_views_user_u2 for login sys_views_login_l1; +GO + +CREATE DATABASE sys_views_vu_prepare_db2; +GO + +USE sys_views_vu_prepare_db2 +GO + +CREATE schema sys_views_vu_prepare_s3; +GO + +create user sys_views_user_u3 for login sys_views_login_l1; +GO + +USE master; +GO + +-- psql +-- checking to make sure that all tsql users have USAGE privilege on tsql schemas. +SELECT n.nspname, r.rolname, has_schema_privilege(r.rolname, n.nspname, 'USAGE') +FROM sys.babelfish_namespace_ext n +INNER JOIN sys.babelfish_sysdatabases db on n.dbid = db.dbid +CROSS JOIN sys.babelfish_authid_user_ext r +WHERE db.name in ('master', 'tempdb', 'msdb', 'sys_views_vu_prepare_db1', 'sys_views_vu_prepare_db2') +and r.database_name in ('master', 'tempdb', 'msdb', 'sys_views_vu_prepare_db1', 'sys_views_vu_prepare_db2') +and n.orig_name in ('dbo', 'guest', 'sys_views_vu_prepare_s1', 'sys_views_vu_prepare_s2', 'sys_views_vu_prepare_s3') +and r.orig_username in ('dbo', 'dbo_owner', 'guest', 'sys_views_user_u1', 'sys_views_user_u2', 'sys_views_user_u3') +ORDER by n.nspname, r.rolname; +GO +~~START~~ +name#!#name#!#bool +master_dbo#!#master_dbo#!#t +master_dbo#!#master_guest#!#t +master_dbo#!#master_sys_views_user_u1#!#t +master_dbo#!#msdb_dbo#!#t +master_dbo#!#msdb_guest#!#t +master_dbo#!#sys_views_vu_prepare_db1_dbo#!#t +master_dbo#!#sys_views_vu_prepare_db1_guest#!#t +master_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +master_dbo#!#sys_views_vu_prepare_db2_dbo#!#t +master_dbo#!#sys_views_vu_prepare_db2_guest#!#t +master_dbo#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +master_dbo#!#tempdb_dbo#!#t +master_dbo#!#tempdb_guest#!#t +master_guest#!#master_dbo#!#t +master_guest#!#master_guest#!#t +master_guest#!#master_sys_views_user_u1#!#t +master_guest#!#msdb_dbo#!#t +master_guest#!#msdb_guest#!#t +master_guest#!#sys_views_vu_prepare_db1_dbo#!#t +master_guest#!#sys_views_vu_prepare_db1_guest#!#t +master_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +master_guest#!#sys_views_vu_prepare_db2_dbo#!#t +master_guest#!#sys_views_vu_prepare_db2_guest#!#t +master_guest#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +master_guest#!#tempdb_dbo#!#t +master_guest#!#tempdb_guest#!#t +master_sys_views_vu_prepare_s1#!#master_dbo#!#t +master_sys_views_vu_prepare_s1#!#master_guest#!#t +master_sys_views_vu_prepare_s1#!#master_sys_views_user_u1#!#t +master_sys_views_vu_prepare_s1#!#msdb_dbo#!#t +master_sys_views_vu_prepare_s1#!#msdb_guest#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db1_dbo#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db1_guest#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db2_dbo#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db2_guest#!#t +master_sys_views_vu_prepare_s1#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +master_sys_views_vu_prepare_s1#!#tempdb_dbo#!#t +master_sys_views_vu_prepare_s1#!#tempdb_guest#!#t +msdb_dbo#!#master_dbo#!#t +msdb_dbo#!#master_guest#!#t +msdb_dbo#!#master_sys_views_user_u1#!#t +msdb_dbo#!#msdb_dbo#!#t +msdb_dbo#!#msdb_guest#!#t +msdb_dbo#!#sys_views_vu_prepare_db1_dbo#!#t +msdb_dbo#!#sys_views_vu_prepare_db1_guest#!#t +msdb_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +msdb_dbo#!#sys_views_vu_prepare_db2_dbo#!#t +msdb_dbo#!#sys_views_vu_prepare_db2_guest#!#t +msdb_dbo#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +msdb_dbo#!#tempdb_dbo#!#t +msdb_dbo#!#tempdb_guest#!#t +msdb_guest#!#master_dbo#!#t +msdb_guest#!#master_guest#!#t +msdb_guest#!#master_sys_views_user_u1#!#t +msdb_guest#!#msdb_dbo#!#t +msdb_guest#!#msdb_guest#!#t +msdb_guest#!#sys_views_vu_prepare_db1_dbo#!#t +msdb_guest#!#sys_views_vu_prepare_db1_guest#!#t +msdb_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +msdb_guest#!#sys_views_vu_prepare_db2_dbo#!#t +msdb_guest#!#sys_views_vu_prepare_db2_guest#!#t +msdb_guest#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +msdb_guest#!#tempdb_dbo#!#t +msdb_guest#!#tempdb_guest#!#t +sys_views_vu_prepare_db1_dbo#!#master_dbo#!#t +sys_views_vu_prepare_db1_dbo#!#master_guest#!#t +sys_views_vu_prepare_db1_dbo#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_db1_dbo#!#msdb_dbo#!#t +sys_views_vu_prepare_db1_dbo#!#msdb_guest#!#t +sys_views_vu_prepare_db1_dbo#!#sys_views_vu_prepare_db1_dbo#!#t +sys_views_vu_prepare_db1_dbo#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_db1_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_db1_dbo#!#sys_views_vu_prepare_db2_dbo#!#t +sys_views_vu_prepare_db1_dbo#!#sys_views_vu_prepare_db2_guest#!#t +sys_views_vu_prepare_db1_dbo#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +sys_views_vu_prepare_db1_dbo#!#tempdb_dbo#!#t +sys_views_vu_prepare_db1_dbo#!#tempdb_guest#!#t +sys_views_vu_prepare_db1_guest#!#master_dbo#!#t +sys_views_vu_prepare_db1_guest#!#master_guest#!#t +sys_views_vu_prepare_db1_guest#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_db1_guest#!#msdb_dbo#!#t +sys_views_vu_prepare_db1_guest#!#msdb_guest#!#t +sys_views_vu_prepare_db1_guest#!#sys_views_vu_prepare_db1_dbo#!#t +sys_views_vu_prepare_db1_guest#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_db1_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_db1_guest#!#sys_views_vu_prepare_db2_dbo#!#t +sys_views_vu_prepare_db1_guest#!#sys_views_vu_prepare_db2_guest#!#t +sys_views_vu_prepare_db1_guest#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +sys_views_vu_prepare_db1_guest#!#tempdb_dbo#!#t +sys_views_vu_prepare_db1_guest#!#tempdb_guest#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#master_dbo#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#master_guest#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#msdb_dbo#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#msdb_guest#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db1_dbo#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db2_dbo#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db2_guest#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#tempdb_dbo#!#t +sys_views_vu_prepare_db1_sys_views_vu_prepare_s2#!#tempdb_guest#!#t +sys_views_vu_prepare_db2_dbo#!#master_dbo#!#t +sys_views_vu_prepare_db2_dbo#!#master_guest#!#t +sys_views_vu_prepare_db2_dbo#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_db2_dbo#!#msdb_dbo#!#t +sys_views_vu_prepare_db2_dbo#!#msdb_guest#!#t +sys_views_vu_prepare_db2_dbo#!#sys_views_vu_prepare_db1_dbo#!#t +sys_views_vu_prepare_db2_dbo#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_db2_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_db2_dbo#!#sys_views_vu_prepare_db2_dbo#!#t +sys_views_vu_prepare_db2_dbo#!#sys_views_vu_prepare_db2_guest#!#t +sys_views_vu_prepare_db2_dbo#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +sys_views_vu_prepare_db2_dbo#!#tempdb_dbo#!#t +sys_views_vu_prepare_db2_dbo#!#tempdb_guest#!#t +sys_views_vu_prepare_db2_guest#!#master_dbo#!#t +sys_views_vu_prepare_db2_guest#!#master_guest#!#t +sys_views_vu_prepare_db2_guest#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_db2_guest#!#msdb_dbo#!#t +sys_views_vu_prepare_db2_guest#!#msdb_guest#!#t +sys_views_vu_prepare_db2_guest#!#sys_views_vu_prepare_db1_dbo#!#t +sys_views_vu_prepare_db2_guest#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_db2_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_db2_guest#!#sys_views_vu_prepare_db2_dbo#!#t +sys_views_vu_prepare_db2_guest#!#sys_views_vu_prepare_db2_guest#!#t +sys_views_vu_prepare_db2_guest#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +sys_views_vu_prepare_db2_guest#!#tempdb_dbo#!#t +sys_views_vu_prepare_db2_guest#!#tempdb_guest#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#master_dbo#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#master_guest#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#master_sys_views_user_u1#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#msdb_dbo#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#msdb_guest#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db1_dbo#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db1_guest#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db2_dbo#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db2_guest#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#tempdb_dbo#!#t +sys_views_vu_prepare_db2_sys_views_vu_prepare_s3#!#tempdb_guest#!#t +tempdb_dbo#!#master_dbo#!#t +tempdb_dbo#!#master_guest#!#t +tempdb_dbo#!#master_sys_views_user_u1#!#t +tempdb_dbo#!#msdb_dbo#!#t +tempdb_dbo#!#msdb_guest#!#t +tempdb_dbo#!#sys_views_vu_prepare_db1_dbo#!#t +tempdb_dbo#!#sys_views_vu_prepare_db1_guest#!#t +tempdb_dbo#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +tempdb_dbo#!#sys_views_vu_prepare_db2_dbo#!#t +tempdb_dbo#!#sys_views_vu_prepare_db2_guest#!#t +tempdb_dbo#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +tempdb_dbo#!#tempdb_dbo#!#t +tempdb_dbo#!#tempdb_guest#!#t +tempdb_guest#!#master_dbo#!#t +tempdb_guest#!#master_guest#!#t +tempdb_guest#!#master_sys_views_user_u1#!#t +tempdb_guest#!#msdb_dbo#!#t +tempdb_guest#!#msdb_guest#!#t +tempdb_guest#!#sys_views_vu_prepare_db1_dbo#!#t +tempdb_guest#!#sys_views_vu_prepare_db1_guest#!#t +tempdb_guest#!#sys_views_vu_prepare_db1_sys_views_user_u2#!#t +tempdb_guest#!#sys_views_vu_prepare_db2_dbo#!#t +tempdb_guest#!#sys_views_vu_prepare_db2_guest#!#t +tempdb_guest#!#sys_views_vu_prepare_db2_sys_views_user_u3#!#t +tempdb_guest#!#tempdb_dbo#!#t +tempdb_guest#!#tempdb_guest#!#t +~~END~~ + + +-- tsql +USE master; +GO + +DROP DATABASE sys_views_vu_prepare_db2; +GO diff --git a/test/JDBC/input/datatypes/TestBIT.txt b/test/JDBC/input/datatypes/TestBIT.txt index 8424eadd59..b0a4a1286d 100644 --- a/test/JDBC/input/datatypes/TestBIT.txt +++ b/test/JDBC/input/datatypes/TestBIT.txt @@ -8,9 +8,8 @@ prepst#!#exec#!#BIT|-|a|-| SELECT * FROM BIT_dt; INSERT INTO BIT_dt(a) values(1) INSERT INTO BIT_dt(a) values(0) -#next two lines are not allowed -#INSERT INTO BIT_dt(a) values(false) -#INSERT INTO BIT_dt(a) values(true) +INSERT INTO BIT_dt(a) values(false) +INSERT INTO BIT_dt(a) values(true) INSERT INTO BIT_dt(a) values(NULL) SELECT * FROM BIT_dt; DROP TABLE BIT_dt; \ No newline at end of file diff --git a/test/JDBC/input/views/sys-views-vu-cleanup.sql b/test/JDBC/input/views/sys-views-vu-cleanup.mix similarity index 52% rename from test/JDBC/input/views/sys-views-vu-cleanup.sql rename to test/JDBC/input/views/sys-views-vu-cleanup.mix index fe65754253..d8c5e50e91 100644 --- a/test/JDBC/input/views/sys-views-vu-cleanup.sql +++ b/test/JDBC/input/views/sys-views-vu-cleanup.mix @@ -4,9 +4,21 @@ GO DROP VIEW sys_views_vu_prepare_t1; GO +DROP schema sys_views_vu_prepare_s2; +GO + USE master; GO +DROP user sys_views_user_u1; +GO + +DROP login sys_views_login_l1; +GO + +DROP SCHEMA sys_views_vu_prepare_s1; +GO + DROP DATABASE sys_views_vu_prepare_db1; GO diff --git a/test/JDBC/input/views/sys-views-vu-prepare.sql b/test/JDBC/input/views/sys-views-vu-prepare.mix similarity index 81% rename from test/JDBC/input/views/sys-views-vu-prepare.sql rename to test/JDBC/input/views/sys-views-vu-prepare.mix index 024627ddc7..cebcb30e9a 100644 --- a/test/JDBC/input/views/sys-views-vu-prepare.sql +++ b/test/JDBC/input/views/sys-views-vu-prepare.mix @@ -7,8 +7,11 @@ GO CREATE VIEW sys_views_vu_prepare_t1 AS select 1; GO +CREATE schema sys_views_vu_prepare_s2; +GO + USE master; GO CREATE VIEW sys_views_vu_prepare_t2 AS select 1; -GO \ No newline at end of file +GO diff --git a/test/JDBC/input/views/sys-views-vu-verify.sql b/test/JDBC/input/views/sys-views-vu-verify.mix similarity index 50% rename from test/JDBC/input/views/sys-views-vu-verify.sql rename to test/JDBC/input/views/sys-views-vu-verify.mix index 7944564212..eb12d0f920 100644 --- a/test/JDBC/input/views/sys-views-vu-verify.sql +++ b/test/JDBC/input/views/sys-views-vu-verify.mix @@ -1,3 +1,5 @@ +-- single_db_mode_expected +-- tsql USE sys_views_vu_prepare_db1 GO @@ -48,3 +50,56 @@ GO SELECT COUNT(*) FROM sys.all_objects WHERE type='V' and name = 'sys_views_vu_prepare_t2'; GO + +USE master ; +GO + +create login sys_views_login_l1 WITH PASSWORD = '12345678'; +GO + +create user sys_views_user_u1 for login sys_views_login_l1; +GO + +CREATE schema sys_views_vu_prepare_s1; +GO + +USE sys_views_vu_prepare_db1 +GO + +create user sys_views_user_u2 for login sys_views_login_l1; +GO + +CREATE DATABASE sys_views_vu_prepare_db2; +GO + +USE sys_views_vu_prepare_db2 +GO + +CREATE schema sys_views_vu_prepare_s3; +GO + +create user sys_views_user_u3 for login sys_views_login_l1; +GO + +USE master; +GO + +-- checking to make sure that all tsql users have USAGE privilege on tsql schemas. +-- psql +SELECT n.nspname, r.rolname, has_schema_privilege(r.rolname, n.nspname, 'USAGE') +FROM sys.babelfish_namespace_ext n +INNER JOIN sys.babelfish_sysdatabases db on n.dbid = db.dbid +CROSS JOIN sys.babelfish_authid_user_ext r +WHERE db.name in ('master', 'tempdb', 'msdb', 'sys_views_vu_prepare_db1', 'sys_views_vu_prepare_db2') +and r.database_name in ('master', 'tempdb', 'msdb', 'sys_views_vu_prepare_db1', 'sys_views_vu_prepare_db2') +and n.orig_name in ('dbo', 'guest', 'sys_views_vu_prepare_s1', 'sys_views_vu_prepare_s2', 'sys_views_vu_prepare_s3') +and r.orig_username in ('dbo', 'dbo_owner', 'guest', 'sys_views_user_u1', 'sys_views_user_u2', 'sys_views_user_u3') +ORDER by n.nspname, r.rolname; +GO + +-- tsql +USE master; +GO + +DROP DATABASE sys_views_vu_prepare_db2; +GO