Skip to content

Commit

Permalink
Merge pull request #3749 from mathesar-foundation/records_patch
Browse files Browse the repository at this point in the history
Add `records.patch` RPC function
  • Loading branch information
mathemancer authored Aug 13, 2024
2 parents 684f871 + a2268f1 commit 58b7f95
Show file tree
Hide file tree
Showing 7 changed files with 206 additions and 0 deletions.
14 changes: 14 additions & 0 deletions db/records/operations/update.py
Original file line number Diff line number Diff line change
@@ -1,10 +1,24 @@
import json
from db import connection as db_conn
from db.records.operations.select import get_record
from db.tables.utils import get_primary_key_column
from sqlalchemy.exc import DataError
from psycopg2.errors import DatetimeFieldOverflow, InvalidDatetimeFormat
from db.records.exceptions import InvalidDate, InvalidDateFormat


def patch_record_in_table(conn, record_def, record_id, table_oid):
"""Update a record in a table."""
result = db_conn.exec_msar_func(
conn,
'patch_record_in_table',
table_oid,
record_id,
json.dumps(record_def)
).fetchone()[0]
return result


def update_record(table, engine, id_value, record_data):
primary_key_column = get_primary_key_column(table)
with engine.begin() as connection:
Expand Down
54 changes: 54 additions & 0 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3821,3 +3821,57 @@ BEGIN
RETURN rec_created;
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.build_update_expr(tab_id oid, rec_def jsonb) RETURNS TEXT AS $$
SELECT
format(
'UPDATE %I.%I SET (%s) = ROW(%s)',
msar.get_relation_schema_name(tab_id),
msar.get_relation_name(tab_id),
string_agg(format('%I', msar.get_column_name(tab_id, key::smallint)), ', '),
string_agg(format('%L', value), ', ')
)
FROM jsonb_each_text(rec_def);
$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.patch_record_in_table(tab_id oid, rec_id anyelement, rec_def jsonb) RETURNS jsonb AS $$/*
Modify (update/patch) a record in a table.
Args:
tab_id: The OID of the table whose record we'll delete.
rec_id: The primary key value of the record we'll modify.
rec_patch: A JSON object defining the parts of the record to patch.
Only tables with a single primary key column are supported.
The `rec_def` object's form is defined by the record being updated. It should have keys
corresponding to the attnums of desired columns and values corresponding to values we should set.
*/
DECLARE
rec_modified jsonb;
BEGIN
EXECUTE format(
$i$
WITH update_cte AS (%1$s %2$s RETURNING %3$s)
SELECT jsonb_build_object('results', %4$s)
FROM update_cte
$i$,
msar.build_update_expr(tab_id, rec_def),
msar.build_where_clause(
tab_id, jsonb_build_object(
'type', 'equal', 'args', jsonb_build_array(
jsonb_build_object('type', 'literal', 'value', rec_id),
jsonb_build_object('type', 'attnum', 'value', msar.get_pk_column(tab_id))
)
)
),
msar.build_selectable_column_expr(tab_id),
msar.build_results_jsonb_expr(tab_id, 'update_cte')
) INTO rec_modified;
RETURN rec_modified;
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;
44 changes: 44 additions & 0 deletions db/sql/test_00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3960,3 +3960,47 @@ BEGIN
);
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_patch_record_in_table_single() RETURNS SETOF TEXT AS $$
DECLARE
rel_id oid;
BEGIN
PERFORM __setup_add_record_table();
rel_id := 'atable'::regclass::oid;
RETURN NEXT is(
msar.patch_record_in_table( rel_id, 2, '{"2": 10}'),
'{"results": [{"1": 2, "2": 10, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}]}'
);
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_patch_record_in_table_multi() RETURNS SETOF TEXT AS $$
DECLARE
rel_id oid;
BEGIN
PERFORM __setup_add_record_table();
rel_id := 'atable'::regclass::oid;
RETURN NEXT is(
msar.patch_record_in_table( rel_id, 2, '{"2": 10, "4": {"a": "json"}}'),
'{"results": [{"1": 2, "2": 10, "3": "sdflfflsk", "4": {"a": "json"}, "5": [1, 2, 3, 4]}]}'
);
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION test_patch_record_in_table_leaves_other_rows() RETURNS SETOF TEXT AS $$
DECLARE
rel_id oid;
patch_result jsonb;
BEGIN
PERFORM __setup_add_record_table();
rel_id := 'atable'::regclass::oid;
PERFORM msar.patch_record_in_table( rel_id, 2, '{"2": 10}');
RETURN NEXT results_eq(
'SELECT id, col1 FROM atable ORDER BY id',
'VALUES (1, 5), (2, 10), (3, 2)'
);
END;
$$ LANGUAGE plpgsql;
1 change: 1 addition & 0 deletions docs/docs/api/rpc.md
Original file line number Diff line number Diff line change
Expand Up @@ -184,6 +184,7 @@ To use an RPC function:
- list_
- get
- add
- patch
- delete
- search
- RecordList
Expand Down
40 changes: 40 additions & 0 deletions mathesar/rpc/records.py
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@
from db.records.operations import delete as record_delete
from db.records.operations import insert as record_insert
from db.records.operations import select as record_select
from db.records.operations import update as record_update
from mathesar.rpc.exceptions.handlers import handle_rpc_exceptions
from mathesar.rpc.utils import connect

