From 7c0e46806954b39848864534b04f4efd86f7efd0 Mon Sep 17 00:00:00 2001 From: Anju Bharti <66729219+anju15bharti@users.noreply.github.com> Date: Thu, 26 Oct 2023 16:44:55 +0530 Subject: [PATCH] Adding support to sys.server_role_members (#1722) Currently, Babelfish does not support TSQL's sys.server_role_members view which is needed to determine the role(sysadmin server role) membership status. This commit implements this view and provides testing. Task: BABEL-2532 Signed-off-by: Anju Bharti abanju@amazon.com --- contrib/babelfishpg_tsql/sql/ownership.sql | 14 ++ .../babelfishpg_tsql--3.3.0--3.4.0.sql | 14 ++ .../sys_server_role_members-vu-cleanup.out | 26 ++++ .../sys_server_role_members-vu-prepare.out | 58 +++++++ .../sys_server_role_members-vu-verify.out | 146 ++++++++++++++++++ .../sys_server_role_members-vu-cleanup.mix | 26 ++++ .../sys_server_role_members-vu-prepare.mix | 58 +++++++ .../sys_server_role_members-vu-verify.mix | 77 +++++++++ test/JDBC/upgrade/latest/schedule | 1 + 9 files changed, 420 insertions(+) create mode 100644 test/JDBC/expected/sys_server_role_members-vu-cleanup.out create mode 100644 test/JDBC/expected/sys_server_role_members-vu-prepare.out create mode 100644 test/JDBC/expected/sys_server_role_members-vu-verify.out create mode 100644 test/JDBC/input/ownership/sys_server_role_members-vu-cleanup.mix create mode 100644 test/JDBC/input/ownership/sys_server_role_members-vu-prepare.mix create mode 100644 test/JDBC/input/ownership/sys_server_role_members-vu-verify.mix diff --git a/contrib/babelfishpg_tsql/sql/ownership.sql b/contrib/babelfishpg_tsql/sql/ownership.sql index 1aad3bfd0a..ee3a5446a4 100644 --- a/contrib/babelfishpg_tsql/sql/ownership.sql +++ b/contrib/babelfishpg_tsql/sql/ownership.sql @@ -507,6 +507,20 @@ AND Ext2.orig_username != 'db_owner'; GRANT SELECT ON sys.database_role_members TO PUBLIC; +--SERVER_ROLE_MEMBER +CREATE OR REPLACE VIEW sys.server_role_members AS +SELECT +CAST(Authmbr.roleid AS INT) AS role_principal_id, +CAST(Authmbr.member AS INT) AS member_principal_id +FROM pg_catalog.pg_auth_members AS Authmbr +INNER JOIN pg_catalog.pg_roles AS Auth1 ON Auth1.oid = Authmbr.roleid +INNER JOIN pg_catalog.pg_roles AS Auth2 ON Auth2.oid = Authmbr.member +INNER JOIN sys.babelfish_authid_login_ext AS Ext1 ON Auth1.rolname = Ext1.rolname +INNER JOIN sys.babelfish_authid_login_ext AS Ext2 ON Auth2.rolname = Ext2.rolname +WHERE Ext1.type = 'R'; + +GRANT SELECT ON sys.server_role_members TO PUBLIC; + -- internal table function for sp_helpdb with no arguments CREATE OR REPLACE FUNCTION sys.babelfish_helpdb() RETURNS table ( 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 c9db0e1f8d..b46942e5e2 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 @@ -1768,6 +1768,20 @@ OR Ext.type = 'R'; GRANT SELECT ON sys.server_principals TO PUBLIC; +--SERVER_ROLE_MEMBER +CREATE OR REPLACE VIEW sys.server_role_members AS +SELECT +CAST(Authmbr.roleid AS INT) AS role_principal_id, +CAST(Authmbr.member AS INT) AS member_principal_id +FROM pg_catalog.pg_auth_members AS Authmbr +INNER JOIN pg_catalog.pg_roles AS Auth1 ON Auth1.oid = Authmbr.roleid +INNER JOIN pg_catalog.pg_roles AS Auth2 ON Auth2.oid = Authmbr.member +INNER JOIN sys.babelfish_authid_login_ext AS Ext1 ON Auth1.rolname = Ext1.rolname +INNER JOIN sys.babelfish_authid_login_ext AS Ext2 ON Auth2.rolname = Ext2.rolname +WHERE Ext1.type = 'R'; + +GRANT SELECT ON sys.server_role_members TO PUBLIC; + create or replace view sys.schemas as select CAST(ext.orig_name as sys.SYSNAME) as name diff --git a/test/JDBC/expected/sys_server_role_members-vu-cleanup.out b/test/JDBC/expected/sys_server_role_members-vu-cleanup.out new file mode 100644 index 0000000000..3ec3cdb173 --- /dev/null +++ b/test/JDBC/expected/sys_server_role_members-vu-cleanup.out @@ -0,0 +1,26 @@ +DROP LOGIN sys_server_role_members_vu_prepare_login1; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_login2; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_login3; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_login4; +GO + +DROP VIEW sys_server_role_members_vu_prepare_view; +GO + +DROP FUNCTION sys_server_role_members_vu_prepare_func; +GO + +DROP PROCEDURE sys_server_role_members_vu_prepare_proc; +GO + +DROP USER sys_server_role_members_vu_prepare_without_sa; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_without_sa; +GO diff --git a/test/JDBC/expected/sys_server_role_members-vu-prepare.out b/test/JDBC/expected/sys_server_role_members-vu-prepare.out new file mode 100644 index 0000000000..d997ec6590 --- /dev/null +++ b/test/JDBC/expected/sys_server_role_members-vu-prepare.out @@ -0,0 +1,58 @@ +-- tsql +CREATE LOGIN sys_server_role_members_vu_prepare_login1 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_login2 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_login3 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_login4 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_without_sa WITH PASSWORD = '123'; +GO + +CREATE USER sys_server_role_members_vu_prepare_without_sa for login sys_server_role_members_vu_prepare_without_sa; +GO + +CREATE VIEW sys_server_role_members_vu_prepare_view AS +SELECT +roles.name AS RolePrincipalName +, members.name AS MemberPrincipalName +FROM sys.server_role_members AS server_role_members +INNER JOIN sys.server_principals AS roles + ON server_role_members.role_principal_id = roles.principal_id +INNER JOIN sys.server_principals AS members + ON server_role_members.member_principal_id = members.principal_id order by MemberPrincipalName; +GO + +CREATE FUNCTION sys_server_role_members_vu_prepare_func () +RETURNS TABLE +AS +RETURN ( + SELECT + roles.name AS RolePrincipalName + , members.name AS MemberPrincipalName + FROM sys.server_role_members AS server_role_members + INNER JOIN sys.server_principals AS roles + ON server_role_members.role_principal_id = roles.principal_id + INNER JOIN sys.server_principals AS members + ON server_role_members.member_principal_id = members.principal_id order by MemberPrincipalName + ); +GO + +CREATE PROCEDURE sys_server_role_members_vu_prepare_proc +AS +BEGIN + SELECT + roles.name AS RolePrincipalName + , members.name AS MemberPrincipalName + FROM sys.server_role_members AS server_role_members + INNER JOIN sys.server_principals AS roles + ON server_role_members.role_principal_id = roles.principal_id + INNER JOIN sys.server_principals AS members + ON server_role_members.member_principal_id = members.principal_id order by MemberPrincipalName; +END; +GO diff --git a/test/JDBC/expected/sys_server_role_members-vu-verify.out b/test/JDBC/expected/sys_server_role_members-vu-verify.out new file mode 100644 index 0000000000..863b2df109 --- /dev/null +++ b/test/JDBC/expected/sys_server_role_members-vu-verify.out @@ -0,0 +1,146 @@ +-- tsql +SELECT * from sys_server_role_members_vu_prepare_view; +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +~~END~~ + + +ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login1; +GO + +ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login2; +GO + +SELECT * from sys_server_role_members_vu_prepare_view; +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +sysadmin#!#sys_server_role_members_vu_prepare_login1 +sysadmin#!#sys_server_role_members_vu_prepare_login2 +~~END~~ + + +ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login3; +GO + +SELECT * from sys_server_role_members_vu_prepare_view; +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +sysadmin#!#sys_server_role_members_vu_prepare_login1 +sysadmin#!#sys_server_role_members_vu_prepare_login2 +sysadmin#!#sys_server_role_members_vu_prepare_login3 +~~END~~ + + +--granting access to user +GRANT SELECT ON sys_server_role_members_vu_prepare_view TO sys_server_role_members_vu_prepare_without_sa; +GO + +GRANT EXECUTE ON sys_server_role_members_vu_prepare_proc TO sys_server_role_members_vu_prepare_without_sa; +GO + +GRANT EXECUTE ON sys_server_role_members_vu_prepare_func TO sys_server_role_members_vu_prepare_without_sa; +GO + +-- reset the login password +ALTER LOGIN sys_server_role_members_vu_prepare_without_sa WITH PASSWORD = '123'; +GO + +-- tsql user=sys_server_role_members_vu_prepare_without_sa password=123 + +SELECT * FROM sys_server_role_members_vu_prepare_view; +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +~~END~~ + + +EXEC sys_server_role_members_vu_prepare_proc +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +~~END~~ + + +SELECT * FROM sys_server_role_members_vu_prepare_func(); +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +~~END~~ + + +-- psql +ALTER USER sys_server_role_members_vu_prepare_login1 PASSWORD '123'; +GO + +-- tsql user=sys_server_role_members_vu_prepare_login1 password=123 +SELECT * from sys_server_role_members_vu_prepare_view; +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +sysadmin#!#sys_server_role_members_vu_prepare_login1 +sysadmin#!#sys_server_role_members_vu_prepare_login2 +sysadmin#!#sys_server_role_members_vu_prepare_login3 +~~END~~ + + +EXEC sys_server_role_members_vu_prepare_proc +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +sysadmin#!#sys_server_role_members_vu_prepare_login1 +sysadmin#!#sys_server_role_members_vu_prepare_login2 +sysadmin#!#sys_server_role_members_vu_prepare_login3 +~~END~~ + + +SELECT * FROM sys_server_role_members_vu_prepare_func(); +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +sysadmin#!#sys_server_role_members_vu_prepare_login1 +sysadmin#!#sys_server_role_members_vu_prepare_login2 +sysadmin#!#sys_server_role_members_vu_prepare_login3 +~~END~~ + + +-- tsql +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login1; +GO + +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login2; +GO + +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login3; +GO + +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login4; +GO + +EXEC sys_server_role_members_vu_prepare_proc +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +~~END~~ + + +SELECT * FROM sys_server_role_members_vu_prepare_func(); +GO +~~START~~ +varchar#!#varchar +sysadmin#!#jdbc_user +~~END~~ + + diff --git a/test/JDBC/input/ownership/sys_server_role_members-vu-cleanup.mix b/test/JDBC/input/ownership/sys_server_role_members-vu-cleanup.mix new file mode 100644 index 0000000000..3ec3cdb173 --- /dev/null +++ b/test/JDBC/input/ownership/sys_server_role_members-vu-cleanup.mix @@ -0,0 +1,26 @@ +DROP LOGIN sys_server_role_members_vu_prepare_login1; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_login2; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_login3; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_login4; +GO + +DROP VIEW sys_server_role_members_vu_prepare_view; +GO + +DROP FUNCTION sys_server_role_members_vu_prepare_func; +GO + +DROP PROCEDURE sys_server_role_members_vu_prepare_proc; +GO + +DROP USER sys_server_role_members_vu_prepare_without_sa; +GO + +DROP LOGIN sys_server_role_members_vu_prepare_without_sa; +GO diff --git a/test/JDBC/input/ownership/sys_server_role_members-vu-prepare.mix b/test/JDBC/input/ownership/sys_server_role_members-vu-prepare.mix new file mode 100644 index 0000000000..9613401b0d --- /dev/null +++ b/test/JDBC/input/ownership/sys_server_role_members-vu-prepare.mix @@ -0,0 +1,58 @@ +-- tsql +CREATE LOGIN sys_server_role_members_vu_prepare_login1 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_login2 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_login3 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_login4 WITH PASSWORD = '123'; +GO + +CREATE LOGIN sys_server_role_members_vu_prepare_without_sa WITH PASSWORD = '123'; +GO + +CREATE USER sys_server_role_members_vu_prepare_without_sa for login sys_server_role_members_vu_prepare_without_sa; +GO + +CREATE VIEW sys_server_role_members_vu_prepare_view AS +SELECT +roles.name AS RolePrincipalName +, members.name AS MemberPrincipalName +FROM sys.server_role_members AS server_role_members +INNER JOIN sys.server_principals AS roles + ON server_role_members.role_principal_id = roles.principal_id +INNER JOIN sys.server_principals AS members + ON server_role_members.member_principal_id = members.principal_id order by MemberPrincipalName; +GO + +CREATE FUNCTION sys_server_role_members_vu_prepare_func () +RETURNS TABLE +AS +RETURN ( + SELECT + roles.name AS RolePrincipalName + , members.name AS MemberPrincipalName + FROM sys.server_role_members AS server_role_members + INNER JOIN sys.server_principals AS roles + ON server_role_members.role_principal_id = roles.principal_id + INNER JOIN sys.server_principals AS members + ON server_role_members.member_principal_id = members.principal_id order by MemberPrincipalName + ); +GO + +CREATE PROCEDURE sys_server_role_members_vu_prepare_proc +AS +BEGIN + SELECT + roles.name AS RolePrincipalName + , members.name AS MemberPrincipalName + FROM sys.server_role_members AS server_role_members + INNER JOIN sys.server_principals AS roles + ON server_role_members.role_principal_id = roles.principal_id + INNER JOIN sys.server_principals AS members + ON server_role_members.member_principal_id = members.principal_id order by MemberPrincipalName; +END; +GO \ No newline at end of file diff --git a/test/JDBC/input/ownership/sys_server_role_members-vu-verify.mix b/test/JDBC/input/ownership/sys_server_role_members-vu-verify.mix new file mode 100644 index 0000000000..4440a73fc1 --- /dev/null +++ b/test/JDBC/input/ownership/sys_server_role_members-vu-verify.mix @@ -0,0 +1,77 @@ +-- tsql +SELECT * from sys_server_role_members_vu_prepare_view; +GO + +ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login1; +GO + +ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login2; +GO + +SELECT * from sys_server_role_members_vu_prepare_view; +GO + +ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login3; +GO + +SELECT * from sys_server_role_members_vu_prepare_view; +GO + +--granting access to user +GRANT SELECT ON sys_server_role_members_vu_prepare_view TO sys_server_role_members_vu_prepare_without_sa; +GO + +GRANT EXECUTE ON sys_server_role_members_vu_prepare_proc TO sys_server_role_members_vu_prepare_without_sa; +GO + +GRANT EXECUTE ON sys_server_role_members_vu_prepare_func TO sys_server_role_members_vu_prepare_without_sa; +GO + +-- reset the login password +ALTER LOGIN sys_server_role_members_vu_prepare_without_sa WITH PASSWORD = '123'; +GO + +-- tsql user=sys_server_role_members_vu_prepare_without_sa password=123 + +SELECT * FROM sys_server_role_members_vu_prepare_view; +GO + +EXEC sys_server_role_members_vu_prepare_proc +GO + +SELECT * FROM sys_server_role_members_vu_prepare_func(); +GO + +-- psql +ALTER USER sys_server_role_members_vu_prepare_login1 PASSWORD '123'; +GO + +-- tsql user=sys_server_role_members_vu_prepare_login1 password=123 +SELECT * from sys_server_role_members_vu_prepare_view; +GO + +EXEC sys_server_role_members_vu_prepare_proc +GO + +SELECT * FROM sys_server_role_members_vu_prepare_func(); +GO + +-- tsql +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login1; +GO + +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login2; +GO + +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login3; +GO + +ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login4; +GO + +EXEC sys_server_role_members_vu_prepare_proc +GO + +SELECT * FROM sys_server_role_members_vu_prepare_func(); +GO + diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index d68c98039f..ddde45d404 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -344,6 +344,7 @@ sys-schemas sys-schemas-dep sys-selective_xml_index_paths sys-server_principals +sys_server_role_members sys_server_principals_dep sys-sid_binary sys-spatial_indexes