Skip to content

Commit

Permalink
Merge pull request #3664 from mathesar-foundation/constraints_rpc
Browse files Browse the repository at this point in the history
Constraints rpc transition (`list`, `delete` & `add`)
  • Loading branch information
mathemancer authored Jul 9, 2024
2 parents 9233bbf + 62eaf28 commit 3cb5280
Show file tree
Hide file tree
Showing 14 changed files with 534 additions and 43 deletions.
1 change: 1 addition & 0 deletions config/settings/common_settings.py
Original file line number Diff line number Diff line change
Expand Up @@ -66,6 +66,7 @@ def pipe_delim(pipe_string):

MODERNRPC_METHODS_MODULES = [
'mathesar.rpc.connections',
'mathesar.rpc.constraints',
'mathesar.rpc.columns',
'mathesar.rpc.columns.metadata',
'mathesar.rpc.roles',
Expand Down
17 changes: 17 additions & 0 deletions db/connection.py
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
from sqlalchemy import text
import psycopg
from psycopg.rows import dict_row


def execute_msar_func_with_engine(engine, func_name, *args):
Expand Down Expand Up @@ -55,6 +56,22 @@ def exec_msar_func(conn, func_name, *args):
)


def select_from_msar_func(conn, func_name, *args):
"""
Select all records from 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
"""
cursor = conn.execute(
f"SELECT * FROM msar.{func_name}({','.join(['%s']*len(args))})", args
)
cursor.row_factory = dict_row
return cursor.fetchall()


def load_file_with_engine(engine, file_handle):
"""Run an SQL script from a file, using psycopg."""
conn_str = str(engine.url)
Expand Down
23 changes: 19 additions & 4 deletions db/constraints/operations/create.py
Original file line number Diff line number Diff line change
@@ -1,13 +1,14 @@
from db.connection import execute_msar_func_with_engine
import json

from db.connection import execute_msar_func_with_engine, exec_msar_func

def add_constraint(constraint_obj, engine):

