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 records.search RPC function #3708

Merged
merged 14 commits into from
Aug 2, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
29 changes: 26 additions & 3 deletions db/records/operations/select.py
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,6 @@ def list_records_from_table(
order=None,
filter=None,
group=None,
search=None,
):
"""
Get records from a table.
Expand All @@ -37,7 +36,6 @@ def list_records_from_table(
order: An array of ordering definition objects.
filter: An array of filter definition objects.
group: An array of group definition objects.
search: An array of search definition objects.
"""
result = db_conn.exec_msar_func(
conn,
Expand All @@ -48,7 +46,32 @@ def list_records_from_table(
json.dumps(order) if order is not None else None,
json.dumps(filter) if filter is not None else None,
json.dumps(group) if group is not None else None,
json.dumps(search) if search is not None else None,
).fetchone()[0]
return result


def search_records_from_table(
conn,
table_oid,
search=[],
limit=10,
):
"""
Get records from a table, according to a search specification

Only data from which the user is granted `SELECT` is returned.

Args:
tab_id: The OID of the table whose records we'll get.
search: A list of dictionaries defining a search.
limit: The maximum number of rows we'll return.

The search definition objects should have the form
{"attnum": <int>, "literal": <text>}
"""
search = search or []
result = db_conn.exec_msar_func(
conn, 'search_records_from_table', table_oid, json.dumps(search), limit
Comment on lines +73 to +74
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think we could avoid this function call when the search list is empty. Assuming frontend already has the records from records.list.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We could, but I'd rather have the front end do that. I.e., if they want to avoid the call, they should just not send the request until there are letters in the array. For the completeness of this function I'd really rather treat it as a kind of "narrowing filter" concept. And for that, we should return unfiltered results whenever we get an empty search definition.

).fetchone()[0]
return result

Expand Down
117 changes: 103 additions & 14 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3399,18 +3399,13 @@ $$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.build_order_by_expr(tab_id oid, order_ jsonb) RETURNS text AS $$/*
Build an ORDER BY expression for the given table and order JSON.

The ORDER BY expression will refer to columns by their attnum. This is designed to work together
with `msar.build_selectable_column_expr`. It will only use the columns to which the user has access.
Finally, this function will append either a primary key, or all columns to the produced ORDER BY so
the resulting ordering is totally defined (i.e., deterministic).

msar.build_total_order_expr(tab_id oid, order_ jsonb) RETURNS text AS $$/*
Build a deterministic order expression for the given table and order JSON.
Args:
tab_id: The OID of the table whose columns we'll order by.
order_: A JSONB array defining any desired ordering of columns.
*/
SELECT 'ORDER BY ' || string_agg(format('%I %s', attnum, msar.sanitize_direction(direction)), ', ')
SELECT string_agg(format('%I %s', attnum, msar.sanitize_direction(direction)), ', ')
FROM jsonb_to_recordset(
COALESCE(
COALESCE(order_, '[]'::jsonb) || msar.get_pkey_order(tab_id),
Expand All @@ -3422,6 +3417,23 @@ WHERE has_column_privilege(tab_id, attnum, 'SELECT');
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION
msar.build_order_by_expr(tab_id oid, order_ jsonb) RETURNS text AS $$/*
Build an ORDER BY expression for the given table and order JSON.

The ORDER BY expression will refer to columns by their attnum. This is designed to work together
with `msar.build_selectable_column_expr`. It will only use the columns to which the user has access.
Finally, this function will append either a primary key, or all columns to the produced ORDER BY so
the resulting ordering is totally defined (i.e., deterministic).

Args:
tab_id: The OID of the table whose columns we'll order by.
order_: A JSONB array defining any desired ordering of columns.
*/
SELECT 'ORDER BY ' || msar.build_total_order_expr(tab_id, order_)
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION
msar.build_selectable_column_expr(tab_id oid) RETURNS text AS $$/*
Build an SQL select-target expression of only columns to which the user has access.
Expand Down Expand Up @@ -3451,8 +3463,7 @@ msar.list_records_from_table(
offset_ integer,
order_ jsonb,
filter_ jsonb,
group_ jsonb,
search_ jsonb
group_ jsonb
) RETURNS jsonb AS $$/*
Get records from a table. Only columns to which the user has access are returned.

Expand All @@ -3463,7 +3474,6 @@ Args:
order_: An array of ordering definition objects.
filter_: An array of filter definition objects.
group_: An array of group definition objects.
search_: An array of search definition objects.

The order definition objects should have the form
{"attnum": <int>, "direction": <text>}
Expand All @@ -3479,8 +3489,8 @@ BEGIN
SELECT %1$s FROM %2$I.%3$I %7$s %6$s LIMIT %4$L OFFSET %5$L
)
SELECT jsonb_build_object(
'results', jsonb_agg(row_to_json(results_cte.*)),
'count', max(count_cte.count),
'results', coalesce(jsonb_agg(row_to_json(results_cte.*)), jsonb_build_array()),
'count', coalesce(max(count_cte.count), 0),
'query', $iq$SELECT %1$s FROM %2$I.%3$I %7$s %6$s LIMIT %4$L OFFSET %5$L$iq$
)
FROM results_cte, count_cte
Expand All @@ -3496,3 +3506,82 @@ BEGIN
RETURN records;
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION
msar.get_score_expr(tab_id oid, parameters_ jsonb) RETURNS text AS $$
SELECT string_agg(
CASE WHEN pgt.typcategory = 'S' THEN
format(
$s$(CASE
WHEN %1$I ILIKE %2$L THEN 4
WHEN %1$I ILIKE %2$L || '%%' THEN 3
WHEN %1$I ILIKE '%%' || %2$L || '%%' THEN 2
ELSE 0
END)$s$,
pga.attname,
x.literal
)
ELSE
format('(CASE WHEN %1$I = %2$L THEN 4 ELSE 0 END)', pga.attname, x.literal)
END,
' + '
)
FROM jsonb_to_recordset(parameters_) AS x(attnum smallint, literal text)
INNER JOIN pg_catalog.pg_attribute AS pga ON x.attnum = pga.attnum
INNER JOIN pg_catalog.pg_type AS pgt ON pga.atttypid = pgt.oid
WHERE
pga.attrelid = tab_id
AND NOT pga.attisdropped
AND has_column_privilege(tab_id, x.attnum, 'SELECT')
$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.search_records_from_table(
tab_id oid,
search_ jsonb,
limit_ integer
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

For some reason having NULL for limit_ here doesn't return anything, But works perfectly in list_records_from_table.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Now it returns all matching records.

Comment on lines +3543 to +3544
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

SELECT msar.search_records_from_table(2254321, '[]'::jsonb, 4);
ERROR:  syntax error at or near ">"

Passing an empty json for search_ and a non null value for limit_ also breaks the function and results in a syntax error.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Empty or null values for the search def now return unfiltered results.

) RETURNS jsonb AS $$/*
Get records from a table, filtering and sorting according to a search specification.

Only columns to which the user has access are returned.

Args:
tab_id: The OID of the table whose records we'll get
search_: An array of search definition objects.
limit_: The maximum number of rows we'll return.

The search definition objects should have the form
{"attnum": <int>, "literal": <any>}
*/
DECLARE
records jsonb;
BEGIN
EXECUTE format(
$q$
WITH count_cte AS (
SELECT count(1) AS count FROM %2$I.%3$I %4$s
), results_cte AS (
SELECT %1$s FROM %2$I.%3$I %4$s ORDER BY %6$s LIMIT %5$L
)
SELECT jsonb_build_object(
'results', coalesce(jsonb_agg(row_to_json(results_cte.*)), jsonb_build_array()),
'count', coalesce(max(count_cte.count), 0),
'query', $iq$SELECT %1$s FROM %2$I.%3$I %4$s ORDER BY %6$s LIMIT %5$L$iq$
)
FROM results_cte, count_cte
$q$,
msar.build_selectable_column_expr(tab_id),
msar.get_relation_schema_name(tab_id),
msar.get_relation_name(tab_id),
'WHERE ' || msar.get_score_expr(tab_id, search_) || ' > 0',
limit_,
concat(
msar.get_score_expr(tab_id, search_) || ' DESC, ',
msar.build_total_order_expr(tab_id, null)
)
) INTO records;
RETURN records;
END;
$$ LANGUAGE plpgsql;
Loading
Loading