Expand Down Expand Up @@ -284,6 +285,45 @@ def add(
return RecordAdded.from_dict(record_info)


@rpc_method(name="records.patch")
@http_basic_auth_login_required
@handle_rpc_exceptions
def patch(
*,
record_def: dict,
record_id: Any,
table_oid: int,
database_id: int,
**kwargs
) -> RecordAdded:
"""
Modify a record in a table.
The form of the `record_def` is determined by the underlying table. Keys
should be attnums, and values should be the desired value for that column in
the modified record. Explicit `null` values will set null for that value
(with obvious exceptions where that would violate some constraint).
Args:
record_def: An object representing the record to be added.
record_id: The primary key value of the record to modify.
table_oid: Identity of the table in the user's database.
database_id: The Django id of the database containing the table.
Returns:
The modified record, along with some metadata.
"""
user = kwargs.get(REQUEST_KEY).user
with connect(database_id, user) as conn:
record_info = record_update.patch_record_in_table(
conn,
record_def,
record_id,
table_oid,
)
return RecordAdded.from_dict(record_info)


@rpc_method(name="records.delete")
@http_basic_auth_login_required
@handle_rpc_exceptions
Expand Down
5 changes: 5 additions & 0 deletions mathesar/tests/rpc/test_endpoints.py
Original file line number Diff line number Diff line change
Expand Up @@ -159,6 +159,11 @@
"records.add",
[user_is_authenticated]
),
(
records.patch,
"records.patch",
[user_is_authenticated]
),
(
records.delete,
"records.delete",
Expand Down
48 changes: 48 additions & 0 deletions mathesar/tests/rpc/test_records.py
Original file line number Diff line number Diff line change
Expand Up @@ -162,6 +162,54 @@ def mock_add_record(
assert actual_record == expect_record


def test_records_patch(rf, monkeypatch):
username = 'alice'
password = 'pass1234'
record_id = 243
table_oid = 23457
database_id = 2
record_def = {"2": "arecord"}
request = rf.post('/api/rpc/v0/', data={})
request.user = User(username=username, password=password)

@contextmanager
def mock_connect(_database_id, user):
if _database_id == database_id and user.username == username:
try:
yield True
finally:
pass
else:
raise AssertionError('incorrect parameters passed')

def mock_patch_record(
conn,
_record_def,
_record_id,
_table_oid,
):
if _table_oid != table_oid or _record_def != record_def or _record_id != record_id:
raise AssertionError('incorrect parameters passed')
return {
"results": [_record_def | {"3": "another"}],
}

monkeypatch.setattr(records, 'connect', mock_connect)
monkeypatch.setattr(records.record_update, 'patch_record_in_table', mock_patch_record)
expect_record = {
"results": [record_def | {"3": "another"}],
"preview_data": [],
}
actual_record = records.patch(
record_def=record_def,
record_id=record_id,
table_oid=table_oid,
database_id=database_id,
request=request
)
assert actual_record == expect_record


def test_records_delete(rf, monkeypatch):
username = 'alice'
password = 'pass1234'
Expand Down

0 comments on commit 58b7f95

Please sign in to comment.