diff --git a/dist/lib/sql/tables/list.sql b/dist/lib/sql/tables/list.sql index 52b85a23..8884a386 100644 --- a/dist/lib/sql/tables/list.sql +++ b/dist/lib/sql/tables/list.sql @@ -87,6 +87,24 @@ WHERE AND pg_class.relnamespace = pg_namespace.oid AND pg_attribute.attrelid = pg_class.oid AND pg_attribute.attnum = any(pg_index.indkey) +), +relationships as ( + select + (tc.table_schema || '.' || (tc.table_name)) as source_table_id, + tc.table_schema as source_schema, + tc.table_name as source_table_name, + kcu.column_name as source_column_name, + (ccu.table_schema || '.' || (ccu.table_name)) as target_table_id, + ccu.table_schema AS target_table_schema, + ccu.table_name AS target_table_name, + ccu.column_name AS target_column_name, + tc.constraint_name + FROM + information_schema.table_constraints AS tc + JOIN information_schema.key_column_usage AS kcu USING (constraint_schema, constraint_name) + JOIN information_schema.constraint_column_usage AS ccu USING (constraint_schema, constraint_name) + where + tc.constraint_type = 'FOREIGN KEY' ) SELECT *, @@ -135,7 +153,24 @@ SELECT WHERE pk_list.table_id = tables.table_id ) primary_keys - ), - '[]' -) AS primary_keys + ), + '[]' + ) AS primary_keys, + COALESCE( + ( + SELECT + array_to_json(array_agg(row_to_json(relationships))) + FROM + ( + SELECT + * + FROM + relationships + WHERE + relationships.source_table_id = tables.table_id + OR relationships.target_table_id = tables.table_id + ) relationships + ), + '[]' + ) AS relationships FROM tables \ No newline at end of file diff --git a/docs/index.html b/docs/index.html index 04974401..35acb8dc 100644 --- a/docs/index.html +++ b/docs/index.html @@ -191,6 +191,30 @@ + + +
  • + API Type Definitions + + +
  • @@ -313,6 +337,8 @@

    getSchemas

    GET /schemas

    Get all schemas

    +

    Returns

    +

    {Array} Schemas.Schema

    Parameters:

    @@ -320,19 +346,6 @@

    getSchemas

    * @param {boolean} [includeSystemSchemas=false] - Return system schemas as well as user schemas */ -
    -

    Returns: Schemas.Schema[]

    -
    -
    {
    - catalog_name: string
    - name: string
    - owner: string
    - default_character_set_catalog: string
    - default_character_set_schema: string
    - default_character_set_name: string
    - sql_path: string
    -}
    -

    Tables

    View and manage your Postgres tables.

    getTables

    @@ -353,6 +366,15 @@

    getTables

    GET /tables

    Get all tables

    +

    Returns

    +

    {Array} Tables.Table

    +
    +

    Parameters:

    +
    +
    /**
    + * @param {boolean} [includeSystemSchemas=false] - Return system schemas as well as user schemas
    + */
    +

    Types

    View and manage your Postgres types.

    getTypes

    @@ -450,6 +472,44 @@

    getVersion

    GET /config/version

    Get your Postgres version information.

    +

    API Type Definitions

    +

    Schemas.Schema

    +
    {
    +  catalog_name: string
    +  name: string
    +  owner: string
    +  default_character_set_catalog: string
    +  default_character_set_schema: string
    +  default_character_set_name: string
    +  sql_path: string
    +}
    +
    +

    Tables.Table

    +
    {
    +  table_id: string
    +  catalog: string
    +  schema: string
    +  name: string
    +  is_insertable_into: boolean
    +  is_typed: boolean
    +  bytes: number
    +  size: string
    +  relationships: Tables.Relationship[]
    +}
    +
    +

    Tables.Relationship

    +
    {
    +  source_table_id: string
    +  source_schema: string
    +  source_table_name: string
    +  source_column_name: string
    +  target_table_id: string
    +  target_table_schema: string
    +  target_table_name: string
    +  target_column_name: string
    +  constraint_name: string
    +}
    +
    diff --git a/docs/source/index.html.md b/docs/source/index.html.md index 7b4ab78d..036d2c66 100644 --- a/docs/source/index.html.md +++ b/docs/source/index.html.md @@ -149,26 +149,17 @@ const data = await fetch('http://localhost:1337/schemas', { *Get all schemas* +### Returns + +`{Array}` [Schemas.Schema](#schemas-schema) + > Parameters: ```javascript /** * @param {boolean} [includeSystemSchemas=false] - Return system schemas as well as user schemas */ ``` - > Returns: Schemas.Schema[] - ```javascript -{ - catalog_name: string - name: string - owner: string - default_character_set_catalog: string - default_character_set_schema: string - default_character_set_name: string - sql_path: string -} -``` - - + @@ -202,7 +193,16 @@ const data = await fetch('http://localhost:1337/tables', { *Get all tables* +### Returns + +`{Array}` [Tables.Table](#tables-table) +> Parameters: +```javascript +/** + * @param {boolean} [includeSystemSchemas=false] - Return system schemas as well as user schemas + */ + ``` @@ -350,3 +350,53 @@ Get your Postgres version information. + +# API Type Definitions + + +## Schemas.Schema + +```typescript +{ + catalog_name: string + name: string + owner: string + default_character_set_catalog: string + default_character_set_schema: string + default_character_set_name: string + sql_path: string +} +``` + +## Tables.Table + +```typescript +{ + table_id: string + catalog: string + schema: string + name: string + is_insertable_into: boolean + is_typed: boolean + bytes: number + size: string + relationships: Tables.Relationship[] +} +``` + +## Tables.Relationship + +```typescript +{ + source_table_id: string + source_schema: string + source_table_name: string + source_column_name: string + target_table_id: string + target_table_schema: string + target_table_name: string + target_column_name: string + constraint_name: string +} +``` + diff --git a/src/lib/interfaces/tables.ts b/src/lib/interfaces/tables.ts index 25407cdb..6548bee7 100644 --- a/src/lib/interfaces/tables.ts +++ b/src/lib/interfaces/tables.ts @@ -9,6 +9,19 @@ export namespace Tables { is_typed: boolean bytes: number size: string + relationships: Tables.Relationship[] + } + + export interface Relationship { + source_table_id: string + source_schema: string + source_table_name: string + source_column_name: string + target_table_id: string + target_table_schema: string + target_table_name: string + target_column_name: string + constraint_name: string } } diff --git a/src/lib/sql/tables/list.sql b/src/lib/sql/tables/list.sql index 52b85a23..8884a386 100644 --- a/src/lib/sql/tables/list.sql +++ b/src/lib/sql/tables/list.sql @@ -87,6 +87,24 @@ WHERE AND pg_class.relnamespace = pg_namespace.oid AND pg_attribute.attrelid = pg_class.oid AND pg_attribute.attnum = any(pg_index.indkey) +), +relationships as ( + select + (tc.table_schema || '.' || (tc.table_name)) as source_table_id, + tc.table_schema as source_schema, + tc.table_name as source_table_name, + kcu.column_name as source_column_name, + (ccu.table_schema || '.' || (ccu.table_name)) as target_table_id, + ccu.table_schema AS target_table_schema, + ccu.table_name AS target_table_name, + ccu.column_name AS target_column_name, + tc.constraint_name + FROM + information_schema.table_constraints AS tc + JOIN information_schema.key_column_usage AS kcu USING (constraint_schema, constraint_name) + JOIN information_schema.constraint_column_usage AS ccu USING (constraint_schema, constraint_name) + where + tc.constraint_type = 'FOREIGN KEY' ) SELECT *, @@ -135,7 +153,24 @@ SELECT WHERE pk_list.table_id = tables.table_id ) primary_keys - ), - '[]' -) AS primary_keys + ), + '[]' + ) AS primary_keys, + COALESCE( + ( + SELECT + array_to_json(array_agg(row_to_json(relationships))) + FROM + ( + SELECT + * + FROM + relationships + WHERE + relationships.source_table_id = tables.table_id + OR relationships.target_table_id = tables.table_id + ) relationships + ), + '[]' + ) AS relationships FROM tables \ No newline at end of file diff --git a/test/integration/index.spec.js b/test/integration/index.spec.js index 9f7e30c6..2d039385 100644 --- a/test/integration/index.spec.js +++ b/test/integration/index.spec.js @@ -145,6 +145,14 @@ describe('/tables', async () => { const datum = tables.data.find((x) => x.table_id == 'public.users') assert.equal(datum.grants.length > 0, true) }) + it('should return the relationships', async () => { + const tables = await axios.get(`${URL}/tables`) + const datum = tables.data.find((x) => x.table_id == 'public.users') + const relationships = datum.relationships + const relationship = relationships.find(x => x.source_table_id == 'public.todos') + assert.equal(relationships.length > 0, true) + assert.equal(true, relationship.target_table_id == 'public.users') + }) it('GET with system tables', async () => { const res = await axios.get(`${URL}/tables?includeSystemSchemas=true`)