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

fix: filter also on schema name when retrieving foreign keys #16770

Open
wants to merge 6 commits into
base: v6
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.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
5 changes: 2 additions & 3 deletions src/dialects/mssql/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -741,9 +741,8 @@ class MSSQLQueryGenerator extends AbstractQueryGenerator {
let sql = `${this._getForeignKeysQueryPrefix(catalogName)
} WHERE TB.NAME =${wrapSingleQuote(tableName)}`;

if (table.schema) {
sql += ` AND SCHEMA_NAME(TB.SCHEMA_ID) =${wrapSingleQuote(table.schema)}`;
}
sql += ` AND SCHEMA_NAME(TB.SCHEMA_ID) =${wrapSingleQuote(table.schema || 'dbo')}`;

return sql;
}

Expand Down
2 changes: 1 addition & 1 deletion src/dialects/oracle/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -1008,7 +1008,7 @@ export class OracleQueryGenerator extends AbstractQueryGenerator {
const [tableName, schemaName] = this.getSchemaNameAndTableName(table);
const sql = [
'SELECT DISTINCT a.table_name "tableName", a.constraint_name "constraintName", a.owner "owner", a.column_name "columnName",',
' b.table_name "referencedTableName", b.column_name "referencedColumnName"',
' b.table_name "referencedTableName", b.column_name "referencedColumnName", a.owner "tableSchema"',
' FROM all_cons_columns a',
' JOIN all_constraints c ON a.owner = c.owner AND a.constraint_name = c.constraint_name',
' JOIN all_cons_columns b ON c.owner = b.owner AND c.r_constraint_name = b.constraint_name',
Expand Down
15 changes: 10 additions & 5 deletions src/dialects/postgres/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -886,8 +886,12 @@ class PostgresQueryGenerator extends AbstractQueryGenerator {
'FROM information_schema.table_constraints AS tc ' +
'JOIN information_schema.key_column_usage AS kcu ' +
'ON tc.constraint_name = kcu.constraint_name ' +
'AND tc.table_schema = kcu.table_schema ' +
'AND tc.table_catalog = kcu.table_catalog ' +
'JOIN information_schema.constraint_column_usage AS ccu ' +
'ON ccu.constraint_name = tc.constraint_name ';
'ON ccu.constraint_name = tc.constraint_name ' +
'AND ccu.table_schema = tc.table_schema ' +
'AND ccu.table_catalog = tc.table_catalog ';
}

/**
Expand All @@ -900,18 +904,19 @@ class PostgresQueryGenerator extends AbstractQueryGenerator {
* @param {string} schemaName
*/
getForeignKeyReferencesQuery(tableName, catalogName, schemaName) {
const schema = schemaName || 'public';

return `${this._getForeignKeyReferencesQueryPrefix()
}WHERE constraint_type = 'FOREIGN KEY' AND tc.table_name = '${tableName}'${
catalogName ? ` AND tc.table_catalog = '${catalogName}'` : ''
}${schemaName ? ` AND tc.table_schema = '${schemaName}'` : ''}`;
} AND tc.table_schema = '${schema}'`;
}

getForeignKeyReferenceQuery(table, columnName) {
const tableName = table.tableName || table;
const schema = table.schema;
const schema = table.schema || 'public';
return `${this._getForeignKeyReferencesQueryPrefix()
}WHERE constraint_type = 'FOREIGN KEY' AND tc.table_name='${tableName}' AND kcu.column_name = '${columnName}'${
schema ? ` AND tc.table_schema = '${schema}'` : ''}`;
}WHERE constraint_type = 'FOREIGN KEY' AND tc.table_name='${tableName}' AND kcu.column_name = '${columnName}' AND tc.table_schema = '${schema}'`;
}

/**
Expand Down
2 changes: 1 addition & 1 deletion src/dialects/postgres/query-interface.js
Original file line number Diff line number Diff line change
Expand Up @@ -157,7 +157,7 @@ class PostgresQueryInterface extends QueryInterface {

// postgres needs some special treatment as those field names returned are all lowercase
// in order to keep same result with other dialects.
const query = this.queryGenerator.getForeignKeyReferencesQuery(table.tableName || table, this.sequelize.config.database);
const query = this.queryGenerator.getForeignKeyReferencesQuery(table.tableName || table, this.sequelize.config.database, table.schema);
const result = await this.sequelize.query(query, queryOptions);

return result.map(fkMeta => {
Expand Down
2 changes: 1 addition & 1 deletion test/integration/query-interface.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -476,7 +476,7 @@ describe(Support.getTestDialectTeaser('QueryInterface'), () => {
} else if (['mysql', 'mariadb', 'mssql'].includes(dialect)) {
expect(Object.keys(foreignKeys[0])).to.have.length(12);
} else if (dialect === 'oracle') {
expect(Object.keys(foreignKeys[0])).to.have.length(6);
expect(Object.keys(foreignKeys[0])).to.have.length(7);
} else {
throw new Error(`This test doesn't support ${dialect}`);
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ const DataTypes = require('../../../lib/data-types');

describe(Support.getTestDialectTeaser('QueryInterface'), () => {
beforeEach(function() {
this.sequelize.options.quoteIdenifiers = true;
this.sequelize.options.quoteIdentifiers = true;
this.queryInterface = this.sequelize.getQueryInterface();
});

Expand Down Expand Up @@ -40,5 +40,51 @@ describe(Support.getTestDialectTeaser('QueryInterface'), () => {
expect(refs[0]).deep.include.all(expectedObject);

});

describe('with schemas', () => {
// MariaDB does not really support schemas (they are synonyms of databases)
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Is this behaviour different between mariadb and mysql?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

For MySQL, Support.sequelize.dialect.supports.schemas is false, but for MariaDB it's true (even though it does not really support schemas).

You can see it there:

  1. For MySQL
  2. For MariaDB

if (Support.sequelize.dialect.supports.schemas && Support.getTestDialect() !== 'mariadb') {
beforeEach(async function() {
this.schema = 'test_schema';
await this.queryInterface.createSchema(this.schema);

const TaskTest = this.sequelize.define('TaskTest', { title: DataTypes.STRING }, { tableName: 'Tasks', schema: this.schema });
const UserTest = this.sequelize.define('UserTest', { username: DataTypes.STRING }, { tableName: 'Users', schema: this.schema });

UserTest.hasOne(TaskTest, { foreignKey: 'UserId' });

const Task = this.sequelize.define('Task', { title: DataTypes.STRING }, { tableName: 'Tasks' });
const User = this.sequelize.define('User', { username: DataTypes.STRING }, { tableName: 'Users' });

User.hasOne(Task, { foreignKey: 'UserId' });

await UserTest.sync({ force: true });
await TaskTest.sync({ force: true });
await User.sync({ force: true });
await Task.sync({ force: true });
});

it('should return only references to the tables on the right schema', async function() {
const tasksTestRefs = await this.queryInterface.getForeignKeyReferencesForTable({ tableName: 'Tasks', schema: this.schema });
expect(tasksTestRefs).to.have.lengthOf(1);
expect(tasksTestRefs[0]).deep.include.all({
columnName: 'UserId',
referencedColumnName: 'id',
referencedTableName: 'Users',
tableSchema: this.schema
});
});

it('should only return references to the tables on the default schema', async function() {
const taskRefs = await this.queryInterface.getForeignKeyReferencesForTable('Tasks');
expect(taskRefs).to.have.lengthOf(1);
expect(taskRefs[0]).deep.include.all({
columnName: 'UserId',
referencedColumnName: 'id',
referencedTableName: 'Users'
});
});
}
});
});
});
4 changes: 2 additions & 2 deletions test/unit/dialects/mssql/query-generator.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -311,11 +311,11 @@ if (current.dialect.name === 'mssql') {

it('getForeignKeysQuery', function() {
expectsql(this.queryGenerator.getForeignKeysQuery('myTable'), {
mssql: "SELECT constraint_name = OBJ.NAME, constraintName = OBJ.NAME, constraintSchema = SCHEMA_NAME(OBJ.SCHEMA_ID), tableName = TB.NAME, tableSchema = SCHEMA_NAME(TB.SCHEMA_ID), columnName = COL.NAME, referencedTableSchema = SCHEMA_NAME(RTB.SCHEMA_ID), referencedTableName = RTB.NAME, referencedColumnName = RCOL.NAME FROM sys.foreign_key_columns FKC INNER JOIN sys.objects OBJ ON OBJ.OBJECT_ID = FKC.CONSTRAINT_OBJECT_ID INNER JOIN sys.tables TB ON TB.OBJECT_ID = FKC.PARENT_OBJECT_ID INNER JOIN sys.columns COL ON COL.COLUMN_ID = PARENT_COLUMN_ID AND COL.OBJECT_ID = TB.OBJECT_ID INNER JOIN sys.tables RTB ON RTB.OBJECT_ID = FKC.REFERENCED_OBJECT_ID INNER JOIN sys.columns RCOL ON RCOL.COLUMN_ID = REFERENCED_COLUMN_ID AND RCOL.OBJECT_ID = RTB.OBJECT_ID WHERE TB.NAME ='myTable'"
mssql: "SELECT constraint_name = OBJ.NAME, constraintName = OBJ.NAME, constraintSchema = SCHEMA_NAME(OBJ.SCHEMA_ID), tableName = TB.NAME, tableSchema = SCHEMA_NAME(TB.SCHEMA_ID), columnName = COL.NAME, referencedTableSchema = SCHEMA_NAME(RTB.SCHEMA_ID), referencedTableName = RTB.NAME, referencedColumnName = RCOL.NAME FROM sys.foreign_key_columns FKC INNER JOIN sys.objects OBJ ON OBJ.OBJECT_ID = FKC.CONSTRAINT_OBJECT_ID INNER JOIN sys.tables TB ON TB.OBJECT_ID = FKC.PARENT_OBJECT_ID INNER JOIN sys.columns COL ON COL.COLUMN_ID = PARENT_COLUMN_ID AND COL.OBJECT_ID = TB.OBJECT_ID INNER JOIN sys.tables RTB ON RTB.OBJECT_ID = FKC.REFERENCED_OBJECT_ID INNER JOIN sys.columns RCOL ON RCOL.COLUMN_ID = REFERENCED_COLUMN_ID AND RCOL.OBJECT_ID = RTB.OBJECT_ID WHERE TB.NAME ='myTable' AND SCHEMA_NAME(TB.SCHEMA_ID) ='dbo'"
});

expectsql(this.queryGenerator.getForeignKeysQuery('myTable', 'myDatabase'), {
mssql: "SELECT constraint_name = OBJ.NAME, constraintName = OBJ.NAME, constraintCatalog = 'myDatabase', constraintSchema = SCHEMA_NAME(OBJ.SCHEMA_ID), tableName = TB.NAME, tableSchema = SCHEMA_NAME(TB.SCHEMA_ID), tableCatalog = 'myDatabase', columnName = COL.NAME, referencedTableSchema = SCHEMA_NAME(RTB.SCHEMA_ID), referencedCatalog = 'myDatabase', referencedTableName = RTB.NAME, referencedColumnName = RCOL.NAME FROM sys.foreign_key_columns FKC INNER JOIN sys.objects OBJ ON OBJ.OBJECT_ID = FKC.CONSTRAINT_OBJECT_ID INNER JOIN sys.tables TB ON TB.OBJECT_ID = FKC.PARENT_OBJECT_ID INNER JOIN sys.columns COL ON COL.COLUMN_ID = PARENT_COLUMN_ID AND COL.OBJECT_ID = TB.OBJECT_ID INNER JOIN sys.tables RTB ON RTB.OBJECT_ID = FKC.REFERENCED_OBJECT_ID INNER JOIN sys.columns RCOL ON RCOL.COLUMN_ID = REFERENCED_COLUMN_ID AND RCOL.OBJECT_ID = RTB.OBJECT_ID WHERE TB.NAME ='myTable'"
mssql: "SELECT constraint_name = OBJ.NAME, constraintName = OBJ.NAME, constraintCatalog = 'myDatabase', constraintSchema = SCHEMA_NAME(OBJ.SCHEMA_ID), tableName = TB.NAME, tableSchema = SCHEMA_NAME(TB.SCHEMA_ID), tableCatalog = 'myDatabase', columnName = COL.NAME, referencedTableSchema = SCHEMA_NAME(RTB.SCHEMA_ID), referencedCatalog = 'myDatabase', referencedTableName = RTB.NAME, referencedColumnName = RCOL.NAME FROM sys.foreign_key_columns FKC INNER JOIN sys.objects OBJ ON OBJ.OBJECT_ID = FKC.CONSTRAINT_OBJECT_ID INNER JOIN sys.tables TB ON TB.OBJECT_ID = FKC.PARENT_OBJECT_ID INNER JOIN sys.columns COL ON COL.COLUMN_ID = PARENT_COLUMN_ID AND COL.OBJECT_ID = TB.OBJECT_ID INNER JOIN sys.tables RTB ON RTB.OBJECT_ID = FKC.REFERENCED_OBJECT_ID INNER JOIN sys.columns RCOL ON RCOL.COLUMN_ID = REFERENCED_COLUMN_ID AND RCOL.OBJECT_ID = RTB.OBJECT_ID WHERE TB.NAME ='myTable' AND SCHEMA_NAME(TB.SCHEMA_ID) ='dbo'"
});

expectsql(this.queryGenerator.getForeignKeysQuery({
Expand Down
47 changes: 28 additions & 19 deletions test/unit/dialects/postgres/query-generator.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -1226,31 +1226,40 @@ if (dialect.startsWith('postgres')) {
'FROM information_schema.table_constraints AS tc ' +
'JOIN information_schema.key_column_usage AS kcu ' +
'ON tc.constraint_name = kcu.constraint_name ' +
'AND tc.table_schema = kcu.table_schema ' +
'AND tc.table_catalog = kcu.table_catalog ' +
'JOIN information_schema.constraint_column_usage AS ccu ' +
'ON ccu.constraint_name = tc.constraint_name ' +
'WHERE constraint_type = \'FOREIGN KEY\' AND tc.table_name=\'myTable\' AND kcu.column_name = \'myColumn\''
'AND ccu.table_schema = tc.table_schema AND ' +
'ccu.table_catalog = tc.table_catalog ' +
'WHERE constraint_type = \'FOREIGN KEY\' AND tc.table_name=\'myTable\' AND kcu.column_name = \'myColumn\' ' +
'AND tc.table_schema = \'public\''
},
{
arguments: [{ schema: 'mySchema', tableName: 'myTable' }, 'myColumn'],
expectation: 'SELECT ' +
'DISTINCT tc.constraint_name as constraint_name, ' +
'tc.constraint_schema as constraint_schema, ' +
'tc.constraint_catalog as constraint_catalog, ' +
'tc.table_name as table_name,' +
'tc.table_schema as table_schema,' +
'tc.table_catalog as table_catalog,' +
'tc.initially_deferred as initially_deferred,' +
'tc.is_deferrable as is_deferrable,' +
'kcu.column_name as column_name,' +
'ccu.table_schema AS referenced_table_schema,' +
'ccu.table_catalog AS referenced_table_catalog,' +
'ccu.table_name AS referenced_table_name,' +
'ccu.column_name AS referenced_column_name ' +
'FROM information_schema.table_constraints AS tc ' +
'JOIN information_schema.key_column_usage AS kcu ' +
'ON tc.constraint_name = kcu.constraint_name ' +
'JOIN information_schema.constraint_column_usage AS ccu ' +
'ON ccu.constraint_name = tc.constraint_name ' +
'DISTINCT tc.constraint_name as constraint_name, ' +
'tc.constraint_schema as constraint_schema, ' +
'tc.constraint_catalog as constraint_catalog, ' +
'tc.table_name as table_name,' +
'tc.table_schema as table_schema,' +
'tc.table_catalog as table_catalog,' +
'tc.initially_deferred as initially_deferred,' +
'tc.is_deferrable as is_deferrable,' +
'kcu.column_name as column_name,' +
'ccu.table_schema AS referenced_table_schema,' +
'ccu.table_catalog AS referenced_table_catalog,' +
'ccu.table_name AS referenced_table_name,' +
'ccu.column_name AS referenced_column_name ' +
'FROM information_schema.table_constraints AS tc ' +
'JOIN information_schema.key_column_usage AS kcu ' +
'ON tc.constraint_name = kcu.constraint_name ' +
'AND tc.table_schema = kcu.table_schema ' +
'AND tc.table_catalog = kcu.table_catalog ' +
'JOIN information_schema.constraint_column_usage AS ccu ' +
'ON ccu.constraint_name = tc.constraint_name ' +
'AND ccu.table_schema = tc.table_schema AND ' +
'ccu.table_catalog = tc.table_catalog ' +
'WHERE constraint_type = \'FOREIGN KEY\' AND tc.table_name=\'myTable\' AND kcu.column_name = \'myColumn\'' +
' AND tc.table_schema = \'mySchema\''
}
Expand Down