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(postgres): use schema set in sequelize config by default #14634

Merged
merged 12 commits into from
Jun 19, 2022
2 changes: 1 addition & 1 deletion src/dialects/abstract/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -52,7 +52,7 @@ export class AbstractQueryGenerator {
tableName = tableName || {};

return {
schema: tableName.schema || options.schema || 'public',
schema: tableName.schema || options.schema || this.options.schema || 'public',
tableName: _.isPlainObject(tableName) ? tableName.tableName : tableName,
delimiter: tableName.delimiter || options.delimiter || '.',
};
Expand Down
10 changes: 5 additions & 5 deletions src/dialects/postgres/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -133,13 +133,13 @@ export class PostgresQueryGenerator extends AbstractQueryGenerator {
}

showTablesQuery() {
return 'SELECT table_name FROM information_schema.tables WHERE table_schema = \'public\' AND table_type LIKE \'%TABLE\' AND table_name != \'spatial_ref_sys\';';
const schema = this.options.schema || 'public';

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';`;
}

describeTableQuery(tableName, schema) {
if (!schema) {
schema = 'public';
}
schema = schema || this.options.schema || 'public';

return 'SELECT '
+ 'pk.constraint_type as "Constraint",'
Expand All @@ -160,7 +160,7 @@ export class PostgresQueryGenerator extends AbstractQueryGenerator {
+ 'ON pk.table_schema=c.table_schema '
+ 'AND pk.table_name=c.table_name '
+ 'AND pk.column_name=c.column_name '
+ `WHERE c.table_name = ${this.escape(tableName)} AND c.table_schema = ${this.escape(schema)} `;
+ `WHERE c.table_name = ${this.escape(tableName)} AND c.table_schema = ${this.escape(schema)}`;
}

/**
Expand Down
48 changes: 48 additions & 0 deletions test/unit/dialects/postgres/query-generator.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -1331,5 +1331,53 @@ if (dialect.startsWith('postgres')) {
});
});
});

describe('Custom Schema Functions', () => {
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
beforeEach(function () {
this.queryGenerator = new QueryGenerator({
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
sequelize: this.sequelize,
_dialect: this.sequelize.dialect,
});
// Add custom schema to sequelize object
this.queryGenerator.sequelize.options.schema = 'custom';
});
afterEach(function () {
// Remove custom schema in order to not interfere with other tests
this.queryGenerator.sequelize.options.schema = null;
});

const customSchemaSuites = {
showTablesQuery: [
{
title: 'showTablesQuery should use correct custom schema',
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
arguments: [],
expectation: 'SELECT table_name FROM information_schema.tables WHERE table_schema = \'custom\' AND table_type LIKE \'%TABLE\' AND table_name != \'spatial_ref_sys\';',
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
},
],
describeTableQuery: [
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
{
title: 'describeTableQuery should use correct custom schema',
arguments: ['myTable', null],
expectation: `SELECT pk.constraint_type as "Constraint",c.column_name as "Field", c.column_default as "Default",c.is_nullable as "Null", (CASE WHEN c.udt_name = 'hstore' THEN c.udt_name ELSE c.data_type END) || (CASE WHEN c.character_maximum_length IS NOT NULL THEN '(' || c.character_maximum_length || ')' ELSE '' END) as "Type", (SELECT array_agg(e.enumlabel) FROM pg_catalog.pg_type t JOIN pg_catalog.pg_enum e ON t.oid=e.enumtypid WHERE t.typname=c.udt_name) AS "special", (SELECT pgd.description FROM pg_catalog.pg_statio_all_tables AS st INNER JOIN pg_catalog.pg_description pgd on (pgd.objoid=st.relid) WHERE c.ordinal_position=pgd.objsubid AND c.table_name=st.relname) AS "Comment" FROM information_schema.columns c LEFT JOIN (SELECT tc.table_schema, tc.table_name, cu.column_name, tc.constraint_type FROM information_schema.TABLE_CONSTRAINTS tc JOIN information_schema.KEY_COLUMN_USAGE cu ON tc.table_schema=cu.table_schema and tc.table_name=cu.table_name and tc.constraint_name=cu.constraint_name and tc.constraint_type='PRIMARY KEY') pk ON pk.table_schema=c.table_schema AND pk.table_name=c.table_name AND pk.column_name=c.column_name WHERE c.table_name = 'myTable' AND c.table_schema = 'custom'`,
},
],
addColumnQuery: [
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
{
title: 'addColumnQuery should use correct custom schema',
arguments: ['myTable', 'myColumn', { type: DataTypes.STRING(191), allowNull: true }],
expectation: 'ALTER TABLE "custom"."myTable" ADD COLUMN "myColumn" VARCHAR(191);',
},
],
};

_.each(customSchemaSuites, (customSchemaTests, customSchemaSuiteTitle) => {
for (const customSchemaTest of customSchemaTests) {
it(customSchemaTest.title, function () {
const convertedText = customSchemaTest.arguments ? this.queryGenerator[customSchemaSuiteTitle](...customSchemaTest.arguments) : this.queryGenerator[customSchemaSuiteTitle]();
expect(convertedText).to.equal(customSchemaTest.expectation);
});
}
});
});
});
}
34 changes: 34 additions & 0 deletions test/unit/sql/add-column.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -2,11 +2,16 @@

const Support = require('../support');
const { DataTypes } = require('@sequelize/core');
const _ = require('lodash');

const expectsql = Support.expectsql;
const current = Support.sequelize;
const sql = current.dialect.queryGenerator;

const custom = _.cloneDeep(current);
custom.options.schema = 'custom';
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
const customSql = custom.dialect.queryGenerator;

if (['mysql', 'mariadb'].includes(current.dialect.name)) {
describe(Support.getTestDialectTeaser('SQL'), () => {
describe('addColumn', () => {
Expand Down Expand Up @@ -66,3 +71,32 @@ if (['mysql', 'mariadb'].includes(current.dialect.name)) {
});
});
}

describe(`Custom Schema ${Support.getTestDialectTeaser('SQL')}`, () => {
describe('addColumnCustomSchema', () => {

const Model = current.define('users', {
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
id: {
type: DataTypes.INTEGER,
primaryKey: true,
autoIncrement: true,
},
}, { timestamps: false });

it('properly generate alter queries', () => {
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
return expectsql(customSql.addColumnQuery(Model.getTableName(), 'level_id', custom.normalizeAttribute({
type: DataTypes.FLOAT,
allowNull: false,
})), {
mariadb: 'ALTER TABLE `users` ADD `level_id` FLOAT NOT NULL;',
mysql: 'ALTER TABLE `users` ADD `level_id` FLOAT NOT NULL;',
postgres: 'ALTER TABLE "custom"."users" ADD COLUMN "level_id" FLOAT NOT NULL;',
sqlite: 'ALTER TABLE `users` ADD `level_id` FLOAT NOT NULL;',
mssql: 'ALTER TABLE [users] ADD [level_id] FLOAT NOT NULL;',
db2: 'ALTER TABLE "users" ADD "level_id" FLOAT NOT NULL;',
snowflake: 'ALTER TABLE "users" ADD "level_id" FLOAT NOT NULL;',
ibmi: 'ALTER TABLE "users" ADD "level_id" FLOAT NOT NULL',
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
});
});
});
});
24 changes: 24 additions & 0 deletions test/unit/sql/remove-column.test.js
Original file line number Diff line number Diff line change
@@ -1,11 +1,16 @@
'use strict';

const Support = require('../support');
const _ = require('lodash');

const expectsql = Support.expectsql;
const current = Support.sequelize;
const sql = current.dialect.queryGenerator;

const custom = _.cloneDeep(current);
custom.options.schema = 'custom';
const customSql = custom.dialect.queryGenerator;

// Notice: [] will be replaced by dialect specific tick/quote character when there is not dialect specific expectation but only a default expectation

if (current.dialect.name !== 'sqlite') {
Expand All @@ -28,3 +33,22 @@ if (current.dialect.name !== 'sqlite') {
});
});
}

describe(`Custom Schema ${Support.getTestDialectTeaser('SQL')}`, () => {
nholmes3 marked this conversation as resolved.
Show resolved Hide resolved
describe('removeColumnCustomSchema', () => {
it('schema', () => {
expectsql(customSql.removeColumnQuery({
tableName: 'user',
}, 'email'), {
ibmi: 'ALTER TABLE "user" DROP COLUMN "email"',
mssql: 'ALTER TABLE [user] DROP COLUMN [email];',
db2: 'ALTER TABLE "user" DROP COLUMN "email";',
mariadb: 'ALTER TABLE `user` DROP `email`;',
mysql: 'ALTER TABLE `user` DROP `email`;',
postgres: 'ALTER TABLE "custom"."user" DROP COLUMN "email";',
snowflake: 'ALTER TABLE "user" DROP "email";',
sqlite: 'CREATE TABLE IF NOT EXISTS `user_backup` (`0` e, `1` m, `2` a, `3` i, `4` l);INSERT INTO `user_backup` SELECT `0`, `1`, `2`, `3`, `4` FROM `user`;DROP TABLE `user`;CREATE TABLE IF NOT EXISTS `user` (`0` e, `1` m, `2` a, `3` i, `4` l);INSERT INTO `user` SELECT `0`, `1`, `2`, `3`, `4` FROM `user_backup`;DROP TABLE `user_backup`;',
});
});
});
});