Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add target_table_info in tables.list_joinable's response #3718

Merged
merged 8 commits into from
Aug 3, 2024
38 changes: 32 additions & 6 deletions db/sql/10_msar_joinable_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,15 +31,16 @@ whether to travel from referrer to referant (when False) or from referant to ref

DROP TYPE IF EXISTS msar.joinable_tables CASCADE;
CREATE TYPE msar.joinable_tables AS (
base integer, -- The OID of the table from which the paths start
target integer, -- The OID of the table where the paths end
base bigint, -- The OID of the table from which the paths start
target bigint, -- The OID of the table where the paths end
join_path jsonb, -- A JSONB array of arrays of arrays
fkey_path jsonb,
depth integer,
multiple_results boolean
);


DROP FUNCTION IF EXISTS msar.get_joinable_tables(integer);
CREATE OR REPLACE FUNCTION
msar.get_joinable_tables(max_depth integer) RETURNS SETOF msar.joinable_tables AS $$/*
This function returns a table of msar.joinable_tables objects, giving paths to various
Expand Down Expand Up @@ -128,11 +129,36 @@ UNION ALL
FROM search_fkey_graph
)
SELECT * FROM output_cte;
$$ LANGUAGE sql;
$$ LANGUAGE SQL STABLE;


DROP FUNCTION IF EXISTS msar.get_joinable_tables(integer, oid);
CREATE OR REPLACE FUNCTION
msar.get_joinable_tables(max_depth integer, table_id oid) RETURNS
SETOF msar.joinable_tables AS $$
SELECT * FROM msar.get_joinable_tables(max_depth) WHERE base=table_id
$$ LANGUAGE sql;
jsonb AS $$
WITH jt_cte AS (
SELECT * FROM msar.get_joinable_tables(max_depth) WHERE base=table_id
), target_cte AS (
SELECT pga.attrelid AS tt_oid,
jsonb_build_object(
'name', msar.get_relation_name(pga.attrelid),
'columns', jsonb_object_agg(
pga.attnum, jsonb_build_object(
'name', pga.attname,
'type', CASE WHEN attndims>0 THEN '_array' ELSE atttypid::regtype::text END
)
)
) AS tt_info
FROM pg_catalog.pg_attribute AS pga, jt_cte
WHERE pga.attrelid=jt_cte.target AND pga.attnum > 0 and NOT pga.attisdropped
GROUP BY pga.attrelid
), joinable_tables AS (
SELECT jsonb_agg(to_jsonb(jt_cte.*)) AS jt FROM jt_cte
), target_table_info AS (
SELECT jsonb_object_agg(tt_oid, tt_info) AS tt FROM target_cte
)
SELECT jsonb_build_object(
'joinable_tables', joinable_tables.jt,
'target_table_info', target_table_info.tt
) FROM joinable_tables, target_table_info;
$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;
4 changes: 2 additions & 2 deletions db/tables/operations/select.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@
)
from sqlalchemy.dialects.postgresql import JSONB

from db.connection import exec_msar_func, select_from_msar_func
from db.connection import exec_msar_func
from db.utils import execute_statement, get_pg_catalog_table

BASE = 'base'
Expand Down Expand Up @@ -60,7 +60,7 @@ def get_table_info(schema, conn):


def list_joinable_tables(table_oid, conn, max_depth):
return select_from_msar_func(conn, 'get_joinable_tables', max_depth, table_oid)
return exec_msar_func(conn, 'get_joinable_tables', max_depth, table_oid).fetchone()[0]


def reflect_table(name, schema, engine, metadata, connection_to_use=None, keep_existing=False):
Expand Down
1 change: 1 addition & 0 deletions docs/docs/api/rpc.md
Original file line number Diff line number Diff line change
Expand Up @@ -113,6 +113,7 @@ To use an RPC function:
- list_joinable
- TableInfo
- SettableTableInfo
- JoinableTableRecord
- JoinableTableInfo

## Table Metadata
Expand Down
29 changes: 24 additions & 5 deletions mathesar/rpc/tables/base.py
Original file line number Diff line number Diff line change
Expand Up @@ -56,9 +56,9 @@ class SettableTableInfo(TypedDict):
columns: Optional[list[SettableColumnInfo]]


class JoinableTableInfo(TypedDict):
class JoinableTableRecord(TypedDict):
"""
Information about a joinable table.
Information about a singular joinable table.

Attributes:
base: The OID of the table from which the paths start
Expand Down Expand Up @@ -102,6 +102,25 @@ def from_dict(cls, joinables):
)


class JoinableTableInfo(TypedDict):
"""
Information about joinable table(s).

Attributes:
joinable_tables: List of reachable joinable table(s) from a base table.
target_table_info: Additional info about target table(s) and its column(s).
"""
joinable_tables: list[JoinableTableRecord]
target_table_info: list

@classmethod
def from_dict(cls, joinable_dict):
return cls(
joinable_tables=[JoinableTableRecord.from_dict(j) for j in joinable_dict["joinable_tables"]],
target_table_info=joinable_dict["target_table_info"]
)


@rpc_method(name="tables.list")
@http_basic_auth_login_required
@handle_rpc_exceptions
Expand Down Expand Up @@ -290,7 +309,7 @@ def list_joinable(
database_id: int,
max_depth: int = 3,
**kwargs
) -> list[JoinableTableInfo]:
) -> JoinableTableInfo:
"""
List details for joinable tables.

Expand All @@ -304,8 +323,8 @@ def list_joinable(
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
joinables = list_joinable_tables(table_oid, conn, max_depth)
return [JoinableTableInfo.from_dict(joinable) for joinable in joinables]
joinable_dict = list_joinable_tables(table_oid, conn, max_depth)
return JoinableTableInfo.from_dict(joinable_dict)


@rpc_method(name="tables.list_with_metadata")
Expand Down
152 changes: 64 additions & 88 deletions mathesar/tests/rpc/tables/test_t_base.py
Original file line number Diff line number Diff line change
Expand Up @@ -288,107 +288,83 @@ def mock_connect(_database_id, user):
def mock_list_joinable_tables(_table_oid, conn, max_depth):
if _table_oid != table_oid:
raise AssertionError('incorrect parameters passed')
return [
return {
'joinable_tables': [
{
'base': 2254329,
'depth': 1,
'target': 2254334,
'fkey_path': [[2254406, False]],
'join_path': [[[2254329, 2], [2254334, 1]]],
'multiple_results': False
},
{
'base': 2254329,
'depth': 1,
'target': 2254350,
'fkey_path': [[2254411, False]],
'join_path': [[[2254329, 3], [2254350, 1]]],
'multiple_results': False
}],
'target_table_info': {
'2254334': {
'name': 'Items',
'columns': {
'1': {'name': 'id', 'type': 'integer'},
'2': {'name': 'Barcode', 'type': 'text'},
'3': {'name': 'Acquisition Date', 'type': 'date'},
'5': {'name': 'Book', 'type': 'integer'}
}
},
'2254350': {
'name': 'Patrons',
'columns': {
'1': {'name': 'id', 'type': 'integer'},
'2': {'name': 'First Name', 'type': 'text'},
'3': {'name': 'Last Name', 'type': 'text'}
}
}
}
}
expected_dict = {
'joinable_tables': [
{
'base': 2254329,
'depth': 1,
'target': 2254334,
'join_path': [[[2254329, 2], [2254334, 1]]],
'fkey_path': [[2254406, False]],
'depth': 1,
'join_path': [[[2254329, 2], [2254334, 1]]],
'multiple_results': False
},
{
'base': 2254329,
'depth': 1,
'target': 2254350,
'join_path': [[[2254329, 3], [2254350, 1]]],
'fkey_path': [[2254411, False]],
'depth': 1,
'multiple_results': False
},
{
'base': 2254329,
'target': 2254321,
'join_path': [[[2254329, 2], [2254334, 1]], [[2254334, 5], [2254321, 1]]],
'fkey_path': [[2254406, False], [2254399, False]],
'depth': 2,
'multiple_results': False
},
{
'base': 2254329,
'target': 2254358,
'join_path': [
[[2254329, 2], [2254334, 1]],
[[2254334, 5], [2254321, 1]],
[[2254321, 11], [2254358, 1]]
],
'fkey_path': [[2254406, False], [2254399, False], [2254394, False]],
'depth': 3,
'join_path': [[[2254329, 3], [2254350, 1]]],
'multiple_results': False
}],
'target_table_info': {
'2254334': {
'name': 'Items',
'columns': {
'1': {'name': 'id', 'type': 'integer'},
'2': {'name': 'Barcode', 'type': 'text'},
'3': {'name': 'Acquisition Date', 'type': 'date'},
'5': {'name': 'Book', 'type': 'integer'}
}
},
{
'base': 2254329,
'target': 2254313,
'join_path': [
[[2254329, 2], [2254334, 1]],
[[2254334, 5], [2254321, 1]],
[[2254321, 10], [2254313, 1]]
],
'fkey_path': [[2254406, False], [2254399, False], [2254389, False]],
'depth': 3,
'multiple_results': False
'2254350': {
'name': 'Patrons',
'columns': {
'1': {'name': 'id', 'type': 'integer'},
'2': {'name': 'First Name', 'type': 'text'},
'3': {'name': 'Last Name', 'type': 'text'}
}
}
]
expected_list = [
{
'base': 2254329,
'target': 2254334,
'join_path': [[[2254329, 2], [2254334, 1]]],
'fkey_path': [[2254406, False]],
'depth': 1,
'multiple_results': False
},
{
'base': 2254329,
'target': 2254350,
'join_path': [[[2254329, 3], [2254350, 1]]],
'fkey_path': [[2254411, False]],
'depth': 1,
'multiple_results': False
},
{
'base': 2254329,
'target': 2254321,
'join_path': [[[2254329, 2], [2254334, 1]], [[2254334, 5], [2254321, 1]]],
'fkey_path': [[2254406, False], [2254399, False]],
'depth': 2,
'multiple_results': False
},
{
'base': 2254329,
'target': 2254358,
'join_path': [
[[2254329, 2], [2254334, 1]],
[[2254334, 5], [2254321, 1]],
[[2254321, 11], [2254358, 1]]
],
'fkey_path': [[2254406, False], [2254399, False], [2254394, False]],
'depth': 3,
'multiple_results': False
},
{
'base': 2254329,
'target': 2254313,
'join_path': [
[[2254329, 2], [2254334, 1]],
[[2254334, 5], [2254321, 1]],
[[2254321, 10], [2254313, 1]]
],
'fkey_path': [[2254406, False], [2254399, False], [2254389, False]],
'depth': 3,
'multiple_results': False
}
]
}
monkeypatch.setattr(tables.base, 'connect', mock_connect)
monkeypatch.setattr(tables.base, 'list_joinable_tables', mock_list_joinable_tables)
actual_list = tables.list_joinable(table_oid=2254329, database_id=11, max_depth=3, request=request)
assert expected_list == actual_list
actual_dict = tables.list_joinable(table_oid=2254329, database_id=11, max_depth=1, request=request)
assert expected_dict == actual_dict
Loading