diff --git a/db/sql/00_msar.sql b/db/sql/00_msar.sql index 6b4edc9dab..e860b15dd8 100644 --- a/db/sql/00_msar.sql +++ b/db/sql/00_msar.sql @@ -3239,12 +3239,12 @@ $f$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION msar.format_data(val date) RETURNS text AS $$ SELECT to_char(val, 'YYYY-MM-DD AD'); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.format_data(val time without time zone) RETURNS text AS $$ SELECT concat(to_char(val, 'HH24:MI'), ':', to_char(date_part('seconds', val), 'FM00.0999999999')); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.format_data(val time with time zone) RETURNS text AS $$ @@ -3262,7 +3262,7 @@ SELECT CASE ltrim(to_char(date_part('timezone_minute', val), '00'), '+- ') ) END; -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.format_data(val timestamp without time zone) RETURNS text AS $$ @@ -3272,7 +3272,7 @@ SELECT ':', to_char(date_part('seconds', val), 'FM00.0999999999'), to_char(val, ' BC') ); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.format_data(val timestamp with time zone) RETURNS text AS $$ @@ -3290,19 +3290,19 @@ SELECT CASE ':', ltrim(to_char(date_part('timezone_minute', val), '00'), '+- '), to_char(val, ' BC') ) END; -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.format_data(val interval) returns text AS $$ SELECT concat( to_char(val, 'PFMYYYY"Y"FMMM"M"FMDD"D""T"FMHH24"H"FMMI"M"'), date_part('seconds', val), 'S' ); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.format_data(val anyelement) returns anyelement AS $$ SELECT val; -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; DROP TABLE IF EXISTS msar.expr_templates; @@ -3327,6 +3327,10 @@ INSERT INTO msar.expr_templates VALUES -- json(b) filters and expressions ('json_array_length', 'jsonb_array_length((%s)::jsonb)'), ('json_array_contains', '(%s)::jsonb @> (%s)::jsonb'), + -- date part extractors + ('truncate_to_year', 'to_char((%s)::date, ''YYYY AD'')'), + ('truncate_to_month', 'to_char((%s)::date, ''YYYY-MM AD'')'), + ('truncate_to_day', 'to_char((%s)::date, ''YYYY-MM-DD AD'')'), -- URI part getters ('uri_scheme', 'mathesar_types.uri_scheme(%s)'), ('uri_authority', 'mathesar_types.uri_authority(%s)'), @@ -3343,12 +3347,12 @@ SELECT CASE tree ->> 'type' END FROM jsonb_array_elements(tree -> 'args') inner_tree, msar.expr_templates WHERE tree ->> 'type' = expr_key -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION msar.build_where_clause(rel_id oid, tree jsonb) RETURNS text AS $$ SELECT 'WHERE ' || msar.build_expr(rel_id, tree); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION @@ -3358,14 +3362,14 @@ SELECT CASE lower(direction) WHEN 'asc' THEN 'ASC' WHEN 'desc' THEN 'DESC' END; -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT PARALLEL SAFE; CREATE OR REPLACE FUNCTION msar.get_pkey_order(tab_id oid) RETURNS jsonb AS $$ SELECT jsonb_agg(jsonb_build_object('attnum', attnum, 'direction', 'asc')) FROM pg_constraint, LATERAL unnest(conkey) attnum WHERE contype='p' AND conrelid=tab_id AND has_column_privilege(tab_id, attnum, 'SELECT'); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION msar.get_total_order(tab_id oid) RETURNS jsonb AS $$ @@ -3395,7 +3399,7 @@ SELECT COALESCE(jsonb_agg(jsonb_build_object('attnum', attnum, 'direction', 'asc FROM orderable_cte -- This privilege check is redundant in context, but may be useful for other callers. WHERE has_column_privilege(tab_id, attnum, 'SELECT'); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION @@ -3414,7 +3418,7 @@ FROM jsonb_to_recordset( ) AS x(attnum smallint, direction text) WHERE has_column_privilege(tab_id, attnum, 'SELECT'); -$$ LANGUAGE SQL; +$$ LANGUAGE SQL STABLE; CREATE OR REPLACE FUNCTION @@ -3431,7 +3435,128 @@ Args: order_: A JSONB array defining any desired ordering of columns. */ SELECT 'ORDER BY ' || msar.build_total_order_expr(tab_id, order_) -$$ LANGUAGE SQL; +$$ LANGUAGE SQL STABLE; + + +CREATE OR REPLACE FUNCTION +msar.build_grouping_columns_expr(tab_id oid, group_ jsonb) RETURNS TEXT AS $$/* +Build a column expression for use in grouping window functions. + +Args: + tab_id: The OID of the table whose records we're grouping + group_ A grouping definition. + +The group_ object should have the form + { + "columns": [, , ...] + "preproc": [, , ...] + } + +The items in the preproc array should be keys appearing in the +`expr_templates` table. The corresponding column will be wrapped +in the preproc function before grouping. +*/ +SELECT string_agg( + COALESCE( + format(expr_template, quote_ident(msar.get_column_name(tab_id, col_id::smallint))), + quote_ident(msar.get_column_name(tab_id, col_id::smallint)) + ), ', ' ORDER BY ordinality +) +FROM msar.expr_templates RIGHT JOIN ROWS FROM( + jsonb_array_elements_text(group_ -> 'columns'), + jsonb_array_elements_text(group_ -> 'preproc') +) WITH ORDINALITY AS x(col_id, preproc) ON expr_key = preproc +WHERE has_column_privilege(tab_id, col_id::smallint, 'SELECT'); +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION +msar.build_group_id_expr(tab_id oid, group_ jsonb) RETURNS TEXT AS $$/* +Build an expression to define an id value for each group. +*/ +SELECT 'dense_rank() OVER (ORDER BY ' || msar.build_grouping_columns_expr(tab_id, group_) || ')'; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION +msar.build_group_count_expr(tab_id oid, group_ jsonb) RETURNS TEXT AS $$/* +Build an expression that adds a column with a count for each group. +*/ +SELECT 'count(1) OVER (PARTITION BY ' || msar.build_grouping_columns_expr(tab_id, group_) || ')'; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; + + +CREATE OR REPLACE FUNCTION +msar.build_grouping_expr(tab_id oid, group_ jsonb) RETURNS TEXT AS $$/* +Build an expression composed of an id and count for each group. + +A group is defined by distinct combinations of the (potentially transformed by preproc functions) +columns passed in `group_`. +*/ +SELECT concat( + COALESCE(msar.build_group_id_expr(tab_id, group_), 'NULL'), ' AS __mathesar_gid, ', + COALESCE(msar.build_group_count_expr(tab_id, group_), 'NULL'), ' AS __mathesar_gcount' +); +$$ LANGUAGE SQL STABLE; + + +CREATE OR REPLACE FUNCTION +msar.build_results_jsonb_expr(tab_id oid, cte_name text) RETURNS TEXT AS $$/* +Build an SQL expresson string that, when added to the record listing query, produces a JSON array +with the records resulting from the request. +*/ +SELECT 'coalesce(jsonb_agg(json_build_object(' + || string_agg(format('%1$L, %2$I.%1$I', attnum, cte_name), ', ') + || ')), jsonb_build_array())' +FROM pg_catalog.pg_attribute +WHERE + attrelid = tab_id + AND attnum > 0 + AND NOT attisdropped + AND has_column_privilege(attrelid, attnum, 'SELECT'); +$$ LANGUAGE SQL STABLE; + + +CREATE OR REPLACE FUNCTION +msar.build_grouping_results_jsonb_expr(tab_id oid, cte_name text, group_ jsonb) RETURNS TEXT AS $$/* +Build an SQL expresson string that, when added to the record listing query, produces a JSON array +with the groups resulting from the request. +*/ +SELECT format( + $gj$ + jsonb_build_object( + 'columns', %3$L::jsonb, + 'preproc', %4$L::jsonb, + 'groups', jsonb_agg( + DISTINCT jsonb_build_object( + 'id', %2$I.__mathesar_gid, + 'count', %2$I.__mathesar_gcount, + 'results_eq', jsonb_build_object(%1$s) + ) + ) + ) + $gj$, + string_agg( + format( + '%1$L, %2$s', + col_id, + COALESCE( + format(expr_template, quote_ident(cte_name) || '.' || quote_ident(col_id)), + quote_ident(cte_name) || '.' || quote_ident(col_id) + ) + ), + ', ' ORDER BY ordinality + ), + cte_name, + group_ ->> 'columns', + group_ ->> 'preproc' +) +FROM msar.expr_templates RIGHT JOIN ROWS FROM( + jsonb_array_elements_text(group_ -> 'columns'), + jsonb_array_elements_text(group_ -> 'preproc') +) WITH ORDINALITY AS x(col_id, preproc) ON expr_key = preproc +WHERE has_column_privilege(tab_id, col_id::smallint, 'SELECT'); +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION @@ -3453,7 +3578,7 @@ WHERE AND attnum > 0 AND NOT attisdropped AND has_column_privilege(attrelid, attnum, 'SELECT'); -$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT; +$$ LANGUAGE SQL STABLE RETURNS NULL ON NULL INPUT; CREATE OR REPLACE FUNCTION @@ -3485,15 +3610,16 @@ BEGIN $q$ WITH count_cte AS ( SELECT count(1) AS count FROM %2$I.%3$I %7$s - ), results_cte AS ( - SELECT %1$s FROM %2$I.%3$I %7$s %6$s LIMIT %4$L OFFSET %5$L + ), enriched_results_cte AS ( + SELECT %1$s, %8$s FROM %2$I.%3$I %7$s %6$s LIMIT %4$L OFFSET %5$L ) SELECT jsonb_build_object( - 'results', coalesce(jsonb_agg(row_to_json(results_cte.*)), jsonb_build_array()), + 'results', %9$s, 'count', coalesce(max(count_cte.count), 0), + 'grouping', %10$s, '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 + FROM enriched_results_cte, count_cte $q$, msar.build_selectable_column_expr(tab_id), msar.get_relation_schema_name(tab_id), @@ -3501,11 +3627,14 @@ BEGIN limit_, offset_, msar.build_order_by_expr(tab_id, order_), - msar.build_where_clause(tab_id, filter_) + msar.build_where_clause(tab_id, filter_), + msar.build_grouping_expr(tab_id, group_), + msar.build_results_jsonb_expr(tab_id, 'enriched_results_cte'), + COALESCE(msar.build_grouping_results_jsonb_expr(tab_id, 'enriched_results_cte', group_), 'NULL') ) INTO records; RETURN records; END; -$$ LANGUAGE plpgsql; +$$ LANGUAGE plpgsql STABLE; CREATE OR REPLACE FUNCTION diff --git a/db/sql/test_00_msar.sql b/db/sql/test_00_msar.sql index ec41be6652..c5c107cbee 100644 --- a/db/sql/test_00_msar.sql +++ b/db/sql/test_00_msar.sql @@ -2890,6 +2890,42 @@ END; $$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION __setup_customers_table() RETURNS SETOF TEXT AS $$ +BEGIN +CREATE TABLE "Customers" ( + id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + "First Name" text, + "Last Name" text, + "Subscription Date" date, + "dropmeee 1" text +); +ALTER TABLE "Customers" DROP COLUMN "dropmeee 1"; +INSERT INTO "Customers" ("First Name", "Last Name", "Subscription Date") VALUES + ('Aaron', 'Adams', '2020-03-21'), + ('Abigail', 'Acosta', '2020-04-16'), + ('Aaron', 'Adams', '2020-04-29'), + ('Abigail', 'Adams', '2020-05-29'), + ('Abigail', 'Abbott', '2020-07-05'), + ('Aaron', 'Adkins', '2020-08-16'), + ('Aaron', 'Acevedo', '2020-10-29'), + ('Abigail', 'Abbott', '2020-10-30'), + ('Abigail', 'Adams', '2021-02-14'), + ('Abigail', 'Acevedo', '2021-03-29'), + ('Aaron', 'Acosta', '2021-04-13'), + ('Aaron', 'Adams', '2021-06-30'), + ('Abigail', 'Adkins', '2021-09-12'), + ('Aaron', 'Adams', '2021-11-11'), + ('Abigail', 'Abbott', '2021-11-30'), + ('Aaron', 'Acevedo', '2022-02-04'), + ('Aaron', 'Adkins', '2022-03-10'), + ('Abigail', 'Abbott', '2022-03-23'), + ('Abigail', 'Adkins', '2022-03-27'), + ('Abigail', 'Abbott', '2022-04-29'), + ('Abigail', 'Adams', '2022-05-24'); +END; +$$ LANGUAGE plpgsql; + + CREATE OR REPLACE FUNCTION test_list_records_from_table() RETURNS SETOF TEXT AS $$ DECLARE rel_id oid; @@ -2897,14 +2933,22 @@ BEGIN PERFORM __setup_list_records_table(); rel_id := 'atable'::regclass::oid; RETURN NEXT is( - msar.list_records_from_table(rel_id, null, null, null, null, null), + msar.list_records_from_table( + tab_id => rel_id, + limit_ => null, + offset_ => null, + order_ => null, + filter_ => null, + group_ => null + ), $j${ "count": 3, "results": [ {"1": 1, "2": 5, "3": "sdflkj", "4": "s", "5": {"a": "val"}}, {"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 }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",' @@ -2916,14 +2960,20 @@ BEGIN ); RETURN NEXT is( msar.list_records_from_table( - rel_id, 2, null, '[{"attnum": 2, "direction": "desc"}]', null, null + tab_id => rel_id, + limit_ => 2, + offset_ => null, + order_ => '[{"attnum": 2, "direction": "desc"}]', + filter_ => null, + group_ => null ), $j${ "count": 3, "results": [ {"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 }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",' @@ -2935,14 +2985,20 @@ BEGIN ); RETURN NEXT is( msar.list_records_from_table( - rel_id, null, 1, '[{"attnum": 1, "direction": "desc"}]', null, null + tab_id => rel_id, + limit_ => null, + offset_ => 1, + order_ => '[{"attnum": 1, "direction": "desc"}]', + filter_ => null, + group_ => null ), $j${ "count": 3, "results": [ {"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 }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(id) AS "1", msar.format_data(col1) AS "2",', @@ -2958,14 +3014,22 @@ BEGIN GRANT SELECT (col1, col2, col3, col4) ON TABLE atable TO intern_no_pkey; SET ROLE intern_no_pkey; RETURN NEXT is( - msar.list_records_from_table(rel_id, null, null, null, null, null), + msar.list_records_from_table( + tab_id => rel_id, + limit_ => null, + offset_ => null, + order_ => null, + filter_ => null, + group_ => null + ), $j${ "count": 3, "results": [ {"2": 2, "3": "abcde", "4": {"k": 3242348}, "5": true}, {"2": 5, "3": "sdflkj", "4": "s", "5": {"a": "val"}}, {"2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]} - ] + ], + "grouping": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(col1) AS "2", msar.format_data(col2) AS "3",', @@ -2976,7 +3040,12 @@ BEGIN ); RETURN NEXT is( msar.list_records_from_table( - rel_id, null, null, '[{"attnum": 3, "direction": "desc"}]', null, null + tab_id => rel_id, + limit_ => null, + offset_ => null, + order_ => '[{"attnum": 3, "direction": "desc"}]', + filter_ => null, + group_ => null ), $j${ "count": 3, @@ -2984,7 +3053,8 @@ BEGIN {"2": 5, "3": "sdflkj", "4": "s", "5": {"a": "val"}}, {"2": 34, "3": "sdflfflsk", "4": null, "5": [1, 2, 3, 4]}, {"2": 2, "3": "abcde", "4": {"k": 3242348}, "5": true} - ] + ], + "grouping": null }$j$ || jsonb_build_object( 'query', concat( 'SELECT msar.format_data(col1) AS "2", msar.format_data(col2) AS "3",', @@ -2997,6 +3067,152 @@ END; $$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION test_list_records_with_grouping() RETURNS SETOF TEXT AS $$ +DECLARE + rel_id oid; +BEGIN + PERFORM __setup_customers_table(); + rel_id := '"Customers"'::regclass::oid; + RETURN NEXT is( + msar.list_records_from_table( + tab_id => rel_id, + limit_ => 10, + offset_ => null, + order_ => '[{"attnum": 3, "direction": "asc"}, {"attnum": 2, "direction": "asc"}]', + filter_ => null, + group_ => '{"columns": [3, 2]}' + ), + $j${ + "count": 21, + "results": [ + {"1": 5, "2": "Abigail", "3": "Abbott", "4": "2020-07-05 AD"}, + {"1": 8, "2": "Abigail", "3": "Abbott", "4": "2020-10-30 AD"}, + {"1": 15, "2": "Abigail", "3": "Abbott", "4": "2021-11-30 AD"}, + {"1": 18, "2": "Abigail", "3": "Abbott", "4": "2022-03-23 AD"}, + {"1": 20, "2": "Abigail", "3": "Abbott", "4": "2022-04-29 AD"}, + {"1": 7, "2": "Aaron", "3": "Acevedo", "4": "2020-10-29 AD"}, + {"1": 16, "2": "Aaron", "3": "Acevedo", "4": "2022-02-04 AD"}, + {"1": 10, "2": "Abigail", "3": "Acevedo", "4": "2021-03-29 AD"}, + {"1": 11, "2": "Aaron", "3": "Acosta", "4": "2021-04-13 AD"}, + {"1": 2, "2": "Abigail", "3": "Acosta", "4": "2020-04-16 AD"} + ], + "grouping": { + "columns": [3, 2], + "preproc": null, + "groups": [ + {"id": 1, "count": 5, "results_eq": {"2": "Abigail", "3": "Abbott"}}, + {"id": 2, "count": 2, "results_eq": {"2": "Aaron", "3": "Acevedo"}}, + {"id": 3, "count": 1, "results_eq": {"2": "Abigail", "3": "Acevedo"}}, + {"id": 4, "count": 1, "results_eq": {"2": "Aaron", "3": "Acosta"}}, + {"id": 5, "count": 1, "results_eq": {"2": "Abigail", "3": "Acosta"}} + ] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' + ' msar.format_data("Last Name") AS "3", msar.format_data("Subscription Date") AS "4"' + ' FROM public."Customers" ORDER BY "3" ASC, "2" ASC, "1" ASC LIMIT ''10'' OFFSET NULL' + ) + ) + ); + RETURN NEXT is( + msar.list_records_from_table( + tab_id => rel_id, + limit_ => 3, + offset_ => null, + order_ => '[{"attnum": 3, "direction": "asc"}, {"attnum": 2, "direction": "asc"}]', + filter_ => null, + group_ => '{"columns": [3, 2]}' + ), + $j${ + "count": 21, + "results": [ + {"1": 5, "2": "Abigail", "3": "Abbott", "4": "2020-07-05 AD"}, + {"1": 8, "2": "Abigail", "3": "Abbott", "4": "2020-10-30 AD"}, + {"1": 15, "2": "Abigail", "3": "Abbott", "4": "2021-11-30 AD"} + ], + "grouping": { + "columns": [3, 2], + "preproc": null, + "groups": [ + {"id": 1, "count": 5, "results_eq": {"2": "Abigail", "3": "Abbott"}} + ] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' + ' msar.format_data("Last Name") AS "3", msar.format_data("Subscription Date") AS "4"' + ' FROM public."Customers" ORDER BY "3" ASC, "2" ASC, "1" ASC LIMIT ''3'' OFFSET NULL' + ) + ) + ); + RETURN NEXT is( + msar.list_records_from_table( + tab_id => rel_id, + limit_ => 3, + offset_ => null, + order_ => '[{"attnum": 4, "direction": "asc"}]', + filter_ => null, + group_ => '{"columns": [4], "preproc": ["truncate_to_month"]}' + ), + $j${ + "count": 21, + "results": [ + {"1": 1, "2": "Aaron", "3": "Adams", "4": "2020-03-21 AD"}, + {"1": 2, "2": "Abigail", "3": "Acosta", "4": "2020-04-16 AD"}, + {"1": 3, "2": "Aaron", "3": "Adams", "4": "2020-04-29 AD"} + ], + "grouping": { + "columns": [4], + "preproc": ["truncate_to_month"], + "groups": [ + {"id": 1, "count": 1, "results_eq": {"4": "2020-03 AD"}}, + {"id": 2, "count": 2, "results_eq": {"4": "2020-04 AD"}} + ] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' + ' msar.format_data("Last Name") AS "3", msar.format_data("Subscription Date") AS "4"' + ' FROM public."Customers" ORDER BY "4" ASC, "1" ASC LIMIT ''3'' OFFSET NULL' + ) + ) + ); + RETURN NEXT is( + msar.list_records_from_table( + tab_id => rel_id, + limit_ => 5, + offset_ => null, + order_ => '[{"attnum": 4, "direction": "asc"}]', + filter_ => null, + group_ => '{"columns": [4], "preproc": ["truncate_to_year"]}' + ), + $j${ + "count": 21, + "results": [ + {"1": 1, "2": "Aaron", "3": "Adams", "4": "2020-03-21 AD"}, + {"1": 2, "2": "Abigail", "3": "Acosta", "4": "2020-04-16 AD"}, + {"1": 3, "2": "Aaron", "3": "Adams", "4": "2020-04-29 AD"}, + {"1": 4, "2": "Abigail", "3": "Adams", "4": "2020-05-29 AD"}, + {"1": 5, "2": "Abigail", "3": "Abbott", "4": "2020-07-05 AD"} + ], + "grouping": { + "columns": [4], + "preproc": ["truncate_to_year"], + "groups": [{"id": 1, "count": 8, "results_eq": {"4": "2020 AD"}}] + } + }$j$ || jsonb_build_object( + 'query', concat( + 'SELECT msar.format_data(id) AS "1", msar.format_data("First Name") AS "2",' + ' msar.format_data("Last Name") AS "3", msar.format_data("Subscription Date") AS "4"' + ' FROM public."Customers" ORDER BY "4" ASC, "1" ASC LIMIT ''5'' OFFSET NULL' + ) + ) + ); +END; +$$ LANGUAGE plpgsql; + + -- msar.build_order_by_expr ------------------------------------------------------------------------ CREATE OR REPLACE FUNCTION test_build_order_by_expr() RETURNS SETOF TEXT AS $$ @@ -3032,7 +3248,7 @@ END; $$ LANGUAGE plpgsql; --- msar.build_expr -------------------------------------------------------------------------- +-- msar.build_expr --------------------------------------------------------------------------------- CREATE OR REPLACE FUNCTION test_build_expr() RETURNS SETOF TEXT AS $$ DECLARE diff --git a/docs/docs/api/rpc.md b/docs/docs/api/rpc.md index 6d9d8e013e..6446af15f0 100644 --- a/docs/docs/api/rpc.md +++ b/docs/docs/api/rpc.md @@ -188,6 +188,9 @@ To use an RPC function: - Filter - FilterAttnum - FilterLiteral + - Grouping + - Group + - GroupingResponse - SearchParam ## Explorations diff --git a/mathesar/rpc/records.py b/mathesar/rpc/records.py index 028f5fe859..3840cc3a4a 100644 --- a/mathesar/rpc/records.py +++ b/mathesar/rpc/records.py @@ -74,6 +74,46 @@ class SearchParam(TypedDict): literal: Any +class Grouping(TypedDict): + """ + Grouping definition. + + Attributes: + columns: The columns to be grouped by. + preproc: The preprocessing funtions to apply (if any). + """ + columns: list[int] + preproc: list[str] + + +class Group(TypedDict): + """ + Group definition. + + Attributes: + id: The id of the group. Consistent for same input. + count: The number of items in the group. + results_eq: The value the results of the group equal. + """ + id: int + count: int + results_eq: list[dict] + + +class GroupingResponse(TypedDict): + """ + Grouping response object. Extends Grouping with actual groups. + + Attributes: + columns: The columns to be grouped by. + preproc: The preprocessing funtions to apply (if any). + groups: The groups applicable to the records being returned. + """ + columns: list[int] + preproc: list[str] + groups: list[Group] + + class RecordList(TypedDict): """ Records from a table, along with some meta data @@ -86,12 +126,12 @@ class RecordList(TypedDict): Attributes: count: The total number of records in the table. results: An array of record objects. - group: Information for displaying the records grouped in some way. + grouping: Information for displaying grouped records. preview_data: Information for previewing foreign key values. """ count: int results: list[dict] - group: dict + grouping: GroupingResponse preview_data: list[dict] @classmethod @@ -99,7 +139,7 @@ def from_dict(cls, d): return cls( count=d["count"], results=d["results"], - group=None, + grouping=d.get("grouping"), preview_data=[], query=d["query"], ) @@ -116,7 +156,7 @@ def list_( offset: int = None, order: list[OrderBy] = None, filter: Filter = None, - group: list[dict] = None, + grouping: Grouping = None, **kwargs ) -> RecordList: """ @@ -130,7 +170,7 @@ def list_( following rows. order: An array of ordering definition objects. filter: An array of filter definition objects. - group: An array of group definition objects. + grouping: An array of group definition objects. Returns: The requested records, along with some metadata. @@ -144,7 +184,7 @@ def list_( offset=offset, order=order, filter=filter, - group=group, + group=grouping, ) return RecordList.from_dict(record_info) diff --git a/mathesar/tests/rpc/test_records.py b/mathesar/tests/rpc/test_records.py index 8fc0229684..ba787d2aff 100644 --- a/mathesar/tests/rpc/test_records.py +++ b/mathesar/tests/rpc/test_records.py @@ -44,6 +44,12 @@ def mock_list_records( "count": 50123, "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', + "grouping": { + "columns": [2], + "groups": [ + {"id": 3, "count": 8, "results_eq": {"1": "lsfj", "2": 3422}} + ] + } } monkeypatch.setattr(records, 'connect', mock_connect) @@ -51,7 +57,12 @@ def mock_list_records( expect_records_list = { "count": 50123, "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], - "group": None, + "grouping": { + "columns": [2], + "groups": [ + {"id": 3, "count": 8, "results_eq": {"1": "lsfj", "2": 3422}} + ] + }, "preview_data": [], "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', } @@ -98,7 +109,7 @@ def mock_search_records( expect_records_list = { "count": 50123, "results": [{"1": "abcde", "2": 12345}, {"1": "fghij", "2": 67890}], - "group": None, + "grouping": None, "preview_data": [], "query": 'SELECT mycol AS "1", anothercol AS "2" FROM mytable LIMIT 2', }