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
13 changes: 13 additions & 0 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -466,6 +466,19 @@ 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 sys.server_principals AS p1 ON p1.principal_id = Authmbr.roleid
INNER JOIN sys.server_principals AS p2 ON p2.principal_id = Authmbr.member
WHERE p1.type_desc='SERVER_ROLE'
AND p1.is_fixed_role=1;
anju15bharti marked this conversation as resolved.
Show resolved Hide resolved

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 @@ -375,6 +375,18 @@ left join pg_catalog.pg_locks blocking_locks
where a.datname = current_database(); /* current physical database will always be babelfish database */
GRANT SELECT ON sys.sysprocesses TO PUBLIC;

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 sys.server_principals AS p1 ON p1.principal_id = Authmbr.roleid
INNER JOIN sys.server_principals AS p2 ON p2.principal_id = Authmbr.member
WHERE p1.type_desc='SERVER_ROLE'
AND p1.is_fixed_role=1;

GRANT SELECT ON sys.server_role_members TO PUBLIC;
Copy link
Contributor

Choose a reason for hiding this comment

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

This will be targeted for 3.4.0 version. So, please rebase it once 3.x development branch is ready for 3.4.0.


CREATE OR REPLACE FUNCTION sys.host_id()
RETURNS sys.VARCHAR(10) AS 'babelfishpg_tsql' LANGUAGE C IMMUTABLE PARALLEL SAFE;
GRANT EXECUTE ON FUNCTION sys.host_id() TO PUBLIC;
Expand Down
14 changes: 14 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,14 @@
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
22 changes: 22 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,22 @@
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 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;
GO
anju15bharti marked this conversation as resolved.
Show resolved Hide resolved
56 changes: 56 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,56 @@
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 DROP MEMBER sys_server_role_members_vu_prepare_login2;
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
~~START~~
varchar#!#varchar
sysadmin#!#jdbc_user
sysadmin#!#sys_server_role_members_vu_prepare_login1
sysadmin#!#sys_server_role_members_vu_prepare_login3
~~END~~


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_login3;
GO

ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login4;
GO

SELECT * from sys_server_role_members_vu_prepare_view;
GO
~~START~~
varchar#!#varchar
sysadmin#!#jdbc_user
~~END~~

14 changes: 14 additions & 0 deletions test/JDBC/input/ownership/sys_server_role_members-vu-cleanup.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
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
22 changes: 22 additions & 0 deletions test/JDBC/input/ownership/sys_server_role_members-vu-prepare.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
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 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;
GO
32 changes: 32 additions & 0 deletions test/JDBC/input/ownership/sys_server_role_members-vu-verify.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
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 DROP MEMBER sys_server_role_members_vu_prepare_login2;
GO

ALTER SERVER ROLE sysadmin ADD MEMBER sys_server_role_members_vu_prepare_login3;
GO
Copy link
Contributor

Choose a reason for hiding this comment

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

Here, we need to test visibility according to the current_login. There may be a case that this view can only show data about current login, not others unless it has some sysadmin - we need to verify such scenarios.

Please check the .mix files for other test - We can also use multiple connections with specific login & database.


SELECT * from sys_server_role_members_vu_prepare_view;
GO

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_login3;
GO

ALTER SERVER ROLE sysadmin DROP MEMBER sys_server_role_members_vu_prepare_login4;
GO

SELECT * from sys_server_role_members_vu_prepare_view;
GO
1 change: 1 addition & 0 deletions test/JDBC/upgrade/latest/schedule
Original file line number Diff line number Diff line change
Expand Up @@ -333,6 +333,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
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -982,4 +982,4 @@ View sys.synonyms
View sys.syscharsets
View sys.syslanguages
View sys.xml_indexes
View sys.xml_schema_collections
anju15bharti marked this conversation as resolved.
Show resolved Hide resolved
View sys.xml_schema_collections