Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Adding support to sys.server_role_members #1722

Merged
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';
Comment on lines +516 to +520
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What about the permissions? Should all server membership should be visible by default? Please refer doc

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

In Babelfish, we only allow one server role sysadmin which is marked as "R" in the catalog.
In SQL Server, the default server role sysadmin is visible to everyone. There is no behavioral difference.
We don't support creating a new server role other that 'sysadmin' in Babelfish, do we?

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes, In future when we support it at that time we may miss it. It will be better to add a condition to check that if it is fixed server role or showing membership's for current server principal.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Agreed.
Currently, we hardcode is_fixed_role to 0 always.
I have suggested a change to Anju on how to update the is_fixed_role column in babelfish_authid_login_ext catalog which will be helpful for #1948 as well.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We would need to update sys.server_role_members view once we support create server role syntax in Babelfish as tracked by https://jira.rds.a2z.com/browse/BABEL-113


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