Skip to content

Commit

Permalink
Support fixed database role db_accessadmin (#66)
Browse files Browse the repository at this point in the history
Description
For review comments see babelfish-for-postgresql#2970

Support fixed database role db_accessadmin in babelfish.
Member of db_accessadmin can do the following

CREATE SCHEMA
CREATE/DROP USER
ALTER USER
They always have connect permission
Engine PR: babelfish-for-postgresql/postgresql_modified_for_babelfish#447
Extension PR: #66
Issues Resolved
[BABEL-5136]
  • Loading branch information
tanscorpio7 authored and ANJU BHARTI committed Dec 12, 2024
1 parent e95da5e commit 13d0506
Show file tree
Hide file tree
Showing 72 changed files with 2,589 additions and 243 deletions.
15 changes: 9 additions & 6 deletions contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2204,7 +2204,7 @@ BEGIN
LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner
WHERE Ext1.database_name = DB_NAME()
AND (Ext1.type != 'R' OR Ext1.type != 'A')
AND Ext1.orig_username != 'db_owner'
AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin')
ORDER BY UserName, RoleName;
END
-- If the security account is the db fixed role - db_owner
Expand Down Expand Up @@ -2236,7 +2236,7 @@ BEGIN
WHERE Ext1.database_name = DB_NAME()
AND Ext2.database_name = DB_NAME()
AND Ext1.type = 'R'
AND Ext2.orig_username != 'db_owner'
AND Ext2.orig_username NOT IN ('db_owner', 'db_accessadmin')
AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db))
ORDER BY Role_name, Users_in_role;
END
Expand Down Expand Up @@ -2274,7 +2274,7 @@ BEGIN
LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner
WHERE Ext1.database_name = DB_NAME()
AND (Ext1.type != 'R' OR Ext1.type != 'A')
AND Ext1.orig_username != 'db_owner'
AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin')
AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db))
ORDER BY UserName, RoleName;
END
Expand Down Expand Up @@ -2435,12 +2435,15 @@ $$
BEGIN
-- Returns a list of the fixed database roles.
-- Only fixed role present in babelfish is db_owner.
IF pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IS NULL OR pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) = 'db_owner'
IF pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IS NULL OR pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin')
BEGIN
SELECT CAST('db_owner' AS sys.SYSNAME) AS DbFixedRole, CAST('DB Owners' AS sys.nvarchar(70)) AS Description;
SELECT CAST(DbFixedRole as sys.SYSNAME) AS DbFixedRole, CAST(Description AS sys.nvarchar(70)) AS Description FROM (
VALUES ('db_owner', 'DB Owners'),
('db_accessadmin', 'DB Access Administrators')) x(DbFixedRole, Description)
WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole;
END
ELSE IF pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IN (
'db_accessadmin','db_securityadmin','db_ddladmin', 'db_backupoperator',
'db_securityadmin','db_ddladmin', 'db_backupoperator',
'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter')
BEGIN
-- Return an empty result set instead of raising an error
Expand Down
8 changes: 6 additions & 2 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -259,7 +259,11 @@ CREATE OR REPLACE PROCEDURE initialize_babelfish ( sa_name VARCHAR(128) )
LANGUAGE plpgsql
AS $$
DECLARE
reserved_roles varchar[] := ARRAY['sysadmin', 'securityadmin', 'master_dbo', 'master_guest', 'master_db_owner', 'tempdb_dbo', 'tempdb_guest', 'tempdb_db_owner', 'msdb_dbo', 'msdb_guest', 'msdb_db_owner'];
reserved_roles varchar[] := ARRAY['sysadmin', 'securityadmin',
'master_dbo', 'master_guest', 'master_db_owner', 'master_db_accessadmin',
'tempdb_dbo', 'tempdb_guest', 'tempdb_db_owner', 'tempdb_db_accessadmin',
'msdb_dbo', 'msdb_guest', 'msdb_db_owner', 'msdb_db_accessadmin'];

