From 64d91acbb215a46baf2dd17d70b779c8481c51f1 Mon Sep 17 00:00:00 2001 From: Sai Rohan Basa <108261379+basasairohan@users.noreply.github.com> Date: Wed, 25 Oct 2023 15:48:10 +0530 Subject: [PATCH] Performance improvements for SSMS query while trying to expand stored procedures (#1923) Currently, the SSMS query to expand stored procedures is found to be very slow (~ 6 hours for 1000 procedures). The bad performance is found to be majorly occurring from sys.all_objects view. So, the following modifications have been done to the sys.all_objects : Bad row estimation arising due to the is_ms_shipped column in sys.all_objects view. This change fixes it by pushing down the computation of is_ms_shipped column to the respective unions. Made the datatype of type and name column consistent and removed the outer CAST as we are already casting them in the respective UNIONs. Removed subqueries and replaced them with suitable JOINs for better query planning. Task: BABEL-4008 Signed-off-by: Sai Rohan Basa --- contrib/babelfishpg_tsql/sql/sys_views.sql | 278 +++++++++--- .../babelfishpg_tsql--3.3.0--3.4.0.sql | 405 ++++++++++++++++++ 2 files changed, 628 insertions(+), 55 deletions(-) diff --git a/contrib/babelfishpg_tsql/sql/sys_views.sql b/contrib/babelfishpg_tsql/sql/sys_views.sql index 52f63d6c59..cc626cf14a 100644 --- a/contrib/babelfishpg_tsql/sql/sys_views.sql +++ b/contrib/babelfishpg_tsql/sql/sys_views.sql @@ -1268,108 +1268,245 @@ GRANT SELECT ON sys.shipped_objects_not_in_sys TO PUBLIC; create or replace view sys.all_objects as select - cast (name as sys.sysname) collate sys.database_default + 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) - , cast (type as char(2)) collate sys.database_default + , type collate sys.database_default , cast (type_desc as sys.nvarchar(60)) , cast (create_date as sys.datetime) , cast (modify_date as sys.datetime) - , cast (case when (schema_id::regnamespace::text = 'sys') then 1 - when name in (select name from sys.shipped_objects_not_in_sys nis - where nis.name = name and nis.schemaid = schema_id and nis.type = type) then 1 - else 0 end as sys.bit) as is_ms_shipped + , is_ms_shipped , cast (is_published as sys.bit) , cast (is_schema_published as sys.bit) from ( --- details of user defined and system tables +-- 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_schema_privilege(s.oid, 'USAGE') +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') + +union all +-- details of user defined tables select - t.relname as name + 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' as type + , 'U'::char(2) as type , 'USER_TABLE' as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , 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' -and (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') -and not sys.is_table_type(t.oid) +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 +-- 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_schema_privilege(s.oid, 'USAGE') and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') union all --- details of user defined and system views +-- Details of user defined views select - t.relname as name + 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'::varchar(2) as type + , 'V'::char(2) as type , 'VIEW'::varchar(60) as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , 0::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.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +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(quote_ident(s.nspname) ||'.'||quote_ident(t.relname), 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +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 as name + 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' as type + , 'F'::char(2) as type , 'FOREIGN_KEY_CONSTRAINT' , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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 -where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') -and has_schema_privilege(s.oid, 'USAGE') +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' +and (s.nspname = 'sys' or ext.nspname is not null) union all -- details of user defined and system primary key constraints select - c.conname as name + 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' as type + , 'PK'::char(2) as type , 'PRIMARY_KEY_CONSTRAINT' as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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 -where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') -and has_schema_privilege(s.oid, 'USAGE') +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' +and (s.nspname = 'sys' or ext.nspname is not null) +union all +-- details of system defined procedures +select + p.proname::sys.sysname as name + , p.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , cast (case when tr.tgrelid is not null + then tr.tgrelid + else 0 end as int) + as parent_object_id + , case p.prokind + when 'p' then 'P'::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_schema_privilege(s.oid, 'USAGE') +and has_function_privilege(p.oid, 'EXECUTE') + union all --- details of user defined and system defined procedures +-- details of user defined procedures select - p.proname as name + p.proname::sys.sysname as name , p.oid as object_id , null::integer as principal_id , s.oid as schema_id @@ -1378,19 +1515,19 @@ select else 0 end as int) as parent_object_id , case p.prokind - when 'p' then 'P'::varchar(2) - when 'a' then 'AF'::varchar(2) + when 'p' then 'P'::char(2) + when 'a' then 'AF'::char(2) else case - when pg_catalog.format_type(p.prorettype, null) = 'trigger' - then 'TR'::varchar(2) + when t.typname = 'trigger' + then 'TR'::char(2) when p.proretset then case when t.typtype = 'c' - then 'TF'::varchar(2) - else 'IF'::varchar(2) + then 'TF'::char(2) + else 'IF'::char(2) end - else 'FN'::varchar(2) + else 'FN'::char(2) end end as type , case p.prokind @@ -1398,7 +1535,7 @@ select when 'a' then 'AGGREGATE_FUNCTION'::varchar(60) else case - when pg_catalog.format_type(p.prorettype, null) = 'trigger' + when t.typname = 'trigger' then 'SQL_TRIGGER'::varchar(60) when p.proretset then case @@ -1411,20 +1548,40 @@ select end as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , 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 -where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +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_schema_privilege(s.oid, 'USAGE') and has_function_privilege(p.oid, 'EXECUTE') + union all -- details of all default constraints select - ('DF_' || o.relname || '_' || d.oid)::name as name + ('DF_' || o.relname || '_' || d.oid)::sys.sysname as name , d.oid as object_id , null::int as principal_id , o.relnamespace as schema_id @@ -1433,73 +1590,84 @@ select , 'DEFAULT_CONSTRAINT'::sys.nvarchar(60) AS type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +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 select - c.conname::name + c.conname::sys.sysname , c.oid::integer as object_id , NULL::integer as principal_id - , c.connamespace::integer as schema_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 - , 0 as is_ms_shipped + , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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 -where (s.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') -and has_schema_privilege(s.oid, 'USAGE') +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 +and (s.nspname = 'sys' or ext.nspname is not null) union all -- details of user defined and system defined sequence objects select - p.relname as name + 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'::varchar(2) as type + , 'SO'::char(2) as type , 'SEQUENCE_OBJECT'::varchar(60) as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 0 as is_ms_shipped + , CAST (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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.oid in (select schema_id from sys.schemas) or s.nspname = 'sys') +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 - ('TT_' || tt.name || '_' || tt.type_table_object_id)::name as name + ('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'::varchar(2) as type + , 'TT'::char(2) as type , 'TABLE_TYPE'::varchar(60) as type_desc , null::timestamp as create_date , null::timestamp as modify_date - , 1 as is_ms_shipped + , 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 , 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; diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql index c822e93d3c..e052df12ad 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql @@ -1261,6 +1261,411 @@ END; $body$ LANGUAGE plpgsql IMMUTABLE; +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 +( +-- 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_schema_privilege(s.oid, 'USAGE') +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' +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 +-- 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_schema_privilege(s.oid, 'USAGE') +and has_table_privilege(t.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER') +union all +-- Details of user defined views + +-- 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. +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_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 +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 (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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' +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 (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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' +and (s.nspname = 'sys' or ext.nspname is not null) +union all +-- details of system defined procedures +select + p.proname::sys.sysname as name + , p.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , cast (case when tr.tgrelid is not null + then tr.tgrelid + else 0 end as int) + as parent_object_id + , case p.prokind + when 'p' then 'P'::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_schema_privilege(s.oid, 'USAGE') +and has_function_privilege(p.oid, 'EXECUTE') + +union all +-- details of user defined procedures +select + p.proname::sys.sysname as name + , p.oid as object_id + , null::integer as principal_id + , s.oid as schema_id + , cast (case when tr.tgrelid is not null + then tr.tgrelid + else 0 end as int) + as parent_object_id + , case p.prokind + when 'p' then 'P'::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_schema_privilege(s.oid, 'USAGE') +and has_function_privilege(p.oid, 'EXECUTE') + +union all +-- details of all default constraints +select + ('DF_' || o.relname || '_' || d.oid)::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 (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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_schema_privilege(s.oid, 'USAGE') +and has_column_privilege(a.attrelid, a.attname, 'SELECT,INSERT,UPDATE,REFERENCES') +union all +-- details of all check constraints +select + c.conname::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 (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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 +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 (case when (s.nspname = 'sys' or nis.name is not null) then 1 + else 0 end 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) +and has_schema_privilege(s.oid, 'USAGE') +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 (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 + , 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.server_principals AS SELECT CAST(Ext.orig_loginname AS sys.SYSNAME) AS name,