Skip to content

Add Schema Support for PostgreSQL Tables #121

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

Open
wants to merge 1 commit into
base: main
Choose a base branch
from
Open
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
50 changes: 40 additions & 10 deletions src/database-engines/postgres-engine.ts
Original file line number Diff line number Diff line change
Expand Up @@ -39,9 +39,11 @@ export class PostgresEngine implements DatabaseEngine {
throw new Error('Not connected to the database');
}

const { schemaName, tableName } = getTableSchema(table);

const tableCreationSql = await this.connection.raw(`
SELECT
'CREATE TABLE ' || quote_ident(table_name) || ' (' ||
'CREATE TABLE ' || quote_ident(table_schema) || '.' || quote_ident(table_name) || ' (' ||
string_agg(column_name || ' ' ||
CASE
WHEN data_type = 'character varying' THEN
Expand All @@ -53,9 +55,9 @@ export class PostgresEngine implements DatabaseEngine {
FROM
information_schema.columns
WHERE
table_name = '${table}'
table_name = '${tableName}' AND table_schema = '${schemaName}'
GROUP BY
table_name
table_name, table_schema
`) as any;

const sql = tableCreationSql.rows[0]?.create_sql || '';
Expand Down Expand Up @@ -84,28 +86,32 @@ export class PostgresEngine implements DatabaseEngine {

const tables = await this.connection('pg_catalog.pg_tables')
.whereNotIn('schemaname', ['pg_catalog', 'information_schema'])
.select(`tablename`);
.select([`tablename`, `schemaname`]);

return tables.map((table: any) => table.tablename);
return tables.map(getTableName);
}

async getColumns(table: string): Promise<Column[]> {
if (!this.connection) {
throw new Error('Not connected to the database');
}

const { schemaName, tableName } = getTableSchema(table);

type TableColumn = { "type": string, name: string, ordinal_position: number, is_nullable: string }

const columns: TableColumn[] = await this.connection('information_schema.columns')
.whereRaw("LOWER(table_name) = LOWER(?)", [table])
.whereRaw("LOWER(table_name) = LOWER(?)", [tableName])
.whereRaw("LOWER(table_schema) = LOWER(?)", [schemaName])
.select(['column_name AS name', 'data_type AS type', 'ordinal_position', 'is_nullable']) as any[];

const editableColumnTypeNamesLowercase = this.getEditableColumnTypeNamesLowercase()

const primaryKeyResult = await this.connection('information_schema.table_constraints as tc')
.join('information_schema.key_column_usage as kcu', 'tc.constraint_name', 'kcu.constraint_name')
.where('tc.constraint_type', 'PRIMARY KEY')
.andWhereRaw('LOWER(tc.table_name) = LOWER(?)', [table])
.andWhereRaw('LOWER(tc.table_name) = LOWER(?)', [tableName])
.andWhereRaw('LOWER(tc.table_schema) = LOWER(?)', [schemaName])
.select('kcu.column_name');
const primaryKeySet = new Set(primaryKeyResult.map(row => row.column_name.toLowerCase()));

Expand Down Expand Up @@ -178,34 +184,58 @@ export class PostgresEngine implements DatabaseEngine {
}
}

function getTableName(table: { schemaname: string, tablename: string }) {
return table.schemaname === 'public'
? table.tablename
: `${table.schemaname}.${table.tablename}`;
}

function getTableSchema(table: string): { schemaName: string, tableName: string } {
let schemaName = 'public';
let tableName = table;

if (tableName.includes('.')) {
const parts = tableName.split('.');
schemaName = parts[0];
tableName = parts[1];
}

return { schemaName, tableName };
}

async function getForeignKeyFor(table: string, column: string, connection: knexlib.Knex): Promise<{ table: string, column: string } | undefined> {
const { schemaName, tableName } = getTableSchema(table);

type Fk = {
referenced_table: string,
referenced_column: string,
referenced_schema: string,
}

const result = await connection.raw(`
SELECT
ccu.table_name AS referenced_table,
ccu.column_name AS referenced_column
ccu.column_name AS referenced_column,
ccu.table_schema AS referenced_schema
FROM
information_schema.table_constraints tc
JOIN information_schema.key_column_usage kcu
ON tc.constraint_name = kcu.constraint_name
AND tc.table_schema = kcu.table_schema
JOIN information_schema.constraint_column_usage ccu
ON ccu.constraint_name = tc.constraint_name
WHERE
tc.constraint_type = 'FOREIGN KEY'
AND kcu.table_name = LOWER('${table}')
AND kcu.table_name = LOWER('${tableName}')
AND kcu.table_schema = LOWER('${schemaName}')
AND kcu.column_name = LOWER('${column}')
`);

const foreignKeys: Fk[] = result.rows;
if (foreignKeys.length === 0) return undefined;

return {
table: foreignKeys[0].referenced_table as string,
table: getTableName({ schemaname: foreignKeys[0].referenced_schema, tablename: foreignKeys[0].referenced_table }),
column: foreignKeys[0].referenced_column as string
};
}
2 changes: 1 addition & 1 deletion src/test/suite/engines/postgres.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -193,7 +193,7 @@ describe('PostgreSQL Tests', () => {
.replace(/\s+/g, ' ')
.trim();

assert.strictEqual(creationSql, 'CREATE TABLE users ( id integer, name CHARACTER varying (255), age integer, location CHARACTER varying (255) );');
assert.strictEqual(creationSql, 'CREATE TABLE public.users ( id integer, name CHARACTER varying (255), age integer, location CHARACTER varying (255) );');
});

it('should filter values in uuid and integer column types', async () => {
Expand Down