def add_constraint_via_sql_alchemy(constraint_obj, engine):
"""
Add a constraint.
Args:
constraint_obj: A constraint object instantiatated with appropriate
params.
constraint_obj: (See __msar.process_con_def_jsonb for details)
engine: SQLAlchemy engine object for connecting.
Returns:
Expand All @@ -19,3 +20,17 @@ def add_constraint(constraint_obj, engine):
constraint_obj.table_oid,
constraint_obj.get_constraint_def_json()
).fetchone()[0]


def create_constraint(table_oid, constraint_obj_list, conn):
"""
Create a constraint using a psycopg connection.
Args:
constraint_obj_list: (See __msar.process_con_def_jsonb for details)
conn: a psycopg connection
Returns:
Returns a list of oid(s) of constraints for a given table.
"""
return exec_msar_func(conn, 'add_constraints', table_oid, json.dumps(constraint_obj_list)).fetchone()[0]
18 changes: 17 additions & 1 deletion db/constraints/operations/drop.py
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
from db.connection import execute_msar_func_with_engine
from db.connection import execute_msar_func_with_engine, exec_msar_func


def drop_constraint(table_name, schema_name, engine, constraint_name):
Expand All @@ -17,3 +17,19 @@ def drop_constraint(table_name, schema_name, engine, constraint_name):
return execute_msar_func_with_engine(
engine, 'drop_constraint', schema_name, table_name, constraint_name
).fetchone()[0]


def drop_constraint_via_oid(table_oid, constraint_oid, conn):
"""
Drop a constraint.
Args:
table_oid: Identity of the table to delete constraint for.
constraint_oid: The OID of the constraint to delete.
Returns:
The name of the dropped constraint.
"""
return exec_msar_func(
conn, 'drop_constraint', table_oid, constraint_oid
).fetchone()[0]
7 changes: 6 additions & 1 deletion db/constraints/operations/select.py
Original file line number Diff line number Diff line change
@@ -1,7 +1,12 @@
from sqlalchemy import select, and_

from db.connection import select_from_msar_func
from db.utils import get_pg_catalog_table
from db.metadata import get_empty_metadata

from sqlalchemy import select, and_

def get_constraints_for_table(table_oid, conn):
return select_from_msar_func(conn, 'get_constraints_for_table', table_oid)


def get_constraints_with_oids(engine, table_oid=None):
Expand Down
136 changes: 108 additions & 28 deletions db/sql/00_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -246,6 +246,52 @@ END
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_relation_name(rel_oid oid) RETURNS TEXT AS $$/*
Return the UNQUOTED name of a given relation (e.g., table).
If the relation does not exist, an exception will be raised.
Args:
rel_oid: The OID of the relation.
*/
DECLARE rel_name text;
BEGIN
SELECT relname INTO rel_name FROM pg_class WHERE oid=rel_oid;

IF rel_name IS NULL THEN
RAISE EXCEPTION 'Relation with OID % does not exist', rel_oid
USING ERRCODE = '42P01'; -- undefined_table
END IF;

RETURN rel_name;
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_relation_schema_name(rel_oid oid) RETURNS TEXT AS $$/*
Return the UNQUOTED name of the schema which contains a given relation (e.g., table).
If the relation does not exist, an exception will be raised.
Args:
rel_oid: The OID of the relation.
*/
DECLARE sch_name text;
BEGIN
SELECT n.nspname INTO sch_name
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE c.oid = rel_oid;

IF sch_name IS NULL THEN
RAISE EXCEPTION 'Relation with OID % does not exist', rel_oid
USING ERRCODE = '42P01'; -- undefined_table
END IF;

RETURN sch_name;
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


DROP FUNCTION IF EXISTS msar.get_relation_oid(text, text) CASCADE;
CREATE OR REPLACE FUNCTION
Expand Down Expand Up @@ -451,6 +497,59 @@ END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_constraint_type_api_code(contype char) RETURNS TEXT AS $$/*
This function returns a string that represents the constraint type code used to describe
constraints when listing them within the Mathesar API.
PostgreSQL constraint types are documented by the `contype` field here:
https://www.postgresql.org/docs/current/catalog-pg-constraint.html
Notably, we don't include 't' (trigger) because triggers a bit different structurally and we don't
support working with them (yet?) in Mathesar.
*/
SELECT CASE contype
WHEN 'c' THEN 'check'
WHEN 'f' THEN 'foreignkey'
WHEN 'p' THEN 'primary'
WHEN 'u' THEN 'unique'
WHEN 'x' THEN 'exclude'
END;
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION msar.get_constraints_for_table(tab_id oid) RETURNS TABLE
(
oid oid,
name text,
type text,
columns smallint[],
referent_table_oid oid,
referent_columns smallint[]
)
AS $$/*
Return data describing the constraints set on a given table.
Args:
tab_id: The OID of the table.
*/
WITH constraints AS (
SELECT
oid,
conname AS name,
msar.get_constraint_type_api_code(contype::char) AS type,
conkey AS columns,
confrelid AS referent_table_oid,
confkey AS referent_columns
FROM pg_catalog.pg_constraint
WHERE conrelid = tab_id
)
SELECT *
FROM constraints
-- Only return constraints with types that we're able to classify
WHERE type IS NOT NULL
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION
msar.get_constraint_name(con_id oid) RETURNS text AS $$/*
Return the UNQUOTED constraint name of the corresponding constraint oid.
Expand Down Expand Up @@ -2270,54 +2369,35 @@ $$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;
----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------

-- Drop constraint ---------------------------------------------------------------------------------


CREATE OR REPLACE FUNCTION
__msar.drop_constraint(tab_name text, con_name text) RETURNS text AS $$/*
Drop a constraint, returning the command executed.
Args:
tab_name: A qualified & quoted name of the table that has the constraint to be dropped.
con_name: Name of the constraint to drop, properly quoted.
*/
BEGIN
RETURN __msar.exec_ddl(
'ALTER TABLE %s DROP CONSTRAINT %s', tab_name, con_name
);
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.drop_constraint(sch_name text, tab_name text, con_name text) RETURNS text AS $$/*
Drop a constraint, returning the command executed.
msar.drop_constraint(sch_name text, tab_name text, con_name text) RETURNS TEXT AS $$/*
Drop a constraint
Args:
sch_name: The name of the schema where the table with constraint to be dropped resides, unquoted.
tab_name: The name of the table that has the constraint to be dropped, unquoted.
con_name: Name of the constraint to drop, unquoted.
*/
BEGIN
RETURN __msar.drop_constraint(
__msar.build_qualified_name_sql(sch_name, tab_name), quote_ident(con_name)
);
EXECUTE format('ALTER TABLE %I.%I DROP CONSTRAINT %I', sch_name, tab_name, con_name);
RETURN con_name;
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION
msar.drop_constraint(tab_id oid, con_id oid) RETURNS TEXT AS $$/*
Drop a constraint, returning the command executed.
Drop a constraint
Args:
tab_id: OID of the table that has the constraint to be dropped.
con_id: OID of the constraint to be dropped.
*/
BEGIN
RETURN __msar.drop_constraint(
__msar.get_qualified_relation_name(tab_id),
quote_ident(msar.get_constraint_name(con_id))
RETURN msar.drop_constraint(
msar.get_relation_schema_name(tab_id),
msar.get_relation_name(tab_id),
msar.get_constraint_name(con_id)
);
END;
$$ LANGUAGE plpgsql RETURNS NULL ON NULL INPUT;
Expand Down
2 changes: 1 addition & 1 deletion db/tests/constraints/operations/test_create.py
Original file line number Diff line number Diff line change
Expand Up @@ -23,7 +23,7 @@
def test_add_constraint_db(engine_with_schema, constraint_obj):
engine = engine_with_schema
with patch.object(con_create, 'execute_msar_func_with_engine') as mock_exec:
con_create.add_constraint(
con_create.add_constraint_via_sql_alchemy(
engine=engine,
constraint_obj=constraint_obj
)
Expand Down
6 changes: 3 additions & 3 deletions db/tests/dependents/test_dependents.py
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
import pytest
from sqlalchemy import MetaData, select, Index
from sqlalchemy_utils import create_view
from db.constraints.operations.create import add_constraint
from db.constraints.operations.create import add_constraint_via_sql_alchemy
from db.constraints.base import ForeignKeyConstraint
from db.dependents.dependents_utils import get_dependents_graph
from db.constraints.operations.select import get_constraint_oid_by_name_and_table_oid
Expand Down Expand Up @@ -93,7 +93,7 @@ def test_self_reference(engine_with_schema, library_tables_oids):
fk_column_attnum = create_column(engine, publishers_oid, {'name': 'Parent Publisher', 'type': PostgresType.INTEGER.id})[0]
pk_column_attnum = get_column_attnum_from_name(publishers_oid, 'id', engine, metadata=get_empty_metadata())
fk_constraint = ForeignKeyConstraint('Publishers_Publisher_fkey', publishers_oid, [fk_column_attnum], publishers_oid, [pk_column_attnum], {})
add_constraint(fk_constraint, engine)
add_constraint_via_sql_alchemy(fk_constraint, engine)

publishers_oid = library_tables_oids['Publishers']
publishers_dependents_graph = get_dependents_graph(publishers_oid, engine, [])
Expand All @@ -114,7 +114,7 @@ def test_circular_reference(engine_with_schema, library_tables_oids):
fk_column_attnum = create_column(engine, publishers_oid, {'name': 'Top Publication', 'type': PostgresType.INTEGER.id})[0]
publications_pk_column_attnum = get_column_attnum_from_name(publications_oid, 'id', engine, metadata=get_empty_metadata())
fk_constraint = ForeignKeyConstraint('Publishers_Publications_fkey', publishers_oid, [fk_column_attnum], publications_oid, [publications_pk_column_attnum], {})
add_constraint(fk_constraint, engine)
add_constraint_via_sql_alchemy(fk_constraint, engine)

publishers_dependents_graph = get_dependents_graph(publishers_oid, engine, [])
publications_dependents_oids = _get_object_dependents_oids(publishers_dependents_graph, publications_oid)
Expand Down
14 changes: 14 additions & 0 deletions docs/docs/api/rpc.md
Original file line number Diff line number Diff line change
Expand Up @@ -111,6 +111,20 @@ To use an RPC function:
- ColumnMetaData
- SettableColumnMetaData

## Constraints

::: constraints
options:
members:
- list_
- add
- delete
- Constraint
- ForeignKeyConstraint
- PrimaryKeyConstraint
- UniqueConstraint
- CreatableConstraintInfo

## Roles

::: roles
Expand Down
4 changes: 2 additions & 2 deletions mathesar/models/deprecated.py
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@
get_column_attnum_from_names_as_map, get_column_name_from_attnum,
get_map_of_attnum_to_column_name, get_map_of_attnum_and_table_oid_to_column_name,
)
from db.constraints.operations.create import add_constraint
from db.constraints.operations.create import add_constraint_via_sql_alchemy
from db.constraints.operations.drop import drop_constraint
from db.constraints.operations.select import get_constraint_record_from_oid
from db.constraints import utils as constraint_utils
Expand Down Expand Up @@ -558,7 +558,7 @@ def add_constraint(self, constraint_obj):
# the most newly-created constraint. Other methods (e.g., trying to get
# a constraint by name when it wasn't set here) are even less robust.
constraint_oid = max(
add_constraint(constraint_obj, engine=self._sa_engine)
add_constraint_via_sql_alchemy(constraint_obj, engine=self._sa_engine)
)
result = Constraint.current_objects.create(oid=constraint_oid, table=self)
reset_reflection(db_name=self.schema.database.name)
Expand Down
Loading

0 comments on commit 3cb5280

Please sign in to comment.