Skip to content

Commit

Permalink
Merge pull request #3833 from mathesar-foundation/sch_tab_transfer_ow…
Browse files Browse the repository at this point in the history
…nership

Implement `transfer_ownership` for schemas and tables
  • Loading branch information
pavish authored Sep 16, 2024
2 parents b2a5051 + 7676701 commit 57d7246
Show file tree
Hide file tree
Showing 11 changed files with 297 additions and 39 deletions.
8 changes: 8 additions & 0 deletions db/roles/operations/ownership.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,3 +3,11 @@

def transfer_database_ownership(new_owner_oid, conn):
return exec_msar_func(conn, 'transfer_database_ownership', new_owner_oid).fetchone()[0]


def transfer_schema_ownership(schema_oid, new_owner_oid, conn):
return exec_msar_func(conn, 'transfer_schema_ownership', schema_oid, new_owner_oid).fetchone()[0]


def transfer_table_ownership(table_oid, new_owner_oid, conn):
return exec_msar_func(conn, 'transfer_table_ownership', table_oid, new_owner_oid).fetchone()[0]
4 changes: 2 additions & 2 deletions db/schemas/operations/select.py
Original file line number Diff line number Diff line change
Expand Up @@ -6,8 +6,8 @@
from db.connection import exec_msar_func


def get_schemas(conn):
return exec_msar_func(conn, 'get_schemas').fetchone()[0]
def list_schemas(conn):
return exec_msar_func(conn, 'list_schemas').fetchone()[0]


def reflect_schema(engine, name=None, oid=None, metadata=None):
Expand Down
134 changes: 107 additions & 27 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -918,7 +918,7 @@ SELECT jsonb_build_object(
'name', relname,
'schema', relnamespace::bigint,
'description', msar.obj_description(oid, 'pg_class'),
'owner_oid', relowner,
'owner_oid', relowner::bigint,
'current_role_priv', msar.list_table_privileges_for_current_role(tab_id),
'current_role_owns', pg_catalog.pg_has_role(relowner, 'USAGE')
) FROM pg_catalog.pg_class WHERE oid = tab_id;
Expand Down Expand Up @@ -949,7 +949,7 @@ SELECT coalesce(
'name', pgc.relname,
'schema', pgc.relnamespace::bigint,
'description', msar.obj_description(pgc.oid, 'pg_class'),
'owner_oid', pgc.relowner,
'owner_oid', pgc.relowner::bigint,
'current_role_priv', msar.list_table_privileges_for_current_role(pgc.oid),
'current_role_owns', pg_catalog.pg_has_role(pgc.relowner, 'USAGE')
)
Expand All @@ -976,7 +976,36 @@ WHERE has_privilege;
$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_schemas() RETURNS jsonb AS $$/*
CREATE OR REPLACE FUNCTION msar.schema_info_table() RETURNS TABLE
(
oid bigint, -- The OID of the schema.
name name, -- Name of the role.
description text, -- The description of the schema on the database.
owner_oid bigint, -- The owner of the schema.
current_role_priv jsonb, -- Privileges of the current role on the schema.
current_role_owns boolean, -- Whether the current role owns the schema.
table_count integer -- The number of tables in the schema.
) AS $$
SELECT
s.oid::bigint AS oid,
s.nspname AS name,
pg_catalog.obj_description(s.oid) AS description,
s.nspowner::bigint AS owner_oid,
msar.list_schema_privileges_for_current_role(s.oid) AS current_role_priv,
pg_catalog.pg_has_role(s.nspowner, 'USAGE') AS current_role_owns,
COALESCE(count(c.oid), 0) AS table_count
FROM pg_catalog.pg_namespace s
LEFT JOIN pg_catalog.pg_class c ON c.relnamespace = s.oid AND c.relkind = 'r'
GROUP BY
s.oid,
s.nspname,
s.nspowner;
-- Filter on relkind so that we only count tables. This must be done in the ON clause so that
-- we still get a row for schemas with no tables.
$$ LANGUAGE SQL STABLE;


CREATE OR REPLACE FUNCTION msar.list_schemas() RETURNS jsonb AS $$/*
Return a json array of objects describing the user-defined schemas in the database.
PostgreSQL system schemas are ignored.
Expand All @@ -997,30 +1026,30 @@ Each returned JSON object in the array will have the form:
}
*/
SELECT jsonb_agg(schema_data)
FROM (
SELECT
s.oid::bigint AS oid,
s.nspname AS name,
pg_catalog.obj_description(s.oid) AS description,
s.nspowner::bigint AS owner_oid,
msar.list_schema_privileges_for_current_role(s.oid) AS current_role_priv,
pg_catalog.pg_has_role(s.nspowner, 'USAGE') AS current_role_owns,
COALESCE(count(c.oid), 0) AS table_count
FROM pg_catalog.pg_namespace s
LEFT JOIN pg_catalog.pg_class c ON
c.relnamespace = s.oid AND
-- Filter on relkind so that we only count tables. This must be done in the ON clause so that
-- we still get a row for schemas with no tables.
c.relkind = 'r'
WHERE
s.nspname <> 'information_schema' AND
s.nspname NOT LIKE 'pg_%'
GROUP BY
s.oid,
s.nspname,
s.nspowner
) AS schema_data;
$$ LANGUAGE SQL;
FROM msar.schema_info_table() AS schema_data
WHERE schema_data.name <> 'information_schema'
AND schema_data.name NOT LIKE 'pg_%';
$$ LANGUAGE SQL STABLE;


