Skip to content

Commit

Permalink
Show public role entry in sys.server_principals (#2765)
Browse files Browse the repository at this point in the history
Currently in Babelfish we don't show any public entry. We should show the public role as well. To achieve this I have added a public entry in the sys.server_principals by making changes in the ownership.sql and added relevant testcases.

A sysadmin login and a non-sysadmin login both see the public role in the sys.server_principals entries.

Task: BABEL-4518

Signed-off-by: P Aswini Kumar <[email protected]>
  • Loading branch information
aswiniip authored Aug 1, 2024
1 parent d141db8 commit 239d212
Show file tree
Hide file tree
Showing 8 changed files with 116 additions and 4 deletions.
23 changes: 19 additions & 4 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -366,10 +366,25 @@ CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.owning_principal_id END AS INT) AS
CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.is_fixed_role END AS sys.BIT) AS is_fixed_role
FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname
WHERE (pg_has_role(suser_id(), 'sysadmin'::TEXT, 'MEMBER')
OR Ext.orig_loginname = suser_name()
OR Ext.orig_loginname = (SELECT pg_get_userbyid(datdba) FROM pg_database WHERE datname = CURRENT_DATABASE()) COLLATE sys.database_default
OR Ext.type = 'R')
AND Ext.type != 'Z';
OR Ext.orig_loginname = suser_name()
OR Ext.orig_loginname = (SELECT pg_get_userbyid(datdba) FROM pg_database WHERE datname = CURRENT_DATABASE()) COLLATE sys.database_default
OR Ext.type = 'R')
AND Ext.type != 'Z'
UNION ALL
SELECT
CAST('public' AS SYS.SYSNAME) AS name,
CAST(-1 AS INT) AS principal_id,
CAST(CAST(0 as INT) as sys.varbinary(85)) AS sid,
CAST('R' AS CHAR(1)) as type,
CAST('SERVER_ROLE' AS NVARCHAR(60)) AS type_desc,
CAST(0 AS INT) AS is_disabled,
CAST(NULL AS SYS.DATETIME) AS create_date,
CAST(NULL AS SYS.DATETIME) AS modify_date,
CAST(NULL AS SYS.SYSNAME) AS default_database_name,
CAST(NULL AS SYS.SYSNAME) AS default_language_name,
CAST(NULL AS INT) AS credential_id,
CAST(1 AS INT) AS owning_principal_id,
CAST(0 AS sys.BIT) AS is_fixed_role;

GRANT SELECT ON sys.server_principals TO PUBLIC;

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -652,6 +652,52 @@ WHERE (SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = C

GRANT SELECT ON sys.user_token TO PUBLIC;

CREATE OR REPLACE VIEW sys.server_principals
AS SELECT
CAST(Ext.orig_loginname AS sys.SYSNAME) AS name,
CAST(Base.oid As INT) AS principal_id,
CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid,
CAST(Ext.type AS CHAR(1)) as type,
CAST(
CASE
WHEN Ext.type = 'S' THEN 'SQL_LOGIN'
WHEN Ext.type = 'R' THEN 'SERVER_ROLE'
WHEN Ext.type = 'U' THEN 'WINDOWS_LOGIN'
ELSE NULL
END
AS NVARCHAR(60)) AS type_desc,
CAST(Ext.is_disabled AS INT) AS is_disabled,
CAST(Ext.create_date AS SYS.DATETIME) AS create_date,
CAST(Ext.modify_date AS SYS.DATETIME) AS modify_date,
CAST(CASE WHEN Ext.type = 'R' THEN NULL ELSE Ext.default_database_name END AS SYS.SYSNAME) AS default_database_name,
CAST(Ext.default_language_name AS SYS.SYSNAME) AS default_language_name,
CAST(CASE WHEN Ext.type = 'R' THEN NULL ELSE Ext.credential_id END AS INT) AS credential_id,
CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.owning_principal_id END AS INT) AS owning_principal_id,
CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.is_fixed_role END AS sys.BIT) AS is_fixed_role
FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname
WHERE (pg_has_role(suser_id(), 'sysadmin'::TEXT, 'MEMBER')
OR Ext.orig_loginname = suser_name()
OR Ext.orig_loginname = (SELECT pg_get_userbyid(datdba) FROM pg_database WHERE datname = CURRENT_DATABASE()) COLLATE sys.database_default
OR Ext.type = 'R')
AND Ext.type != 'Z'
UNION ALL
SELECT
CAST('public' AS SYS.SYSNAME) AS name,
CAST(-1 AS INT) AS principal_id,
CAST(CAST(0 as INT) as sys.varbinary(85)) AS sid,
CAST('R' AS CHAR(1)) as type,
CAST('SERVER_ROLE' AS NVARCHAR(60)) AS type_desc,
CAST(0 AS INT) AS is_disabled,
CAST(NULL AS SYS.DATETIME) AS create_date,
CAST(NULL AS SYS.DATETIME) AS modify_date,
CAST(NULL AS SYS.SYSNAME) AS default_database_name,
CAST(NULL AS SYS.SYSNAME) AS default_language_name,
CAST(NULL AS INT) AS credential_id,
CAST(1 AS INT) AS owning_principal_id,
CAST(0 AS sys.BIT) AS is_fixed_role;

