Skip to content

Commit

Permalink
feat: migrate tableExists to typescript (#16320)
Browse files Browse the repository at this point in the history
Co-authored-by: Rik Smale <13023439+WikiRik@users.noreply.github.com>
  • Loading branch information
lohart13 and WikiRik committed Jul 28, 2023
1 parent c59011c commit 5167e88
Show file tree
Hide file tree
Showing 18 changed files with 178 additions and 94 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -813,4 +813,10 @@ Only named replacements (:name) are allowed in literal() because we cannot guara
versionQuery(): string {
throw new Error(`${this.dialect.name} did not implement versionQuery`);
}

tableExistsQuery(tableName: TableNameOrModel): string {
const table = this.extractTableDetails(tableName);

return `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = ${this.escape(table.tableName)} AND TABLE_SCHEMA = ${this.escape(table.schema)}`;
}
}
13 changes: 13 additions & 0 deletions packages/core/src/dialects/abstract/query-interface-typescript.ts
Original file line number Diff line number Diff line change
Expand Up @@ -134,6 +134,19 @@ export class AbstractQueryInterfaceTypeScript {
return schemaNames.flatMap((value: any) => (value.schema_name ? value.schema_name : value));
}

/**
* Returns a promise that will resolve to true if the table or model exists in the database, false otherwise.
*
* @param tableName - The name of the table or model
* @param options - Query options
*/
async tableExists(tableName: TableNameOrModel, options?: QueryRawOptions): Promise<boolean> {
const sql = this.queryGenerator.tableExistsQuery(tableName);
const out = await this.sequelize.query(sql, { ...options, type: QueryTypes.SELECT });

return out.length === 1;
}

/**
* Describe a table structure
*
Expand Down
8 changes: 0 additions & 8 deletions packages/core/src/dialects/abstract/query-interface.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -314,14 +314,6 @@ export class AbstractQueryInterface extends AbstractQueryInterfaceTypeScript {
*/
showAllTables(options?: QueryRawOptions): Promise<string[]>;

/**
* Returns a promise that resolves to true if the table exists in the database, false otherwise.
*
* @param tableName The name of the table
* @param options Options passed to {@link Sequelize#query}
*/
tableExists(tableName: TableName, options?: QueryRawOptions): Promise<boolean>;

/**
* Adds a new column to a table
*/
Expand Down
18 changes: 0 additions & 18 deletions packages/core/src/dialects/abstract/query-interface.js
Original file line number Diff line number Diff line change
Expand Up @@ -175,24 +175,6 @@ export class AbstractQueryInterface extends AbstractQueryInterfaceTypeScript {
return await this.sequelize.queryRaw(sql, options);
}

/**
* Returns a promise that will resolve to true if the table exists in the database, false otherwise.
*
* @param {TableName} tableName - The name of the table
* @param {QueryOptions} options - Query options
* @returns {Promise<boolean>}
*/
async tableExists(tableName, options) {
const sql = this.queryGenerator.tableExistsQuery(tableName);

const out = await this.sequelize.query(sql, {
...options,
type: QueryTypes.SHOWTABLES,
});

return out.length === 1;
}

