Skip to content

Commit

Permalink
Merge pull request #3769 from mathesar-foundation/roles_add
Browse files Browse the repository at this point in the history
Implement `roles.add` RPC endpoint
  • Loading branch information
pavish authored Aug 23, 2024
2 parents 02f0509 + cb02642 commit 1a44405
Show file tree
Hide file tree
Showing 10 changed files with 294 additions and 86 deletions.
5 changes: 5 additions & 0 deletions db/roles/operations/create.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
from db.connection import exec_msar_func


def create_role(rolename, password, login, conn):
return exec_msar_func(conn, 'create_role', rolename, password, login).fetchone()[0]
4 changes: 2 additions & 2 deletions db/roles/operations/select.py
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
from db.connection import exec_msar_func


def get_roles(conn):
return exec_msar_func(conn, 'get_roles').fetchone()[0]
def list_roles(conn):
return exec_msar_func(conn, 'list_roles').fetchone()[0]


def list_db_priv(db_name, conn):
Expand Down
149 changes: 98 additions & 51 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -897,7 +897,49 @@ FROM (
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION msar.get_roles() RETURNS jsonb AS $$/*
CREATE OR REPLACE FUNCTION msar.role_info_table() RETURNS TABLE
(
oid oid, -- The OID of the role.
name name, -- Name of the role.
super boolean, -- Whether the role has SUPERUSER status.
inherits boolean, -- Whether the role has INHERIT attribute.
create_role boolean, -- Whether the role has CREATEROLE attribute.
create_db boolean, -- Whether the role has CREATEDB attribute.
login boolean, -- Whether the role has LOGIN attribute.
description text, -- A description of the role
members jsonb -- The member roles that *directly* inherit the role.
) AS $$/*
Returns a table describing all the roles present on the database server.
*/
WITH rolemembers as (
SELECT
pgr.oid AS oid,
jsonb_agg(
jsonb_build_object(
'oid', pgm.member::bigint,
'admin', pgm.admin_option
)
) AS members
FROM pg_catalog.pg_roles pgr
INNER JOIN pg_catalog.pg_auth_members pgm ON pgr.oid=pgm.roleid
GROUP BY pgr.oid
)
SELECT
r.oid::bigint AS oid,
r.rolname AS name,
r.rolsuper AS super,
r.rolinherit AS inherits,
r.rolcreaterole AS create_role,
r.rolcreatedb AS create_db,
r.rolcanlogin AS login,
pg_catalog.shobj_description(r.oid, 'pg_authid') AS description,
rolemembers.members AS members
FROM pg_catalog.pg_roles r
LEFT OUTER JOIN rolemembers ON r.oid = rolemembers.oid;
$$ LANGUAGE SQL STABLE;


CREATE OR REPLACE FUNCTION msar.list_roles() RETURNS jsonb AS $$/*
Return a json array of objects with the list of roles in a database server,
excluding pg system roles.
Expand All @@ -916,35 +958,33 @@ Each returned JSON object in the array has the form:
]|null>
}
*/
WITH rolemembers as (
SELECT
pgr.oid AS oid,
jsonb_agg(
jsonb_build_object(
'oid', pgm.member::bigint,
'admin', pgm.admin_option
)
) AS members
FROM pg_catalog.pg_roles pgr
INNER JOIN pg_catalog.pg_auth_members pgm ON pgr.oid=pgm.roleid
GROUP BY pgr.oid
)
SELECT jsonb_agg(role_data)
FROM (
SELECT
r.oid::bigint AS oid,
r.rolname AS name,
r.rolsuper AS super,
r.rolinherit AS inherits,
r.rolcreaterole AS create_role,
r.rolcreatedb AS create_db,
r.rolcanlogin AS login,
pg_catalog.shobj_description(r.oid, 'pg_authid') AS description,
rolemembers.members AS members
FROM pg_catalog.pg_roles r
LEFT OUTER JOIN rolemembers ON r.oid = rolemembers.oid
WHERE r.rolname NOT LIKE 'pg_%'
) AS role_data;
FROM msar.role_info_table() AS role_data
WHERE role_data.name NOT LIKE 'pg_%';
$$ LANGUAGE SQL STABLE;


CREATE OR REPLACE FUNCTION msar.get_role(rolename text) RETURNS jsonb AS $$/*
Given a rolename, return a JSON object describing the role in a database server.
The returned JSON object has the form:
{
"oid": <int>
"name": <str>
"super": <bool>
"inherits": <bool>
"create_role": <bool>
"create_db": <bool>
"login": <bool>
"description": <str|null>
"members": <[
{ "oid": <int>, "admin": <bool> }
]|null>
}
*/
SELECT to_jsonb(role_data)
FROM msar.role_info_table() AS role_data
WHERE role_data.name = rolename;
$$ LANGUAGE SQL STABLE;


Expand Down Expand Up @@ -1008,33 +1048,40 @@ $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;
----------------------------------------------------------------------------------------------------


-- Create mathesar user ----------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION
msar.create_role(rolename text, password_ text, login_ boolean) RETURNS jsonb AS $$/*
Creates a login/non-login role, depending on whether the login_ flag is set.
Only the rolename field is required, the password field is required only if login_ is set to true.
Returns a JSON object describing the created role in the form:
{
"oid": <int>
"name": <str>
"super": <bool>
"inherits": <bool>
"create_role": <bool>
"create_db": <bool>
"login": <bool>
"description": <str|null>
"members": <[
{ "oid": <int>, "admin": <bool> }
]|null>
}
CREATE OR REPLACE FUNCTION
msar.create_basic_mathesar_user(username text, password_ text) RETURNS TEXT AS $$/*
Args:
rolename: The name of the role to be created, unquoted.
password_: The password for the rolename to set, unquoted.
login_: Specify whether the role to be created could login.
*/
DECLARE
sch_name text;
mathesar_schemas text[] := ARRAY['mathesar_types', '__msar', 'msar'];
BEGIN
PERFORM __msar.exec_ddl('CREATE USER %I WITH PASSWORD %L', username, password_);
PERFORM __msar.exec_ddl(
'GRANT CREATE, CONNECT, TEMP ON DATABASE %I TO %I',
current_database()::text,
username
);
FOREACH sch_name IN ARRAY mathesar_schemas LOOP
BEGIN
PERFORM __msar.exec_ddl('GRANT USAGE ON SCHEMA %I TO %I', sch_name, username);
EXCEPTION
WHEN invalid_schema_name THEN
RAISE NOTICE 'Schema % does not exist', sch_name;
END;
END LOOP;
RETURN username;
CASE WHEN login_ THEN
EXECUTE format('CREATE USER %I WITH PASSWORD %L', rolename, password_);
ELSE
EXECUTE format('CREATE ROLE %I', rolename);
END CASE;
RETURN msar.get_role(rolename);
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;
$$ LANGUAGE plpgsql;


----------------------------------------------------------------------------------------------------
Expand Down
40 changes: 18 additions & 22 deletions db/sql/test_00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2273,24 +2273,20 @@ END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_create_basic_mathesar_user() RETURNS SETOF TEXT AS $$
CREATE OR REPLACE FUNCTION test_create_role() RETURNS SETOF TEXT AS $$
BEGIN
PERFORM msar.create_basic_mathesar_user('testuser', 'mypass1234');
RETURN NEXT database_privs_are (
'mathesar_testing', 'testuser', ARRAY['CREATE', 'CONNECT', 'TEMPORARY']
);
RETURN NEXT schema_privs_are ('msar', 'testuser', ARRAY['USAGE']);
RETURN NEXT schema_privs_are ('__msar', 'testuser', ARRAY['USAGE']);
PERFORM msar.create_basic_mathesar_user(
'Ro"\bert''); DROP SCHEMA public;', 'my''pass1234"; DROP SCHEMA public;'
PERFORM msar.create_role('testuser', 'mypass1234', true);
RETURN NEXT database_privs_are('mathesar_testing', 'testuser', ARRAY['CONNECT', 'TEMPORARY']);
PERFORM msar.create_role(
'Ro"\bert''); DROP SCHEMA public;', 'my''pass1234"; DROP SCHEMA public;', true
);
RETURN NEXT has_schema('public');
RETURN NEXT has_user('Ro"\bert''); DROP SCHEMA public;');
RETURN NEXT database_privs_are (
'mathesar_testing', 'Ro"\bert''); DROP SCHEMA public;', ARRAY['CREATE', 'CONNECT', 'TEMPORARY']
'mathesar_testing', 'Ro"\bert''); DROP SCHEMA public;', ARRAY['CONNECT', 'TEMPORARY']
);
RETURN NEXT schema_privs_are ('msar', 'Ro"\bert''); DROP SCHEMA public;', ARRAY['USAGE']);
RETURN NEXT schema_privs_are ('__msar', 'Ro"\bert''); DROP SCHEMA public;', ARRAY['USAGE']);
PERFORM msar.create_role('testnopass', null, null);
RETURN NEXT database_privs_are('mathesar_testing', 'testnopass', ARRAY['CONNECT', 'TEMPORARY']);
END;
$$ LANGUAGE plpgsql;

Expand Down Expand Up @@ -2806,18 +2802,18 @@ END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_get_roles() RETURNS SETOF TEXT AS $$
CREATE OR REPLACE FUNCTION test_list_roles() RETURNS SETOF TEXT AS $$
DECLARE
initial_role_count int;
foo_role jsonb;
bar_role jsonb;
BEGIN
SELECT jsonb_array_length(msar.get_roles()) INTO initial_role_count;
SELECT jsonb_array_length(msar.list_roles()) INTO initial_role_count;

-- Create role and check if role is present in response & count is increased
CREATE ROLE foo;
RETURN NEXT is(jsonb_array_length(msar.get_roles()), initial_role_count + 1);
SELECT jsonb_path_query(msar.get_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
RETURN NEXT is(jsonb_array_length(msar.list_roles()), initial_role_count + 1);
SELECT jsonb_path_query(msar.list_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;

-- Check if role has expected properties
RETURN NEXT is(jsonb_typeof(foo_role), 'object');
Expand All @@ -2831,7 +2827,7 @@ BEGIN

-- Modify properties and check role again
ALTER ROLE foo WITH CREATEDB CREATEROLE LOGIN NOINHERIT;
SELECT jsonb_path_query(msar.get_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
SELECT jsonb_path_query(msar.list_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
RETURN NEXT is((foo_role->>'super')::boolean, false);
RETURN NEXT is((foo_role->>'inherits')::boolean, false);
RETURN NEXT is((foo_role->>'create_role')::boolean, true);
Expand All @@ -2840,15 +2836,15 @@ BEGIN

-- Add comment and check if comment is present
COMMENT ON ROLE foo IS 'A test role';
SELECT jsonb_path_query(msar.get_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
SELECT jsonb_path_query(msar.list_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
RETURN NEXT is(foo_role->'description'#>>'{}', 'A test role');

-- Add members and check result
CREATE ROLE bar;
GRANT foo TO bar;
RETURN NEXT is(jsonb_array_length(msar.get_roles()), initial_role_count + 2);
SELECT jsonb_path_query(msar.get_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
SELECT jsonb_path_query(msar.get_roles(), '$[*] ? (@.name == "bar")') INTO bar_role;
RETURN NEXT is(jsonb_array_length(msar.list_roles()), initial_role_count + 2);
SELECT jsonb_path_query(msar.list_roles(), '$[*] ? (@.name == "foo")') INTO foo_role;
SELECT jsonb_path_query(msar.list_roles(), '$[*] ? (@.name == "bar")') INTO bar_role;
RETURN NEXT is(jsonb_typeof(foo_role->'members'), 'array');
RETURN NEXT is(
foo_role->'members'->0->>'oid', bar_role->>'oid'
Expand All @@ -2857,7 +2853,7 @@ BEGIN

-- Drop role and ensure role is not present in response
DROP ROLE foo;
RETURN NEXT ok(NOT jsonb_path_exists(msar.get_roles(), '$[*] ? (@.name == "foo")'));
RETURN NEXT ok(NOT jsonb_path_exists(msar.list_roles(), '$[*] ? (@.name == "foo")'));
END;
$$ LANGUAGE plpgsql;

Expand Down
6 changes: 3 additions & 3 deletions db/tests/roles/operations/test_select.py
Original file line number Diff line number Diff line change
Expand Up @@ -2,9 +2,9 @@
from db.roles.operations import select as ma_sel


def test_get_roles():
def test_list_roles():
with patch.object(ma_sel, 'exec_msar_func') as mock_exec:
mock_exec.return_value.fetchone = lambda: ('a', 'b')
result = ma_sel.get_roles('conn')
mock_exec.assert_called_once_with('conn', 'get_roles')
result = ma_sel.list_roles('conn')
mock_exec.assert_called_once_with('conn', 'list_roles')
assert result == 'a'
1 change: 1 addition & 0 deletions docs/docs/api/rpc.md
Original file line number Diff line number Diff line change
Expand Up @@ -230,6 +230,7 @@ To use an RPC function:
options:
members:
- list_
- add
- RoleInfo
- RoleMember

Expand Down
55 changes: 49 additions & 6 deletions mathesar/rpc/roles.py
Original file line number Diff line number Diff line change
Expand Up @@ -8,12 +8,13 @@

from mathesar.rpc.exceptions.handlers import handle_rpc_exceptions
from mathesar.rpc.utils import connect
from db.roles.operations.select import get_roles
from db.roles.operations.select import list_roles
from db.roles.operations.create import create_role


class RoleMember(TypedDict):
"""
Information about a member role of an inherited role.
Information about a member role of a directly inherited role.
Attributes:
oid: The OID of the member role.
Expand All @@ -36,7 +37,7 @@ class RoleInfo(TypedDict):
create_db: Whether the role has CREATEDB attribute.
login: Whether the role has LOGIN attribute.
description: A description of the role
members: The member roles that inherit the role.
members: The member roles that directly inherit the role.
Refer PostgreSQL documenation on:
- [pg_roles table](https://www.postgresql.org/docs/current/view-pg-roles.html).
Expand All @@ -53,6 +54,20 @@ class RoleInfo(TypedDict):
description: Optional[str]
members: Optional[list[RoleMember]]

@classmethod
def from_dict(cls, d):
return cls(
oid=d["oid"],
name=d["name"],
super=d["super"],
inherits=d["inherits"],
create_role=d["create_role"],
create_db=d["create_db"],
login=d["login"],
description=d["description"],
members=d["members"]
)


@rpc_method(name="roles.list")
@http_basic_auth_login_required
Expand All @@ -63,13 +78,41 @@ def list_(*, database_id: int, **kwargs) -> list[RoleInfo]:
Requires a database id inorder to connect to the server.
Args:
database_id: The Django id of the database containing the table.
database_id: The Django id of the database.
Returns:
A list of roles present on the database server.
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
roles = get_roles(conn)
roles = list_roles(conn)
return [RoleInfo.from_dict(role) for role in roles]


@rpc_method(name="roles.add")
@http_basic_auth_login_required
@handle_rpc_exceptions
def add(
*,
rolename: str,
database_id: int,
password: str = None,
login: bool = None,
**kwargs
) -> RoleInfo:
"""
Add a new login/non-login role on a database server.
return roles
Args:
rolename: The name of the role to be created.
database_id: The Django id of the database.
password: The password for the rolename to set.
login: Whether the role to be created could login.
Returns:
A dict describing the created role.
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
role = create_role(rolename, password, login, conn)
return RoleInfo.from_dict(role)
Loading

0 comments on commit 1a44405

Please sign in to comment.