Skip to content

Commit

Permalink
Merge branch 'develop' into explorations_run
Browse files Browse the repository at this point in the history
  • Loading branch information
Anish9901 authored Jul 20, 2024
2 parents 6fe4cdc + 2f698bf commit 122d30d
Show file tree
Hide file tree
Showing 60 changed files with 961 additions and 355 deletions.
1 change: 1 addition & 0 deletions config/settings/common_settings.py
Original file line number Diff line number Diff line change
Expand Up @@ -73,6 +73,7 @@ def pipe_delim(pipe_string):
'mathesar.rpc.columns.metadata',
'mathesar.rpc.database_setup',
'mathesar.rpc.databases',
'mathesar.rpc.records',
'mathesar.rpc.roles',
'mathesar.rpc.schemas',
'mathesar.rpc.servers',
Expand Down
44 changes: 44 additions & 0 deletions db/records/operations/select.py
Original file line number Diff line number Diff line change
@@ -1,6 +1,8 @@
import json
from sqlalchemy import select
from sqlalchemy.sql.functions import count

from db import connection as db_conn
from db.columns.base import MathesarColumn
from db.tables.utils import get_primary_key_column
from db.types.operations.cast import get_column_cast_expression
Expand All @@ -9,6 +11,48 @@
from db.transforms.operations.apply import apply_transformations_deprecated


def list_records_from_table(
conn,
table_oid,
limit=None,
offset=None,
order=None,
filter=None,
group=None,
search=None,
):
"""
Get records from a table.
The order definition objects should have the form
{"attnum": <int>, "direction": <text>}
Only data from which the user is granted `SELECT` is returned.
Args:
tab_id: The OID of the table whose records we'll get.
limit: The maximum number of rows we'll return.
offset: The number of rows to skip before returning records from
following rows.
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,
'list_records_from_table',
table_oid,
limit,
offset,
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 get_record(table, engine, id_value):
primary_key_column = get_primary_key_column(table)
pg_query = select(table).where(primary_key_column == id_value)
Expand Down
224 changes: 224 additions & 0 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3228,3 +3228,227 @@ BEGIN
RETURN jsonb_build_array(extracted_table_id, fkey_attnum);
END;
$f$ LANGUAGE plpgsql;


----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------
-- DQL FUNCTIONS
--
-- This set of functions is for getting records from python.
----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------

-- Data type formatting functions


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;


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;


CREATE OR REPLACE FUNCTION msar.format_data(val time with time zone) RETURNS text AS $$
SELECT CASE
WHEN date_part('timezone_hour', val) = 0 AND date_part('timezone_minute', val) = 0
THEN concat(
to_char(date_part('hour', val), 'FM00'), ':', to_char(date_part('minute', val), 'FM00'),
':', to_char(date_part('seconds', val), 'FM00.0999999999'), 'Z'
)
ELSE
concat(
to_char(date_part('hour', val), 'FM00'), ':', to_char(date_part('minute', val), 'FM00'),
':', to_char(date_part('seconds', val), 'FM00.0999999999'),
to_char(date_part('timezone_hour', val), 'S00'), ':',
ltrim(to_char(date_part('timezone_minute', val), '00'), '+- ')
)
END;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.format_data(val timestamp without time zone) RETURNS text AS $$
SELECT
concat(
to_char(val, 'YYYY-MM-DD"T"HH24:MI'),
':', to_char(date_part('seconds', val), 'FM00.0999999999'),
to_char(val, ' BC')
);
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.format_data(val timestamp with time zone) RETURNS text AS $$
SELECT CASE
WHEN date_part('timezone_hour', val) = 0 AND date_part('timezone_minute', val) = 0
THEN concat(
to_char(val, 'YYYY-MM-DD"T"HH24:MI'),
':', to_char(date_part('seconds', val), 'FM00.0999999999'), 'Z', to_char(val, ' BC')
)
ELSE
concat(
to_char(val, 'YYYY-MM-DD"T"HH24:MI'),
':', to_char(date_part('seconds', val), 'FM00.0999999999'),
to_char(date_part('timezone_hour', val), 'S00'),
':', ltrim(to_char(date_part('timezone_minute', val), '00'), '+- '), to_char(val, ' BC')
)
END;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


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;


CREATE OR REPLACE FUNCTION msar.format_data(val anyelement) returns anyelement AS $$
SELECT val;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.sanitize_direction(direction text) RETURNS text AS $$/*
*/
SELECT CASE lower(direction)
WHEN 'asc' THEN 'ASC'
WHEN 'desc' THEN 'DESC'
END;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


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;


CREATE OR REPLACE FUNCTION msar.get_total_order(tab_id oid) RETURNS jsonb AS $$
WITH orderable_cte AS (
SELECT attnum
FROM pg_catalog.pg_attribute
INNER JOIN pg_catalog.pg_cast ON atttypid=castsource
INNER JOIN pg_catalog.pg_operator ON casttarget=oprleft
WHERE
attrelid = tab_id
AND attnum > 0
AND NOT attisdropped
AND castcontext = 'i'
AND oprname = '<'
UNION SELECT attnum
FROM pg_catalog.pg_attribute
INNER JOIN pg_catalog.pg_operator ON atttypid=oprleft
WHERE
attrelid = tab_id
AND attnum > 0
AND NOT attisdropped
AND oprname = '<'
ORDER BY attnum
)
SELECT COALESCE(jsonb_agg(jsonb_build_object('attnum', attnum, 'direction', 'asc')), '[]'::jsonb)
-- This privilege check is redundant in context, but may be useful for other callers.
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;


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.
*/
SELECT 'ORDER BY ' || string_agg(format('%I %s', attnum, msar.sanitize_direction(direction)), ', ')
FROM jsonb_to_recordset(
COALESCE(
COALESCE(order_, '[]'::jsonb) || msar.get_pkey_order(tab_id),
COALESCE(order_, '[]'::jsonb) || msar.get_total_order(tab_id)
)
)
AS x(attnum smallint, direction text)
WHERE has_column_privilege(tab_id, attnum, 'SELECT');
$$ 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.
Given columns with attnums 2, 3, and 4, and assuming the user has access only to columns 2 and 4,
this function will return an expression of the form:
column_name AS "2", another_column_name AS "4"
Args:
tab_id: The OID of the table containing the columns to select.
*/
SELECT string_agg(format('msar.format_data(%I) AS %I', attname, attnum), ', ')
FROM pg_catalog.pg_attribute
WHERE
attrelid = tab_id
AND attnum > 0
AND NOT attisdropped
AND has_column_privilege(attrelid, attnum, 'SELECT');
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.list_records_from_table(
tab_id oid,
limit_ integer,
offset_ integer,
order_ jsonb,
filter_ jsonb,
group_ jsonb,
search_ jsonb
) RETURNS jsonb AS $$/*
Get records from a table. Only columns to which the user has access are returned.
Args:
tab_id: The OID of the table whose records we'll get
limit_: The maximum number of rows we'll return
offset_: The number of rows to skip before returning records from following rows.
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>}
*/
DECLARE
records jsonb;
BEGIN
EXECUTE format(
$q$
WITH count_cte AS (
SELECT count(1) AS count FROM %2$I.%3$I
), results_cte AS (
SELECT %1$s FROM %2$I.%3$I %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)
)
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),
limit_,
offset_,
msar.build_order_by_expr(tab_id, order_)
) INTO records;
RETURN records;
END;
$$ LANGUAGE plpgsql;
Loading

0 comments on commit 122d30d

Please sign in to comment.