/**
* Drop a table from database
*
Expand Down
6 changes: 6 additions & 0 deletions packages/core/src/dialects/db2/query-generator-typescript.ts
Original file line number Diff line number Diff line change
Expand Up @@ -133,4 +133,10 @@ export class Db2QueryGeneratorTypeScript extends AbstractQueryGenerator {
versionQuery() {
return 'select service_level as "version" from TABLE (sysproc.env_get_inst_info()) as A';
}

tableExistsQuery(tableName: TableNameOrModel): string {
const table = this.extractTableDetails(tableName);

return `SELECT TABNAME FROM SYSCAT.TABLES WHERE TABNAME = ${this.escape(table.tableName)} AND TABSCHEMA = ${this.escape(table.schema)}`;
}
}
6 changes: 0 additions & 6 deletions packages/core/src/dialects/db2/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -207,12 +207,6 @@ export class Db2QueryGenerator extends Db2QueryGeneratorTypeScript {
return `SELECT TABNAME AS "tableName", TRIM(TABSCHEMA) AS "tableSchema" FROM SYSCAT.TABLES WHERE TABSCHEMA = ${this.escape(this.dialect.getDefaultSchema())} AND TYPE = 'T' ORDER BY TABSCHEMA, TABNAME`;
}

tableExistsQuery(tableName) {
const table = this.extractTableDetails(tableName);

return `SELECT TABNAME as "name" FROM SYSCAT.TABLES WHERE TABNAME = ${this.escape(table.tableName)} AND TABSCHEMA = ${this.escape(table.schema)}`;
}

addColumnQuery(table, key, dataType, options) {
if (options) {
rejectInvalidOptions(
Expand Down
9 changes: 9 additions & 0 deletions packages/core/src/dialects/ibmi/query-generator-typescript.ts
Original file line number Diff line number Diff line change
Expand Up @@ -144,4 +144,13 @@ export class IBMiQueryGeneratorTypeScript extends AbstractQueryGenerator {
versionQuery() {
return 'SELECT CONCAT(OS_VERSION, CONCAT(\'.\', OS_RELEASE)) AS "version" FROM SYSIBMADM.ENV_SYS_INFO';
}

tableExistsQuery(tableName: TableNameOrModel): string {
const table = this.extractTableDetails(tableName);

return joinSQLFragments([
`SELECT TABLE_NAME FROM QSYS2.SYSTABLES WHERE TABLE_NAME = ${this.escape(table.tableName)} AND TABLE_SCHEMA = `,
table.schema ? this.escape(table.schema) : 'CURRENT SCHEMA',
]);
}
}
7 changes: 0 additions & 7 deletions packages/core/src/dialects/mariadb/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -140,13 +140,6 @@ export class MariaDbQueryGenerator extends MariaDbQueryGeneratorTypeScript {
return `${query};`;
}

tableExistsQuery(table) {
// remove first & last `, then escape as SQL string
const tableName = this.escape(this.quoteTable(table).slice(1, -1));

return `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = ${tableName} AND TABLE_SCHEMA = ${this.escape(this.sequelize.config.database)}`;
}

addColumnQuery(table, key, dataType, options = {}) {
const ifNotExists = options.ifNotExists ? 'IF NOT EXISTS' : '';

Expand Down
7 changes: 0 additions & 7 deletions packages/core/src/dialects/mssql/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -241,13 +241,6 @@ export class MsSqlQueryGenerator extends MsSqlQueryGeneratorTypeScript {
return 'SELECT TABLE_NAME, TABLE_SCHEMA FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = \'BASE TABLE\';';
}

tableExistsQuery(table) {
const tableName = table.tableName || table;
const schemaName = table.schema || 'dbo';

return `SELECT TABLE_NAME, TABLE_SCHEMA FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = ${this.escape(tableName)} AND TABLE_SCHEMA = ${this.escape(schemaName)}`;
}

dropTableQuery(tableName, options) {
if (options) {
rejectInvalidOptions(
Expand Down
7 changes: 0 additions & 7 deletions packages/core/src/dialects/mysql/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -145,13 +145,6 @@ export class MySqlQueryGenerator extends MySqlQueryGeneratorTypeScript {
return `${query};`;
}

tableExistsQuery(table) {
// remove first & last `, then escape as SQL string
const tableName = this.escape(this.quoteTable(table).slice(1, -1));

return `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = ${tableName} AND TABLE_SCHEMA = ${this.escape(this.sequelize.config.database)}`;
}

addColumnQuery(table, key, dataType, options) {
if (options) {
rejectInvalidOptions(
Expand Down
7 changes: 0 additions & 7 deletions packages/core/src/dialects/postgres/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -184,13 +184,6 @@ export class PostgresQueryGenerator extends PostgresQueryGeneratorTypeScript {
return `SELECT table_name FROM information_schema.tables WHERE table_schema = ${this.escape(schema)} AND table_type LIKE '%TABLE' AND table_name != 'spatial_ref_sys';`;
}

tableExistsQuery(tableName) {
const table = tableName.tableName || tableName;
const schema = tableName.schema || 'public';

return `SELECT table_name FROM information_schema.tables WHERE table_schema = ${this.escape(schema)} AND table_name = ${this.escape(table)}`;
}

addColumnQuery(table, key, attribute, options) {
options = options || {};

Expand Down
12 changes: 0 additions & 12 deletions packages/core/src/dialects/snowflake/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -197,18 +197,6 @@ export class SnowflakeQueryGenerator extends SnowflakeQueryGeneratorTypeScript {
]);
}

tableExistsQuery(table) {
const tableName = table.tableName ?? table;
const schema = table.schema;

return joinSQLFragments([
'SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = \'BASE TABLE\'',
`AND TABLE_SCHEMA = ${schema !== undefined ? this.escape(schema) : 'CURRENT_SCHEMA()'}`,
`AND TABLE_NAME = ${this.escape(tableName)}`,
';',
]);
}

addColumnQuery(table, key, dataType, options) {
if (options) {
rejectInvalidOptions(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -141,4 +141,9 @@ export class SqliteQueryGeneratorTypeScript extends AbstractQueryGenerator {
versionQuery() {
return 'SELECT sqlite_version() as `version`';
}

tableExistsQuery(tableName: TableNameOrModel): string {

return `SELECT name FROM sqlite_master WHERE type = 'table' AND name = ${this.escapeTable(tableName)}`;
}
}
4 changes: 0 additions & 4 deletions packages/core/src/dialects/sqlite/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -330,10 +330,6 @@ export class SqliteQueryGenerator extends SqliteQueryGeneratorTypeScript {
return sql.replaceAll(/DEFAULT '?false'?/g, 'DEFAULT 0').replaceAll(/DEFAULT '?true'?/g, 'DEFAULT 1');
}

tableExistsQuery(tableName) {
return `SELECT name FROM sqlite_master WHERE type='table' AND name=${this.escape(this.extractTableDetails(tableName).tableName)};`;
}

/**
* Generates an SQL query to check if there are any foreign key violations in the db schema
*
Expand Down
9 changes: 2 additions & 7 deletions packages/core/src/model.js
Original file line number Diff line number Diff line change
Expand Up @@ -817,21 +817,16 @@ ${associationOwner._getAssociationDebugList()}`);
// Check foreign keys. If it's a foreign key, it should remove constraint first.
const references = currentAttribute.references;
if (currentAttribute.references) {
let database = this.sequelize.config.database;
const schema = tableName.schema;
if (schema && this.sequelize.options.dialect === 'mariadb') {
// because for mariadb schema is synonym for database
database = schema;
}

const database = this.sequelize.config.database;
const foreignReferenceSchema = currentAttribute.references.table.schema;
const foreignReferenceTableName = typeof references.table === 'object'
? references.table.tableName : references.table;
// Find existed foreign keys
for (const foreignKeyReference of foreignKeyReferences) {
const constraintName = foreignKeyReference.constraintName;
if ((Boolean(constraintName)
&& foreignKeyReference.tableCatalog === database
&& (foreignKeyReference.tableCatalog ? foreignKeyReference.tableCatalog === database : true)
&& (schema ? foreignKeyReference.tableSchema === schema : true)
&& foreignKeyReference.referencedTableName === foreignReferenceTableName
&& foreignKeyReference.referencedColumnName === references.key
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
import { expect } from 'chai';
import { DataTypes } from '@sequelize/core';
import { sequelize } from '../support';

const queryInterface = sequelize.queryInterface;

describe('QueryInterface#tableExists', () => {
describe('Without schema', () => {
beforeEach(async () => {
await queryInterface.createTable('levels', {
id: {
type: DataTypes.INTEGER,
autoIncrement: true,
primaryKey: true,
},
name: {
type: DataTypes.STRING,
allowNull: false,
},
});
});

it('should return true if table exists', async () => {
const exists = await queryInterface.tableExists('levels');
expect(exists).to.be.true;
});

it('should return false if table does not exist', async () => {
const exists = await queryInterface.tableExists('actors');
expect(exists).to.be.false;
});
});

if (sequelize.dialect.supports.schemas) {
describe('With schema', () => {
beforeEach(async () => {
await queryInterface.createSchema('archive');

await queryInterface.createTable({ tableName: 'levels', schema: 'archive' }, {
id: {
type: DataTypes.INTEGER,
primaryKey: true,
autoIncrement: true,
},
name: {
type: DataTypes.STRING,
allowNull: false,
},
});
});

it('should return true if table exists', async () => {
const exists = await queryInterface.tableExists({ tableName: 'levels', schema: 'archive' });
expect(exists).to.be.true;
});

it('should return false if table does not exist', async () => {
const exists = await queryInterface.tableExists({ tableName: 'actors', schema: 'archive' });
expect(exists).to.be.false;
});
});
}
});
11 changes: 0 additions & 11 deletions packages/core/test/unit/dialects/snowflake/query-generator.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -128,17 +128,6 @@ if (dialect === 'snowflake') {
},
],

tableExistsQuery: [
{
arguments: ['myTable'],
expectation: 'SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = \'BASE TABLE\' AND TABLE_SCHEMA = CURRENT_SCHEMA() AND TABLE_NAME = \'myTable\';',
},
{
arguments: [{ tableName: 'myTable', schema: 'mySchema' }],
expectation: 'SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = \'BASE TABLE\' AND TABLE_SCHEMA = \'mySchema\' AND TABLE_NAME = \'myTable\';',
},
],

selectQuery: [
{
arguments: ['myTable'],
Expand Down
74 changes: 74 additions & 0 deletions packages/core/test/unit/query-generator/table-exists-query.test.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
import { createSequelizeInstance, expectsql, sequelize } from '../../support';

const dialect = sequelize.dialect;

describe('QueryGenerator#tableExistsQuery', () => {
const queryGenerator = sequelize.queryGenerator;
const defaultSchema = dialect.getDefaultSchema();

it('produces a table exists query for a table', () => {
expectsql(() => queryGenerator.tableExistsQuery('myTable'), {
default: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = 'myTable' AND TABLE_SCHEMA = '${defaultSchema}'`,
db2: `SELECT TABNAME FROM SYSCAT.TABLES WHERE TABNAME = 'myTable' AND TABSCHEMA = '${defaultSchema}'`,
ibmi: `SELECT TABLE_NAME FROM QSYS2.SYSTABLES WHERE TABLE_NAME = 'myTable' AND TABLE_SCHEMA = CURRENT SCHEMA`,
mssql: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = N'myTable' AND TABLE_SCHEMA = N'${defaultSchema}'`,
sqlite: `SELECT name FROM sqlite_master WHERE type = 'table' AND name = 'myTable'`,
});
});

it('produces a table exists query for a model', () => {
const MyModel = sequelize.define('MyModel', {});

expectsql(() => queryGenerator.tableExistsQuery(MyModel), {
default: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = 'MyModels' AND TABLE_SCHEMA = '${defaultSchema}'`,
db2: `SELECT TABNAME FROM SYSCAT.TABLES WHERE TABNAME = 'MyModels' AND TABSCHEMA = '${defaultSchema}'`,
ibmi: `SELECT TABLE_NAME FROM QSYS2.SYSTABLES WHERE TABLE_NAME = 'MyModels' AND TABLE_SCHEMA = CURRENT SCHEMA`,
mssql: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = N'MyModels' AND TABLE_SCHEMA = N'${defaultSchema}'`,
sqlite: `SELECT name FROM sqlite_master WHERE type = 'table' AND name = 'MyModels'`,
});
});

it('produces a table exists query for a table and schema', () => {
expectsql(() => queryGenerator.tableExistsQuery({ tableName: 'myTable', schema: 'mySchema' }), {
default: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = 'myTable' AND TABLE_SCHEMA = 'mySchema'`,
db2: `SELECT TABNAME FROM SYSCAT.TABLES WHERE TABNAME = 'myTable' AND TABSCHEMA = 'mySchema'`,
ibmi: `SELECT TABLE_NAME FROM QSYS2.SYSTABLES WHERE TABLE_NAME = 'myTable' AND TABLE_SCHEMA = 'mySchema'`,
mssql: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = N'myTable' AND TABLE_SCHEMA = N'mySchema'`,
sqlite: `SELECT name FROM sqlite_master WHERE type = 'table' AND name = 'mySchema.myTable'`,
});
});

it('produces a table exists query for a table and default schema', () => {
expectsql(() => queryGenerator.tableExistsQuery({ tableName: 'myTable', schema: dialect.getDefaultSchema() }), {
default: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = 'myTable' AND TABLE_SCHEMA = '${defaultSchema}'`,
db2: `SELECT TABNAME FROM SYSCAT.TABLES WHERE TABNAME = 'myTable' AND TABSCHEMA = '${defaultSchema}'`,
ibmi: `SELECT TABLE_NAME FROM QSYS2.SYSTABLES WHERE TABLE_NAME = 'myTable' AND TABLE_SCHEMA = CURRENT SCHEMA`,
mssql: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = N'myTable' AND TABLE_SCHEMA = N'${defaultSchema}'`,
sqlite: `SELECT name FROM sqlite_master WHERE type = 'table' AND name = 'myTable'`,
});
});

it('produces a table exists query for a table and globally set schema', () => {
const sequelizeSchema = createSequelizeInstance({ schema: 'mySchema' });
const queryGeneratorSchema = sequelizeSchema.queryGenerator;

expectsql(() => queryGeneratorSchema.tableExistsQuery('myTable'), {
default: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = 'myTable' AND TABLE_SCHEMA = 'mySchema'`,
db2: `SELECT TABNAME FROM SYSCAT.TABLES WHERE TABNAME = 'myTable' AND TABSCHEMA = 'mySchema'`,
ibmi: `SELECT TABLE_NAME FROM QSYS2.SYSTABLES WHERE TABLE_NAME = 'myTable' AND TABLE_SCHEMA = 'mySchema'`,
mssql: `SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME = N'myTable' AND TABLE_SCHEMA = N'mySchema'`,
sqlite: `SELECT name FROM sqlite_master WHERE type = 'table' AND name = 'mySchema.myTable'`,
});
});

it('produces a table exists query for a table with schema and custom delimiter argument', () => {
// This test is only relevant for dialects that do not support schemas
if (dialect.supports.schemas) {
return;
}

expectsql(() => queryGenerator.tableExistsQuery({ tableName: 'myTable', schema: 'mySchema', delimiter: 'custom' }), {
sqlite: `SELECT name FROM sqlite_master WHERE type = 'table' AND name = 'mySchemacustommyTable'`,
});
});
});

0 comments on commit 5167e88

Please sign in to comment.