Skip to content

Commit

Permalink
Add msar.get_schemas DB function
Browse files Browse the repository at this point in the history
  • Loading branch information
seancolsen committed May 16, 2024
1 parent d7b9426 commit 4a1a3d8
Show file tree
Hide file tree
Showing 3 changed files with 95 additions and 0 deletions.
5 changes: 5 additions & 0 deletions db/schemas/operations/select.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,11 @@
from db.constants import INTERNAL_SCHEMAS
from db.utils import get_pg_catalog_table
from db.metadata import get_empty_metadata
from db.connection import exec_msar_func


def get_schemas(conn):
return exec_msar_func(conn, 'get_schemas').fetchone()[0]


def reflect_schema(engine, name=None, oid=None, metadata=None):
Expand Down
39 changes: 39 additions & 0 deletions db/sql/0_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -662,6 +662,45 @@ SELECT EXISTS (SELECT 1 FROM pg_attribute WHERE attrelid=tab_id AND attname=col_
$$ LANGUAGE SQL RETURNS NULL ON NULL INPUT;


CREATE OR REPLACE FUNCTION msar.get_schemas() RETURNS jsonb AS $$/*
Return a json array of objects describing the user-defined schemas in the database.
PostgreSQL system schemas are ignored.
Internal Mathesar-specifc schemas are INCLUDED. These should be filtered out by the caller. This
behavior is to avoid tight coupling between this function and other SQL files that might need to
define additional Mathesar-specific schemas as our codebase grows.
Each returned JSON object in the array will have the form:
{
"oid": <int>
"name": <str>
"description": <str|null>
"table_count": <int>
}
*/
SELECT jsonb_agg(schema_data)
FROM (
SELECT
s.oid AS oid,
min(s.nspname) AS name,
min(d.description) AS description,
COALESCE(count(c.oid), 0) AS table_count
FROM pg_catalog.pg_namespace s
LEFT JOIN pg_catalog.pg_description d ON
d.objoid = s.oid AND
d.objsubid = 0
LEFT JOIN pg_catalog.pg_class c ON
c.relnamespace = s.oid AND
c.relkind = 'r'
WHERE
s.nspname <> 'information_schema' AND
s.nspname NOT LIKE 'pg_%'
GROUP BY s.oid
) AS schema_data;
$$ LANGUAGE sql;


----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------
-- ROLE MANIPULATION FUNCTIONS
Expand Down
51 changes: 51 additions & 0 deletions db/sql/test_0_msar.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2557,3 +2557,54 @@ BEGIN
);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_get_schemas() RETURNS SETOF TEXT AS $$
DECLARE
initial_schema_count int;
foo_schema jsonb;
BEGIN
-- Get the initial schema count
SELECT jsonb_array_length(msar.get_schemas()) INTO initial_schema_count;
-- Create a schema
CREATE SCHEMA foo;
-- We should now have one additional schema
RETURN NEXT is(jsonb_array_length(msar.get_schemas()), initial_schema_count + 1);
-- Reflect the "foo" schema
SELECT jsonb_path_query(msar.get_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
-- We should have a foo schema object
RETURN NEXT is(jsonb_typeof(foo_schema), 'object');
-- It should have no description
RETURN NEXT is(jsonb_typeof(foo_schema->'description'), 'null');
-- It should have no tables
RETURN NEXT is((foo_schema->'table_count')::int, 0);
-- And comment
COMMENT ON SCHEMA foo IS 'A test schema';
-- Create two tables
CREATE TABLE foo.test_table_1 (id serial PRIMARY KEY);
CREATE TABLE foo.test_table_2 (id serial PRIMARY KEY);
-- Reflect again
SELECT jsonb_path_query(msar.get_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
-- We should see the description we set
RETURN NEXT is(foo_schema->'description'#>>'{}', 'A test schema');
-- We should see two tables
RETURN NEXT is((foo_schema->'table_count')::int, 2);
-- Drop the tables we created
DROP TABLE foo.test_table_1;
DROP TABLE foo.test_table_2;
-- Reflect the "foo" schema
SELECT jsonb_path_query(msar.get_schemas(), '$[*] ? (@.name == "foo")') INTO foo_schema;
-- The "foo" schema should now have no tables
RETURN NEXT is((foo_schema->'table_count')::int, 0);
-- Drop the "foo" schema
DROP SCHEMA foo;
-- We should now have no "foo" schema
RETURN NEXT ok(NOT jsonb_path_exists(msar.get_schemas(), '$[*] ? (@.name == "foo")'));
-- We should see the initial schema count again
RETURN NEXT is(jsonb_array_length(msar.get_schemas()), initial_schema_count);
END;
$$ LANGUAGE plpgsql;

0 comments on commit 4a1a3d8

Please sign in to comment.