Skip to content

Commit

Permalink
Adding support to sys.server_role_members (#1722)
Browse files Browse the repository at this point in the history
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 [email protected]
  • Loading branch information
anju15bharti authored Oct 26, 2023
1 parent 9fab304 commit 7c0e468
Show file tree
Hide file tree
Showing 9 changed files with 420 additions and 0 deletions.
14 changes: 14 additions & 0 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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 (
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
26 changes: 26 additions & 0 deletions test/JDBC/expected/sys_server_role_members-vu-cleanup.out
Original file line number Diff line number Diff line change
@@ -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
58 changes: 58 additions & 0 deletions test/JDBC/expected/sys_server_role_members-vu-prepare.out
Original file line number Diff line number Diff line change
@@ -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
146 changes: 146 additions & 0 deletions test/JDBC/expected/sys_server_role_members-vu-verify.out
Original file line number Diff line number Diff line change
@@ -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~~


26 changes: 26 additions & 0 deletions test/JDBC/input/ownership/sys_server_role_members-vu-cleanup.mix
Original file line number Diff line number Diff line change
@@ -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
58 changes: 58 additions & 0 deletions test/JDBC/input/ownership/sys_server_role_members-vu-prepare.mix
Original file line number Diff line number Diff line change
@@ -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
Loading

0 comments on commit 7c0e468

Please sign in to comment.