Skip to content

Commit

Permalink
Support db_datareader/db_datawriter (#68)
Browse files Browse the repository at this point in the history
### Description
Implement database roles `db_datareader` and `db_datawriter` 

* Members of the db_datareader fixed database role can read all data from all user tables and views. User objects can exist in any schema except sys and INFORMATION_SCHEMA.
* Members of the db_datawriter fixed database role can add, delete, or change data in all user tables. In most use cases, this role is combined with db_datareader membership to allow reading the data that is to be modified.

Engine PR: amazon-aurora/postgresql_modified_for_babelfish#98

### Issues Resolved
Task: [BABEL-3883](https://jira.rds.a2z.com/browse/BABEL-3883)
Signed-off-by: Shalini Lohia <[email protected]>
  • Loading branch information
shalinilohia50 authored Oct 23, 2024
1 parent 4cc60db commit f945d2f
Show file tree
Hide file tree
Showing 74 changed files with 7,234 additions and 84 deletions.
19 changes: 12 additions & 7 deletions contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1254,7 +1254,9 @@ FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.column_privileges t5 ON t1.relname = t5.table_name AND t2.nspname = t5.table_schema
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name;
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t5.grantee
WHERE ext.orig_username NOT IN ('db_datawriter', 'db_datareader');
GRANT SELECT ON sys.sp_column_privileges_view TO PUBLIC;
CREATE OR REPLACE PROCEDURE sys.sp_column_privileges(
Expand Down Expand Up @@ -1362,7 +1364,8 @@ FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name
WHERE t4.privilege_type = 'DELETE';
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t4.grantee
WHERE t4.privilege_type = 'DELETE' AND ext.orig_username != 'db_datawriter';
GRANT SELECT on sys.sp_table_privileges_view TO PUBLIC;
CREATE OR REPLACE PROCEDURE sys.sp_table_privileges(
Expand Down Expand Up @@ -2118,7 +2121,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 NOT IN ('db_owner', 'db_accessadmin')
AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
ORDER BY UserName, RoleName;
END
-- If the security account is the db fixed role - db_owner
Expand Down Expand Up @@ -2150,7 +2153,7 @@ BEGIN
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 Ext2.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
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 @@ -2188,7 +2191,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 NOT IN ('db_owner', 'db_accessadmin')
AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
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 @@ -2348,11 +2351,13 @@ CREATE OR REPLACE PROCEDURE sys.sp_helpdbfixedrole("@rolename" sys.SYSNAME = NUL
$$
BEGIN
-- Returns a list of the fixed database roles.
IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin')
IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
BEGIN
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)
('db_accessadmin', 'DB Access Administrators'),
('db_datareader', 'DB Data Reader'),
('db_datawriter', 'DB Data Writer')) x(DbFixedRole, Description)
WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole;
END
ELSE IF LOWER(RTRIM(@rolename)) IN (
Expand Down
8 changes: 4 additions & 4 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -260,9 +260,9 @@ LANGUAGE plpgsql
AS $$
DECLARE
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'];
'master_dbo', 'master_guest', 'master_db_owner', 'master_db_accessadmin', 'master_db_datareader', 'master_db_datawriter',
'tempdb_dbo', 'tempdb_guest', 'tempdb_db_owner', 'tempdb_db_accessadmin', 'tempdb_db_datareader', 'tempdb_db_datawriter',
'msdb_dbo', 'msdb_guest', 'msdb_db_owner', 'msdb_db_accessadmin', 'msdb_db_datareader', 'msdb_db_datawriter'];

user_id oid := -1;
db_name name := NULL;
Expand Down Expand Up @@ -460,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', 'db_accessadmin', 'guest') -- system users should always be visible
AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter', '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
2 changes: 1 addition & 1 deletion contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4501,7 +4501,7 @@ BEGIN
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'))
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', 'db_datareader', 'db_datawriter'))
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
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -1261,7 +1261,7 @@ BEGIN
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'))
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', 'db_datareader', 'db_datawriter'))
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
Expand Down Expand Up @@ -1896,6 +1896,103 @@ BEGIN
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE VIEW sys.sp_column_privileges_view AS
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST(COALESCE(SPLIT_PART(t6.attoptions[1], '=', 2), t5.column_name) AS sys.sysname) AS COLUMN_NAME,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t5.grantor::name) AS sys.sysname) AS GRANTOR,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t5.grantee::name) AS sys.sysname) AS GRANTEE,
CAST(t5.privilege_type AS sys.varchar(32)) COLLATE sys.database_default AS PRIVILEGE,
CAST(t5.is_grantable AS sys.varchar(3)) COLLATE sys.database_default AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.column_privileges t5 ON t1.relname = t5.table_name AND t2.nspname = t5.table_schema
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t5.grantee
WHERE ext.orig_username NOT IN ('db_datawriter', 'db_datareader');

CREATE OR REPLACE PROCEDURE sys.sp_column_privileges(
"@table_name" sys.sysname,
"@table_owner" sys.sysname = '',
"@table_qualifier" sys.sysname = '',
"@column_name" sys.nvarchar(384) = ''
)
AS $$
BEGIN
IF (@table_qualifier != '') AND (LOWER(@table_qualifier) != LOWER(sys.db_name()))
BEGIN
THROW 33557097, N'The database name component of the object qualifier must be the name of the current database.', 1;
END

IF (COALESCE(@table_owner, '') = '')
BEGIN

