Skip to content

Commit

Permalink
Merge pull request #3556 from mathesar-foundation/permissions_stub
Browse files Browse the repository at this point in the history
Add `columns.list` function
  • Loading branch information
Anish9901 committed May 9, 2024
2 parents 5cbd321 + 7740f76 commit ddab8b9
Show file tree
Hide file tree
Showing 15 changed files with 1,219 additions and 102 deletions.
3 changes: 2 additions & 1 deletion config/settings/common_settings.py
Original file line number Diff line number Diff line change
Expand Up @@ -65,7 +65,8 @@ def pipe_delim(pipe_string):
ROOT_URLCONF = "config.urls"

MODERNRPC_METHODS_MODULES = [
'mathesar.rpc.connections'
'mathesar.rpc.connections',
'mathesar.rpc.columns'
]

TEMPLATES = [
Expand Down
39 changes: 38 additions & 1 deletion db/columns/operations/select.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,11 +3,48 @@
from sqlalchemy import and_, asc, cast, select, text, exists, Identity

from db.columns.exceptions import DynamicDefaultWarning
from db.connection import execute_msar_func_with_engine
from db.connection import execute_msar_func_with_engine, exec_msar_func
from db.tables.operations.select import reflect_table_from_oid
from db.utils import execute_statement, get_pg_catalog_table


def get_column_info_for_table(table, conn):
"""
Return a list of dictionaries describing the columns of the table.
The `table` can be given as either a "qualified name", or an OID.
The OID is the preferred identifier, since it's much more robust.
The returned list contains dictionaries of the following form:
{
"id": <int>,
"name": <str>,
"type": <str>,
"type_options": {
"precision": <int>,
"scale": <int>,
"fields": <str>,
"length": <int>,
"item_type": <str>,
},
"nullable": <bool>,
"primary_key": <bool>,
"valid_target_types": [<str>, <str>, ..., <str>]
"default": {"value": <str>, "is_dynamic": <bool>},
"has_dependents": <bool>,
"description": <str>
}
The fields of the "type_options" dictionary are all optional,
depending on the "type" value.
Args:
table: The table for which we want column info.
"""
return exec_msar_func(conn, 'get_column_info', table).fetchone()[0]


def get_column_description(oid, attnum, engine):
cursor = execute_msar_func_with_engine(engine, 'col_description', oid, attnum)
row = cursor.fetchone()
Expand Down
15 changes: 15 additions & 0 deletions db/connection.py
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,21 @@ def execute_msar_func_with_psycopg2_conn(conn, func_name, *args):
return conn.execute(stmt)


def exec_msar_func(conn, func_name, *args):
"""
Execute an msar function using a psycopg (3) connection.
Args:
conn: a psycopg connection
func_name: The unqualified msar_function name (danger; not sanitized)
*args: The list of parameters to pass
"""
# Returns a cursor
return conn.execute(
f"SELECT msar.{func_name}({','.join(['%s']*len(args))})", args
)


def load_file_with_engine(engine, file_handle):
"""Run an SQL script from a file, using psycopg."""
conn_str = str(engine.url)
Expand Down
192 changes: 186 additions & 6 deletions db/sql/0_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -131,6 +131,23 @@ Wraps the `?` jsonb operator for improved readability.
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION msar.schema_exists(schema_name text) RETURNS boolean AS $$/*
Return true if the given schema exists in the current database, false otherwise.
*/
SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname=schema_name);
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION __msar.get_schema_oid(sch_name text) RETURNS oid AS $$/*
Return the OID of a schema, if it can be diretly found from a name.
Args :
sch_name: The name of the schema.
*/
SELECT CASE WHEN msar.schema_exists(sch_name) THEN sch_name::regnamespace::oid END;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION __msar.get_schema_name(sch_id oid) RETURNS TEXT AS $$/*
Return the name for a given schema, quoted as appropriate.
Expand Down Expand Up @@ -468,17 +485,180 @@ AND attrelid = msar.get_relation_oid(sch_name, rel_name);
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.column_exists(tab_id oid, col_name text) RETURNS boolean AS $$/*
Return true if the given column exists in the table, false otherwise.
CREATE OR REPLACE FUNCTION
msar.get_interval_fields(typ_mod integer) RETURNS text AS $$/*
Return the string giving the fields for an interval typmod integer.
This logic is ported from the relevant PostgreSQL source code, reimplemented in SQL. See the
`intervaltypmodout` function at
https://doxygen.postgresql.org/backend_2utils_2adt_2timestamp_8c.html
Args:
typ_mod: The atttypmod from the pg_attribute table. Should be valid for the interval type.
*/
SELECT EXISTS (SELECT 1 FROM pg_attribute WHERE attrelid=tab_id AND attname=col_name);
SELECT CASE (typ_mod >> 16 & 32767)
WHEN 1 << 2 THEN 'year'
WHEN 1 << 1 THEN 'month'
WHEN 1 << 3 THEN 'day'
WHEN 1 << 10 THEN 'hour'
WHEN 1 << 11 THEN 'minute'
WHEN 1 << 12 THEN 'second'
WHEN (1 << 2) | (1 << 1) THEN 'year to month'
WHEN (1 << 3) | (1 << 10) THEN 'day to hour'
WHEN (1 << 3) | (1 << 10) | (1 << 11) THEN 'day to minute'
WHEN (1 << 3) | (1 << 10) | (1 << 11) | (1 << 12) THEN 'day to second'
WHEN (1 << 10) | (1 << 11) THEN 'hour to minute'
WHEN (1 << 10) | (1 << 11) | (1 << 12) THEN 'hour to second'
WHEN (1 << 11) | (1 << 12) THEN 'minute to second'
END;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.schema_exists(schema_name text) RETURNS boolean AS $$/*
Return true if the given schema exists in the current database, false otherwise.
CREATE OR REPLACE FUNCTION
msar.get_type_options(typ_id regtype, typ_mod integer, typ_ndims integer) RETURNS jsonb AS $$/*
Return the type options calculated from a type, typmod pair.
This function uses a number of hard-coded constants. The form of the returned object is determined
by the input type, but the keys will be a subset of:
precision: the precision of a numeric or interval type. See PostgreSQL docs for details.
scale: the scale of a numeric type
fields: See PostgreSQL documentation of the `interval` type.
length: Applies to "text" types where the user can specify the length.
item_type: Gives the type of array members for array-types
Args:
typ_id: an OID or valid type representing string will work here.
typ_mod: The integer corresponding to the type options; see pg_attribute catalog table.
typ_ndims: Used to determine whether the type is actually an array without an extra join.
*/
SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname=schema_name);
SELECT nullif(
CASE
WHEN typ_id = ANY('{numeric, _numeric}'::regtype[]) THEN
jsonb_build_object(
-- This calculation is modified from the relevant PostgreSQL source code. See the function
-- numeric_typmod_precision(int32) at
-- https://doxygen.postgresql.org/backend_2utils_2adt_2numeric_8c.html
'precision', ((nullif(typ_mod, -1) - 4) >> 16) & 65535,
-- This calculation is from numeric_typmod_scale(int32) at the same location
'scale', (((nullif(typ_mod, -1) - 4) & 2047) # 1024) - 1024
)
WHEN typ_id = ANY('{interval, _interval}'::regtype[]) THEN
jsonb_build_object(
'precision', nullif(typ_mod & 65535, 65535),
'fields', msar.get_interval_fields(typ_mod)
)
WHEN typ_id = ANY('{bpchar, _bpchar, varchar, _varchar}'::regtype[]) THEN
-- For char and varchar types, the typemod is equal to 4 more than the set length.
jsonb_build_object('length', nullif(typ_mod, -1) - 4)
WHEN typ_id = ANY(
'{bit, varbit, time, timetz, timestamp, timestamptz}'::regtype[]
|| '{_bit, _varbit, _time, _timetz, _timestamp, _timestamptz}'::regtype[]
) THEN
-- For all these types, the typmod is equal to the precision.
jsonb_build_object(
'precision', nullif(typ_mod, -1)
)
ELSE jsonb_build_object()
END
|| CASE
WHEN typ_ndims>0 THEN
-- This string wrangling is debatably dubious, but avoids a slow join.
jsonb_build_object('item_type', rtrim(typ_id::regtype::text, '[]'))
ELSE '{}'
END,
'{}'
)
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_valid_target_type_strings(typ_id regtype) RETURNS jsonb AS $$/*
Given a source type, return the target types for which Mathesar provides a casting function.
Args:
typ_id: The type we're casting from.
*/

SELECT jsonb_agg(prorettype::regtype::text)
FROM pg_proc
WHERE
pronamespace=__msar.get_schema_oid('mathesar_types')
AND proargtypes[0]=typ_id
AND left(proname, 5) = 'cast_';
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.has_dependents(rel_id oid, att_id smallint) RETURNS boolean AS $$/*
Return a boolean according to whether the column identified by the given oid, attnum pair is
referenced (i.e., would dropping that column require CASCADE?).
Args:
rel_id: The relation of the attribute.
att_id: The attnum of the attribute in the relation.
*/
SELECT EXISTS (
SELECT 1 FROM pg_depend WHERE refobjid=rel_id AND refobjsubid=att_id AND deptype='n'
);
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_column_info(tab_id regclass) RETURNS jsonb AS $$/*
Given a table identifier, return an array of objects describing the columns of the table.
Each returned JSON object in the array will have the form:
{
"id": <int>,
"name": <str>,
"type": <str>,
"type_options": <obj>,
"nullable": <bool>,
"primary_key": <bool>,
"default": {"value": <str>, "is_dynamic": <bool>},
"has_dependents": <bool>,
"description": <str>
}
The `type_options` object is described in the docstring of `msar.get_type_options`. The `default`
object has the keys:
value: A string giving the value (as an SQL expression) of the default.
is_dynamic: A boolean giving whether the default is (likely to be) dynamic.
*/
SELECT jsonb_agg(
jsonb_build_object(
'id', attnum,
'name', attname,
'type', CASE WHEN attndims>0 THEN '_array' ELSE atttypid::regtype::text END,
'type_options', msar.get_type_options(atttypid, atttypmod, attndims),
'nullable', NOT attnotnull,
'primary_key', COALESCE(pgi.indisprimary, false),
'default',
nullif(
jsonb_strip_nulls(
jsonb_build_object(
'value',
CASE
WHEN attidentity='' THEN pg_get_expr(adbin, tab_id)
ELSE 'identity'
END,
'is_dynamic', msar.is_default_possibly_dynamic(tab_id, attnum)
)
),
jsonb_build_object()
),
'has_dependents', msar.has_dependents(tab_id, attnum),
'description', msar.col_description(tab_id, attnum)
)
)
FROM pg_attribute pga
LEFT JOIN pg_index pgi ON pga.attrelid=pgi.indrelid AND pga.attnum=ANY(pgi.indkey)
LEFT JOIN pg_attrdef pgd ON pga.attrelid=pgd.adrelid AND pga.attnum=pgd.adnum
WHERE pga.attrelid=tab_id AND pga.attnum > 0 and NOT attisdropped;
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.column_exists(tab_id oid, col_name text) RETURNS boolean AS $$/*
Return true if the given column exists in the table, false otherwise.
*/
SELECT EXISTS (SELECT 1 FROM pg_attribute WHERE attrelid=tab_id AND attname=col_name);
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


Expand Down

0 comments on commit ddab8b9

Please sign in to comment.