Skip to content

Feature/#11 add foreign keys #14

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 2 commits into from
Jun 15, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
41 changes: 38 additions & 3 deletions dist/lib/sql/tables/list.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
*,
Expand Down Expand Up @@ -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
86 changes: 73 additions & 13 deletions docs/index.html
Original file line number Diff line number Diff line change
Expand Up @@ -191,6 +191,30 @@

</ul>

</li>

<li>
<a href="#api-type-definitions" class="toc-h1 toc-link" data-title="API Type Definitions">API Type Definitions</a>

<ul class="toc-list-h2">

<li>
<a href="#schemas-schema" class="toc-h2 toc-link" data-title="">Schemas.Schema</a>

</li>

<li>
<a href="#tables-table" class="toc-h2 toc-link" data-title="">Tables.Table</a>

</li>

<li>
<a href="#tables-relationship" class="toc-h2 toc-link" data-title="">Tables.Relationship</a>

</li>

</ul>

</li>

</ul>
Expand Down Expand Up @@ -313,26 +337,15 @@ <h2 id="getschemas">getSchemas</h2>
</code></pre>
<p><code>GET /schemas</code></p>
<p><em>Get all schemas</em></p>
<h3 id="returns">Returns</h3>
<p><code>{Array}</code> <a href="#schemas-schema">Schemas.Schema</a></p>
<blockquote>
<p>Parameters:</p>
</blockquote>
<pre class="highlight tab tab-javascript"><code><span class="hljs-comment">/**
* <span class="hljs-doctag">@param <span class="hljs-type">{boolean}</span> </span>[includeSystemSchemas=false] - Return system schemas as well as user schemas
*/</span>
</code></pre>
<blockquote>
<p>Returns: Schemas.Schema[]</p>
</blockquote>
<pre class="highlight tab tab-javascript"><code>{
<span class="hljs-attr">catalog_name</span>: string
<span class="hljs-attr">name</span>: string
<span class="hljs-attr">owner</span>: string
<span class="hljs-attr">default_character_set_catalog</span>: string
<span class="hljs-attr">default_character_set_schema</span>: string
<span class="hljs-attr">default_character_set_name</span>: string
<span class="hljs-attr">sql_path</span>: string
}
</code></pre>
<h1 id="pg-api-tables">Tables</h1>
<p>View and manage your Postgres tables.</p>
<h2 id="gettables">getTables</h2>
Expand All @@ -353,6 +366,15 @@ <h2 id="gettables">getTables</h2>
</code></pre>
<p><code>GET /tables</code></p>
<p><em>Get all tables</em></p>
<h3 id="returns-2">Returns</h3>
<p><code>{Array}</code> <a href="#tables-table">Tables.Table</a></p>
<blockquote>
<p>Parameters:</p>
</blockquote>
<pre class="highlight tab tab-javascript"><code><span class="hljs-comment">/**
* <span class="hljs-doctag">@param <span class="hljs-type">{boolean}</span> </span>[includeSystemSchemas=false] - Return system schemas as well as user schemas
*/</span>
</code></pre>
<h1 id="pg-api-schemas">Types</h1>
<p>View and manage your Postgres types.</p>
<h2 id="gettypes">getTypes</h2>
Expand Down Expand Up @@ -450,6 +472,44 @@ <h2 id="getversion">getVersion</h2>
</code></pre>
<p><code>GET /config/version</code></p>
<p>Get your Postgres version information.</p>
<h1 id="api-type-definitions">API Type Definitions</h1>
<h2 id="schemas-schema">Schemas.Schema</h2>
<pre class="highlight tab tab-typescript"><code>{
catalog_name: <span class="hljs-built_in">string</span>
name: <span class="hljs-built_in">string</span>
owner: <span class="hljs-built_in">string</span>
default_character_set_catalog: <span class="hljs-built_in">string</span>
default_character_set_schema: <span class="hljs-built_in">string</span>
default_character_set_name: <span class="hljs-built_in">string</span>
sql_path: <span class="hljs-built_in">string</span>
}
</code></pre>
<h2 id="tables-table">Tables.Table</h2>
<pre class="highlight tab tab-typescript"><code>{
table_id: <span class="hljs-built_in">string</span>
catalog: <span class="hljs-built_in">string</span>
schema: <span class="hljs-built_in">string</span>
name: <span class="hljs-built_in">string</span>
is_insertable_into: <span class="hljs-built_in">boolean</span>
is_typed: <span class="hljs-built_in">boolean</span>
bytes: <span class="hljs-built_in">number</span>
size: <span class="hljs-built_in">string</span>
relationships: Tables.Relationship[]
}
</code></pre>
<h2 id="tables-relationship">Tables.Relationship</h2>
<pre class="highlight tab tab-typescript"><code>{
source_table_id: <span class="hljs-built_in">string</span>
source_schema: <span class="hljs-built_in">string</span>
source_table_name: <span class="hljs-built_in">string</span>
source_column_name: <span class="hljs-built_in">string</span>
target_table_id: <span class="hljs-built_in">string</span>
target_table_schema: <span class="hljs-built_in">string</span>
target_table_name: <span class="hljs-built_in">string</span>
target_column_name: <span class="hljs-built_in">string</span>
constraint_name: <span class="hljs-built_in">string</span>
}
</code></pre>
<!-- Renderer: Shins v2.5.0 -->
<!-- Generator: Widdershins v4.0.1 -->
</div>
Expand Down
78 changes: 64 additions & 14 deletions docs/source/index.html.md
Original file line number Diff line number Diff line change
Expand Up @@ -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
}
```






Expand Down Expand Up @@ -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
*/
```



Expand Down Expand Up @@ -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
}
```

13 changes: 13 additions & 0 deletions src/lib/interfaces/tables.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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
}

}
Expand Down
41 changes: 38 additions & 3 deletions src/lib/sql/tables/list.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
*,
Expand Down Expand Up @@ -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
8 changes: 8 additions & 0 deletions test/integration/index.spec.js
Original file line number Diff line number Diff line change
Expand Up @@ -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`)
Expand Down