user_id oid := -1;
db_name name := NULL;
role_name varchar;
Expand Down Expand Up @@ -456,7 +460,7 @@ ON Base.rolname = Ext.rolname
LEFT OUTER JOIN pg_catalog.pg_roles Base2
ON Ext.login_name = Base2.rolname
WHERE Ext.database_name = DB_NAME()
AND (Ext.orig_username IN ('dbo', 'db_owner', 'guest') -- system users should always be visible
AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_accessadmin', 'guest') -- system users should always be visible
OR pg_has_role(Ext.rolname, 'MEMBER')) -- Current user should be able to see users it has permission of
UNION ALL
SELECT
Expand Down
4 changes: 3 additions & 1 deletion contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4500,7 +4500,9 @@ BEGIN
END IF;
ELSIF EXISTS (SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE orig_username = role COLLATE sys.database_default)
THEN
IF EXISTS (SELECT name FROM sys.user_token WHERE name = role COLLATE sys.database_default)
IF (((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = CURRENT_USER) = 'dbo' COLLATE sys.database_default) AND role COLLATE sys.database_default IN ('db_owner', 'db_accessadmin'))
THEN RETURN 1;
ELSIF EXISTS (SELECT name FROM sys.user_token WHERE name = role COLLATE sys.database_default)
THEN RETURN 1; -- Return 1 if current session user is a member of role or windows group
ELSIF (is_windows_grp)
THEN RETURN NULL; -- Return NULL if session is not a windows auth session but argument is a windows group
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -112,6 +112,224 @@ BEGIN
END;
$$;

CREATE OR REPLACE PROCEDURE sys.create_db_roles_during_upgrade()
LANGUAGE C
AS 'babelfishpg_tsql', 'create_db_roles_during_upgrade';

CALL sys.create_db_roles_during_upgrade();

DROP PROCEDURE sys.create_db_roles_during_upgrade();


