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

Records grouping #3721

Merged
merged 15 commits into from
Aug 6, 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
171 changes: 150 additions & 21 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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 $$
Expand All @@ -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 $$
Expand All @@ -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 $$
Expand All @@ -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;
Expand All @@ -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)'),
Expand All @@ -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
Expand All @@ -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 $$
Expand Down Expand Up @@ -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
Expand All @@ -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
Expand All @@ -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": [<int>, <int>, ...]
"preproc": [<str>, <str>, ...]
}

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
Expand All @@ -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
Expand Down Expand Up @@ -3485,27 +3610,31 @@ 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$
mathemancer marked this conversation as resolved.
Show resolved Hide resolved
)
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),
msar.get_relation_name(tab_id),
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
Expand Down
Loading
Loading