IF EXISTS (
SELECT * FROM sys.sp_column_privileges_view
WHERE LOWER(@table_name) = LOWER(table_name) and LOWER(SCHEMA_NAME()) = LOWER(table_qualifier)
)
BEGIN
SELECT
TABLE_QUALIFIER,
TABLE_OWNER,
TABLE_NAME,
COLUMN_NAME,
GRANTOR,
GRANTEE,
PRIVILEGE,
IS_GRANTABLE
FROM sys.sp_column_privileges_view
WHERE LOWER(@table_name) = LOWER(table_name)
AND (LOWER(SCHEMA_NAME()) = LOWER(table_owner))
AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier))
AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name))
ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee;
END
ELSE
BEGIN
SELECT
TABLE_QUALIFIER,
TABLE_OWNER,
TABLE_NAME,
COLUMN_NAME,
GRANTOR,
GRANTEE,
PRIVILEGE,
IS_GRANTABLE
FROM sys.sp_column_privileges_view
WHERE LOWER(@table_name) = LOWER(table_name)
AND (LOWER('dbo')= LOWER(table_owner))
AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier))
AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name))
ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee;
END
END
ELSE
BEGIN
SELECT
TABLE_QUALIFIER,
TABLE_OWNER,
TABLE_NAME,
COLUMN_NAME,
GRANTOR,
GRANTEE,
PRIVILEGE,
IS_GRANTABLE
FROM sys.sp_column_privileges_view
WHERE LOWER(@table_name) = LOWER(table_name)
AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(table_owner) = LOWER(@table_owner))
AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier))
AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name))
ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee;
END
END;
$$
LANGUAGE 'pltsql';
GRANT EXECUTE ON PROCEDURE sys.sp_column_privileges TO PUBLIC;

CREATE OR REPLACE VIEW sys.sp_table_privileges_view AS
-- Will use sp_column_priivleges_view to get information from SELECT, INSERT and REFERENCES (only need permission from 1 column in table)
SELECT DISTINCT
Expand All @@ -1922,7 +2019,56 @@ FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name
WHERE t4.privilege_type = 'DELETE';
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t4.grantee
WHERE t4.privilege_type = 'DELETE' AND ext.orig_username != 'db_datawriter';

CREATE OR REPLACE PROCEDURE sys.sp_table_privileges(
"@table_name" sys.nvarchar(384),
"@table_owner" sys.nvarchar(384) = '',
"@table_qualifier" sys.sysname = '',
"@fusepattern" sys.bit = 1
)
AS $$
BEGIN

IF (@table_qualifier != '') AND (LOWER(@table_qualifier) != LOWER(sys.db_name()))
BEGIN
THROW 33557097, N'The database name component of the object qualifier must be the name of the current database.', 1;
END

IF @fusepattern = 1
BEGIN
SELECT
TABLE_QUALIFIER,
TABLE_OWNER,
TABLE_NAME,
GRANTOR,
GRANTEE,
PRIVILEGE,
IS_GRANTABLE FROM sys.sp_table_privileges_view
WHERE LOWER(TABLE_NAME) LIKE LOWER(@table_name)
AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) LIKE LOWER(@table_owner))
ORDER BY table_qualifier, table_owner, table_name, privilege, grantee;
END
ELSE
BEGIN
SELECT
TABLE_QUALIFIER,
TABLE_OWNER,
TABLE_NAME,
GRANTOR,
GRANTEE,
PRIVILEGE,
IS_GRANTABLE FROM sys.sp_table_privileges_view
WHERE LOWER(TABLE_NAME) = LOWER(@table_name)
AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) = LOWER(@table_owner))
ORDER BY table_qualifier, table_owner, table_name, privilege, grantee;
END

END;
$$
LANGUAGE 'pltsql';
GRANT EXECUTE ON PROCEDURE sys.sp_table_privileges TO PUBLIC;

CREATE OR REPLACE PROCEDURE sys.sp_helpuser("@name_in_db" sys.SYSNAME = NULL) AS
$$
Expand Down Expand Up @@ -4257,7 +4403,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', 'db_accessadmin', 'guest') -- system users should always be visible
AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter', '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 Expand Up @@ -4290,11 +4436,13 @@ CREATE OR REPLACE PROCEDURE sys.sp_helpdbfixedrole("@rolename" sys.SYSNAME = NUL
$$
BEGIN
-- Returns a list of the fixed database roles.
IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin')
IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
BEGIN
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)
('db_accessadmin', 'DB Access Administrators'),
('db_datareader', 'DB Data Reader'),
('db_datawriter', 'DB Data Writer')) x(DbFixedRole, Description)
WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole;
END
ELSE IF LOWER(RTRIM(@rolename)) IN (
Expand Down Expand Up @@ -4345,7 +4493,7 @@ BEGIN
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 NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
ORDER BY UserName, RoleName;
END
-- If the security account is the db fixed role - db_owner
Expand Down Expand Up @@ -4378,7 +4526,7 @@ BEGIN
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 Ext2.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
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 @@ -4417,7 +4565,7 @@ BEGIN
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 NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')
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
4 changes: 2 additions & 2 deletions contrib/babelfishpg_tsql/src/catalog.c
Original file line number Diff line number Diff line change
Expand Up @@ -4244,7 +4244,7 @@ grant_perms_to_objects_in_schema(const char *schema_name,

/* do this step */
ProcessUtility(wrapper,
"(GRANT STATEMENT )",
INTERNAL_GRANT_STATEMENT,
false,
PROCESS_UTILITY_SUBCOMMAND,
NULL,
Expand Down Expand Up @@ -4342,7 +4342,7 @@ exec_internal_grant_on_function(const char *logicalschema,

/* do this step */
ProcessUtility(wrapper,
"(GRANT STATEMENT )",
INTERNAL_GRANT_STATEMENT,
false,
PROCESS_UTILITY_SUBCOMMAND,
NULL,
Expand Down
Loading

0 comments on commit f945d2f

Please sign in to comment.