CREATE OR REPLACE FUNCTION sys.is_member(IN role sys.SYSNAME)
RETURNS INT AS
$$
DECLARE
is_windows_grp boolean := (CHARINDEX('\', role) != 0); -- ' adding quote in comment to suppress build warning
BEGIN
-- Always return 1 for 'public'
IF (role = 'public' COLLATE sys.database_default )
THEN RETURN 1;
END IF;

IF EXISTS (SELECT orig_loginname FROM sys.babelfish_authid_login_ext WHERE orig_loginname = role COLLATE sys.database_default AND type != 'S') -- do not consider sql logins
THEN
IF ((EXISTS (SELECT name FROM sys.login_token WHERE name = role COLLATE sys.database_default AND type IN ('SERVER ROLE', 'SQL LOGIN'))) OR is_windows_grp) -- do not consider sql logins, server roles
THEN RETURN NULL; -- Also return NULL if session is not a windows auth session but argument is a windows group
ELSIF EXISTS (SELECT name FROM sys.login_token WHERE name = role COLLATE sys.database_default AND type NOT IN ('SERVER ROLE', 'SQL LOGIN'))
THEN RETURN 1; -- Return 1 if current session user is a member of role or windows group
ELSE RETURN 0; -- Return 0 if current session user is not a member of role or windows group
END IF;
ELSIF EXISTS (SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE orig_username = role COLLATE sys.database_default)
THEN
IF (((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = CURRENT_USER) = 'dbo' COLLATE sys.database_default) AND role COLLATE sys.database_default IN ('db_owner', 'db_accessadmin'))
THEN RETURN 1;
ELSIF EXISTS (SELECT name FROM sys.user_token WHERE name = role COLLATE sys.database_default)
THEN RETURN 1; -- Return 1 if current session user is a member of role or windows group
ELSIF (is_windows_grp)
THEN RETURN NULL; -- Return NULL if session is not a windows auth session but argument is a windows group
ELSE RETURN 0; -- Return 0 if current session user is not a member of role or windows group
END IF;
ELSE RETURN NULL; -- Return NULL if role/group does not exist
END IF;
END;
$$
LANGUAGE plpgsql STRICT STABLE;

-- DATABASE_PRINCIPALS
CREATE OR REPLACE VIEW sys.database_principals AS
SELECT
CAST(Ext.orig_username AS SYS.SYSNAME) AS name,
CAST(Base.oid AS INT) AS principal_id,
CAST(Ext.type AS CHAR(1)) as type,
CAST(
CASE
WHEN Ext.type = 'S' THEN 'SQL_USER'
WHEN Ext.type = 'R' THEN 'DATABASE_ROLE'
WHEN Ext.type = 'U' THEN 'WINDOWS_USER'
ELSE NULL
END
AS SYS.NVARCHAR(60)) AS type_desc,
CAST(Ext.default_schema_name AS SYS.SYSNAME) AS default_schema_name,
CAST(Ext.create_date AS SYS.DATETIME) AS create_date,
CAST(Ext.modify_date AS SYS.DATETIME) AS modify_date,
CAST(Ext.owning_principal_id AS INT) AS owning_principal_id,
CAST(CAST(Base2.oid AS INT) AS SYS.VARBINARY(85)) AS SID,
CAST(Ext.is_fixed_role AS SYS.BIT) AS is_fixed_role,
CAST(Ext.authentication_type AS INT) AS authentication_type,
CAST(Ext.authentication_type_desc AS SYS.NVARCHAR(60)) AS authentication_type_desc,
CAST(Ext.default_language_name AS SYS.SYSNAME) AS default_language_name,
CAST(Ext.default_language_lcid AS INT) AS default_language_lcid,
CAST(Ext.allow_encrypted_value_modifications AS SYS.BIT) AS allow_encrypted_value_modifications
FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_user_ext AS Ext
ON Base.rolname = Ext.rolname
LEFT OUTER JOIN pg_catalog.pg_roles Base2
ON Ext.login_name = Base2.rolname
WHERE Ext.database_name = DB_NAME()
AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_accessadmin', 'guest') -- system users should always be visible
OR pg_has_role(Ext.rolname, 'MEMBER')) -- Current user should be able to see users it has permission of
UNION ALL
SELECT
CAST(name AS SYS.SYSNAME) AS name,
CAST(-1 AS INT) AS principal_id,
CAST(type AS CHAR(1)) as type,
CAST(
CASE
WHEN type = 'S' THEN 'SQL_USER'
WHEN type = 'R' THEN 'DATABASE_ROLE'
WHEN type = 'U' THEN 'WINDOWS_USER'
ELSE NULL
END
AS SYS.NVARCHAR(60)) AS type_desc,
CAST(NULL AS SYS.SYSNAME) AS default_schema_name,
CAST(NULL AS SYS.DATETIME) AS create_date,
CAST(NULL AS SYS.DATETIME) AS modify_date,
CAST(-1 AS INT) AS owning_principal_id,
CAST(CAST(0 AS INT) AS SYS.VARBINARY(85)) AS SID,
CAST(0 AS SYS.BIT) AS is_fixed_role,
CAST(-1 AS INT) AS authentication_type,
CAST(NULL AS SYS.NVARCHAR(60)) AS authentication_type_desc,
CAST(NULL AS SYS.SYSNAME) AS default_language_name,
CAST(-1 AS INT) AS default_language_lcid,
CAST(0 AS SYS.BIT) AS allow_encrypted_value_modifications
FROM (VALUES ('public', 'R'), ('sys', 'S'), ('INFORMATION_SCHEMA', 'S')) as dummy_principals(name, type);

GRANT SELECT ON sys.database_principals TO PUBLIC;

CREATE OR REPLACE PROCEDURE sys.sp_helpuser("@name_in_db" sys.SYSNAME = NULL) AS
$$
BEGIN
-- If security account is not specified, return info about all users
IF @name_in_db IS NULL
BEGIN
SELECT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'UserName',
CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN 'db_owner'
WHEN Ext2.orig_username IS NULL THEN 'public'
ELSE Ext2.orig_username END
AS SYS.SYSNAME) AS 'RoleName',
CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN Base4.rolname COLLATE database_default
ELSE LogExt.orig_loginname END
AS SYS.SYSNAME) AS 'LoginName',
CAST(LogExt.default_database_name AS SYS.SYSNAME) AS 'DefDBName',
CAST(Ext1.default_schema_name AS SYS.SYSNAME) AS 'DefSchemaName',
CAST(Base1.oid AS INT) AS 'UserID',
CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN CAST(Base4.oid AS INT)
WHEN Ext1.orig_username = 'guest' THEN CAST(0 AS INT)
ELSE CAST(Base3.oid AS INT) END
AS SYS.VARBINARY(85)) AS 'SID'
FROM sys.babelfish_authid_user_ext AS Ext1
INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.rolname = Ext1.rolname
LEFT OUTER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base1.oid = Authmbr.member
LEFT OUTER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.roleid
LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext2 ON Base2.rolname = Ext2.rolname
LEFT OUTER JOIN sys.babelfish_authid_login_ext As LogExt ON LogExt.rolname = Ext1.login_name
LEFT OUTER JOIN pg_catalog.pg_roles AS Base3 ON Base3.rolname = LogExt.rolname
LEFT OUTER JOIN sys.babelfish_sysdatabases AS Bsdb ON Bsdb.name = DB_NAME()
LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner
WHERE Ext1.database_name = DB_NAME()
AND (Ext1.type != 'R' OR Ext1.type != 'A')
AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin')
ORDER BY UserName, RoleName;
END
-- If the security account is the db fixed role - db_owner
ELSE IF @name_in_db = 'db_owner'
BEGIN
-- TODO: Need to change after we can add/drop members to/from db_owner
SELECT CAST('db_owner' AS SYS.SYSNAME) AS 'Role_name',
ROLE_ID('db_owner') AS 'Role_id',
CAST('dbo' AS SYS.SYSNAME) AS 'Users_in_role',
USER_ID('dbo') AS 'Userid';
END
-- If the security account is a db role
ELSE IF EXISTS (SELECT 1
FROM sys.babelfish_authid_user_ext
WHERE (orig_username = @name_in_db
OR pg_catalog.lower(orig_username) = pg_catalog.lower(@name_in_db))
AND database_name = DB_NAME()
AND type = 'R')
BEGIN
SELECT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'Role_name',
CAST(Base1.oid AS INT) AS 'Role_id',
CAST(Ext2.orig_username AS SYS.SYSNAME) AS 'Users_in_role',
CAST(Base2.oid AS INT) AS 'Userid'
FROM sys.babelfish_authid_user_ext AS Ext2
INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.rolname = Ext2.rolname
INNER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base2.oid = Authmbr.member
LEFT OUTER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid
LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext1 ON Base1.rolname = Ext1.rolname
WHERE Ext1.database_name = DB_NAME()
AND Ext2.database_name = DB_NAME()
AND Ext1.type = 'R'
AND Ext2.orig_username NOT IN ('db_owner', 'db_accessadmin')
AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db))
ORDER BY Role_name, Users_in_role;
END
-- If the security account is a user
ELSE IF EXISTS (SELECT 1
FROM sys.babelfish_authid_user_ext
WHERE (orig_username = @name_in_db
OR pg_catalog.lower(orig_username) = pg_catalog.lower(@name_in_db))
AND database_name = DB_NAME()
AND type != 'R')
BEGIN
SELECT DISTINCT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'UserName',
CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN 'db_owner'
WHEN Ext2.orig_username IS NULL THEN 'public'
ELSE Ext2.orig_username END
AS SYS.SYSNAME) AS 'RoleName',
CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN Base4.rolname COLLATE database_default
ELSE LogExt.orig_loginname END
AS SYS.SYSNAME) AS 'LoginName',
CAST(LogExt.default_database_name AS SYS.SYSNAME) AS 'DefDBName',
CAST(Ext1.default_schema_name AS SYS.SYSNAME) AS 'DefSchemaName',
CAST(Base1.oid AS INT) AS 'UserID',
CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN CAST(Base4.oid AS INT)
WHEN Ext1.orig_username = 'guest' THEN CAST(0 AS INT)
ELSE CAST(Base3.oid AS INT) END
AS SYS.VARBINARY(85)) AS 'SID'
FROM sys.babelfish_authid_user_ext AS Ext1
INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.rolname = Ext1.rolname
LEFT OUTER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base1.oid = Authmbr.member
LEFT OUTER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.roleid
LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext2 ON Base2.rolname = Ext2.rolname
LEFT OUTER JOIN sys.babelfish_authid_login_ext As LogExt ON LogExt.rolname = Ext1.login_name
LEFT OUTER JOIN pg_catalog.pg_roles AS Base3 ON Base3.rolname = LogExt.rolname
LEFT OUTER JOIN sys.babelfish_sysdatabases AS Bsdb ON Bsdb.name = DB_NAME()
LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner
WHERE Ext1.database_name = DB_NAME()
AND (Ext1.type != 'R' OR Ext1.type != 'A')
AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin')
AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db))
ORDER BY UserName, RoleName;
END
-- If the security account is not valid
ELSE
RAISERROR ( 'The name supplied (%s) is not a user, role, or aliased login.', 16, 1, @name_in_db);
END;
$$
LANGUAGE 'pltsql';
GRANT EXECUTE on PROCEDURE sys.sp_helpuser TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.bbf_is_member_of_role_nosuper(OID, OID)
RETURNS BOOLEAN AS 'babelfishpg_tsql', 'bbf_is_member_of_role_nosuper'
LANGUAGE C STABLE STRICT PARALLEL SAFE;
Expand Down Expand Up @@ -1498,12 +1716,15 @@ $$
BEGIN
-- Returns a list of the fixed database roles.
-- Only fixed role present in babelfish is db_owner.
IF pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IS NULL OR pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) = 'db_owner'
IF pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IS NULL OR pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin')
BEGIN
SELECT CAST('db_owner' AS sys.SYSNAME) AS DbFixedRole, CAST('DB Owners' AS sys.nvarchar(70)) AS Description;
SELECT CAST(DbFixedRole as sys.SYSNAME) AS DbFixedRole, CAST(Description AS sys.nvarchar(70)) AS Description FROM (
VALUES ('db_owner', 'DB Owners'),
('db_accessadmin', 'DB Access Administrators')) x(DbFixedRole, Description)
WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole;
END
ELSE IF pg_catalog.lower(PG_CATALOG.RTRIM(@rolename)) IN (
'db_accessadmin','db_securityadmin','db_ddladmin', 'db_backupoperator',
'db_securityadmin','db_ddladmin', 'db_backupoperator',
'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter')
BEGIN
-- Return an empty result set instead of raising an error
Expand Down
Loading

0 comments on commit 13d0506

Please sign in to comment.