GRANT SELECT ON sys.server_principals TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.is_member(IN role sys.SYSNAME)
RETURNS INT AS
$$
Expand Down
7 changes: 7 additions & 0 deletions test/JDBC/expected/sys-server_principals-vu-prepare.out
Original file line number Diff line number Diff line change
Expand Up @@ -4,3 +4,10 @@ GO

CREATE LOGIN sys_server_principals_vu_login_with_sa with password = '123'
GO

CREATE LOGIN [public] WITH PASSWORD = 'test';
GO
~~ERROR (Code: 33557097)~~

~~ERROR (Message: role name "public" is reserved)~~

11 changes: 11 additions & 0 deletions test/JDBC/expected/sys-server_principals-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,16 @@ sysadmin#!#R#!#SERVER_ROLE#!#<NULL>#!#English#!#<NULL>#!#1#!#1
~~END~~


SELECT name, type, type_desc, default_database_name, default_language_name, credential_id, owning_principal_id, is_fixed_role
FROM sys.server_principals
WHERE name = 'public';
GO
~~START~~
varchar#!#char#!#nvarchar#!#varchar#!#varchar#!#int#!#int#!#bit
public#!#R#!#SERVER_ROLE#!#<NULL>#!#<NULL>#!#<NULL>#!#1#!#0
~~END~~


-- server_principals view should not show internal role bbf_role_admin
SELECT name, type, type_desc, default_database_name, default_language_name, credential_id, owning_principal_id, is_fixed_role
FROM sys.server_principals
Expand All @@ -52,6 +62,7 @@ GO
~~START~~
varchar#!#char#!#nvarchar#!#varchar#!#varchar#!#int#!#int#!#bit
jdbc_user#!#S#!#SQL_LOGIN#!#master#!#English#!#-1#!#-1#!#0
public#!#R#!#SERVER_ROLE#!#<NULL>#!#<NULL>#!#<NULL>#!#1#!#0
sys_server_principals_vu_login_without_sa#!#S#!#SQL_LOGIN#!#master#!#English#!#-1#!#-1#!#0
sysadmin#!#R#!#SERVER_ROLE#!#<NULL>#!#English#!#<NULL>#!#1#!#1
~~END~~
Expand Down
3 changes: 3 additions & 0 deletions test/JDBC/input/sys-server_principals-vu-prepare.mix
Original file line number Diff line number Diff line change
Expand Up @@ -3,4 +3,7 @@ CREATE LOGIN sys_server_principals_vu_login_without_sa with password = '123'
GO

CREATE LOGIN sys_server_principals_vu_login_with_sa with password = '123'
GO

CREATE LOGIN [public] WITH PASSWORD = 'test';
GO
5 changes: 5 additions & 0 deletions test/JDBC/input/sys-server_principals-vu-verify.mix
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,11 @@ FROM sys.server_principals
WHERE name = 'sysadmin';
GO

SELECT name, type, type_desc, default_database_name, default_language_name, credential_id, owning_principal_id, is_fixed_role
FROM sys.server_principals
WHERE name = 'public';
GO

-- server_principals view should not show internal role bbf_role_admin
SELECT name, type, type_desc, default_database_name, default_language_name, credential_id, owning_principal_id, is_fixed_role
FROM sys.server_principals
Expand Down
8 changes: 8 additions & 0 deletions test/JDBC/input/views/sys-server_principals.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,9 +11,17 @@ FROM sys.server_principals
WHERE name = 'sysadmin';
GO

SELECT name, type, type_desc, default_database_name, default_language_name, credential_id, owning_principal_id, is_fixed_role
FROM sys.server_principals
WHERE name = 'public';
GO

CREATE LOGIN serv_principal_test WITH PASSWORD = 'test';
GO

CREATE LOGIN [public] WITH PASSWORD = 'test';
GO

SELECT name, type, type_desc, default_database_name, default_language_name
FROM sys.server_principals
WHERE name in ('jdbc_user', 'serv_principal_test') order by name;
Expand Down
17 changes: 17 additions & 0 deletions test/JDBC/sql_expected/sys-server_principals.out
Original file line number Diff line number Diff line change
Expand Up @@ -26,9 +26,26 @@ sysadmin#!#R#!#SERVER_ROLE#!#<NULL>#!#English#!#<NULL>#!#1#!#1
~~END~~


SELECT name, type, type_desc, default_database_name, default_language_name, credential_id, owning_principal_id, is_fixed_role
FROM sys.server_principals
WHERE name = 'public';
GO
~~START~~
varchar#!#char#!#nvarchar#!#varchar#!#varchar#!#int#!#int#!#bit
public#!#R#!#SERVER_ROLE#!#<NULL>#!#<NULL>#!#<NULL>#!#1#!#0
~~END~~


CREATE LOGIN serv_principal_test WITH PASSWORD = 'test';
GO

CREATE LOGIN [public] WITH PASSWORD = 'test';
GO
~~ERROR (Code: 33557097)~~

~~ERROR (Message: role name "public" is reserved)~~


SELECT name, type, type_desc, default_database_name, default_language_name
FROM sys.server_principals
WHERE name in ('jdbc_user', 'serv_principal_test') order by name;
Expand Down

0 comments on commit 239d212

Please sign in to comment.