不要怂,就是干,撸起袖子干!

Commit 5b6dae76 by Jeremy Fowler Committed by Sushant

feat(dropSchema): support for mssql (#9081)

1 parent baba4bc5
...@@ -33,6 +33,41 @@ const QueryGenerator = { ...@@ -33,6 +33,41 @@ const QueryGenerator = {
].join(' '); ].join(' ');
}, },
dropSchema(schema) {
// Mimics Postgres CASCADE, will drop objects belonging to the schema
const quotedSchema = wrapSingleQuote(schema);
return [
'IF EXISTS (SELECT schema_name',
'FROM information_schema.schemata',
'WHERE schema_name =', quotedSchema, ')',
'BEGIN',
'DECLARE @id INT, @ms_sql NVARCHAR(2000);',
'DECLARE @cascade TABLE (',
'id INT NOT NULL IDENTITY PRIMARY KEY,',
'ms_sql NVARCHAR(2000) NOT NULL );',
'INSERT INTO @cascade ( ms_sql )',
"SELECT CASE WHEN o.type IN ('F','PK')",
"THEN N'ALTER TABLE ['+ s.name + N'].[' + p.name + N'] DROP CONSTRAINT [' + o.name + N']'",
"ELSE N'DROP TABLE ['+ s.name + N'].[' + o.name + N']' END",
'FROM sys.objects o',
'JOIN sys.schemas s on o.schema_id = s.schema_id',
'LEFT OUTER JOIN sys.objects p on o.parent_object_id = p.object_id',
"WHERE o.type IN ('F', 'PK', 'U') AND s.name = ", quotedSchema,
'ORDER BY o.type ASC;',
'SELECT TOP 1 @id = id, @ms_sql = ms_sql FROM @cascade ORDER BY id;',
'WHILE @id IS NOT NULL',
'BEGIN',
'BEGIN TRY EXEC sp_executesql @ms_sql; END TRY',
'BEGIN CATCH BREAK; THROW; END CATCH;',
'DELETE FROM @cascade WHERE id = @id;',
'SELECT @id = NULL, @ms_sql = NULL;',
'SELECT TOP 1 @id = id, @ms_sql = ms_sql FROM @cascade ORDER BY id;',
'END',
"EXEC sp_executesql N'DROP SCHEMA", this.quoteIdentifier(schema), ";'",
'END;'
].join(' ');
},
showSchemasQuery() { showSchemasQuery() {
return [ return [
'SELECT "name" as "schema_name" FROM sys.schemas as s', 'SELECT "name" as "schema_name" FROM sys.schemas as s',
......
...@@ -176,15 +176,14 @@ describe(Support.getTestDialectTeaser('BelongsToMany'), () => { ...@@ -176,15 +176,14 @@ describe(Support.getTestDialectTeaser('BelongsToMany'), () => {
}); });
it('should support schemas', function() { it('should support schemas', function() {
const self = this, const AcmeUser = this.sequelize.define('User', {
AcmeUser = self.sequelize.define('User', {
username: DataTypes.STRING username: DataTypes.STRING
}).schema('acme', '_'), }).schema('acme', '_'),
AcmeProject = self.sequelize.define('Project', { AcmeProject = this.sequelize.define('Project', {
title: DataTypes.STRING, title: DataTypes.STRING,
active: DataTypes.BOOLEAN active: DataTypes.BOOLEAN
}).schema('acme', '_'), }).schema('acme', '_'),
AcmeProjectUsers = self.sequelize.define('ProjectUsers', { AcmeProjectUsers = this.sequelize.define('ProjectUsers', {
status: DataTypes.STRING, status: DataTypes.STRING,
data: DataTypes.INTEGER data: DataTypes.INTEGER
}).schema('acme', '_'); }).schema('acme', '_');
...@@ -192,8 +191,8 @@ describe(Support.getTestDialectTeaser('BelongsToMany'), () => { ...@@ -192,8 +191,8 @@ describe(Support.getTestDialectTeaser('BelongsToMany'), () => {
AcmeUser.belongsToMany(AcmeProject, {through: AcmeProjectUsers}); AcmeUser.belongsToMany(AcmeProject, {through: AcmeProjectUsers});
AcmeProject.belongsToMany(AcmeUser, {through: AcmeProjectUsers}); AcmeProject.belongsToMany(AcmeUser, {through: AcmeProjectUsers});
return self.sequelize.dropAllSchemas().then(() => { return this.sequelize.dropAllSchemas().then(() => {
return self.sequelize.createSchema('acme'); return this.sequelize.createSchema('acme');
}).then(() => { }).then(() => {
return Promise.all([ return Promise.all([
AcmeUser.sync({force: true}), AcmeUser.sync({force: true}),
...@@ -216,6 +215,13 @@ describe(Support.getTestDialectTeaser('BelongsToMany'), () => { ...@@ -216,6 +215,13 @@ describe(Support.getTestDialectTeaser('BelongsToMany'), () => {
expect(project.ProjectUsers).to.be.ok; expect(project.ProjectUsers).to.be.ok;
expect(project.status).not.to.exist; expect(project.status).not.to.exist;
expect(project.ProjectUsers.status).to.equal('active'); expect(project.ProjectUsers.status).to.equal('active');
return this.sequelize.dropSchema('acme').then(() => {
return this.sequelize.showAllSchemas().then(schemas => {
if (dialect === 'postgres' || dialect === 'mssql') {
expect(schemas).to.be.empty;
}
});
});
}); });
}); });
......
...@@ -7,7 +7,8 @@ const chai = require('chai'), ...@@ -7,7 +7,8 @@ const chai = require('chai'),
DataTypes = require(__dirname + '/../../../lib/data-types'), DataTypes = require(__dirname + '/../../../lib/data-types'),
Sequelize = require('../../../index'), Sequelize = require('../../../index'),
Promise = Sequelize.Promise, Promise = Sequelize.Promise,
current = Support.sequelize; current = Support.sequelize,
dialect = Support.getTestDialect();
describe(Support.getTestDialectTeaser('BelongsTo'), () => { describe(Support.getTestDialectTeaser('BelongsTo'), () => {
describe('Model.associations', () => { describe('Model.associations', () => {
...@@ -121,13 +122,12 @@ describe(Support.getTestDialectTeaser('BelongsTo'), () => { ...@@ -121,13 +122,12 @@ describe(Support.getTestDialectTeaser('BelongsTo'), () => {
it('supports schemas', function() { it('supports schemas', function() {
const User = this.sequelize.define('UserXYZ', { username: Sequelize.STRING, gender: Sequelize.STRING }).schema('archive'), const User = this.sequelize.define('UserXYZ', { username: Sequelize.STRING, gender: Sequelize.STRING }).schema('archive'),
Task = this.sequelize.define('TaskXYZ', { title: Sequelize.STRING, status: Sequelize.STRING }).schema('archive'), Task = this.sequelize.define('TaskXYZ', { title: Sequelize.STRING, status: Sequelize.STRING }).schema('archive');
self = this;
Task.belongsTo(User); Task.belongsTo(User);
return self.sequelize.dropAllSchemas().then(() => { return this.sequelize.dropAllSchemas().then(() => {
return self.sequelize.createSchema('archive'); return this.sequelize.createSchema('archive');
}).then(() => { }).then(() => {
return User.sync({force: true }); return User.sync({force: true });
}).then(() => { }).then(() => {
...@@ -143,6 +143,13 @@ describe(Support.getTestDialectTeaser('BelongsTo'), () => { ...@@ -143,6 +143,13 @@ describe(Support.getTestDialectTeaser('BelongsTo'), () => {
}); });
}).then(user => { }).then(user => {
expect(user).to.be.ok; expect(user).to.be.ok;
return this.sequelize.dropSchema('archive').then(() => {
return this.sequelize.showAllSchemas().then(schemas => {
if (dialect === 'postgres' || dialect === 'mssql') {
expect(schemas).to.be.empty;
}
});
});
}); });
}); });
}); });
......
...@@ -317,6 +317,126 @@ describe(Support.getTestDialectTeaser('HasMany'), () => { ...@@ -317,6 +317,126 @@ describe(Support.getTestDialectTeaser('HasMany'), () => {
}); });
}); });
}); });
it('supports schemas', function() {
const User = this.sequelize.define('User', {}).schema('work'),
Task = this.sequelize.define('Task', {
title: DataTypes.STRING
}).schema('work'),
SubTask = this.sequelize.define('SubTask', {
title: DataTypes.STRING
}).schema('work');
User.Tasks = User.hasMany(Task, {as: 'tasks'});
Task.SubTasks = Task.hasMany(SubTask, {as: 'subtasks'});
return this.sequelize.dropAllSchemas().then(() => {
return this.sequelize.createSchema('work');
}).then(() => {
return User.sync({force: true});
}).then(() => {
return Task.sync({force: true});
}).then(() => {
return SubTask.sync({force: true});
}).then(() => {
return Promise.join(
User.create({
id: 1,
tasks: [
{title: 'b', subtasks: [
{title: 'c'},
{title: 'a'}
]},
{title: 'd'},
{title: 'c', subtasks: [
{title: 'b'},
{title: 'a'},
{title: 'c'}
]},
{title: 'a', subtasks: [
{title: 'c'},
{title: 'a'},
{title: 'b'}
]}
]
}, {
include: [{association: User.Tasks, include: [Task.SubTasks]}]
}),
User.create({
id: 2,
tasks: [
{title: 'a', subtasks: [
{title: 'b'},
{title: 'a'},
{title: 'c'}
]},
{title: 'c', subtasks: [
{title: 'a'}
]},
{title: 'b', subtasks: [
{title: 'a'},
{title: 'b'}
]}
]
}, {
include: [{association: User.Tasks, include: [Task.SubTasks]}]
})
);
}).then(() => {
return User.findAll({
include: [{
association: User.Tasks,
limit: 2,
order: [['title', 'ASC']],
separate: true,
as: 'tasks',
include: [
{
association: Task.SubTasks,
order: [['title', 'DESC']],
separate: true,
as: 'subtasks'
}
]
}],
order: [
['id', 'ASC']
]
}).then(users => {
expect(users[0].tasks.length).to.equal(2);
expect(users[0].tasks[0].title).to.equal('a');
expect(users[0].tasks[0].subtasks.length).to.equal(3);
expect(users[0].tasks[0].subtasks[0].title).to.equal('c');
expect(users[0].tasks[0].subtasks[1].title).to.equal('b');
expect(users[0].tasks[0].subtasks[2].title).to.equal('a');
expect(users[0].tasks[1].title).to.equal('b');
expect(users[0].tasks[1].subtasks.length).to.equal(2);
expect(users[0].tasks[1].subtasks[0].title).to.equal('c');
expect(users[0].tasks[1].subtasks[1].title).to.equal('a');
expect(users[1].tasks.length).to.equal(2);
expect(users[1].tasks[0].title).to.equal('a');
expect(users[1].tasks[0].subtasks.length).to.equal(3);
expect(users[1].tasks[0].subtasks[0].title).to.equal('c');
expect(users[1].tasks[0].subtasks[1].title).to.equal('b');
expect(users[1].tasks[0].subtasks[2].title).to.equal('a');
expect(users[1].tasks[1].title).to.equal('b');
expect(users[1].tasks[1].subtasks.length).to.equal(2);
expect(users[1].tasks[1].subtasks[0].title).to.equal('b');
expect(users[1].tasks[1].subtasks[1].title).to.equal('a');
return this.sequelize.dropSchema('work').then(() => {
return this.sequelize.showAllSchemas().then(schemas => {
if (dialect === 'postgres' || dialect === 'mssql') {
expect(schemas).to.be.empty;
}
});
});
});
});
});
}); });
} }
}); });
......
...@@ -5,7 +5,8 @@ const chai = require('chai'), ...@@ -5,7 +5,8 @@ const chai = require('chai'),
Support = require(__dirname + '/../support'), Support = require(__dirname + '/../support'),
Sequelize = require('../../../index'), Sequelize = require('../../../index'),
Promise = Sequelize.Promise, Promise = Sequelize.Promise,
current = Support.sequelize; current = Support.sequelize,
dialect = Support.getTestDialect();
describe(Support.getTestDialectTeaser('HasOne'), () => { describe(Support.getTestDialectTeaser('HasOne'), () => {
describe('Model.associations', () => { describe('Model.associations', () => {
...@@ -117,6 +118,45 @@ describe(Support.getTestDialectTeaser('HasOne'), () => { ...@@ -117,6 +118,45 @@ describe(Support.getTestDialectTeaser('HasOne'), () => {
}); });
}); });
}); });
it('supports schemas', function() {
const User = this.sequelize.define('User', { username: Support.Sequelize.STRING }).schema('admin'),
Group = this.sequelize.define('Group', { name: Support.Sequelize.STRING }).schema('admin');
Group.hasOne(User);
return this.sequelize.dropAllSchemas().then(() => {
return this.sequelize.createSchema('admin');
}).then(() => {
return Group.sync({force: true });
}).then(() => {
return User.sync({force: true });
}).then(() => {
return Promise.all([
User.create({ username: 'foo' }),
User.create({ username: 'foo' }),
Group.create({ name: 'bar' })
]);
}).spread((fakeUser, user, group) => {
return group.setUser(user).then(() => {
return Group.all().then(groups => {
return groups[0].getUser().then(associatedUser => {
expect(associatedUser).not.to.be.null;
expect(associatedUser.id).to.equal(user.id);
expect(associatedUser.id).not.to.equal(fakeUser.id);
});
});
});
}).then(() => {
return this.sequelize.dropSchema('admin').then(() => {
return this.sequelize.showAllSchemas().then(schemas => {
if (dialect === 'postgres' || dialect === 'mssql') {
expect(schemas).to.be.empty;
};
});
});
});
});
}); });
describe('setAssociation', () => { describe('setAssociation', () => {
......
...@@ -7,6 +7,7 @@ const chai = require('chai'), ...@@ -7,6 +7,7 @@ const chai = require('chai'),
Sequelize = require(__dirname + '/../../../index'), Sequelize = require(__dirname + '/../../../index'),
DataTypes = require(__dirname + '/../../../lib/data-types'), DataTypes = require(__dirname + '/../../../lib/data-types'),
current = Support.sequelize, current = Support.sequelize,
dialect = Support.getTestDialect(),
Promise = Sequelize.Promise, Promise = Sequelize.Promise,
_ = require('lodash'); _ = require('lodash');
...@@ -423,6 +424,13 @@ if (current.dialect.supports.groupedLimit) { ...@@ -423,6 +424,13 @@ if (current.dialect.supports.groupedLimit) {
expect(result[1].tasks.length).to.equal(2); expect(result[1].tasks.length).to.equal(2);
expect(result[1].tasks[0].title).to.equal('a'); expect(result[1].tasks[0].title).to.equal('a');
expect(result[1].tasks[1].title).to.equal('c'); expect(result[1].tasks[1].title).to.equal('c');
return this.sequelize.dropSchema('archive').then(() => {
return this.sequelize.showAllSchemas().then(schemas => {
if (dialect === 'postgres' || dialect === 'mssql') {
expect(schemas).to.be.empty;
}
});
});
}); });
}); });
}); });
......
...@@ -2227,13 +2227,9 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -2227,13 +2227,9 @@ describe(Support.getTestDialectTeaser('Model'), () => {
return this.sequelize.showAllSchemas().then(schemas => { return this.sequelize.showAllSchemas().then(schemas => {
expect(schemas).to.be.instanceof(Array); expect(schemas).to.be.instanceof(Array);
// FIXME: reenable when schema support is properly added // sqlite & MySQL doesn't actually create schemas unless Model.sync() is called
if (dialect !== 'mssql') { // Postgres supports schemas natively
// sqlite & MySQL doesn't actually create schemas unless Model.sync() is called expect(schemas).to.have.length(dialect === 'postgres' || dialect === 'mssql' ? 2 : 1);
// Postgres supports schemas natively
expect(schemas).to.have.length(dialect === 'postgres' ? 2 : 1);
}
}); });
}); });
...@@ -2338,7 +2334,7 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -2338,7 +2334,7 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
}; };
if (dialect === 'postgres') { if (dialect === 'postgres' || dialect === 'mssql') {
return this.sequelize.queryInterface.dropAllSchemas().then(() => { return this.sequelize.queryInterface.dropAllSchemas().then(() => {
return self.sequelize.queryInterface.createSchema('prefix').then(() => { return self.sequelize.queryInterface.createSchema('prefix').then(() => {
return run.call(self); return run.call(self);
......
...@@ -125,6 +125,12 @@ if (current.dialect.name === 'mssql') { ...@@ -125,6 +125,12 @@ if (current.dialect.name === 'mssql') {
}); });
}); });
test('dropSchema', () => {
expectsql(QueryGenerator.dropSchema('mySchema'), {
mssql: 'IF EXISTS (SELECT schema_name FROM information_schema.schemata WHERE schema_name = \'mySchema\' ) BEGIN DECLARE @id INT, @ms_sql NVARCHAR(2000); DECLARE @cascade TABLE ( id INT NOT NULL IDENTITY PRIMARY KEY, ms_sql NVARCHAR(2000) NOT NULL ); INSERT INTO @cascade ( ms_sql ) SELECT CASE WHEN o.type IN (\'F\',\'PK\') THEN N\'ALTER TABLE [\'+ s.name + N\'].[\' + p.name + N\'] DROP CONSTRAINT [\' + o.name + N\']\' ELSE N\'DROP TABLE [\'+ s.name + N\'].[\' + o.name + N\']\' END FROM sys.objects o JOIN sys.schemas s on o.schema_id = s.schema_id LEFT OUTER JOIN sys.objects p on o.parent_object_id = p.object_id WHERE o.type IN (\'F\', \'PK\', \'U\') AND s.name = \'mySchema\' ORDER BY o.type ASC; SELECT TOP 1 @id = id, @ms_sql = ms_sql FROM @cascade ORDER BY id; WHILE @id IS NOT NULL BEGIN BEGIN TRY EXEC sp_executesql @ms_sql; END TRY BEGIN CATCH BREAK; THROW; END CATCH; DELETE FROM @cascade WHERE id = @id; SELECT @id = NULL, @ms_sql = NULL; SELECT TOP 1 @id = id, @ms_sql = ms_sql FROM @cascade ORDER BY id; END EXEC sp_executesql N\'DROP SCHEMA [mySchema] ;\' END;'
});
});
test('showSchemasQuery', () => { test('showSchemasQuery', () => {
expectsql(QueryGenerator.showSchemasQuery(), { expectsql(QueryGenerator.showSchemasQuery(), {
mssql: 'SELECT "name" as "schema_name" FROM sys.schemas as s WHERE "s"."name" NOT IN ( \'INFORMATION_SCHEMA\', \'dbo\', \'guest\', \'sys\', \'archive\' ) AND "s"."name" NOT LIKE \'db_%\'' mssql: 'SELECT "name" as "schema_name" FROM sys.schemas as s WHERE "s"."name" NOT IN ( \'INFORMATION_SCHEMA\', \'dbo\', \'guest\', \'sys\', \'archive\' ) AND "s"."name" NOT LIKE \'db_%\''
......
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!