CREATE OR REPLACE FUNCTION msar.get_schema(sch_id regnamespace) RETURNS jsonb AS $$/*
Return a json object describing the user-defined schema in the database.
Each returned JSON object will have the form:
{
"oid": <int>
"name": <str>
"description": <str|null>
"owner_oid": <int>,
"current_role_priv": [<str>],
"current_role_owns": <bool>,
"table_count": <int>
}
*/
SELECT to_jsonb(schema_data)
FROM msar.schema_info_table() AS schema_data
WHERE schema_data.oid = sch_id;
$$ LANGUAGE SQL STABLE;


CREATE OR REPLACE FUNCTION msar.list_schema_privileges(sch_id regnamespace) RETURNS jsonb AS $$/*
Expand Down Expand Up @@ -1459,6 +1488,57 @@ END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.transfer_schema_ownership(sch_id regnamespace, new_owner_oid regrole) RETURNS jsonb AS $$/*
Transfers ownership of a given schema to a new owner.
Args:
sch_id: The OID of the schema to transfer.
new_owner_oid: The OID of the role whom we want to be the new owner of the schema.
NOTE: To successfully transfer ownership of a schema to a new owner the current user must:
- Be a Superuser/Owner of the schema.
- Be a `MEMBER` of the new owning role. i.e. The current role should be able to `SET ROLE`
to the new owning role.
- Have `CREATE` privilege for the database.
*/
BEGIN
EXECUTE format(
'ALTER SCHEMA %I OWNER TO %I',
msar.get_schema_name(sch_id),
msar.get_role_name(new_owner_oid)
);
RETURN msar.get_schema(sch_id);
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.transfer_table_ownership(tab_id regclass, new_owner_oid regrole) RETURNS jsonb AS $$/*
Transfers ownership of a given table to a new owner.
Args:
tab_id: The OID of the table to transfer.
new_owner_oid: The OID of the role whom we want to be the new owner of the table.
NOTE: To successfully transfer ownership of a table to a new owner the current user must:
- Be a Superuser/Owner of the table.
- Be a `MEMBER` of the new owning role. i.e. The current role should be able to `SET ROLE`
to the new owning role.
- Have `CREATE` privilege on the table's schema.
*/
BEGIN
EXECUTE format(
'ALTER TABLE %I.%I OWNER TO %I',
msar.get_relation_schema_name(tab_id),
msar.get_relation_name(tab_id),
msar.get_role_name(new_owner_oid)
);
RETURN msar.get_table(tab_id);
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------
-- ALTER SCHEMA FUNCTIONS
Expand Down
16 changes: 8 additions & 8 deletions db/sql/test_00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2784,20 +2784,20 @@ END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_get_schemas() RETURNS SETOF TEXT AS $$
CREATE OR REPLACE FUNCTION test_list_schemas() RETURNS SETOF TEXT AS $$
DECLARE
initial_schema_count int;
foo_schema jsonb;
BEGIN
-- Get the initial schema count
SELECT jsonb_array_length(msar.get_schemas()) INTO initial_schema_count;
SELECT jsonb_array_length(msar.list_schemas()) INTO initial_schema_count;

