From 83e9fb680ecc84449833ef433ee250ccc196f66a Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Thu, 15 Aug 2024 17:29:38 +0800 Subject: [PATCH 01/13] add first draft summary getting into record lister --- db/sql/00_msar.sql | 104 +++++++++++++++++++++++++++++++++++++++++++-- 1 file changed, 101 insertions(+), 3 deletions(-) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 406844459f..712752283d 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3632,6 +3632,100 @@ WHERE $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; +CREATE OR REPLACE FUNCTION msar.get_default_summary_column(tab_id oid) RETURNS smallint AS $$/* +Choose a column to use for summarizing rows of a table. + +If a string type column exists, we choose the one with a minimal attnum. If no such column exists, +we just return the column (of any type) with minimum attnum. + +Only columns to which the user has access are returned. + +Args: + tab_id: The OID of the table for which we're finding a good summary column +*/ +SELECT attnum +FROM pg_catalog.pg_attribute pga JOIN pg_catalog.pg_type pgt ON pga.atttypid = pgt.oid +WHERE pga.attrelid = tab_id + AND pga.attnum > 0 + AND NOT pga.attisdropped + AND has_column_privilege(pga.attrelid, pga.attnum, 'SELECT') +ORDER BY (CASE WHEN pgt.typcategory='S' THEN 0 ELSE 1 END), pga.attnum +LIMIT 1; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION msar.get_fkey_map_cte(tab_id oid) + RETURNS TABLE (target_oid oid, conkey smallint, confkey smallint) +AS $$/* +*/ +SELECT pgc.confrelid AS target_oid, x.conkey AS conkey, min(y.confkey) AS confkey +FROM pg_constraint pgc, LATERAL unnest(conkey) x(conkey), LATERAL unnest(confkey) y(confkey) +WHERE + pgc.conrelid = tab_id + AND pgc.contype='f' + AND cardinality(pgc.confkey) = 1 + AND has_column_privilege(tab_id, x.conkey, 'SELECT') + AND has_column_privilege(pgc.confrelid, y.confkey, 'SELECT') +GROUP BY pgc.confrelid, x.conkey +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION msar.build_summary_cte_expr_for_table(tab_id oid) RETURNS TEXT AS $$/* +*/ +WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) +SELECT ', ' || string_agg( + format( + $c$summary_cte_%1$s AS ( + SELECT + msar.format_data(%2$I) AS key, + msar.format_data(%3$I)::text AS summary + FROM %4$I.%5$I + )$c$, + conkey, + msar.get_column_name(target_oid, confkey), + msar.get_column_name(target_oid, msar.get_default_summary_column(target_oid)), + msar.get_relation_schema_name(target_oid), + msar.get_relation_name(target_oid) + ), ', ' +) +FROM fkey_map_cte; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION +msar.build_summary_join_expr_for_table(tab_id oid, cte_name text) RETURNS TEXT AS $$/* +*/ +WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) +SELECT string_agg( + format( + $j$ + LEFT JOIN summary_cte_%1$s ON %2$I.%1$I = summary_cte_%1$s.key$j$, + conkey, + cte_name + ), ' ' +) +FROM fkey_map_cte; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION +msar.build_summary_json_expr_for_table(tab_id oid) RETURNS TEXT AS $$/* +*/ +WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) +SELECT 'jsonb_build_object(' || string_agg( + format( + $j$ + %1$L, jsonb_agg( + DISTINCT jsonb_build_object('key', summary_cte_%1$s.key, 'summary', summary_cte_%1$s.summary) + ) + $j$, + conkey + ), ', ' +) || ')' +FROM fkey_map_cte; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + CREATE OR REPLACE FUNCTION msar.list_records_from_table( tab_id oid, @@ -3667,15 +3761,16 @@ BEGIN SELECT *, row_number() OVER (%6$s) - 1 AS __mathesar_result_idx FROM enriched_results_cte ), groups_cte AS ( SELECT %11$s - ) + )%12$s SELECT jsonb_build_object( 'results', %9$s, 'count', coalesce(max(count_cte.count), 0), 'grouping', %10$s, + 'preview_data', %14$s, 'query', $iq$SELECT %1$s FROM %2$I.%3$I %7$s %6$s LIMIT %4$L OFFSET %5$L$iq$ ) FROM enriched_results_cte - LEFT JOIN groups_cte ON enriched_results_cte.__mathesar_gid = groups_cte.id + LEFT JOIN groups_cte ON enriched_results_cte.__mathesar_gid = groups_cte.id %13$s CROSS JOIN count_cte $q$, msar.build_selectable_column_expr(tab_id), @@ -3688,7 +3783,10 @@ BEGIN msar.build_grouping_expr(tab_id, group_), msar.build_results_jsonb_expr(tab_id, 'enriched_results_cte', order_), COALESCE(msar.build_grouping_results_jsonb_expr(tab_id, 'groups_cte', group_), 'NULL'), - COALESCE(msar.build_groups_cte_expr(tab_id, 'results_ranked_cte', group_), 'NULL AS id') + COALESCE(msar.build_groups_cte_expr(tab_id, 'results_ranked_cte', group_), 'NULL AS id'), + msar.build_summary_cte_expr_for_table(tab_id), + msar.build_summary_join_expr_for_table(tab_id, 'enriched_results_cte'), + COALESCE(msar.build_summary_json_expr_for_table(tab_id), 'NULL') ) INTO records; RETURN records; END; From e64e1fec22822457e9d22f25a276459b0ed59921 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Thu, 15 Aug 2024 17:54:14 +0800 Subject: [PATCH 02/13] add record previews into search function --- db/sql/00_msar.sql | 11 ++++++++--- 1 file changed, 8 insertions(+), 3 deletions(-) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 712752283d..79e57bec87 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3849,13 +3849,15 @@ BEGIN 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 - ) + )%7$s SELECT jsonb_build_object( 'results', coalesce(jsonb_agg(row_to_json(results_cte.*)), jsonb_build_array()), 'count', coalesce(max(count_cte.count), 0), + 'preview_data', %9$s, '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 + FROM results_cte %8$s + CROSS JOIN count_cte $q$, msar.build_selectable_column_expr(tab_id), msar.get_relation_schema_name(tab_id), @@ -3865,7 +3867,10 @@ BEGIN concat( msar.get_score_expr(tab_id, search_) || ' DESC, ', msar.build_total_order_expr(tab_id, null) - ) + ), + msar.build_summary_cte_expr_for_table(tab_id), + msar.build_summary_join_expr_for_table(tab_id, 'results_cte'), + COALESCE(msar.build_summary_json_expr_for_table(tab_id), 'NULL') ) INTO records; RETURN records; END; From 53eada2acb2d46d6f55853781c0a8558e047b53e Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 16:09:34 +0800 Subject: [PATCH 03/13] add null preview data to previous test --- db/sql/test_00_msar.sql | 33 ++++++++++++++++++++++----------- 1 file changed, 22 insertions(+), 11 deletions(-) diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index 9c0030deaa..a1399a18cb 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -2948,7 +2948,8 @@ BEGIN {"1": 2, "2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}, {"1": 3, "2": 2, "3": "abcde", "4": {"k": 3242348}, "5": true} ], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",' @@ -2973,7 +2974,8 @@ BEGIN {"1": 2, "2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}, {"1": 1, "2": 5, "3": "sdflkj", "4": "s", "5": {"a": "val"}} ], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",' @@ -2998,7 +3000,8 @@ BEGIN {"1": 2, "2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}, {"1": 1, "2": 5, "3": "sdflkj", "4": "s", "5": {"a": "val"}} ], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",', @@ -3029,7 +3032,8 @@ BEGIN {"2": 5, "3": "sdflkj", "4": "s", "5": {"a": "val"}}, {"2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]} ], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(col1) AS "2", msar.format_data(col2) AS "3",', @@ -3054,7 +3058,8 @@ BEGIN {"2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}, {"2": 2, "3": "abcde", "4": {"k": 3242348}, "5": true} ], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(col1) AS "2", msar.format_data(col2) AS "3",', @@ -3131,7 +3136,8 @@ BEGIN "result_indices": [9] } ] - } + }, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' @@ -3167,7 +3173,8 @@ BEGIN "result_indices": [0, 1, 2] } ] - } + }, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' @@ -3199,7 +3206,8 @@ BEGIN {"id": 1, "count": 1, "results_eq": {"4": "2020-03 AD"}, "result_indices": [0]}, {"id": 2, "count": 2, "results_eq": {"4": "2020-04 AD"}, "result_indices": [1, 2]} ] - } + }, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' @@ -3232,7 +3240,8 @@ BEGIN "groups": [ {"id": 1, "count": 8, "results_eq": {"4": "2020 AD"}, "result_indices": [0, 1, 2, 3, 4]} ] - } + }, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' @@ -3743,7 +3752,8 @@ BEGIN "results": [ {"1": 2, "2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]} ], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",', @@ -3758,7 +3768,8 @@ BEGIN $j${ "count": 0, "results": [], - "grouping": null + "grouping": null, + "preview_data": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",', From a39c2a5d937323afcfeb446b92a42acac4a5d1a5 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 16:35:54 +0800 Subject: [PATCH 04/13] add basic test for record previews --- db/sql/test_00_msar.sql | 92 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 92 insertions(+) diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index a1399a18cb..3604f74a7b 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -4067,3 +4067,95 @@ BEGIN ); END; $$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION __setup_preview_fkey_cols() RETURNS SETOF TEXT AS $$ +BEGIN +CREATE TABLE "Counselors" ( + coid numeric UNIQUE, + "Name" text, + "Email" text +); +CREATE TABLE "Teachers" ( + id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, + "Counselor" numeric REFERENCES "Counselors" (coid), + "Name" text, + "Email" text +); +CREATE TABLE "Students" ( + id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, + "Counselor" numeric REFERENCES "Counselors" (coid), + "Teacher" integer REFERENCES "Teachers" (id), + "Name" text, + "Grade" integer, + "Email" text +); + +INSERT INTO "Counselors" VALUES + (1.234, 'Alice Alison', 'aalison@example.edu'), + (2.345, 'Bob Bobinson', 'bbobinson@example.edu'); + +INSERT INTO "Teachers" ("Counselor", "Name", "Email") VALUES + (1.234, 'Carol Carlson', 'ccarlson@example.edu'), + (2.345, 'Dave Davidson', 'ddavison@example.edu'), + (1.234, 'Eve Evilson', 'eevilson@example.edu'); + +INSERT INTO "Students" ("Counselor", "Teacher", "Name", "Grade", "Email") VALUES + (2.345, 3, 'Fred Fredrickson', 95, 'ffredrickson@example.edu'), + (1.234, 1, 'Gabby Gabberson', 100, 'ggabberson@example.edu'), + (1.234, 2, 'Hank Hankson', 75, 'hhankson@example.edu'), + (2.345, 1, 'Ida Idalia', 90, 'iidalia@example.edu'), + (2.345, 2, 'James Jameson', 80, 'jjameson@example.edu'), + (1.234, 3, 'Kelly Kellison', 80, 'kkellison@example.edu'); + +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION test_list_records_with_preview() RETURNS SETOF TEXT AS $$ +DECLARE + list_result jsonb; +BEGIN + PERFORM __setup_preview_fkey_cols(); + RETURN NEXT is( + msar.list_records_from_table( + tab_id => '"Students"'::regclass::oid, + limit_ => null, + offset_ => null, + order_ => null, + filter_ => null, + group_ => null + ), + $j${ + "count": 6, + "results": [ + {"1": 1, "2": 2.345, "3": 3, "4": "Fred Fredrickson", "5": 95, "6": "ffredrickson@example.edu"}, + {"1": 2, "2": 1.234, "3": 1, "4": "Gabby Gabberson", "5": 100, "6": "ggabberson@example.edu"}, + {"1": 3, "2": 1.234, "3": 2, "4": "Hank Hankson", "5": 75, "6": "hhankson@example.edu"}, + {"1": 4, "2": 2.345, "3": 1, "4": "Ida Idalia", "5": 90, "6": "iidalia@example.edu"}, + {"1": 5, "2": 2.345, "3": 2, "4": "James Jameson", "5": 80, "6": "jjameson@example.edu"}, + {"1": 6, "2": 1.234, "3": 3, "4": "Kelly Kellison", "5": 80, "6": "kkellison@example.edu"} + ], + "grouping": null, + "preview_data": { + "2": [ + {"key": 1.234, "summary": "Alice Alison"}, + {"key": 2.345, "summary": "Bob Bobinson"} + ], + "3": [ + {"key": 1, "summary": "Carol Carlson"}, + {"key": 2, "summary": "Dave Davidson"}, + {"key": 3, "summary": "Eve Evilson"} + ] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("Counselor") AS "2",', + ' msar.format_data("Teacher") AS "3", msar.format_data("Name") AS "4",', + ' msar.format_data("Grade") AS "5", msar.format_data("Email") AS "6"', + ' FROM public."Students" ORDER BY "1" ASC LIMIT NULL OFFSET NULL' + ) + ) + ); +END; +$$ LANGUAGE plpgsql; From 132598aad1402bad4a4352f0be2754010278902a Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 17:03:40 +0800 Subject: [PATCH 05/13] add limit and grouping tests for previews --- db/sql/test_00_msar.sql | 74 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 74 insertions(+) diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index 3604f74a7b..d194e42220 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -4157,5 +4157,79 @@ BEGIN ) ) ); + RETURN NEXT is( + msar.list_records_from_table( + tab_id => '"Students"'::regclass::oid, + limit_ => 3, + offset_ => 1, + order_ => null, + filter_ => null, + group_ => null + ), + $j${ + "count": 6, + "results": [ + {"1": 2, "2": 1.234, "3": 1, "4": "Gabby Gabberson", "5": 100, "6": "ggabberson@example.edu"}, + {"1": 3, "2": 1.234, "3": 2, "4": "Hank Hankson", "5": 75, "6": "hhankson@example.edu"}, + {"1": 4, "2": 2.345, "3": 1, "4": "Ida Idalia", "5": 90, "6": "iidalia@example.edu"} + ], + "grouping": null, + "preview_data": { + "2": [ + {"key": 1.234, "summary": "Alice Alison"}, + {"key": 2.345, "summary": "Bob Bobinson"} + ], + "3": [ + {"key": 1, "summary": "Carol Carlson"}, + {"key": 2, "summary": "Dave Davidson"} + ] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("Counselor") AS "2",', + ' msar.format_data("Teacher") AS "3", msar.format_data("Name") AS "4",', + ' msar.format_data("Grade") AS "5", msar.format_data("Email") AS "6"', + ' FROM public."Students" ORDER BY "1" ASC LIMIT ''3'' OFFSET ''1''' + ) + ) + ); + RETURN NEXT is( + msar.list_records_from_table( + tab_id => '"Students"'::regclass::oid, + limit_ => 2, + offset_ => null, + order_ => '[{"attnum": 2, "direction": "asc"}]', + filter_ => null, + group_ => '{"columns": [2]}' + ), + $j${ + "count": 6, + "results": [ + {"1": 2, "2": 1.234, "3": 1, "4": "Gabby Gabberson", "5": 100, "6": "ggabberson@example.edu"}, + {"1": 3, "2": 1.234, "3": 2, "4": "Hank Hankson", "5": 75, "6": "hhankson@example.edu"} + ], + "grouping": { + "columns": [2], + "preproc": null, + "groups": [{"id": 1, "count": 3, "results_eq": {"2": 1.234}, "result_indices": [0, 1]}] + }, + "preview_data": { + "2": [ + {"key": 1.234, "summary": "Alice Alison"} + ], + "3": [ + {"key": 1, "summary": "Carol Carlson"}, + {"key": 2, "summary": "Dave Davidson"} + ] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("Counselor") AS "2",', + ' msar.format_data("Teacher") AS "3", msar.format_data("Name") AS "4",', + ' msar.format_data("Grade") AS "5", msar.format_data("Email") AS "6"', + ' FROM public."Students" ORDER BY "2" ASC, "1" ASC LIMIT ''2'' OFFSET NULL' + ) + ) + ); END; $$ LANGUAGE plpgsql; From a1d8c3de003b55beebdedb9473aab4b4279376cd Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 18:05:32 +0800 Subject: [PATCH 06/13] expose preview results through RPC functions --- mathesar/rpc/records.py | 20 ++++++++++++++++---- mathesar/tests/rpc/test_records.py | 17 +++++++++++------ 2 files changed, 27 insertions(+), 10 deletions(-) diff --git a/mathesar/rpc/records.py b/mathesar/rpc/records.py index 39b8dbe173..2239b0aab3 100644 --- a/mathesar/rpc/records.py +++ b/mathesar/rpc/records.py @@ -127,6 +127,18 @@ class GroupingResponse(TypedDict): groups: list[Group] +class PreviewEntry(TypedDict): + """ + Preview entry object. Maps a foreign key to a text summary. + + Attributes: + key: The foreign key value. + summary: The summary of the referenced record. + """ + key: Any + summary: str + + class RecordList(TypedDict): """ Records from a table, along with some meta data @@ -145,7 +157,7 @@ class RecordList(TypedDict): count: int results: list[dict] grouping: GroupingResponse - preview_data: list[dict] + preview_data: dict[str, list[PreviewEntry]] @classmethod def from_dict(cls, d): @@ -153,7 +165,7 @@ def from_dict(cls, d): count=d["count"], results=d["results"], grouping=d.get("grouping"), - preview_data=[], + preview_data=d.get("preview_data"), query=d["query"], ) @@ -172,13 +184,13 @@ class RecordAdded(TypedDict): preview_data: Information for previewing foreign key values. """ results: list[dict] - preview_data: list[dict] + preview_data: dict[str, list[PreviewEntry]] @classmethod def from_dict(cls, d): return cls( results=d["results"], - preview_data=[], + preview_data=d.get("preview_data"), ) diff --git a/mathesar/tests/rpc/test_records.py b/mathesar/tests/rpc/test_records.py index 14bfbe5f74..7a9099a4df 100644 --- a/mathesar/tests/rpc/test_records.py +++ b/mathesar/tests/rpc/test_records.py @@ -49,7 +49,8 @@ def mock_list_records( "groups": [ {"id": 3, "count": 8, "results_eq": {"1": "lsfj", "2": 3422}} ] - } + }, + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, } monkeypatch.setattr(records, 'connect', mock_connect) @@ -63,7 +64,7 @@ def mock_list_records( {"id": 3, "count": 8, "results_eq": {"1": "lsfj", "2": 3422}} ] }, - "preview_data": [], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', } actual_records_list = records.list_( @@ -103,6 +104,7 @@ def mock_get_record( "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', "grouping": None, + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, } monkeypatch.setattr(records, 'connect', mock_connect) @@ -111,7 +113,7 @@ def mock_get_record( "count": 1, "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], "grouping": None, - "preview_data": [], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', } actual_record = records.get( @@ -148,13 +150,14 @@ def mock_add_record( raise AssertionError('incorrect parameters passed') return { "results": [_record_def], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, } monkeypatch.setattr(records, 'connect', mock_connect) monkeypatch.setattr(records.record_insert, 'add_record_to_table', mock_add_record) expect_record = { "results": [record_def], - "preview_data": [], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, } actual_record = records.add( record_def=record_def, table_oid=table_oid, database_id=database_id, request=request @@ -192,13 +195,14 @@ def mock_patch_record( raise AssertionError('incorrect parameters passed') return { "results": [_record_def | {"3": "another"}], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, } 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": [], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, } actual_record = records.patch( record_def=record_def, @@ -276,6 +280,7 @@ def mock_search_records( return { "count": 50123, "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', } @@ -285,7 +290,7 @@ def mock_search_records( "count": 50123, "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], "grouping": None, - "preview_data": [], + "preview_data": {"2": [{"key": 12345, "summary": "blkjdfslkj"}]}, "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', } actual_records_list = records.search( From 13c6511cac2eeb776a93bf6389996d1fd9125233 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 18:30:53 +0800 Subject: [PATCH 07/13] add record previewing into record adder function --- db/sql/00_msar.sql | 14 +++++++---- db/sql/test_00_msar.sql | 51 +++++++++++++++++++++++++++++++++++++---- 2 files changed, 56 insertions(+), 9 deletions(-) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 79e57bec87..07d8df1126 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3970,13 +3970,19 @@ DECLARE BEGIN EXECUTE format( $i$ - WITH insert_cte AS (%1$s RETURNING %2$s) - SELECT jsonb_build_object('results', %3$s) - FROM insert_cte + WITH insert_cte AS (%1$s RETURNING %2$s)%4$s + SELECT jsonb_build_object( + 'results', %3$s, + 'preview_data', %6$s + ) + FROM insert_cte %5$s $i$, msar.build_single_insert_expr(tab_id, rec_def), msar.build_selectable_column_expr(tab_id), - msar.build_results_jsonb_expr(tab_id, 'insert_cte', null) + msar.build_results_jsonb_expr(tab_id, 'insert_cte', null), + msar.build_summary_cte_expr_for_table(tab_id), + msar.build_summary_join_expr_for_table(tab_id, 'insert_cte'), + COALESCE(msar.build_summary_json_expr_for_table(tab_id), 'NULL') ) INTO rec_created; RETURN rec_created; END; diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index d194e42220..740d9a91cd 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -3951,7 +3951,10 @@ BEGIN rel_id, '{"2": 234, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}' ), - '{"results": [{"1": 4, "2": 234, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}]}' + $a${ + "results": [{"1": 4, "2": 234, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}], + "preview_data": null + }$a$ ); END; $$ LANGUAGE plpgsql; @@ -3968,7 +3971,10 @@ BEGIN rel_id, '{"2": 234, "3": "ab234", "4": {"key": "val"}, "5": "{\"key2\": \"val2\"}"}' ), - '{"results": [{"1": 4, "2": 234, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}]}' + $a${ + "results": [{"1": 4, "2": 234, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}], + "preview_data": null + }$a$ ); END; $$ LANGUAGE plpgsql; @@ -3985,7 +3991,10 @@ BEGIN rel_id, '{"3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}' ), - '{"results": [{"1": 4, "2": 200, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}]}' + $a${ + "results": [{"1": 4, "2": 200, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}], + "preview_data": null + }$a$ ); END; $$ LANGUAGE plpgsql; @@ -4002,7 +4011,10 @@ BEGIN rel_id, '{"2": null, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}' ), - '{"results": [{"1": 4, "2": null, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}]}' + $a${ + "results": [{"1": 4, "2": null, "3": "ab234", "4": {"key": "val"}, "5": {"key2": "val2"}}], + "preview_data": null + }$a$ ); END; $$ LANGUAGE plpgsql; @@ -4019,7 +4031,10 @@ BEGIN rel_id, '{"2": null, "3": "ab234", "4": 3, "5": "\"234\""}' ), - '{"results": [{"1": 4, "2": null, "3": "ab234", "4": 3, "5": "234"}]}' + $a${ + "results": [{"1": 4, "2": null, "3": "ab234", "4": 3, "5": "234"}], + "preview_data": null + }$a$ ); END; $$ LANGUAGE plpgsql; @@ -4233,3 +4248,29 @@ BEGIN ); END; $$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION test_add_record_to_table_with_preview() RETURNS SETOF TEXT AS $$ +BEGIN + PERFORM __setup_preview_fkey_cols(); + RETURN NEXT is( + msar.add_record_to_table( + '"Students"'::regclass::oid, + '{"2": 2.345, "3": 1, "4": "Larry Laurelson", "5": 70, "6": "llaurelson@example.edu"}' + ), + $a${ + "results": [ + {"1": 7, "2": 2.345, "3": 1, "4": "Larry Laurelson", "5": 70, "6": "llaurelson@example.edu"} + ], + "preview_data": { + "2": [ + {"key": 2.345, "summary": "Bob Bobinson"} + ], + "3": [ + {"key": 1, "summary": "Carol Carlson"} + ] + } + }$a$ + ); +END; +$$ LANGUAGE plpgsql; From 619cd4686cc362073e5cbcbdc90fb98bed91595d Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 22:04:05 +0800 Subject: [PATCH 08/13] add record summaries into record patching function --- db/sql/00_msar.sql | 14 ++++++++++---- db/sql/test_00_msar.sql | 41 +++++++++++++++++++++++++++++++++-------- 2 files changed, 43 insertions(+), 12 deletions(-) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 07d8df1126..69a9dfb865 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -4022,9 +4022,12 @@ DECLARE 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 + WITH update_cte AS (%1$s %2$s RETURNING %3$s)%5$s + SELECT jsonb_build_object( + 'results', %4$s, + 'preview_data', %7$s + ) + FROM update_cte %6$s $i$, msar.build_update_expr(tab_id, rec_def), msar.build_where_clause( @@ -4036,7 +4039,10 @@ BEGIN ) ), msar.build_selectable_column_expr(tab_id), - msar.build_results_jsonb_expr(tab_id, 'update_cte', null) + msar.build_results_jsonb_expr(tab_id, 'update_cte', null), + msar.build_summary_cte_expr_for_table(tab_id), + msar.build_summary_join_expr_for_table(tab_id, 'update_cte'), + COALESCE(msar.build_summary_json_expr_for_table(tab_id), 'NULL') ) INTO rec_modified; RETURN rec_modified; END; diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index 740d9a91cd..0cc52aabfb 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -4048,7 +4048,10 @@ BEGIN 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]}]}' + $p${ + "results": [{"1": 2, "2": 10, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}], + "preview_data": null + }$p$ ); END; $$ LANGUAGE plpgsql; @@ -4062,7 +4065,10 @@ BEGIN 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]}]}' + $p${ + "results": [{"1": 2, "2": 10, "3": "sdflfflsk", "4": {"a": "json"}, "5": [1, 2, 3, 4]}], + "preview_data": null + }$p$ ); END; $$ LANGUAGE plpgsql; @@ -4263,12 +4269,31 @@ BEGIN {"1": 7, "2": 2.345, "3": 1, "4": "Larry Laurelson", "5": 70, "6": "llaurelson@example.edu"} ], "preview_data": { - "2": [ - {"key": 2.345, "summary": "Bob Bobinson"} - ], - "3": [ - {"key": 1, "summary": "Carol Carlson"} - ] + "2": [{"key": 2.345, "summary": "Bob Bobinson"}], + "3": [{"key": 1, "summary": "Carol Carlson"}] + } + }$a$ + ); +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION test_patch_record_in_table_with_preview() RETURNS SETOF TEXT AS $$ +BEGIN + PERFORM __setup_preview_fkey_cols(); + RETURN NEXT is( + msar.patch_record_in_table( + '"Students"'::regclass::oid, + 2, + '{"2": 2.345, "3": 2, "5": 85}' + ), + $a${ + "results": [ + {"1": 2, "2": 2.345, "3": 2, "4": "Gabby Gabberson", "5": 85, "6": "ggabberson@example.edu"} + ], + "preview_data": { + "2": [{"key": 2.345, "summary": "Bob Bobinson"}], + "3": [{"key": 2, "summary": "Dave Davidson"}] } }$a$ ); From 12d6e8f88cbcaebe4e06716f798ab4bfd24954d0 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 22:15:19 +0800 Subject: [PATCH 09/13] add test for previews in record searching --- db/sql/test_00_msar.sql | 18 ++++++++++++++++++ 1 file changed, 18 insertions(+) diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index 0cc52aabfb..3544bead5b 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -4299,3 +4299,21 @@ BEGIN ); END; $$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION test_search_records_in_table_with_preview() RETURNS SETOF TEXT AS $$ +BEGIN + PERFORM __setup_preview_fkey_cols(); + RETURN NEXT is( + msar.search_records_from_table( + '"Students"'::regclass::oid, + '[{"attnum": 4, "literal": "k"}]', + 2 + ) -> 'preview_data', + $a${ + "2": [{"key": 1.234, "summary": "Alice Alison"}, {"key": 2.345, "summary": "Bob Bobinson"}], + "3": [{"key": 3, "summary": "Eve Evilson"}] + }$a$ + ); +END; +$$ LANGUAGE plpgsql; From 04409c5826535a2ee0c921a705d7bdb9ecb3eb56 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 22:50:06 +0800 Subject: [PATCH 10/13] fix edge-case bug involving multitarget fkeys --- db/sql/00_msar.sql | 12 ++++++++++-- 1 file changed, 10 insertions(+), 2 deletions(-) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 69a9dfb865..7d11c1b9ea 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3657,8 +3657,16 @@ $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION msar.get_fkey_map_cte(tab_id oid) RETURNS TABLE (target_oid oid, conkey smallint, confkey smallint) AS $$/* +Generate a table mapping foreign key values from refererrer to referant tables. + +Given an input table (identified by OID), we return a table with each row representing a foreign key +constraint on that table. We return only single-column foreign keys, and only one per foreign key +column. + +Args: + tab_id: The OID of the table containing the foreign key columns to map. */ -SELECT pgc.confrelid AS target_oid, x.conkey AS conkey, min(y.confkey) AS confkey +SELECT DISTINCT ON (conkey) pgc.confrelid AS target_oid, x.conkey AS conkey, y.confkey AS confkey FROM pg_constraint pgc, LATERAL unnest(conkey) x(conkey), LATERAL unnest(confkey) y(confkey) WHERE pgc.conrelid = tab_id @@ -3666,7 +3674,7 @@ WHERE AND cardinality(pgc.confkey) = 1 AND has_column_privilege(tab_id, x.conkey, 'SELECT') AND has_column_privilege(pgc.confrelid, y.confkey, 'SELECT') -GROUP BY pgc.confrelid, x.conkey +ORDER BY conkey, target_oid, confkey; $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; From 56f93b394c2c6aa01e7e63435f57e350531d6c51 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Mon, 19 Aug 2024 22:56:06 +0800 Subject: [PATCH 11/13] add SQL function docstrings --- db/sql/00_msar.sql | 15 +++++++++++++++ 1 file changed, 15 insertions(+) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 7d11c1b9ea..1bfeaa6843 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3679,6 +3679,12 @@ $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION msar.build_summary_cte_expr_for_table(tab_id oid) RETURNS TEXT AS $$/* +Build an SQL text expression defining a sequence of CTEs that give summaries for linked records. + +This summary amounts to just the first string-like column value for that linked record. + +Args: + tab_oid: The table for whose fkey values' linked records we'll get summaries. */ WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) SELECT ', ' || string_agg( @@ -3702,6 +3708,11 @@ $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION msar.build_summary_join_expr_for_table(tab_id oid, cte_name text) RETURNS TEXT AS $$/* +Build an SQL expression to join the summary CTEs to the main CTE along fkey values. + +Args: + tab_oid: The table defining the columns of the main CTE. + cte_name: The name of the main CTE we'll join the summary CTEs to. */ WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) SELECT string_agg( @@ -3718,6 +3729,10 @@ $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION msar.build_summary_json_expr_for_table(tab_id oid) RETURNS TEXT AS $$/* +Build a JSON object with the results of summarizing linked records. + +Args: + tab_oid: The OID of the table for which we're getting linked record summaries. */ WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) SELECT 'jsonb_build_object(' || string_agg( From a2651f6e2611f05976a4a637f64b45bc4258a387 Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Tue, 20 Aug 2024 01:15:37 +0800 Subject: [PATCH 12/13] add preview object to docs --- docs/docs/api/rpc.md | 1 + 1 file changed, 1 insertion(+) diff --git a/docs/docs/api/rpc.md b/docs/docs/api/rpc.md index 1dc1378d00..972c12f7fd 100644 --- a/docs/docs/api/rpc.md +++ b/docs/docs/api/rpc.md @@ -203,6 +203,7 @@ To use an RPC function: - Filter - FilterAttnum - FilterLiteral + - PreviewEntry - Grouping - Group - GroupingResponse From 6a7e991b54f0d7be2e79d77e16b406492feb2d8d Mon Sep 17 00:00:00 2001 From: Brent Moran Date: Fri, 23 Aug 2024 13:29:07 +0800 Subject: [PATCH 13/13] extract summary building logic to separate function for clarity --- db/sql/00_msar.sql | 19 ++++++++++++++++--- 1 file changed, 16 insertions(+), 3 deletions(-) diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 8e82f6d8c0..e3afe32ef7 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3821,13 +3821,26 @@ ORDER BY conkey, target_oid, confkey; $$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; +CREATE OR REPLACE FUNCTION msar.build_summary_expr(tab_id oid) RETURNS TEXT AS $$/* +Given a table, return an SQL expression that will build a summary for each row of the table. + +Args: + tab_id: The OID of the table being summarized. +*/ +SELECT format( + 'msar.format_data(%I)::text', + msar.get_column_name(tab_id, msar.get_default_summary_column(tab_id)) +); +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + CREATE OR REPLACE FUNCTION msar.build_summary_cte_expr_for_table(tab_id oid) RETURNS TEXT AS $$/* Build an SQL text expression defining a sequence of CTEs that give summaries for linked records. This summary amounts to just the first string-like column value for that linked record. Args: - tab_oid: The table for whose fkey values' linked records we'll get summaries. + tab_id: The table for whose fkey values' linked records we'll get summaries. */ WITH fkey_map_cte AS (SELECT * FROM msar.get_fkey_map_cte(tab_id)) SELECT ', ' || string_agg( @@ -3835,12 +3848,12 @@ SELECT ', ' || string_agg( $c$summary_cte_%1$s AS ( SELECT msar.format_data(%2$I) AS key, - msar.format_data(%3$I)::text AS summary + %3$s AS summary FROM %4$I.%5$I )$c$, conkey, msar.get_column_name(target_oid, confkey), - msar.get_column_name(target_oid, msar.get_default_summary_column(target_oid)), + msar.build_summary_expr(target_oid), msar.get_relation_schema_name(target_oid), msar.get_relation_name(target_oid) ), ', '