Skip to content
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

Added method uniqueConstraints #149

Open
wants to merge 10 commits into
base: master
Choose a base branch
from
2 changes: 1 addition & 1 deletion .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -105,4 +105,4 @@ dist

.DS_Store
.vscode

.idea
19 changes: 19 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -77,6 +77,10 @@ Note 3: MSSQL doesn't support comment for either tables or columns

- [`foreignKeys(): Promise<ForeignKey>`](#foreign-keys)

**Unique Constraints**

- [`uniqueConstraints(): Promise<UniqueConstraint[]>`](#unique-constraints)

**Misc.**

- [`withSchema(schema: string): void`](#withschemaschema-string-void)
Expand Down Expand Up @@ -244,6 +248,21 @@ await inspector.foreignKeys();
// ]
```

### Unique Constraints

Retrieve all user created unique constraints.

```ts
await inspector.uniqueConstraints();
// => [
// {
// table: 'users',
// constraint_name: 'users_firstnamelastname_unique'
// columns: ['firstname', 'lastname'],
// }
// ]
```

### Misc.

#### `withSchema(schema: string): void`
Expand Down
37 changes: 37 additions & 0 deletions lib/dialects/cockroachdb.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import { Table } from '../types/table';
import { Column } from '../types/column';
import { ForeignKey } from '../types/foreign-key';
import { stripQuotes } from '../utils/strip-quotes';
import { UniqueConstraint } from '../types/unique-constraint';

type RawTable = {
table_name: string;
Expand Down Expand Up @@ -470,4 +471,40 @@ export default class CockroachDB implements SchemaInspector {
) as ForeignKey;
}
}

/**
* Get all unique constraints. Limit to single table by specifying optional parameter
*/

async uniqueConstraints(table?: string): Promise<UniqueConstraint[]> {
const { knex } = this;

const query = knex
.select(
'tc.table_name as table_name',
'tc.constraint_name as constraint_name',
knex.raw('array_agg("ccu"."column_name") as columns')
)
.from('information_schema.table_constraints as tc')
.join('information_schema.constraint_column_usage as ccu', function () {
this.on('ccu.constraint_name', '=', 'tc.constraint_name');
})
.groupBy(['tc.table_name', 'tc.constraint_name'])
.orderBy(['tc.table_name', 'tc.constraint_name'])
.where('tc.constraint_type', '=', 'UNIQUE');

if (table) query.andWhere('tc.table_name', '=', table);

const result: {
table_name: string;
constraint_name: string;
columns: string[];
}[] = await query.then();

return result.map((v) => ({
table: v.table_name,
constraint_name: v.constraint_name,
columns: v.columns,
}));
}
}
36 changes: 36 additions & 0 deletions lib/dialects/mssql.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import { Table } from '../types/table';
import { Column } from '../types/column';
import { ForeignKey } from '../types/foreign-key';
import { stripQuotes } from '../utils/strip-quotes';
import { UniqueConstraint } from '../types/unique-constraint';

type RawTable = {
TABLE_NAME: string;
Expand Down Expand Up @@ -372,4 +373,39 @@ export default class MSSQL implements SchemaInspector {

return result;
}

/**
* Get all unique constraints. Limit to single table by specifying optional parameter
*/

async uniqueConstraints(table?: string): Promise<UniqueConstraint[]> {
const { knex } = this;

const query = knex
.select(
'tc.TABLE_NAME as TABLE_NAME',
'tc.CONSTRAINT_NAME as CONSTRAINT_NAME',
knex.raw('STRING_AGG("ccu".COLUMN_NAME, \',\') as COLUMNS')
)
.from('INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS tc')
.join('INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE AS ccu', function () {
this.on('ccu.CONSTRAINT_NAME', '=', 'tc.CONSTRAINT_NAME');
})
.groupBy(['tc.TABLE_NAME', 'tc.CONSTRAINT_NAME'])
.orderBy(['tc.TABLE_NAME', 'tc.CONSTRAINT_NAME'])
.where('tc.CONSTRAINT_TYPE', '=', 'UNIQUE');
if (table) query.andWhere('tc.TABLE_NAME', '=', table);

const result: {
TABLE_NAME: string;
CONSTRAINT_NAME: string;
COLUMNS: string;
}[] = await query.then();

return result.map((v) => ({
table: v.TABLE_NAME,
constraint_name: v.CONSTRAINT_NAME,
columns: v.COLUMNS.split(',').map((c) => c.trim()),
}));
}
}
42 changes: 42 additions & 0 deletions lib/dialects/mysql.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import { Table } from '../types/table';
import { Column } from '../types/column';
import { ForeignKey } from '../types/foreign-key';
import { stripQuotes } from '../utils/strip-quotes';
import { UniqueConstraint } from '../types/unique-constraint';

type RawTable = {
TABLE_NAME: string;
Expand Down Expand Up @@ -316,4 +317,45 @@ export default class MySQL implements SchemaInspector {
const result: ForeignKey[] = await query;
return result;
}

/**
* Get all unique constraints. Limit to single table by specifying optional parameter
*/

async uniqueConstraints(table?: string): Promise<UniqueConstraint[]> {
const { knex } = this;

const query = knex
.select(
'stat.table_name AS table_name',
'stat.index_name AS constraint_name',
knex.raw(
"group_concat(stat.column_name ORDER BY stat.seq_in_index separator ', ') AS columns"
)
)
.from('information_schema.statistics AS stat')
.join('information_schema.table_constraints AS tco', function () {
this.on('stat.table_schema', '=', 'tco.table_schema')
.andOn('stat.table_name', '=', 'tco.table_name')
.andOn('stat.index_name', '=', 'tco.constraint_name');
})
.where('stat.non_unique', '=', 0)
.andWhere('tco.constraint_type', '=', 'UNIQUE')
.andWhere('stat.table_schema', knex.client.database())
.groupBy(['stat.table_name', 'stat.index_name', 'tco.constraint_type']);

if (table) query.andWhere('stat.table_name', '=', table);

const result: {
table_name: string;
constraint_name: string;
columns: string;
}[] = await query;

return result.map((v) => ({
table: v.table_name,
constraint_name: v.constraint_name,
columns: v.columns.split(',').map((c) => c.trim()),
}));
}
}
36 changes: 36 additions & 0 deletions lib/dialects/oracledb.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ import { Table } from '../types/table';
import { Column } from '../types/column';
import { ForeignKey } from '../types/foreign-key';
import { stripQuotes } from '../utils/strip-quotes';
import { UniqueConstraint } from '../types/unique-constraint';

/**
* NOTE: Use previous optimizer for better data dictionary performance.
Expand Down Expand Up @@ -330,4 +331,39 @@ export default class oracleDB implements SchemaInspector {

return await query;
}

/**
* Get all unique constraints. Limit to single table by specifying optional parameter
*/

async uniqueConstraints(table?: string): Promise<UniqueConstraint[]> {
const { knex } = this;

const query = knex
.select(
'uc.TABLE_NAME as TABLE_NAME',
'uic.INDEX_NAME as CONSTRAINT_NAME',
knex.raw('LISTAGG("uic".COLUMN_NAME, \',\') as COLUMNS')
)
.from('USER_CONSTRAINTS AS uc')
.join('USER_IND_COLUMNS as uic', function () {
this.on('uic.INDEX_NAME', '=', 'uc.INDEX_NAME');
})
.groupBy(['uc.TABLE_NAME', 'uic.INDEX_NAME'])
.orderBy(['uc.TABLE_NAME', 'uic.INDEX_NAME'])
.where('uc.CONSTRAINT_TYPE', '=', 'U');
if (table) query.andWhere('uc.TABLE_NAME', '=', table);

const result: {
TABLE_NAME: string;
CONSTRAINT_NAME: string;
COLUMNS: string;
}[] = await query.then();

return result.map((v) => ({
table: v.TABLE_NAME,
constraint_name: v.CONSTRAINT_NAME,
columns: v.COLUMNS.split(',').map((c) => c.trim()),
}));
}
}
60 changes: 59 additions & 1 deletion lib/dialects/postgres.ts
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,8 @@ import { SchemaInspector } from '../types/schema-inspector';
import { Table } from '../types/table';
import { Column } from '../types/column';
import { stripQuotes } from '../utils/strip-quotes';
import { ForeignKey } from '../types/foreign-key';
import { UniqueConstraint } from '../types/unique-constraint';

type RawColumn = {
name: string;
Expand Down Expand Up @@ -410,7 +412,7 @@ export default class Postgres implements SchemaInspector {
// Foreign Keys
// ===============================================================================================

async foreignKeys(table?: string) {
async foreignKeys(table?: string): Promise<ForeignKey[]> {
const schemaIn = this.explodedSchema.map(
(schemaName) => `${this.knex.raw('?', [schemaName])}::regnamespace`
);
Expand Down Expand Up @@ -472,4 +474,60 @@ export default class Postgres implements SchemaInspector {

return result.rows;
}

/**
* Get all unique constraints. Limit to single table by specifying optional parameter
*/

async uniqueConstraints(table?: string): Promise<UniqueConstraint[]> {
const { knex } = this;

const schemaIn = this.explodedSchema.map(
(schemaName) => `${this.knex.raw('?', [schemaName])}::regnamespace`
);

const bindings: any[] = [];
if (table) bindings.push(table);

const result = await knex.raw<{
rows: {
table_name: string;
constraint_name: string;
columns: string[] | string;
}[];
}>(
`
SELECT
con.conrelid::regclass AS table_name,
con.conname AS constraint_name,
array_agg(a.attname ORDER BY k.n) AS columns
FROM
pg_constraint AS con
CROSS JOIN LATERAL unnest(con.conkey) WITH ORDINALITY AS k(con,n)
LEFT JOIN pg_class rel ON con.conrelid = rel.oid
JOIN pg_attribute AS a ON a.attnum = k.con AND a.attrelid = con.conrelid
WHERE con.contype = 'u'
AND con.connamespace IN (${schemaIn})
${table ? `AND rel.relname = ?` : ''}
GROUP BY con.oid, con.conrelid, con.conname
ORDER BY con.conrelid::regclass, con.conname
`,
bindings
);

return result.rows.map((v) => {
const columns: string[] = Array.isArray(v.columns)
? v.columns
: v.columns
.substring(1, v.columns.length - 1)
.split(',')
.map((c) => c.trim());

return {
table: v.table_name,
constraint_name: v.constraint_name,
columns,
};
});
}
}
45 changes: 45 additions & 0 deletions lib/dialects/sqlite.ts
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@ import extractMaxLength from '../utils/extract-max-length';
import extractType from '../utils/extract-type';
import { ForeignKey } from '../types/foreign-key';
import { stripQuotes } from '../utils/strip-quotes';
import { UniqueConstraint } from '../types/unique-constraint';

type RawColumn = {
cid: number;
Expand Down Expand Up @@ -263,4 +264,48 @@ export default class SQLite implements SchemaInspector {

return flatten(keysPerTable);
}

/**
* Get all unique constraints. Limit to single table by specifying optional parameter
*/

async uniqueConstraints(table?: string): Promise<UniqueConstraint[]> {
if (table) {
const indexList = await this.knex.raw<
{ name: string; unique: boolean }[]
>(`PRAGMA index_list(??)`, table);

const indexInfoList = await Promise.all(
indexList.map((index) =>
this.knex.raw<{ seqno: number; cid: number; name: string }[]>(
`PRAGMA index_info(??)`,
index.name
)
)
);

return indexList
.filter((i) => i.unique)
.map((index, i) => {
const info = indexInfoList[i];

return {
table,
constraint_name: index.name,
columns: info.map((c) => c.name),
};
})
.sort(function (a, b) {
return a.constraint_name.localeCompare(b.constraint_name);
});
}

const tables = (await this.tables()).sort();

const constraintsPerTable = await Promise.all(
tables.map(async (table) => await this.uniqueConstraints(table))
);

return flatten(constraintsPerTable);
}
}
2 changes: 2 additions & 0 deletions lib/types/schema-inspector.ts
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@ import { Knex } from 'knex';
import { Table } from './table';
import { Column } from './column';
import { ForeignKey } from './foreign-key';
import { UniqueConstraint } from './unique-constraint';

export interface SchemaInspector {
knex: Knex;
Expand All @@ -23,6 +24,7 @@ export interface SchemaInspector {
primary(table: string): Promise<string | null>;

foreignKeys(table?: string): Promise<ForeignKey[]>;
uniqueConstraints(table?: string): Promise<UniqueConstraint[]>;

// Not in MySQL
withSchema?(schema: string): void;
Expand Down
5 changes: 5 additions & 0 deletions lib/types/unique-constraint.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
export type UniqueConstraint = {
table: string;
constraint_name: null | string;
columns: string[];
};