From 88bfb3690315cf054256f80aadda7ecbbb39564f Mon Sep 17 00:00:00 2001 From: Jungkook Lee Date: Wed, 17 Jan 2024 23:47:33 +0000 Subject: [PATCH] Remove pltsql_call_handler from sys.all_objects We have fixed duplicate OIDs for most objects, however, `pltsql_call_handler` still has a possibility of duplicate OIDs after MVU to PG14/15/16 because `GetNewObjectId_hook()` is not called when we restore the first C function. This commit removes pltsql_call_handler from sys.all_objects, hence sys.all_objects won't have duplicate OIDs after major version upgrades. Task: BABEL-4662 Signed-off-by: Jungkook Lee --- contrib/babelfishpg_tsql/sql/sys_views.sql | 1 + .../babelfishpg_tsql--2.7.0--2.8.0.sql | 406 ++++++++++++++++++ test/JDBC/expected/BABEL-3613-vu-verify.out | 23 + test/JDBC/input/BABEL-3613-vu-verify.sql | 8 + 4 files changed, 438 insertions(+) diff --git a/contrib/babelfishpg_tsql/sql/sys_views.sql b/contrib/babelfishpg_tsql/sql/sys_views.sql index fa99914292..233e8047ea 100644 --- a/contrib/babelfishpg_tsql/sql/sys_views.sql +++ b/contrib/babelfishpg_tsql/sql/sys_views.sql @@ -1498,6 +1498,7 @@ and nis.type = (case p.prokind 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' union all -- details of user defined procedures diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql index 16d32946f8..d15d4af10a 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--2.7.0--2.8.0.sql @@ -265,6 +265,412 @@ AS SELECT WHERE FALSE; GRANT SELECT ON sys.availability_groups 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_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 +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') +and p.proname != 'pltsql_call_handler' + +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; + -- 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/test/JDBC/expected/BABEL-3613-vu-verify.out b/test/JDBC/expected/BABEL-3613-vu-verify.out index b5bdb89060..2bd175f29c 100644 --- a/test/JDBC/expected/BABEL-3613-vu-verify.out +++ b/test/JDBC/expected/BABEL-3613-vu-verify.out @@ -58,3 +58,26 @@ GO int#!#varchar#!#int#!#nvarchar ~~END~~ + +-- BABEL-4662 +select count(*) from sys.all_objects where name = 'pltsql_call_handler'; +go +~~START~~ +int +0 +~~END~~ + +select count(*) from sys.procedures where name = 'pltsql_call_handler'; +go +~~START~~ +int +0 +~~END~~ + +select count(*) from sys.system_objects where name = 'pltsql_call_handler'; +go +~~START~~ +int +0 +~~END~~ + diff --git a/test/JDBC/input/BABEL-3613-vu-verify.sql b/test/JDBC/input/BABEL-3613-vu-verify.sql index f5c4ba1956..7c5a34ae4d 100644 --- a/test/JDBC/input/BABEL-3613-vu-verify.sql +++ b/test/JDBC/input/BABEL-3613-vu-verify.sql @@ -26,3 +26,11 @@ where object_id in (select object_id from sys.all_objects group by object_id having count(object_id) > 1) order by object_id, name; GO + +-- BABEL-4662 +select count(*) from sys.all_objects where name = 'pltsql_call_handler'; +go +select count(*) from sys.procedures where name = 'pltsql_call_handler'; +go +select count(*) from sys.system_objects where name = 'pltsql_call_handler'; +go