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

Commit 2949a639 by ckeboss Committed by Sushant

feat(model): add `options.include[].right` option (#11537)

1 parent 7d251bd8
...@@ -759,3 +759,49 @@ Include all also supports nested loading: ...@@ -759,3 +759,49 @@ Include all also supports nested loading:
```js ```js
User.findAll({ include: [{ all: true, nested: true }]}); User.findAll({ include: [{ all: true, nested: true }]});
``` ```
### Use right join for association
By default, associations are loaded using a left join, that is to say it only includes records from the parent table. You can change this behavior to a right join by passing the `right` property, if the dialect you are using supports it. Currenly, `sqlite` *does not* support [right joins](https://www.sqlite.org/omitted.html).
*Note:* `right` is only respected if `required` is false.
```js
User.findAll({
include: [{
model: Tool // will create a left join
}]
});
User.findAll({
include: [{
model: Tool,
right: true // will create a right join
}]
});
User.findAll({
include: [{
model: Tool,
required: true,
right: true // has no effect, will create an inner join
}]
});
User.findAll({
include: [{
model: Tool,
where: { name: { [Op.like]: '%ooth%' } },
right: true // has no effect, will create an inner join
}]
});
User.findAll({
include: [{
model: Tool,
where: { name: { [Op.like]: '%ooth%' } },
required: false
right: true // because we set `required` to false, this will create a right join
}]
});
```
...@@ -11,6 +11,7 @@ AbstractDialect.prototype.supports = { ...@@ -11,6 +11,7 @@ AbstractDialect.prototype.supports = {
'ORDER NULLS': false, 'ORDER NULLS': false,
'UNION': true, 'UNION': true,
'UNION ALL': true, 'UNION ALL': true,
'RIGHT JOIN': true,
/* does the dialect support returning values for inserted/updated fields */ /* does the dialect support returning values for inserted/updated fields */
returnValues: false, returnValues: false,
......
...@@ -1716,7 +1716,7 @@ class QueryGenerator { ...@@ -1716,7 +1716,7 @@ class QueryGenerator {
} }
return { return {
join: include.required ? 'INNER JOIN' : 'LEFT OUTER JOIN', join: include.required ? 'INNER JOIN' : include.right && this._dialect.supports['RIGHT JOIN'] ? 'RIGHT OUTER JOIN' : 'LEFT OUTER JOIN',
body: this.quoteTable(tableRight, asRight), body: this.quoteTable(tableRight, asRight),
condition: joinOn, condition: joinOn,
attributes: { attributes: {
...@@ -1750,7 +1750,7 @@ class QueryGenerator { ...@@ -1750,7 +1750,7 @@ class QueryGenerator {
const identTarget = association.foreignIdentifierField; const identTarget = association.foreignIdentifierField;
const attrTarget = association.targetKeyField; const attrTarget = association.targetKeyField;
const joinType = include.required ? 'INNER JOIN' : 'LEFT OUTER JOIN'; const joinType = include.required ? 'INNER JOIN' : include.right && this._dialect.supports['RIGHT JOIN'] ? 'RIGHT OUTER JOIN' : 'LEFT OUTER JOIN';
let joinBody; let joinBody;
let joinCondition; let joinCondition;
const attributes = { const attributes = {
......
...@@ -23,6 +23,7 @@ SqliteDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototype ...@@ -23,6 +23,7 @@ SqliteDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototype
'DEFAULT': false, 'DEFAULT': false,
'DEFAULT VALUES': true, 'DEFAULT VALUES': true,
'UNION ALL': false, 'UNION ALL': false,
'RIGHT JOIN': false,
inserts: { inserts: {
ignoreDuplicates: ' OR IGNORE', ignoreDuplicates: ' OR IGNORE',
updateOnDuplicate: ' ON CONFLICT DO UPDATE SET' updateOnDuplicate: ' ON CONFLICT DO UPDATE SET'
......
...@@ -1653,6 +1653,7 @@ class Model { ...@@ -1653,6 +1653,7 @@ class Model {
* @param {Object} [options.include[].on] Supply your own ON condition for the join. * @param {Object} [options.include[].on] Supply your own ON condition for the join.
* @param {Array<string>} [options.include[].attributes] A list of attributes to select from the child model * @param {Array<string>} [options.include[].attributes] A list of attributes to select from the child model
* @param {boolean} [options.include[].required] If true, converts to an inner join, which means that the parent model will only be loaded if it has any matching children. True if `include.where` is set, false otherwise. * @param {boolean} [options.include[].required] If true, converts to an inner join, which means that the parent model will only be loaded if it has any matching children. True if `include.where` is set, false otherwise.
* @param {boolean} [options.include[].right] If true, converts to a right join if dialect support it. Ignored if `include.required` is true.
* @param {boolean} [options.include[].separate] If true, runs a separate query to fetch the associated instances, only supported for hasMany associations * @param {boolean} [options.include[].separate] If true, runs a separate query to fetch the associated instances, only supported for hasMany associations
* @param {number} [options.include[].limit] Limit the joined rows, only supported with include.separate=true * @param {number} [options.include[].limit] Limit the joined rows, only supported with include.separate=true
* @param {Object} [options.include[].through.where] Filter on the join model for belongsToMany relations * @param {Object} [options.include[].through.where] Filter on the join model for belongsToMany relations
......
...@@ -7,7 +7,8 @@ const chai = require('chai'), ...@@ -7,7 +7,8 @@ const chai = require('chai'),
Support = require('./support'), Support = require('./support'),
DataTypes = require('../../lib/data-types'), DataTypes = require('../../lib/data-types'),
_ = require('lodash'), _ = require('lodash'),
dialect = Support.getTestDialect(); dialect = Support.getTestDialect(),
current = Support.sequelize;
const sortById = function(a, b) { const sortById = function(a, b) {
return a.id < b.id ? -1 : 1; return a.id < b.id ? -1 : 1;
...@@ -911,6 +912,104 @@ describe(Support.getTestDialectTeaser('Include'), () => { ...@@ -911,6 +912,104 @@ describe(Support.getTestDialectTeaser('Include'), () => {
}); });
}); });
describe('right join', () => {
it('should support getting an include with a right join', function() {
const User = this.sequelize.define('user', {
name: DataTypes.STRING
}),
Group = this.sequelize.define('group', {
name: DataTypes.STRING
});
User.hasMany(Group);
Group.belongsTo(User);
return this.sequelize.sync({ force: true }).then(() => {
return Promise.all([
User.create({ name: 'User 1' }),
User.create({ name: 'User 2' }),
User.create({ name: 'User 3' }),
Group.create({ name: 'A Group' })
]);
}).then(() => {
return Group.findAll({
include: [{
model: User,
right: true
}]
});
}).then(groups => {
if (current.dialect.supports['RIGHT JOIN']) {
expect(groups.length).to.equal(3);
} else {
expect(groups.length).to.equal(1);
}
});
});
it('should support getting an include through with a right join', function() {
const User = this.sequelize.define('user', {
name: DataTypes.STRING
}),
Group = this.sequelize.define('group', {
name: DataTypes.STRING
}),
UserGroup = this.sequelize.define('user_group', {
vip: DataTypes.INTEGER
});
User.hasMany(Group);
Group.belongsTo(User);
User.belongsToMany(Group, {
through: UserGroup,
as: 'Clubs',
constraints: false
});
Group.belongsToMany(User, {
through: UserGroup,
as: 'Members',
constraints: false
});
const ctx = {};
return this.sequelize.sync({ force: true }).then(() => {
return Promise.all([
User.create({ name: 'Member 1' }),
User.create({ name: 'Member 2' }),
Group.create({ name: 'Group 1' }),
Group.create({ name: 'Group 2' })
]);
}).then(([member1, member2, group1, group2]) => {
ctx.member1 = member1;
ctx.member2 = member2;
ctx.group1 = group1;
ctx.group2 = group2;
}).then(() => {
return Promise.all([
ctx.group1.addMember(ctx.member1),
ctx.group1.addMember(ctx.member2),
ctx.group2.addMember(ctx.member1)
]);
}).then(() => {
return ctx.group2.destroy();
}).then(() => {
return Group.findAll({
include: [{
model: User,
as: 'Members',
right: true
}]
});
}).then(groups => {
if (current.dialect.supports['RIGHT JOIN']) {
expect(groups.length).to.equal(2);
} else {
expect(groups.length).to.equal(1);
}
});
});
});
describe('nested includes', () => { describe('nested includes', () => {
beforeEach(function() { beforeEach(function() {
const Employee = this.sequelize.define('Employee', { 'name': DataTypes.STRING }); const Employee = this.sequelize.define('Employee', { 'name': DataTypes.STRING });
......
...@@ -53,7 +53,7 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -53,7 +53,7 @@ describe(Support.getTestDialectTeaser('Model'), () => {
{ username: 'bar' }, { username: 'bar' },
{ {
username: 'valak', username: 'valak',
createdAt: (new Date()).setFullYear(2015) createdAt: new Date().setFullYear(2015)
} }
]).then(() => this.User.count({ ]).then(() => this.User.count({
attributes: ['createdAt'], attributes: ['createdAt'],
......
...@@ -173,6 +173,22 @@ describe(Support.getTestDialectTeaser('SQL'), () => { ...@@ -173,6 +173,22 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
); );
testsql( testsql(
'include[0]',
{
model: User,
subQuery: true,
include: [
{
association: User.Company, right: true
}
]
},
{
default: `${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN [company] AS [Company] ON [User].[companyId] = [Company].[id]`
}
);
testsql(
'include[0].include[0]', 'include[0].include[0]',
{ {
subQuery: true, subQuery: true,
......
...@@ -159,7 +159,6 @@ describe(Support.getTestDialectTeaser('SQL'), () => { ...@@ -159,7 +159,6 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
}) AS [user] ORDER BY [subquery_order_0] ASC;` }) AS [user] ORDER BY [subquery_order_0] ASC;`
}); });
testsql({ testsql({
table: User.getTableName(), table: User.getTableName(),
model: User, model: User,
...@@ -374,6 +373,82 @@ describe(Support.getTestDialectTeaser('SQL'), () => { ...@@ -374,6 +373,82 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
}); });
}); });
it('include (right outer join)', () => {
const User = Support.sequelize.define('User', {
name: DataTypes.STRING,
age: DataTypes.INTEGER
},
{
freezeTableName: true
});
const Post = Support.sequelize.define('Post', {
title: DataTypes.STRING
},
{
freezeTableName: true
});
User.Posts = User.hasMany(Post, { foreignKey: 'user_id' });
expectsql(sql.selectQuery('User', {
attributes: ['name', 'age'],
include: Model._validateIncludedElements({
include: [{
attributes: ['title'],
association: User.Posts,
right: true
}],
model: User
}).include,
model: User
}, User), {
default: `SELECT [User].[name], [User].[age], [Posts].[id] AS [Posts.id], [Posts].[title] AS [Posts.title] FROM [User] AS [User] ${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN [Post] AS [Posts] ON [User].[id] = [Posts].[user_id];`
});
});
it('include through (right outer join)', () => {
const User = Support.sequelize.define('user', {
id: {
type: DataTypes.INTEGER,
primaryKey: true,
autoIncrement: true,
field: 'id_user'
}
});
const Project = Support.sequelize.define('project', {
title: DataTypes.STRING
});
const ProjectUser = Support.sequelize.define('project_user', {
userId: {
type: DataTypes.INTEGER,
field: 'user_id'
},
projectId: {
type: DataTypes.INTEGER,
field: 'project_id'
}
}, { timestamps: false });
User.Projects = User.belongsToMany(Project, { through: ProjectUser });
Project.belongsToMany(User, { through: ProjectUser });
expectsql(sql.selectQuery('User', {
attributes: ['id_user', 'id'],
include: Model._validateIncludedElements({
include: [{
model: Project,
right: true
}],
model: User
}).include,
model: User
}, User), {
default: `SELECT [user].[id_user], [user].[id], [projects].[id] AS [projects.id], [projects].[title] AS [projects.title], [projects].[createdAt] AS [projects.createdAt], [projects].[updatedAt] AS [projects.updatedAt], [projects->project_user].[user_id] AS [projects.project_user.userId], [projects->project_user].[project_id] AS [projects.project_user.projectId] FROM [User] AS [user] ${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN ( [project_users] AS [projects->project_user] INNER JOIN [projects] AS [projects] ON [projects].[id] = [projects->project_user].[project_id]) ON [user].[id_user] = [projects->project_user].[user_id];`,
sqlite: `SELECT \`user\`.\`id_user\`, \`user\`.\`id\`, \`projects\`.\`id\` AS \`projects.id\`, \`projects\`.\`title\` AS \`projects.title\`, \`projects\`.\`createdAt\` AS \`projects.createdAt\`, \`projects\`.\`updatedAt\` AS \`projects.updatedAt\`, \`projects->project_user\`.\`user_id\` AS \`projects.project_user.userId\`, \`projects->project_user\`.\`project_id\` AS \`projects.project_user.projectId\` FROM \`User\` AS \`user\` ${current.dialect.supports['RIGHT JOIN'] ? 'RIGHT' : 'LEFT'} OUTER JOIN \`project_users\` AS \`projects->project_user\` ON \`user\`.\`id_user\` = \`projects->project_user\`.\`user_id\` LEFT OUTER JOIN \`projects\` AS \`projects\` ON \`projects\`.\`id\` = \`projects->project_user\`.\`project_id\`;`
});
});
it('include (subQuery alias)', () => { it('include (subQuery alias)', () => {
const User = Support.sequelize.define('User', { const User = Support.sequelize.define('User', {
name: DataTypes.STRING, name: DataTypes.STRING,
......
...@@ -421,6 +421,11 @@ export interface IncludeOptions extends Filterable, Projectable, Paranoid { ...@@ -421,6 +421,11 @@ export interface IncludeOptions extends Filterable, Projectable, Paranoid {
required?: boolean; required?: boolean;
/** /**
* If true, converts to a right join if dialect support it. Ignored if `include.required` is true.
*/
right?: boolean;
/**
* Limit include. Only available when setting `separate` to true. * Limit include. Only available when setting `separate` to true.
*/ */
limit?: number; limit?: number;
......
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!