-- Create a schema
CREATE SCHEMA foo;
-- We should now have one additional schema
RETURN NEXT is(jsonb_array_length(msar.get_schemas()), initial_schema_count + 1);
RETURN NEXT is(jsonb_array_length(msar.list_schemas()), initial_schema_count + 1);
-- Reflect the "foo" schema
SELECT jsonb_path_query(msar.get_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
SELECT jsonb_path_query(msar.list_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
-- We should have a foo schema object
RETURN NEXT is(jsonb_typeof(foo_schema), 'object');
-- It should have no description
Expand All @@ -2811,7 +2811,7 @@ BEGIN
CREATE TABLE foo.test_table_1 (id serial PRIMARY KEY);
CREATE TABLE foo.test_table_2 (id serial PRIMARY KEY);
-- Reflect again
SELECT jsonb_path_query(msar.get_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
SELECT jsonb_path_query(msar.list_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
-- We should see the description we set
RETURN NEXT is(foo_schema->'description'#>>'{}', 'A test schema');
-- We should see two tables
Expand All @@ -2821,16 +2821,16 @@ BEGIN
DROP TABLE foo.test_table_1;
DROP TABLE foo.test_table_2;
-- Reflect the "foo" schema
SELECT jsonb_path_query(msar.get_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
SELECT jsonb_path_query(msar.list_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
-- The "foo" schema should now have no tables
RETURN NEXT is((foo_schema->'table_count')::int, 0);

-- Drop the "foo" schema
DROP SCHEMA foo;
-- We should now have no "foo" schema
RETURN NEXT ok(NOT jsonb_path_exists(msar.get_schemas(), '$[*] ? (@.name == "foo")'));
RETURN NEXT ok(NOT jsonb_path_exists(msar.list_schemas(), '$[*] ? (@.name == "foo")'));
-- We should see the initial schema count again
RETURN NEXT is(jsonb_array_length(msar.get_schemas()), initial_schema_count);
RETURN NEXT is(jsonb_array_length(msar.list_schemas()), initial_schema_count);
END;
$$ LANGUAGE plpgsql;

Expand Down
2 changes: 2 additions & 0 deletions docs/docs/api/rpc.md
Original file line number Diff line number Diff line change
Expand Up @@ -112,6 +112,7 @@ To use an RPC function:
members:
- list_direct
- replace_for_roles
- transfer_ownership
- SchemaPrivileges

## Tables
Expand Down Expand Up @@ -142,6 +143,7 @@ To use an RPC function:
members:
- list_direct
- replace_for_roles
- transfer_ownership
- TablePrivileges

## Table Metadata
Expand Down
4 changes: 2 additions & 2 deletions mathesar/rpc/schemas/base.py
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@

from db.constants import INTERNAL_SCHEMAS
from db.schemas.operations.create import create_schema
from db.schemas.operations.select import get_schemas
from db.schemas.operations.select import list_schemas
from db.schemas.operations.drop import drop_schema_via_oid
from db.schemas.operations.alter import patch_schema
from mathesar.rpc.exceptions.handlers import handle_rpc_exceptions
Expand Down Expand Up @@ -93,7 +93,7 @@ def list_(*, database_id: int, **kwargs) -> list[SchemaInfo]:
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
schemas = get_schemas(conn)
schemas = list_schemas(conn)

return [s for s in schemas if s['name'] not in INTERNAL_SCHEMAS]

Expand Down
28 changes: 28 additions & 0 deletions mathesar/rpc/schemas/privileges.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,10 +3,12 @@
from modernrpc.core import rpc_method, REQUEST_KEY
from modernrpc.auth.basic import http_basic_auth_login_required

from db.roles.operations.ownership import transfer_schema_ownership
from db.roles.operations.select import list_schema_privileges
from db.roles.operations.update import replace_schema_privileges_for_roles
from mathesar.rpc.utils import connect
from mathesar.rpc.exceptions.handlers import handle_rpc_exceptions
from mathesar.rpc.schemas.base import SchemaInfo


class SchemaPrivileges(TypedDict):
Expand Down Expand Up @@ -84,3 +86,29 @@ def replace_for_roles(
conn, schema_oid, [SchemaPrivileges.from_dict(i) for i in privileges]
)
return [SchemaPrivileges.from_dict(i) for i in raw_priv]


@rpc_method(name="schemas.privileges.transfer_ownership")
@http_basic_auth_login_required
@handle_rpc_exceptions
def transfer_ownership(*, schema_oid: int, new_owner_oid: int, database_id: int, **kwargs) -> SchemaInfo:
"""
Transfers ownership of a given schema to a new owner.
Attributes:
schema_oid: The OID of the schema to transfer.
new_owner_oid: The OID of the role whom we want to be the new owner of the schema.
Note: To successfully transfer ownership of a schema to a new owner the current user must:
- Be a Superuser/Owner of the schema.
- Be a `MEMBER` of the new owning role. i.e. The current role should be able to `SET ROLE`
to the new owning role.
- Have `CREATE` privilege for the database.
Returns:
Information about the schema, and the current user privileges.
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
schema_info = transfer_schema_ownership(schema_oid, new_owner_oid, conn)
return SchemaInfo(schema_info)
28 changes: 28 additions & 0 deletions mathesar/rpc/tables/privileges.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,10 +3,12 @@
from modernrpc.core import rpc_method, REQUEST_KEY
from modernrpc.auth.basic import http_basic_auth_login_required

from db.roles.operations.ownership import transfer_table_ownership
from db.roles.operations.select import list_table_privileges
from db.roles.operations.update import replace_table_privileges_for_roles
from mathesar.rpc.utils import connect
from mathesar.rpc.exceptions.handlers import handle_rpc_exceptions
from mathesar.rpc.tables.base import TableInfo


class TablePrivileges(TypedDict):
Expand Down Expand Up @@ -81,3 +83,29 @@ def replace_for_roles(
conn, table_oid, [TablePrivileges.from_dict(i) for i in privileges]
)
return [TablePrivileges.from_dict(i) for i in raw_priv]


@rpc_method(name="tables.privileges.transfer_ownership")
@http_basic_auth_login_required
@handle_rpc_exceptions
def transfer_ownership(*, table_oid: int, new_owner_oid: int, database_id: int, **kwargs) -> TableInfo:
"""
Transfers ownership of a given table to a new owner.
Attributes:
table_oid: The OID of the table to transfer.
new_owner_oid: The OID of the role whom we want to be the new owner of the table.
Note: To successfully transfer ownership of a table to a new owner the current user must:
- Be a Superuser/Owner of the table.
- Be a `MEMBER` of the new owning role. i.e. The current role should be able to `SET ROLE`
to the new owning role.
- Have `CREATE` privilege on the table's schema.
Returns:
Information about the table, and the current user privileges.
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
table_info = transfer_table_ownership(table_oid, new_owner_oid, conn)
return TableInfo(table_info)
10 changes: 10 additions & 0 deletions mathesar/tests/rpc/test_endpoints.py
Original file line number Diff line number Diff line change
Expand Up @@ -313,6 +313,11 @@
"schemas.privileges.replace_for_roles",
[user_is_authenticated]
),
(
schemas.privileges.transfer_ownership,
"schemas.privileges.transfer_ownership",
[user_is_authenticated]
),

(
servers.configured.list_,
Expand Down Expand Up @@ -388,6 +393,11 @@
"tables.privileges.replace_for_roles",
[user_is_authenticated]
),
(
tables.privileges.transfer_ownership,
"tables.privileges.transfer_ownership",
[user_is_authenticated]
),

(
tables.metadata.list_,
Expand Down
Loading

0 comments on commit 57d7246

Please sign in to comment.